--抓所有的 Table
Select * from INFORMATION_SCHEMA.TABLES
--抓所有的 COLUMNS
Select * from INFORMATION_SCHEMA.COLUMNS
--抓欄位的 Description
select
st.name [Table],
sc.name [Column],
sep.value [Description]
from sys.tables st
inner join sys.columns sc on st.object_id = sc.object_id
left join sys.extended_properties sep on st.object_id = sep.major_id
and sc.column_id = sep.minor_id
and sep.name = 'MS_Description'
where st.name = 'TableName'
and sc.name = 'ColumnName'
--修改欄位的 Description.
EXEC sp_updateextendedproperty
@name = N'MS_Description', @value = 'Your description',
@level0type = N'Schema', @level0name = 'dbo',
@level1type = N'Table', @level1name = 'TableName',
@level2type = N'Column', @level2name = 'Name';
EXEC sp_addextendedproperty
@name = N'MS_Description', @value = 'Code description',
@level0type = N'Schema', @level0name = 'dbo',
@level1type = N'Table', @level1name = 'TableName',
@level2type = N'Column', @level2name = 'ColumnName';
--新增 Table 的 extendedproperty
EXEC sp_addextendedproperty
@name = N'Description', @value = 'Hey, here is TableName description!',
@level0type = N'Schema', @level0name = 'dbo',
@level1type = N'Table', @level1name = 'TableName'
GO
--修改 Table 的 extendedproperty
EXEC sp_updateextendedproperty
@name = N'Description', @value = 'Hey, here is my description! 123',
@level0type = N'Schema', @level0name = 'dbo',
@level1type = N'Table', @level1name = 'TableName'
GO
--讀取 Extended Property
SELECT sys.objects.name AS TableName, ep.name AS PropertyName,
ep.value AS Description
FROM sys.objects
CROSS APPLY fn_listextendedproperty(default,
'SCHEMA', schema_name(schema_id),
'TABLE', name, null, null) ep
WHERE sys.objects.name NOT IN ('sysdiagrams')
ORDER BY sys.objects.name
--讀取 Column 的 Description
SELECT objtype, objname, name, value
FROM fn_listextendedproperty (NULL, 'schema', 'dbo', 'table', 'TableName', 'column', default);
GO
--讀取特定 Table 的 Description
SELECT *
FROM fn_listextendedproperty (NULL, 'schema', 'dbo', 'table', 'TableName', default, default);
GO
--讀取 所有 Table 的 Description
SELECT *
FROM fn_listextendedproperty (NULL, 'schema', 'dbo', 'table', default, default, default);
GO
--新增或修改資料表說明
IF not exists(SELECT * FROM ::fn_listextendedproperty (NULL, 'user', 'dbo', 'table', '資料表名稱', NULL, NULL))
BEGIN
exec sp_addextendedproperty 'MS_Description', '資料表說明', 'user', 'dbo', 'table', '資料表名稱'
END
ELSE
BEGIN
exec sp_updateextendedproperty 'MS_Description', '資料表說明', 'user', 'dbo', 'table', '資料表名稱'
END
--新增或修改欄位說明
IF not exists(SELECT * FROM ::fn_listextendedproperty (NULL, 'user', 'dbo', 'table', '資料表名稱', 'column', '欄位名稱'))
BEGIN
exec sp_addextendedproperty 'MS_Description', '欄位說明', 'user', 'dbo', 'table', '資料表名稱', 'column', '欄位名稱'
END
ELSE
BEGIN
exec sp_updateextendedproperty 'MS_Description', '欄位說明', 'user', 'dbo', 'table', '資料表名稱', 'column', '欄位名稱'
END