DBCC SHOW_STATISTICS (Transact-SQL)DBCC SHOW_STATISTICS (Transact-SQL)

適用於: 是SQL Server 是Azure SQL Database 是Azure SQL 資料倉儲 是平行處理資料倉儲 APPLIES TO: yesSQL Server yesAzure SQL Database yesAzure SQL Data Warehouse yesParallel Data Warehouse

DBCC SHOW_STATISTICS 會針對資料表或索引檢視表顯示目前的查詢最佳化統計資料。DBCC SHOW_STATISTICS displays current query optimization statistics for a table or indexed view. 查詢最佳化工具會使用統計資料來預估基數或查詢結果中的資料列數,如此可讓查詢最佳化工具建立高品質的查詢計畫。The query optimizer uses statistics to estimate the cardinality or number of rows in the query result, which enables the query optimizer to create a high quality query plan. 例如,查詢最佳化工具可使用基數預估來選擇查詢計畫中的索引搜尋運算子,而不是索引掃描運算子,避免發生資源密集的索引掃描來提高查詢效能。For example, the query optimizer could use cardinality estimates to choose the index seek operator instead of the index scan operator in the query plan, improving query performance by avoiding a resource-intensive index scan.

查詢最佳化工具會將資料表或索引檢視表的統計資料儲存在統計資料物件中。The query optimizer stores statistics for a table or indexed view in a statistics object. 如果是資料表,將會在索引或資料表資料行清單上建立統計資料物件。For a table, the statistics object is created on either an index or a list of table columns. 統計資料物件包含標頭 (其中包含有關統計資料的中繼資料)、長條圖 (包含統計資料物件之第一個索引鍵資料行中的值分佈),以及用來測量跨資料行關聯的密度向量。The statistics object includes a header with metadata about the statistics, a histogram with the distribution of values in the first key column of the statistics object, and a density vector to measure cross-column correlation. Database EngineDatabase Engine 可以使用統計資料物件中的任何資料來計算基數預估。The Database EngineDatabase Engine can compute cardinality estimates with any of the data in the statistics object.

DBCC SHOW_STATISTICS 會根據儲存在統計資料物件中的資料來顯示標頭、長條圖和密度向量。DBCC SHOW_STATISTICS displays the header, histogram, and density vector based on data stored in the statistics object. 此語法可讓您指定資料表或索引檢視表,連同目標索引名稱、統計資料名稱或資料行名稱。The syntax lets you specify a table or indexed view along with a target index name, statistics name, or column name. 此主題描述如何顯示統計資料以及如何了解顯示的結果。This topic describes how to display the statistics and how to understand the displayed results.

如需詳細資訊,請參閱 StatisticsFor more information, see Statistics.

主題連結圖示 Transact-SQL 語法慣例Topic link icon Transact-SQL Syntax Conventions

語法Syntax

-- Syntax for SQL Server and Azure SQL Database  
  
DBCC SHOW_STATISTICS ( table_or_indexed_view_name , target )   
[ WITH [ NO_INFOMSGS ] < option > [ , n ] ]  
< option > :: =  
    STAT_HEADER | DENSITY_VECTOR | HISTOGRAM | STATS_STREAM  
-- Syntax for Azure SQL Data Warehouse and Parallel Data Warehouse  

DBCC SHOW_STATISTICS ( table_name , target )   
    [ WITH {STAT_HEADER | DENSITY_VECTOR | HISTOGRAM } [ ,...n ] ]  
[;]  

引數Arguments

table_or_indexed_view_nametable_or_indexed_view_name
要顯示統計資料資訊之資料表或索引檢視表的名稱。Name of the table or indexed view for which to display statistics information.

table_nametable_name
包含要顯示之統計資料的資料表名稱。Name of the table that contains the statistics to display. 資料表不得為外部資料表。The table cannot be an external table.

目標target
要顯示統計資料資訊之索引、統計資料或資料行的名稱。Name of the index, statistics, or column for which to display statistics information. 「目標」 以括號、單引號、雙引號括住,或是沒有引號。target is enclosed in brackets, single quotes, double quotes, or no quotes. 如果「目標」 是資料表或索引檢視表上現有索引或統計資料的名稱,便會傳回這個目標的相關統計資料資訊。If target is a name of an existing index or statistics on a table or indexed view, the statistics information about this target is returned. 如果「目標」 是現有資料行的名稱,而且這個資料行含有自動建立的統計資料,便會傳回自動建立之統計資料的相關資訊。If target is the name of an existing column, and an automatically created statistics on this column exists, information about that auto-created statistic is returned. 如果資料行目標之自動建立的統計資料不存在,就會傳回錯誤訊息 2767。If an automatically created statistic does not exist for a column target, error message 2767 is returned.
SQL 資料倉儲SQL Data Warehouse平行處理資料倉儲Parallel Data Warehouse 中,「目標」 不可以是資料行名稱。In SQL 資料倉儲SQL Data Warehouse and 平行處理資料倉儲Parallel Data Warehouse, target cannot be a column name.

NO_INFOMSGSNO_INFOMSGS
抑制所有嚴重性層級在 0 到 10 的參考用訊息。Suppresses all informational messages that have severity levels from 0 through 10.

STAT_HEADER | DENSITY_VECTOR | HISTOGRAM | STATS_STREAM [ , n ]STAT_HEADER | DENSITY_VECTOR | HISTOGRAM | STATS_STREAM [ ,n ]
如果指定其中一或多個選項,就會限制陳述式針對指定之選項所傳回的結果集。Specifying one or more of these options limits the result sets returned by the statement to the specified option or options. 如果沒有指定任何選項,便會傳回所有的統計資料資訊。If no options are specified, all statistics information is returned.

STATS_STREAM 是 僅供參考之用。Identified for informational purposes only. 不支援。Not supported. 我們無法保證未來的相容性。Future compatibility is not guaranteed.STATS_STREAM is 僅供參考之用。Identified for informational purposes only. 不支援。Not supported. 我們無法保證未來的相容性。Future compatibility is not guaranteed.

結果集Result Sets

下表描述指定 STAT_HEADER 時,結果集所傳回的資料行。The following table describes the columns returned in the result set when STAT_HEADER is specified.

資料行名稱Column name DescriptionDescription
[屬性]Name 統計資料物件的名稱。Name of the statistics object.
已更新Updated 上次更新統計資料的日期和時間。Date and time the statistics were last updated. STATS_DATE 函數是擷取這項資訊的替代方式。The STATS_DATE function is an alternate way to retrieve this information. 如需詳細資訊,請參閱此頁的備註一節。For more information, see the Remarks section in this page.
資料列Rows 上一次更新統計資料時位於資料表或索引檢視表中的資料列總數。Total number of rows in the table or indexed view when the statistics were last updated. 如果篩選了統計資料或是統計資料對應至篩選過的索引,此資料列數可能會少於資料表中的資料列數。If the statistics are filtered or correspond to a filtered index, the number of rows might be less than the number of rows in the table. 如需詳細資訊,請參閱統計資料For more information, seeStatistics.
取樣的資料列Rows Sampled 針對統計資料計算進行取樣的資料列總數。Total number of rows sampled for statistics calculations. 如果取樣的資料列數 < 資料列數,顯示的長條圖和密度結果將會是根據取樣資料列數的預估值。If Rows Sampled < Rows, the displayed histogram and density results are estimates based on the sampled rows.
步驟Steps 長條圖中的步驟數。Number of steps in the histogram. 每一個步驟都會跨越某個範圍的資料行值,後面緊接著上限資料行值。Each step spans a range of column values followed by an upper bound column value. 長條圖步驟會在統計資料中的第一個索引鍵資料行上定義。The histogram steps are defined on the first key column in the statistics. 步驟數的最大值為 200。The maximum number of steps is 200.
密度Density 針對統計資料物件第一個索引鍵資料行中的所有值,計算為 1 / 相異值 ,不包括長條圖界限值。Calculated as 1 / distinct values for all values in the first key column of the statistics object, excluding the histogram boundary values. 查詢最佳化工具不會使用這個 Density 值,而且會針對與 SQL Server 2008SQL Server 2008 之前版本之間的回溯相容性顯示。This Density value is not used by the query optimizer and is displayed for backward compatibility with versions before SQL Server 2008SQL Server 2008.
平均索引鍵長度Average Key Length 針對統計資料物件中的所有索引鍵資料行計算之每個值的平均位元組數。Average number of bytes per value for all of the key columns in the statistics object.
String IndexString Index Yes 表示統計資料物件包含了字串摘要統計資料來改善使用 LIKE 運算子之查詢述詞的基數預估,例如 WHERE ProductName LIKE '%Bike'Yes indicates the statistics object contains string summary statistics to improve the cardinality estimates for query predicates that use the LIKE operator; for example, WHERE ProductName LIKE '%Bike'. 字串摘要統計資料會與長條圖分開儲存,而且會在具有 charvarcharncharnvarcharvarchar(max)nvarchar(max)textntext 類型時於統計資料物件的第一個索引鍵資料行上建立。String summary statistics are stored separately from the histogram and are created on the first key column of the statistics object when it is of type char, varchar, nchar, nvarchar, varchar(max), nvarchar(max), text, or ntext..
篩選運算式Filter Expression 包含在統計資料物件中之資料表資料列子集的述詞。Predicate for the subset of table rows included in the statistics object. NULL = 非篩選的統計資料。NULL = non-filtered statistics. 如需篩選述詞的詳細資訊,請參閱建立篩選的索引For more information about filtered predicates, see Create Filtered Indexes. 如需已篩選統計資料的詳細資訊,請參閱統計資料For more information about filtered statistics, see Statistics.
Unfiltered RowsUnfiltered Rows 套用篩選運算式之前,資料表中的資料列總數。Total number of rows in the table before applying the filter expression. 如果 Filter Expression 為 NULL,Unfiltered Rows 就會等於 Rows。If Filter Expression is NULL, Unfiltered Rows is equal to Rows.
保存取樣百分比Persisted Sample Percent 使用於未明確指定取樣百分比之統計資料更新的保存取樣百分比。Persisted sample percentage used for statistic updates that do not explicitly specify a sampling percentage. 如果值為零,表示這個統計資料未設定保存取樣百分比。If value is zero, then no persisted sample percentage is set for this statistic.

適用於: SQL Server 2016 (13.x)SQL Server 2016 (13.x) SP1 CU4Applies to: SQL Server 2016 (13.x)SQL Server 2016 (13.x) SP1 CU4

下表描述指定 DENSITY_VECTOR 時,結果集所傳回的資料行。The following table describes the columns returned in the result set when DENSITY_VECTOR is specified.

資料行名稱Column name DescriptionDescription
所有密度All Density 密度是 1 / 相異值 。Density is 1 / distinct values. 結果會針對統計資料物件中資料行的每個前置詞來顯示密度,一個密度一個資料列。Results display density for each prefix of columns in the statistics object, one row per density. 相異值是每個資料列和每個資料行前置詞的資料行值相異清單。A distinct value is a distinct list of the column values per row and per columns prefix. 例如,如果統計資料物件包含索引鍵資料行 (A, B, C),結果就會報告每一個資料行前置詞中相異值清單的密度:(A)、(A,B) 和 (A, B, C)。For example, if the statistics object contains key columns (A, B, C), the results report the density of the distinct lists of values in each of these column prefixes: (A), (A,B), and (A, B, C). 使用前置詞 (A, B, C) 時,這些清單的每一個都會是相異值清單:(3, 5, 6)、(4, 4, 6)、(4, 5, 6)、(4, 5, 7)。Using the prefix (A, B, C), each of these lists is a distinct value list: (3, 5, 6), (4, 4, 6), (4, 5, 6), (4, 5, 7). 使用前置詞 (A, B) 時,相同的資料行值都會有這些相異值清單:(3, 5)、(4, 4) 和 (4, 5)Using the prefix (A, B) the same column values have these distinct value lists: (3, 5), (4, 4), and (4, 5)
平均長度Average Length 平均長度 (以位元組為單位),用來儲存資料行前置詞的資料行值清單。Average length, in bytes, to store a list of the column values for the column prefix. 例如,如果清單 (3, 5, 6) 中的每一個值都需要 4 位元組,長度就是 12 位元組。For example, if the values in the list (3, 5, 6) each require 4 bytes the length is 12 bytes.
[資料行]Columns 在前置詞中顯示 All density 和 Average length 的資料行名稱。Names of columns in the prefix for which All density and Average length are displayed.

下表描述指定 HISTOGRAM 選項時,結果集所傳回的資料行。The following table describes the columns returned in the result set when the HISTOGRAM option is specified.

資料行名稱Column name DescriptionDescription
RANGE_HI_KEYRANGE_HI_KEY 長條圖步驟的上限資料行值。Upper bound column value for a histogram step. 此資料行值也稱為索引鍵值。The column value is also called a key value.
RANGE_ROWSRANGE_ROWS 資料行值在長條圖步驟內的預估資料列數,不包括上限。Estimated number of rows whose column value falls within a histogram step, excluding the upper bound.
EQ_ROWSEQ_ROWS 資料行值等於長條圖步驟之上限的預估資料列數。Estimated number of rows whose column value equals the upper bound of the histogram step.
DISTINCT_RANGE_ROWSDISTINCT_RANGE_ROWS 在長條圖步驟內具有相異資料行值的預估資料列數,不包括上限。Estimated number of rows with a distinct column value within a histogram step, excluding the upper bound.
AVG_RANGE_ROWSAVG_RANGE_ROWS 在長條圖步驟內具有重複資料行值的平均資料列數,不包括上限。Average number of rows with duplicate column values within a histogram step, excluding the upper bound. 當 DISTINCT_RANGE_ROWS 大於 0 時,AVG_RANGE_ROWS 的計算方式為 RANGE_ROWS 除以 DISTINCT_RANGE_ROWS。When DISTINCT_RANGE_ROWS is greater than 0, AVG_RANGE_ROWS is calculated by dividing RANGE_ROWS by DISTINCT_RANGE_ROWS. 當 DISTINCT_RANGE_ROWS 為 0 時,AVG_RANGE_ROWS 會針對長條圖步驟傳回 1。When DISTINCT_RANGE_ROWS is 0, AVG_RANGE_ROWS returns 1 for the histogram step.

備註Remarks

統計資料更新日期儲存在統計資料 Blob 物件中,其中還有長條圖密度向量,不是儲存在中繼資料中。Statistics update date is stored in the statistics blob object together with the histogram and density vector, not in the metadata. 如果沒有讀取資料以產生統計資料,則不會建立統計 Blob、沒有日期,且「已更新」 資料行為 NULL。When no data is read to generate statistics data, the statistics blob is not created, the date is not available, and the updated column is NULL. 這是已篩選統計資料的情況,其中述詞未傳回任何資料列,或為新的空白資料表的情況。This is the case for filtered statistics for which the predicate does not return any rows, or for new empty tables.

長條圖Histogram

長條圖會測量資料集中每一個相異值的發生頻率。A histogram measures the frequency of occurrence for each distinct value in a data set. 查詢最佳化工具會計算有關統計資料物件之第一個索引鍵資料行中資料行值的長條圖,以統計方式取樣資料列或執行資料表或檢視表中所有資料列的完整掃描來選取資料行值。The query optimizer computes a histogram on the column values in the first key column of the statistics object, selecting the column values by statistically sampling the rows or by performing a full scan of all rows in the table or view. 如果長條圖是從一組取樣的資料列所建立,資料列數和相異值數的儲存總計會是預估值,而且不需要為整數。If the histogram is created from a sampled set of rows, the stored totals for number of rows and number of distinct values are estimates and do not need to be whole integers.

若要建立長條圖,查詢最佳化工具會排序資料行值、計算符合每一個相異資料行值的值數目,然後將資料行值彙總成最多 200 個連續長條圖步驟。To create the histogram, the query optimizer sorts the column values, computes the number of values that match each distinct column value and then aggregates the column values into a maximum of 200 contiguous histogram steps. 每一個步驟都包含某個範圍的資料行值,後面緊接著上限資料行值。Each step includes a range of column values followed by an upper bound column value. 此範圍包括界限值之間的所有可能資料行值,但是不包括界限值本身。The range includes all possible column values between boundary values, excluding the boundary values themselves. 最低的已排序資料行值就是第一個長條圖步驟的上限值。The lowest of the sorted column values is the upper boundary value for the first histogram step.

下列長條圖顯示包含六個步驟的長條圖。The following diagram shows a histogram with six steps. 第一個上限值左側的區域就是第一個步驟。The area to the left of the first upper boundary value is the first step.

每一個長條圖步驟:For each histogram step:

  • 粗線代表上限值 (RANGE_HI_KEY) 以及其所發生的次數 (EQ_ROWS)Bold line represents the upper boundary value (RANGE_HI_KEY) and the number of times it occurs (EQ_ROWS)
  • RANGE_HI_KEY 左邊的實線區域代表資料行值範圍以及每一個資料行值發生的平均次數 (AVG_RANGE_ROWS)。Solid area left of RANGE_HI_KEY represents the range of column values and the average number of times each column value occurs (AVG_RANGE_ROWS). 第一個長條圖步驟的 AVG_RANGE_ROWS 一定是 0。The AVG_RANGE_ROWS for the first histogram step is always 0.
  • 虛線代表用來預估範圍內相異值總數的取樣值 (DISTINCT_RANGE_ROWS) 以及範圍內的值總數 (RANGE_ROWS)。Dotted lines represent the sampled values used to estimate total number of distinct values in the range (DISTINCT_RANGE_ROWS) and total number of values in the range (RANGE_ROWS). 查詢最佳化工具會使用 RANGE_ROWS 和 DISTINCT_RANGE_ROWS 來計算 AVG_RANGE_ROWS,而且不會儲存取樣值。The query optimizer uses RANGE_ROWS and DISTINCT_RANGE_ROWS to compute AVG_RANGE_ROWS and does not store the sampled values.

查詢最佳化工具會根據長條圖步驟的統計重要性來定義長條圖步驟。The query optimizer defines the histogram steps according to their statistical significance. 它會使用最大值差異演算法,讓長條圖中的步驟數減至最少,同時讓界限值之間的差異最大化。It uses a maximum difference algorithm to minimize the number of steps in the histogram while maximizing the difference between the boundary values. 步驟數的最大值為 200。The maximum number of steps is 200. 長條圖步驟的數目可以少於相異值數目,即使包含了少於 200 個界限點的資料行也是如此。The number of histogram steps can be fewer than the number of distinct values, even for columns with fewer than 200 boundary points. 例如,包含 100 個相異值的資料行可以擁有少於 100 個界限點的長條圖。For example, a column with 100 distinct values can have a histogram with fewer than 100 boundary points.

密度向量Density Vector

查詢最佳化工具會使用密度來增強查詢的基數預估,這些查詢會從相同的資料表或索引檢視表傳回多個資料行。The query optimizer uses densities to enhance cardinality estimates for queries that return multiple columns from the same table or indexed view. 密度向量針對統計資料物件中資料行的每個前置詞各包含一個密度。The density vector contains one density for each prefix of columns in the statistics object. 例如,如果統計資料物件具有 CustomerIdItemIdPrice 等索引鍵資料行,就會根據下列每一個資料行前置詞來計算密度。For example, if a statistics object has the key columns CustomerId, ItemId and Price, density is calculated on each of the following column prefixes.

資料行前置詞Column prefix 計算密度的依據Density calculated on
(CustomerId)(CustomerId) 與 CustomerId 的值相符的資料列Rows with matching values for CustomerId
(CustomerId, ItemId)(CustomerId, ItemId) 與 CustomerId 和 ItemId 的值相符的資料列Rows with matching values for CustomerId and ItemId
(CustomerId, ItemId, Price)(CustomerId, ItemId, Price) 與 CustomerId、ItemId 和 Price 的值相符的資料列Rows with matching values for CustomerId, ItemId, and Price

限制Restrictions

DBCC SHOW_STATISTICS 不會提供空間或 xVelocity 記憶體最佳化的資料行存放區索引之統計資料。DBCC SHOW_STATISTICS does not provide statistics for spatial or xVelocity memory optimized columnstore indexes.

SQL ServerSQL ServerSQL DatabaseSQL Database 的權限Permissions for SQL ServerSQL Server and SQL DatabaseSQL Database

使用者必須擁有資料表,或者使用者必須是系統管理員 (sysadmin) 固定伺服器角色、db_owner 固定資料庫角色或 db_ddladmin 固定資料庫角色的成員,才能檢視統計資料物件。In order to view the statistics object, the user must own the table or the user must be a member of the sysadmin fixed server role, the db_owner fixed database role, or the db_ddladmin fixed database role.

SQL Server 2012 (11.x)SQL Server 2012 (11.x) SP1 修改了權限限制,允許具有 SELECT 權限的使用者使用此命令。SP1 modifies the permission restrictions and allows users with SELECT permission to use this command. 請注意,必須先符合下列需求,足夠的 SELECT 權限才能執行此命令:Note that the following requirements exist for SELECT permissions to be sufficient to run the command:

  • 使用者必須有統計資料物件的所有資料行的權限Users must have permissions on all columns in the statistics object
  • 使用者必須有篩選條件 (如果有) 的所有資料行的權限Users must have permission on all columns in a filter condition (if one exists)
  • 資料表不能有資料列層級安全性原則。The table cannot have a row-level security policy.

若要停用此行為,請使用追蹤旗標 9485。To disable this behavior, use traceflag 9485.

SQL 資料倉儲SQL Data Warehouse平行處理資料倉儲Parallel Data Warehouse 的權限Permissions for SQL 資料倉儲SQL Data Warehouse and 平行處理資料倉儲Parallel Data Warehouse

DBCC SHOW_STATISTICS 需要資料表上的 SELECT 權限或下列其中一項的成員資格:DBCC SHOW_STATISTICS requires SELECT permission on the table or membership in one of the following:

  • sysadmin 固定伺服器角色sysadmin fixed server role
  • db_owner 固定資料庫角色db_owner fixed database role
  • db_ddladmin 固定資料庫角色db_ddladmin fixed database role

SQL 資料倉儲SQL Data Warehouse平行處理資料倉儲Parallel Data Warehouse 的限制事項Limitations and Restrictions for SQL 資料倉儲SQL Data Warehouse and 平行處理資料倉儲Parallel Data Warehouse

DBCC SHOW_STATISTICS 會顯示在控制節點層級的 Shell 資料庫中儲存的統計資料。DBCC SHOW_STATISTICS shows statistics stored in the Shell database at the Control node level. 不會顯示 SQL ServerSQL Server 在計算節點上自動建立的統計資料。It does not show statistics that are auto-created by SQL ServerSQL Server on the Compute nodes.

不支援在外部資料表上使用 DBCC SHOW_STATISTICS。DBCC SHOW_STATISTICS is not supported on external tables.

範例:SQL ServerSQL ServerSQL DatabaseSQL DatabaseExamples: SQL ServerSQL Server and SQL DatabaseSQL Database

A.A. 傳回所有的統計資料資訊Returning all statistics information

下列範例會顯示 AdventureWorks2012AdventureWorks2012 資料庫中 Person.Address 資料表之 AK_Address_rowguid 索引的所有統計資料資訊。The following example displays all statistics information for the AK_Address_rowguid index of the Person.Address table in the AdventureWorks2012AdventureWorks2012 database.

DBCC SHOW_STATISTICS ("Person.Address", AK_Address_rowguid);  
GO  

B.B. 指定 HISTOGRAM 選項Specifying the HISTOGRAM option

這會限制 Customer_LastName 顯示的統計資料資訊是 HISTOGRAM 資料。This limits the statistics information displayed for Customer_LastName to the HISTOGRAM data.

DBCC SHOW_STATISTICS ("dbo.DimCustomer",Customer_LastName) WITH HISTOGRAM;  
GO  

範例:SQL 資料倉儲SQL Data Warehouse平行處理資料倉儲Parallel Data WarehouseExamples: SQL 資料倉儲SQL Data Warehouse and 平行處理資料倉儲Parallel Data Warehouse

C.C. 顯示一個統計資料物件的內容Display the contents of one statistics object

下列範例會顯示 DimCustomer 資料表上 Customer_LastName 統計資料的內容。The following example displays the contents of the Customer_LastName statistics on the DimCustomer table.

-- Uses AdventureWorks  
--First, create a statistics object  
CREATE STATISTICS Customer_LastName   
ON AdventureWorksPDW2012.dbo.DimCustomer (LastName);  
GO  
DBCC SHOW_STATISTICS ("dbo.DimCustomer",Customer_LastName);  
GO  

結果會顯示標頭、密度向量和部分長條圖。The results show the header, the density vector, and part of the histogram.

DBCC SHOW_STATISTICS 結果DBCC SHOW_STATISTICS results

另請參閱See Also

統計資料Statistics
CREATE INDEX (Transact-SQL)CREATE INDEX (Transact-SQL)
CREATE STATISTICS (TRANSACT-SQL)CREATE STATISTICS (Transact-SQL)
DROP STATISTICS (Transact-SQL)DROP STATISTICS (Transact-SQL)
sp_autostats (Transact-SQL)sp_autostats (Transact-SQL)
sp_createstats (Transact-SQL)sp_createstats (Transact-SQL)
STATS_DATE (Transact-SQL)STATS_DATE (Transact-SQL)
UPDATE STATISTICS (Transact-SQL)UPDATE STATISTICS (Transact-SQL)
sys.dm_db_stats_properties (Transact-SQL)sys.dm_db_stats_properties (Transact-SQL)
sys.dm_db_stats_histogram (Transact-SQL)sys.dm_db_stats_histogram (Transact-SQL)