簡(jiǎn)單的3個(gè)SQL視圖搞定所有SqlServer數(shù)據(jù)庫(kù)字典
|
tercel
2011年3月15日 12:39
本文熱度 3879
|
網(wǎng)上有很多SQL SERVER數(shù)據(jù)庫(kù)字典的SQL語(yǔ)句,七零八落,我在工作整理了一下思路,總結(jié)SQL代碼如下。數(shù)據(jù)庫(kù)字典包括表結(jié)構(gòu)(分2K和2005)、索引和主鍵.外鍵.約束.視圖.函數(shù).存儲(chǔ)過(guò)程.觸發(fā)器.規(guī)則。可以在企業(yè)管理器、查詢(xún)分析器中簡(jiǎn)單執(zhí)行,直接了當(dāng)?shù)牟槌鯯QL2K及SQL2005的所有數(shù)據(jù)字典,方便文檔的編寫(xiě),希望對(duì)大家有幫助。
1. SqlServer2000數(shù)據(jù)庫(kù)字典--表結(jié)構(gòu).sql
SELECT TOP 100 PERCENT --a.id,
CASE WHEN a.colorder = 1 THEN d.name ELSE '' END AS 表名,
CASE WHEN a.colorder = 1 THEN isnull(f.value, '') ELSE '' END AS 表說(shuō)明,
a.colorder AS 字段序號(hào), a.name AS 字段名, CASE WHEN COLUMNPROPERTY(a.id,
a.name, 'IsIdentity') = 1 THEN '√' ELSE '' END AS 標(biāo)識(shí),
CASE WHEN EXISTS
(SELECT 1
FROM dbo.sysindexes si INNER JOIN
dbo.sysindexkeys sik ON si.id = sik.id AND si.indid = sik.indid INNER JOIN
dbo.syscolumns sc ON sc.id = sik.id AND sc.colid = sik.colid INNER JOIN
dbo.sysobjects so ON so.name = si.name AND so.xtype = 'PK'
WHERE sc.id = a.id AND sc.colid = a.colid) THEN '√' ELSE '' END AS 主鍵,
b.name AS 類(lèi)型, a.length AS 長(zhǎng)度, COLUMNPROPERTY(a.id, a.name, 'PRECISION')
AS 精度, ISNULL(COLUMNPROPERTY(a.id, a.name, 'Scale'), 0) AS 小數(shù)位數(shù),
CASE WHEN a.isnullable = 1 THEN '√' ELSE '' END AS 允許空, ISNULL(e.text, '')
AS 默認(rèn)值, ISNULL(g.[value], '') AS 字段說(shuō)明, d.crdate AS 創(chuàng)建時(shí)間,
CASE WHEN a.colorder = 1 THEN d.refdate ELSE NULL END AS 更改時(shí)間
FROM dbo.syscolumns a LEFT OUTER JOIN
dbo.systypes b ON a.xtype = b.xusertype INNER JOIN
dbo.sysobjects d ON a.id = d.id AND d.xtype = 'U' AND
d.status >= 0 LEFT OUTER JOIN
dbo.syscomments e ON a.cdefault = e.id LEFT OUTER JOIN
dbo.sysproperties g ON a.id = g.id AND a.colid = g.smallid AND
g.name = 'MS_Description' LEFT OUTER JOIN
dbo.sysproperties f ON d.id = f.id AND f.smallid = 0 AND
f.name = 'MS_Description'
ORDER BY d.name, a.colorder
SqlServer2005數(shù)據(jù)庫(kù)字典--表結(jié)構(gòu).sql
SELECT TOP 100 PERCENT --a.id,
CASE WHEN a.colorder = 1 THEN d.name ELSE '' END AS 表名,
CASE WHEN a.colorder = 1 THEN isnull(f.value, '') ELSE '' END AS 表說(shuō)明,
a.colorder AS 字段序號(hào), a.name AS 字段名, CASE WHEN COLUMNPROPERTY(a.id,
a.name, 'IsIdentity') = 1 THEN '√' ELSE '' END AS 標(biāo)識(shí),
CASE WHEN EXISTS
(SELECT 1
FROM dbo.sysindexes si INNER JOIN
dbo.sysindexkeys sik ON si.id = sik.id AND si.indid = sik.indid INNER JOIN
dbo.syscolumns sc ON sc.id = sik.id AND sc.colid = sik.colid INNER JOIN
dbo.sysobjects so ON so.name = si.name AND so.xtype = 'PK'
WHERE sc.id = a.id AND sc.colid = a.colid) THEN '√' ELSE '' END AS 主鍵,
b.name AS 類(lèi)型, a.length AS 長(zhǎng)度, COLUMNPROPERTY(a.id, a.name, 'PRECISION')
AS 精度, ISNULL(COLUMNPROPERTY(a.id, a.name, 'Scale'), 0) AS 小數(shù)位數(shù),
CASE WHEN a.isnullable = 1 THEN '√' ELSE '' END AS 允許空, ISNULL(e.text, '')
AS 默認(rèn)值, ISNULL(g.[value], '') AS 字段說(shuō)明, d.crdate AS 創(chuàng)建時(shí)間,
CASE WHEN a.colorder = 1 THEN d.refdate ELSE NULL END AS 更改時(shí)間
FROM dbo.syscolumns a LEFT OUTER JOIN
dbo.systypes b ON a.xtype = b.xusertype INNER JOIN
dbo.sysobjects d ON a.id = d.id AND d.xtype = 'U' AND
d.status >= 0 LEFT OUTER JOIN
dbo.syscomments e ON a.cdefault = e.id LEFT OUTER JOIN
sys.extended_properties g ON a.id = g.major_id AND a.colid = g.minor_id AND
g.name = 'MS_Description' LEFT OUTER JOIN
sys.extended_properties f ON d.id = f.major_id AND f.minor_id = 0 AND
f.name = 'MS_Description'
ORDER BY d.name, 字段序號(hào)
2. SqlServer數(shù)據(jù)庫(kù)字典--索引.sql
SELECT TOP 100 PERCENT --a.id,
CASE WHEN b.keyno = 1 THEN c.name ELSE '' END AS 表名,
CASE WHEN b.keyno = 1 THEN a.name ELSE '' END AS 索引名稱(chēng), d.name AS 列名,
b.keyno AS 索引順序, CASE indexkey_property(c.id, b.indid, b.keyno, 'isdescending')
WHEN 1 THEN '降序' WHEN 0 THEN '升序' END AS 排序, CASE WHEN p.id IS NULL
THEN '' ELSE '√' END AS 主鍵, CASE INDEXPROPERTY(c.id, a.name, 'IsClustered')
WHEN 1 THEN '√' WHEN 0 THEN '' END AS 聚集, CASE INDEXPROPERTY(c.id,
a.name, 'IsUnique') WHEN 1 THEN '√' WHEN 0 THEN '' END AS 唯一,
CASE WHEN e.id IS NULL THEN '' ELSE '√' END AS 唯一約束,
a.OrigFillFactor AS 填充因子, c.crdate AS 創(chuàng)建時(shí)間, c.refdate AS 更改時(shí)間
FROM dbo.sysindexes a INNER JOIN
dbo.sysindexkeys b ON a.id = b.id AND a.indid = b.indid INNER JOIN
dbo.syscolumns d ON b.id = d.id AND b.colid = d.colid INNER JOIN
dbo.sysobjects c ON a.id = c.id AND c.xtype = 'U' LEFT OUTER JOIN
dbo.sysobjects e ON e.name = a.name AND e.xtype = 'UQ' LEFT OUTER JOIN
dbo.sysobjects p ON p.name = a.name AND p.xtype = 'PK'
WHERE (OBJECTPROPERTY(a.id, N'IsUserTable') = 1) AND (OBJECTPROPERTY(a.id,
N'IsMSShipped') = 0) AND (INDEXPROPERTY(a.id, a.name, 'IsAutoStatistics') = 0)
ORDER BY c.name, a.name, b.keyno
3. SqlServer數(shù)據(jù)庫(kù)字典--表.視圖.函數(shù).存儲(chǔ)過(guò)程.觸發(fā)器.主鍵.外鍵.約束.規(guī)則.sql
SELECT DISTINCT
TOP 100 PERCENT isnull(p.name,'') AS 父對(duì)象, o.xtype,
CASE o.xtype WHEN 'C' THEN 'CHECK 約束' WHEN 'D' THEN '默認(rèn)值或DEFAULT約束'
WHEN 'F' THEN 'FOREIGNKEY約束' WHEN 'L' THEN '日志' WHEN 'FN' THEN '標(biāo)量函數(shù)'
WHEN 'IF' THEN '內(nèi)嵌表函數(shù)' WHEN 'P' THEN '存儲(chǔ)過(guò)程' WHEN 'PK' THEN 'PRIMARYKEY約束'
WHEN 'RF' THEN '復(fù)制篩選存儲(chǔ)過(guò)程' WHEN 'S' THEN '系統(tǒng)表' WHEN 'TF' THEN '表函數(shù)'
WHEN 'TR' THEN '觸發(fā)器' WHEN 'U' THEN '用戶(hù)表' WHEN 'UQ' THEN 'UNIQUE 約束'
WHEN 'V' THEN '視圖' WHEN 'X' THEN '擴(kuò)展存儲(chǔ)過(guò)程' WHEN 'R' THEN '規(guī)則' ELSE NULL
END AS 類(lèi)型, o.name AS 對(duì)象名, o.crdate AS 創(chuàng)建時(shí)間, o.refdate AS 更改時(shí)間,
c.text AS 聲明語(yǔ)句,OBJECTPROPERTY(o.id, N'IsMSShipped')
FROM dbo.sysobjects o Left JOIN
dbo.sysobjects p ON o.parent_obj = p.id LEFT OUTER JOIN
dbo.syscomments c ON o.id = c.id
WHERE --(o.xtype IN ('C','D','F','PK','UQ','L','FN','IF','TF','TR','P','R','RF','X','S','U','V')) AND
(OBJECTPROPERTY(o.id, N'IsMSShipped') = 0) AND (isnull(p.name,'') <> N'dtproperties')
ORDER BY o.xtype DESC
數(shù)據(jù)庫(kù)技術(shù)就是一壇陳年老酒,越久越香,學(xué)以致用。
該文章在 2011/3/15 12:39:18 編輯過(guò)
| |
全部評(píng)論1 |
|
Ccoffee
2025年4月14日 10:26
SELECT 表名 = CASE WHEN a.colorder = 1 THEN d .name ELSE '' END, 字段序號(hào) = a.colorder, 字段名 = a.name, 標(biāo)識(shí) = CASE WHEN COLUMNPROPERTY(a.id, a.name, 'IsIdentity') = 1 THEN '√' ELSE '' END, 類(lèi)型 = b.name, 占用字節(jié)數(shù) = a.length, 長(zhǎng)度 = COLUMNPROPERTY(a.id, a.name, 'PRECISION'), 小數(shù)位數(shù) = isnull(COLUMNPROPERTY(a.id, a.name, 'Scale'), 0), 允許空 = CASE WHEN a.isnullable = 1 THEN '√' ELSE '' END, 默認(rèn)值 = isnull(e.text, ''), 字段說(shuō)明 = isnull(g.[value], '') FROM syscolumns a LEFT JOIN systypes b ON a.xtype = b.xusertype INNER JOIN sysobjects d ON a.id = d .id AND d .xtype = 'U' AND d .name <> 'dtproperties' LEFT JOIN syscomments e ON a.cdefault = e.id LEFT JOIN dtproperties g ON a.id = g.id AND a.colid = g.id ORDER BY a.id, a.colorder
|
|
關(guān)鍵字查詢(xún)
相關(guān)文章
|