適用於:SQL Server Azure SQL 資料庫 Azure SQL 受控執行個體 Azure Synapse Analytics Microsoft Fabric 中的 SQL 分析端點 Microsoft Fabric 中的倉儲
本主題包含常見問題清單。 這些問題的解答是以目錄檢視為基礎的查詢。
常見問題集
Data types (資料類型)
數據表、索引、檢視表和條件約束
模組 (預存程式、使用者定義函式和觸發程式)
架構、使用者、角色和許可權
回答
執行下列查詢之前,請將 取代 <database_name>
為有效的資料庫名稱。
SELECT SCHEMA_NAME(t.schema_id) AS schema_name, t.name AS table_name
FROM sys.tables AS t
WHERE NOT EXISTS
(
SELECT * FROM sys.indexes AS i
WHERE i.object_id = t.object_id
AND i.type = 1 -- or type_desc = 'CLUSTERED'
)
ORDER BY schema_name, table_name;
GO
或者,您可以使用 函 OBJECTPROPERTY
式,如下列範例所示。
USE <database_name>;
GO
SELECT SCHEMA_NAME(schema_id) AS schema_name, name AS table_name
FROM sys.tables
WHERE OBJECTPROPERTY(object_id,'TableHasClustIndex') = 0
ORDER BY schema_id, name;
GO
執行下列查詢之前,請將 和 <schema_name>
取代<database_name>
為有效的名稱。
USE <database_name>;
GO
SELECT 'OBJECT' AS entity_type
,USER_NAME(OBJECTPROPERTY(object_id, 'OwnerId')) AS owner_name
,name
FROM sys.objects WHERE SCHEMA_NAME(schema_id) = '<schema_name>'
UNION
SELECT 'TYPE' AS entity_type
,USER_NAME(TYPEPROPERTY(SCHEMA_NAME(schema_id) + '.' + name, 'OwnerId')) AS owner_name
,name
FROM sys.types WHERE SCHEMA_NAME(schema_id) = '<schema_name>'
UNION
SELECT 'XML SCHEMA COLLECTION' AS entity_type
,COALESCE(USER_NAME(xsc.principal_id),USER_NAME(s.principal_id)) AS owner_name
,xsc.name
FROM sys.xml_schema_collections AS xsc JOIN sys.schemas AS s
ON s.schema_id = xsc.schema_id
WHERE s.name = '<schema_name>';
GO
執行下列查詢之前,請將 取代 <database_name>
為有效的資料庫名稱。
USE <database_name>;
GO
SELECT SCHEMA_NAME(t.schema_id) AS schema_name
,t.name AS table_name
FROM sys.tables t
WHERE object_id NOT IN
(
SELECT parent_object_id
FROM sys.key_constraints
WHERE type_desc = 'PRIMARY_KEY_CONSTRAINT' -- or type = 'PK'
);
GO
或者,您可以執行下列查詢。
USE <database_name>;
GO
SELECT SCHEMA_NAME(schema_id) AS schema_name
,name AS table_name
FROM sys.tables
WHERE OBJECTPROPERTY(object_id,'TableHasPrimaryKey') = 0
ORDER BY schema_name, table_name;
GO
執行下列查詢之前,請將 取代 <database_name>
為有效的資料庫名稱。
USE <database_name>;
GO
SELECT SCHEMA_NAME(schema_id) AS schema_name
,name AS table_name
FROM sys.tables
WHERE OBJECTPROPERTY(object_id,'IsIndexed') = 0
ORDER BY schema_name, table_name;
GO
執行下列查詢之前,請將 取代 <database_name>
為有效的資料庫名稱。
USE <database_name>;
GO
SELECT SCHEMA_NAME(schema_id) AS schema_name
, t.name AS table_name
, c.name AS column_name
FROM sys.tables AS t
JOIN sys.identity_columns c ON t.object_id = c.object_id
ORDER BY schema_name, table_name;
GO
或者,您可以執行下列查詢。
注意
此查詢不會傳回資料行的名稱。
USE <database_name>;
GO
SELECT SCHEMA_NAME(schema_id) AS schema_name
,name AS table_name
FROM sys.tables
WHERE OBJECTPROPERTY(object_id,'TableHasIdentity') = 1
ORDER BY schema_name, table_name;
GO
執行下列查詢之前,請將 和 <schema_name.table_name>
取代<database_name>
為有效的名稱。
USE <database_name>;
GO
SELECT c.name AS column_name
,c.column_id
,SCHEMA_NAME(t.schema_id) AS type_schema
,t.name AS type_name
,t.is_user_defined
,t.is_assembly_type
,c.max_length
,c.precision
,c.scale
FROM sys.columns AS c
JOIN sys.types AS t ON c.user_type_id=t.user_type_id
WHERE c.object_id = OBJECT_ID('<schema_name.table_name>')
ORDER BY c.column_id;
GO
執行下列查詢之前,請將 和 <schema_name.function_name>
取代<database_name>
為有效的名稱。
USE <database_name>;
GO
SELECT OBJECT_NAME(object_id) AS referencing_object_name
,COALESCE(COL_NAME(object_id, column_id), '(n/a)') AS referencing_column_name
,*
FROM sys.sql_dependencies
WHERE referenced_major_id = OBJECT_ID('<schema_name.function_name>')
ORDER BY OBJECT_NAME(object_id), COL_NAME(object_id, column_id);
GO
執行下列查詢之前,請將 取代 <database_name>
為有效的名稱。
USE <database_name>;
GO
SELECT name AS procedure_name
,SCHEMA_NAME(schema_id) AS schema_name
,type_desc
,create_date
,modify_date
FROM sys.procedures;
GO
執行下列查詢之前,請將 和 <schema_name.object_name>
取代<database_name>
為有效的名稱。
USE <database_name>;
GO
SELECT SCHEMA_NAME(schema_id) AS schema_name
,o.name AS object_name
,o.type_desc
,p.parameter_id
,p.name AS parameter_name
,TYPE_NAME(p.user_type_id) AS parameter_type
,p.max_length
,p.precision
,p.scale
,p.is_output
FROM sys.objects AS o
INNER JOIN sys.parameters AS p ON o.object_id = p.object_id
WHERE o.object_id = OBJECT_ID('<schema_name.object_name>')
ORDER BY schema_name, object_name, p.parameter_id;
GO
執行下列查詢之前,請將 取代 <database_name>
為有效的資料庫名稱。
USE <database_name>;
GO
SELECT name AS function_name
,SCHEMA_NAME(schema_id) AS schema_name
,type_desc
,create_date
,modify_date
FROM sys.objects
WHERE type_desc LIKE '%FUNCTION%';
GO
執行下列查詢之前,請將 取代 <database_name>
為有效的資料庫名稱。
USE <database_name>;
GO
SELECT name AS view_name
,SCHEMA_NAME(schema_id) AS schema_name
,OBJECTPROPERTYEX(object_id,'IsIndexed') AS IsIndexed
,OBJECTPROPERTYEX(object_id,'IsIndexable') AS IsIndexable
,create_date
,modify_date
FROM sys.views;
執行下列查詢之前,請將 和 <n_days>
取代<database_name>
為有效的值。
USE <database_name>;
GO
SELECT name AS object_name
,SCHEMA_NAME(schema_id) AS schema_name
,type_desc
,create_date
,modify_date
FROM sys.objects
WHERE modify_date > GETDATE() - <n_days>
ORDER BY modify_date;
GO
執行下列查詢之前,請將 和 <schema_name.table_name>
取代<database_name>
為有效的名稱。
USE <database_name>;
GO
SELECT name AS column_name
,column_id
,TYPE_NAME(user_type_id) AS type_name
,max_length
,CASE
WHEN max_length = -1 AND TYPE_NAME(user_type_id) <> 'xml'
THEN 1
ELSE 0
END AS [(max)]
FROM sys.columns
WHERE object_id=OBJECT_ID('<schema_name.table_name>')
AND ( TYPE_NAME(user_type_id) IN ('xml','text', 'ntext','image')
OR (TYPE_NAME(user_type_id) IN ('varchar','nvarchar','varbinary')
AND max_length = -1)
);
GO
執行下列查詢之前,請將 和 <schema_name.object_name>
取代<database_name>
為有效的名稱。
USE <database_name>;
GO
SELECT definition
FROM sys.sql_modules
WHERE object_id = OBJECT_ID('<schema_name.object_name>');
GO
或者,您可以使用 函 OBJECT_DEFINITION
式,如下列範例所示。
USE <database_name>;
GO
SELECT OBJECT_DEFINITION (OBJECT_ID('<schema_name.object_name>')) AS ObjectDefinition;
GO
SELECT definition
FROM sys.server_sql_modules;
GO
執行下列查詢之前,請將 和 <schema_name.table_name>
取代<database_name>
為有效的名稱。
USE <database_name>;
GO
SELECT i.name AS index_name
,ic.index_column_id
,key_ordinal
,c.name AS column_name
,TYPE_NAME(c.user_type_id)AS column_type
,is_identity
FROM sys.indexes AS i
INNER JOIN sys.index_columns AS ic
ON i.object_id = ic.object_id AND i.index_id = ic.index_id
INNER JOIN sys.columns AS c
ON ic.object_id = c.object_id AND c.column_id = ic.column_id
WHERE i.is_primary_key = 1
AND i.object_id = OBJECT_ID('<schema_name.table_name>');
GO
或者,您可以使用 函 COL_NAME
式,如下列範例所示。
USE <database_name>;
GO
SELECT i.name AS index_name
,COL_NAME(ic.object_id,ic.column_id) AS column_name
,ic.index_column_id
,key_ordinal
FROM sys.indexes AS i
INNER JOIN sys.index_columns AS ic
ON i.object_id = ic.object_id AND i.index_id = ic.index_id
WHERE i.is_primary_key = 1
AND i.object_id = OBJECT_ID('<schema_name.table_name>');
GO
執行下列查詢之前,請將 和 <schema_name.table_name>
取代<database_name>
為有效的名稱。
USE <database_name>;
GO
SELECT
f.name AS foreign_key_name
,OBJECT_NAME(f.parent_object_id) AS table_name
,COL_NAME(fc.parent_object_id, fc.parent_column_id) AS constraint_column_name
,OBJECT_NAME (f.referenced_object_id) AS referenced_object
,COL_NAME(fc.referenced_object_id, fc.referenced_column_id) AS referenced_column_name
,is_disabled
,delete_referential_action_desc
,update_referential_action_desc
FROM sys.foreign_keys AS f
INNER JOIN sys.foreign_key_columns AS fc
ON f.object_id = fc.constraint_object_id
WHERE f.parent_object_id = OBJECT_ID('<schema_name.table_name>');
如何? 尋找授與或拒絕給指定主體的許可權嗎?下列範例會建立函式,以傳回檢查許可權所在的實體名稱。 函式會在後續查詢中叫用。 函式必須在您要檢查許可權的每個資料庫中建立。
-- Create a function to return the name of the entity on which the permissions are checked.
IF OBJECT_ID (N'dbo.entity_instance_name', N'FN') IS NOT NULL
DROP FUNCTION dbo.entity_instance_name;
GO
CREATE FUNCTION dbo.entity_instance_name(@class_desc nvarchar(60), @major_id int)
RETURNS sysname AS
BEGIN
DECLARE @the_entity_name sysname
SELECT @the_entity_name = CASE
WHEN @class_desc = 'DATABASE' THEN DB_NAME()
WHEN @class_desc = 'SCHEMA' THEN SCHEMA_NAME(@major_id)
WHEN @class_desc = 'OBJECT_OR_COLUMN' THEN OBJECT_NAME(@major_id)
WHEN @class_desc = 'DATABASE_PRINCIPAL' THEN USER_NAME(@major_id)
WHEN @class_desc = 'ASSEMBLY' THEN
(SELECT name FROM sys.assemblies WHERE assembly_id=@major_id)
WHEN @class_desc = 'TYPE' THEN TYPE_NAME(@major_id)
WHEN @class_desc = 'XML_SCHEMA_COLLECTION' THEN
(SELECT name FROM sys.xml_schema_collections
WHERE xml_collection_id=@major_id)
WHEN @class_desc = 'MESSAGE_TYPE' THEN
(SELECT name FROM sys.service_message_types WHERE message_type_id=@major_id)
WHEN @class_desc = 'SERVICE_CONTRACT' THEN
(SELECT name FROM sys.service_contracts
WHERE service_contract_id=@major_id)
WHEN @class_desc = 'SERVICE' THEN
(SELECT name FROM sys.services WHERE service_id=@major_id)
WHEN @class_desc = 'REMOTE_SERVICE_BINDING' THEN
(SELECT name FROM sys.remote_service_bindings
WHERE remote_service_binding_id=@major_id)
WHEN @class_desc = 'ROUTE' THEN
(SELECT name FROM sys.routes WHERE route_id=@major_id)
WHEN @class_desc = 'FULLTEXT_CATALOG' THEN
(SELECT name FROM sys.fulltext_catalogs WHERE fulltext_catalog_id=@major_id)
WHEN @class_desc = 'SYMMETRIC_KEY' THEN
(SELECT name FROM sys.symmetric_keys WHERE symmetric_key_id=@major_id)
WHEN @class_desc = 'CERTIFICATE' THEN
(SELECT name FROM sys.certificates WHERE certificate_id=@major_id)
WHEN @class_desc = 'ASYMMETRIC_KEY' THEN
(SELECT name FROM sys.asymmetric_keys WHERE asymmetric_key_id=@major_id)
WHEN @class_desc = 'SERVER' THEN
(SELECT name FROM sys.servers WHERE server_id=@major_id)
WHEN @class_desc = 'SERVER_PRINCIPAL' THEN SUSER_NAME(@major_id)
WHEN @class_desc = 'ENDPOINT' THEN
(SELECT name FROM sys.endpoints WHERE endpoint_id=@major_id)
ELSE '?'
END
RETURN @the_entity_name
END;
GO
-- Return server-level permissions for the user.
SELECT class
,class_desc
,dbo.entity_instance_name(class_desc, major_id) AS entity_name
,minor_id
,SUSER_NAME(grantee_principal_id) AS grantee
,SUSER_NAME(grantor_principal_id) AS grantor
,type
,permission_name
,state_desc
FROM sys.server_permissions
WHERE grantee_principal_id = SUSER_ID('public');
GO
-- Return database-level permissions for the user.
SELECT class
,class_desc
,dbo.entity_instance_name(class_desc , major_id) AS entity_name
,minor_id
,USER_NAME(grantee_principal_id) AS grantee
,USER_NAME(grantor_principal_id) AS grantor
,type
,permission_name
,state_desc
FROM sys.database_permissions
WHERE grantee_principal_id = DATABASE_PRINCIPAL_ID('public');
GO
執行下列查詢之前,請以有效的名稱取代 <database_name>
、 <schema_name.table_name>
和 <column_name
> 。
USE <database_name>;
GO
SELECT OBJECT_NAME(object_id) AS object_name
,COL_NAME(object_id, column_id) AS computed_column
,class_desc
,is_selected
,is_updated
,is_select_all
FROM sys.sql_dependencies
WHERE referenced_major_id = OBJECT_ID('<schema_name.table_name>')
AND referenced_minor_id = COLUMNPROPERTY(referenced_major_id, '<column_name>', 'ColumnId')
AND class = 1;
GO
執行下列查詢之前,請將 取代 <database_name>
為有效的名稱。
USE <database_name>;
GO
SELECT OBJECT_NAME(d.referenced_major_id) AS object_name
,COL_NAME(d.referenced_major_id, d.referenced_minor_id) AS column_name
,OBJECT_NAME(referenced_major_id) AS dependent_object_name
,COL_NAME(d.object_id, d.column_id) AS dependent_computed_column
,cc.definition AS computed_column_definition
FROM sys.sql_dependencies AS d
JOIN sys.computed_columns AS cc
ON cc.object_id = d.object_id AND cc.column_id = d.column_id AND d.object_id=d.referenced_major_id
WHERE d.class = 1
ORDER BY object_name, column_name;
GO
如何? 尋找相依於指定 CLR 使用者定義類型或別名類型的數據行?
執行下列查詢之前,請將 取代 <database_name>
為有效的名稱,並以 <schema_name.data_type_name>
有效的架構限定 CLR 使用者定義類型或架構限定別名類型名稱取代 。 下列查詢需要db_owner角色或許可權的成員資格,才能查看資料庫中的所有相依數據行和計算數據行元數據。
USE <database_name>;
GO
SELECT OBJECT_NAME(object_id) AS object_name
,c.name AS column_name
,SCHEMA_NAME(t.schema_id) AS schema_name
,TYPE_NAME(c.user_type_id) AS user_type_name
,c.max_length
,c.precision
,c.scale
,c.is_nullable
,c.is_computed
FROM sys.columns AS c
INNER JOIN sys.types AS t ON c.user_type_id = t.user_type_id
WHERE c.user_type_id = TYPE_ID('<schema_name.data_type_name>');
GO
下列查詢會傳回相依於CLR使用者定義類型或別名之數據行的限制和窄檢視,但公用角色可以看到結果集。 如果您已將使用者定義型別的 REFERENCE 許可權授與給其他人,而且您沒有許可權檢視其他人所建立的物件元數據,則可以使用此查詢。
USE <database_name>;
GO
SELECT OBJECT_NAME(object_id) AS object_name
,COL_NAME(object_id, column_id) AS column_name
,TYPE_NAME(user_type_id) AS user_type
FROM sys.column_type_usages
WHERE user_type_id = TYPE_ID('<schema_name.data_type_name>');
GO
如何? 尋找相依於指定 CLR 使用者定義類型或別名類型的計算資料行?
執行下列查詢之前,請將 取代為有效的名稱,並以<schema_name.data_type_name>
有效的架構限定 CLR 使用者定義類型、別名類型名稱取代 <database_name>
。
USE <database_name>;
GO
SELECT OBJECT_NAME(object_id) AS object_name
,COL_NAME(object_id, column_id) AS column_name
FROM sys.sql_dependencies
WHERE referenced_major_id = TYPE_ID('<schema_name.data_type_name>')
AND class = 2 -- schema-bound references to type
AND OBJECTPROPERTY(object_id, 'IsTable') = 1; -- exclude non-table dependencies
如何? 尋找相依於指定 CLR 使用者定義類型或別名類型的參數?
執行下列查詢之前,請將 取代為有效的名稱,並以<schema_name.data_type_name>
有效的架構限定 CLR 使用者定義類型、別名類型名稱取代 <database_name>
。 下列查詢需要db_owner角色或許可權的成員資格,才能查看資料庫中的所有相依數據行和計算數據行元數據。
USE <database_name>;
GO
SELECT OBJECT_NAME(object_id) AS object_name
,NULL AS procedure_number
,name AS param_name
,parameter_id AS param_num
,TYPE_NAME(p.user_TYPE_ID) AS type_name
FROM sys.parameters AS p
WHERE p.user_TYPE_ID = TYPE_ID('<schema_name.data_type_name>')
UNION
SELECT OBJECT_NAME(object_id) AS object_name
,procedure_number
,name AS param_name
,parameter_id AS param_num
,TYPE_NAME(p.user_TYPE_ID) AS type_name
FROM sys.numbered_procedure_parameters AS p
WHERE p.user_TYPE_ID = TYPE_ID('<schema_name.data_type_name>')
ORDER BY object_name, procedure_number, param_num;
GO
下列查詢會傳回取決於 CLR 使用者定義類型或別名之參數的限制和窄型別檢視,但公用角色可以看到結果集。 如果您已將使用者定義型別的 REFERENCE 許可權授與給其他人,而且您沒有許可權檢視其他人所建立的物件元數據,則可以使用此查詢。
USE <database_name>;
GO
SELECT OBJECT_NAME(object_id) AS object_name
,parameter_id
,TYPE_NAME(user_type_id) AS type_name
FROM sys.parameter_type_usages
WHERE user_type_id = TYPE_ID('<schema_name.data_type_name>');
GO
如何? 尋找相依於指定 CLR 使用者定義類型的 CHECK 條件約束嗎?
執行下列查詢之前,請將 取代為有效的名稱,並以<schema_name.data_type_name>
有效的架構限定 CLR 使用者定義類型名稱取代 <database_name>
。
USE <database_name>;
GO
SELECT SCHEMA_NAME(o.schema_id) AS schema_name
,OBJECT_NAME(o.parent_object_id) AS table_name
,OBJECT_NAME(o.object_id) AS constraint_name
FROM sys.sql_dependencies AS d
JOIN sys.objects AS o ON o.object_id = d.object_id
WHERE referenced_major_id = TYPE_ID('<schema_name.data_type_name>')
AND class = 2 -- schema-bound references to type
AND OBJECTPROPERTY(o.object_id, 'IsCheckCnst') = 1; -- exclude non-CHECK dependencies
GO
如何? 尋找相依於指定CLR使用者定義類型或別名類型的檢視、Transact-SQL 函式和 Transact-SQL 預存程式?
執行下列查詢之前,請將 取代為有效的名稱,並以<schema_name.data_type_name>
有效的架構限定 CLR 使用者定義類型、別名類型名稱取代 <database_name>
。
函式或程式中定義的參數是隱含架構系結。 因此,可以使用 sys.sql_dependencies 目錄檢視來檢視相依於 CLR 使用者定義類型或別名類型的參數。 程式和觸發程式不是架構系結。 這表示不會維護程式或觸發程式主體中定義之任何表達式與CLR用戶定義型別或別名類型之間的相依性。 架構系結檢視和架構系結使用者定義函式,其表達式相依於 CLR 使用者定義類型或別名類型,會在 sys.sql_dependencies 目錄檢視中維護。 不會維護類型和 CLR 函式與 CLR 程式之間的相依性。
下列查詢會針對指定的CLR使用者定義類型或別名類型,傳回檢視表、Transact-SQL 函數和 Transact-SQL 預存程式中的所有架構系結相依性。
USE <database_name>;
GO
SELECT SCHEMA_NAME(o.schema_id) AS dependent_object_schema
,OBJECT_NAME(o.object_id) AS dependent_object_name
,o.type_desc AS dependent_object_type
,d.class_desc AS kind_of_dependency
,TYPE_NAME (d.referenced_major_id) AS type_name
FROM sys.sql_dependencies AS d
JOIN sys.objects AS o
ON d.object_id = o.object_id
AND o.type IN ('FN','IF','TF', 'V', 'P')
WHERE d.class = 2 -- dependencies on types
AND d.referenced_major_id = TYPE_ID('<schema_name.data_type_name>')
ORDER BY dependent_object_schema, dependent_object_name;
GO
執行下列查詢之前,請將 和 <schema_name.table_name>
取代<database_name>
為有效的名稱。
USE <database_name>;
GO
SELECT OBJECT_NAME(object_id) as constraint_name
,SCHEMA_NAME(schema_id) AS schema_name
,OBJECT_NAME(parent_object_id) AS table_name
,type_desc
,create_date
,modify_date
,is_ms_shipped
,is_published
,is_schema_published
FROM sys.objects
WHERE type_desc LIKE '%CONSTRAINT'
AND parent_object_id = OBJECT_ID('<schema_name.table_name>');
GO
執行下列查詢之前,請將 和 <schema_name.table_name>
取代<database_name>
為有效的名稱。
USE <database_name>;
GO
SELECT i.name AS index_name
,i.type_desc
,is_unique
,ds.type_desc AS filegroup_or_partition_scheme
,ds.name AS filegroup_or_partition_scheme_name
,ignore_dup_key
,is_primary_key
,is_unique_constraint
,fill_factor
,is_padded
,is_disabled
,allow_row_locks
,allow_page_locks
FROM sys.indexes AS i
INNER JOIN sys.data_spaces AS ds ON i.data_space_id = ds.data_space_id
WHERE is_hypothetical = 0 AND i.index_id <> 0
AND i.object_id = OBJECT_ID('<schema_name.table_name>');
GO
執行下列查詢之前,請將 和 <column_name>
取代<database_name>
為有效的名稱。
USE <database_name>;
GO
SELECT OBJECT_NAME(object_id)
FROM sys.columns
WHERE name = '<column_name>';
GO
Or
USE <database_name>;
GO
SELECT SCHEMA_NAME(o.schema_id) AS schema_name
,o.name AS object_name
,type_desc
FROM sys.objects AS o
INNER JOIN sys.columns AS c ON o.object_id = c.object_id
WHERE c.name = '<column_name>';
GO
執行下列查詢之前,請將 取代 <database_name>
為有效的名稱。
USE <database_name>;
GO
SELECT *
FROM sys.tables;
GO
執行下列查詢之前,請將 取代 <database_name>
為有效的名稱。
USE <database_name>;
GO
SELECT SCHEMA_NAME(o.schema_id) AS schema_name
,OBJECT_NAME(p.object_id) AS table_name
,i.name AS index_name
,p.partition_number
,rows
FROM sys.partitions AS p
INNER JOIN sys.indexes AS i ON p.object_id = i.object_id AND p.index_id = i.index_id
INNER JOIN sys.partition_schemes ps ON i.data_space_id=ps.data_space_id
INNER JOIN sys.objects AS o ON o.object_id = i.object_id
ORDER BY index_name, partition_number;
GO
執行下列查詢之前,請將 取代為有效的名稱,並以<schema_name.object_name>
有效的資料表、索引檢視表或數據表值函式名稱取代 <database_name>
。
USE <database_name>;
GO
SELECT name AS statistics_name
,stats_id
,auto_created
,user_created
,no_recompute
FROM sys.stats
WHERE object_id = OBJECT_ID('<schema_name.object_name>');
GO
執行下列查詢之前,請將 取代為有效的名稱,並以<schema_name.object_name>
有效的資料表、索引檢視表或數據表值函式名稱取代 <database_name>
。
USE <database_name>;
GO
SELECT s.name AS statistics_name
,c.name AS column_name
,sc.stats_column_id
FROM sys.stats AS s
INNER JOIN sys.stats_columns AS sc
ON s.object_id = sc.object_id AND s.stats_id = sc.stats_id
INNER JOIN sys.columns AS c
ON sc.object_id = c.object_id AND c.column_id = sc.column_id
WHERE s.object_id = OBJECT_ID('<schema_name.object_name>');
GO
執行下列查詢之前,請將 和 <schema_name.object_name>
取代<database_name>
為有效的名稱。
USE <database_name>;
GO
SELECT definition
FROM sys.sql_modules
WHERE object_id = OBJECT_ID('<schema_name.object_name>');
GO
或者,您可以使用 函 OBJECT_DEFINITION
式,如下列範例所示。
USE <database_name>;
GO
SELECT OBJECT_DEFINITION (OBJECT_ID('<schema_name.object_name>')) AS ObjectDefinition;
GO