MS SQL SERVER 数据字典 生成SQL

在库内查询,可用于生成如下字段结构:

[表], [字段], [数据类型], [允许为空], [主键], [外键], [引用表], [说明描述]

SELECT TOP (100) PERCENT a.name AS 表, b.name AS 字段, c.name AS 数据类型, CASE WHEN b.isnullable = 0 THEN '-' WHEN b.isnullable = 1 THEN '是' END AS 允许为空,
CASE WHEN d .name IS NULL THEN '-' WHEN d .name IS NOT NULL THEN '是' END AS 主键, CASE WHEN e.parent_object_id IS NULL THEN 0 ELSE 1 END AS 外键,
CASE WHEN e.parent_object_id IS NULL THEN '-' ELSE g.name END AS 引用表, CASE WHEN h.value IS NULL THEN '-' ELSE h.value END AS 说明描述,
i.text AS 默认值
FROM sys.sysobjects AS a INNER JOIN
sys.syscolumns AS b ON a.id = b.id INNER JOIN
sys.systypes AS c ON b.xtype = c.xtype LEFT OUTER JOIN
(SELECT so.id, sc.colid, sc.name
FROM sys.syscolumns AS sc INNER JOIN
sys.sysobjects AS so ON so.id = sc.id INNER JOIN
sys.sysindexkeys AS si ON so.id = si.id AND sc.colid = si.colid
WHERE (si.indid = 1)) AS d ON a.id = d.id AND b.colid = d.colid LEFT OUTER JOIN
sys.foreign_key_columns AS e ON a.id = e.parent_object_id AND b.colid = e.parent_column_id LEFT OUTER JOIN
sys.objects AS g ON e.referenced_object_id = g.object_id LEFT OUTER JOIN
sys.extended_properties AS h ON a.id = h.major_id AND b.colid = h.minor_id LEFT OUTER JOIN
sys.syscomments AS i ON b.cdefault = i.id
WHERE (a.type = 'U') AND (c.name <> 'sysname')
ORDER BY 表, 字段

还有一个查全库表字段的,参见另一篇 《通过(sys.sysobjects)对象表,查询全库表的基础信息Sql Server 查询全库表信息

查询获取表中, 字段,数据类型的sql

存档一个今天用到的sql,  可以用来查询表中, 字段, 数据类型的sql.

SELECT OBJECT_NAME(c.id) AS 表名, c.name AS 字段名, t.name AS 数据类型, 
      c.prec AS 长度
FROM syscolumns c INNER JOIN
      systypes t ON c.xusertype = t.xusertype
WHERE (objectproperty(c.id, 'IsUserTable') = 1) AND 
      (c.id = OBJECT_ID('你的表名'))

 

如果要查视图的话, 要修改一下where条件,  把where的objectproperty放到上面增加一个case判断,  AS 出类型

SELECT     CASE WHEN (OBJECTPROPERTY(c.id, 'IsUserTable') = 1) THEN 'Table' WHEN (OBJECTPROPERTY(c.id, 'IsView') = 1) THEN 'View' END AS 类型, OBJECT_NAME(c.id) 
                      AS 表名, c.name AS 字段名, t.name AS 数据类型, c.prec AS 长度
FROM         sys.syscolumns AS c INNER JOIN
                      sys.systypes AS t ON c.xusertype = t.xusertype
WHERE     (c.id = OBJECT_ID('View_1'))

(OBJECTPROPERTY(c.id, ‘IsUserTable’) = 1) 是表,  (OBJECTPROPERTY(c.id, ‘IsView’) = 1) 是视图

关于 OBJECTPROPERTY 的详细用法和参数, 请查看: http://technet.microsoft.com/zh-cn/library/ms176105(v=sql.90).aspx