Mysql数据库查询表结构很方便,用客户端(SQLyog)可以直接复制出需要的表结构,据说可以用简单的命令查询表结构 desc 表结构

Sqlserver导出表结构就很坑爹了,首先呢客户端不支持,表设计页面虽说可以复制表结构但是不包含字段注释,想想这种场景应该很常见不可能没有解决方案的,于是在网上发现了一段脚本,稍加调整就可以查询出需要的表结构

脚本及查询示例

SELECT  表名 = CASE WHEN a.colorder = 1 THEN d.name ELSE '' END ,
        字段说明 = ISNULL(g.[value], '') ,
        字段名 = a.name ,
        类型 = CASE WHEN b.name IN ( 'varchar', 'nvarchar' )
                  THEN b.name + '('
                       + CAST(COLUMNPROPERTY(a.id, a.name, 'PRECISION') AS VARCHAR(4))
                       + ')'
                  WHEN b.name = 'decimal'
                  THEN b.name + '('
                       + CAST(COLUMNPROPERTY(a.id, a.name, 'PRECISION') AS VARCHAR(4))
                       + ','
                       + CAST(COLUMNPROPERTY(a.id, a.name, 'Scale') AS VARCHAR(4))
                       + ')'
                  ELSE b.name
             END
FROM syscolumns a    -- 列名
    LEFT JOIN systypes b ON a.xusertype = 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 sys.extended_properties g ON a.id = g.major_id AND a.colid = g.minor_id    --扩展属性(字段说明)
    --LEFT JOIN sys.extended_properties f ON d.id = f.major_id AND f.minor_id = 0        --扩展属性(表说明)
WHERE d.name = 'SCM_Module'    --可修改表名
ORDER BY a.id , a.colorder

查询比较全面的:

 --快速查看表结构(比较全面的)
SELECT  CASE WHEN col.colorder = 1 THEN obj.name
                  ELSE ''
             END AS 表名,
        col.colorder AS 序号 ,
        col.name AS 列名 ,
        ISNULL(ep.[value], '') AS 列说明 ,
        t.name AS 数据类型 ,
        col.length AS 长度 ,
        ISNULL(COLUMNPROPERTY(col.id, col.name, 'Scale'), 0) AS 小数位数 ,
        CASE WHEN COLUMNPROPERTY(col.id, col.name, 'IsIdentity') = 1 THEN '√'
             ELSE ''
        END AS 标识 ,
        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 = col.id
                                    AND sc.colid = col.colid ) THEN '√'
             ELSE ''
        END AS 主键 ,
        CASE WHEN col.isnullable = 1 THEN '√'
             ELSE ''
        END AS 允许空 ,
        ISNULL(comm.text, '') AS 默认值
FROM    dbo.syscolumns col
        LEFT  JOIN dbo.systypes t ON col.xtype = t.xusertype
        inner JOIN dbo.sysobjects obj ON col.id = obj.id
                                         AND obj.xtype = 'U'
                                         AND obj.status >= 0
        LEFT  JOIN dbo.syscomments comm ON col.cdefault = comm.id
        LEFT  JOIN sys.extended_properties ep ON col.id = ep.major_id
                                                      AND col.colid = ep.minor_id
                                                      AND ep.name = 'MS_Description'
        LEFT  JOIN sys.extended_properties epTwo ON obj.id = epTwo.major_id
                                                         AND epTwo.minor_id = 0
                                                         AND epTwo.name = 'MS_Description'
WHERE   obj.name = 'SCM_Module'--表名
ORDER BY col.colorder ;