Click here to Skip to main content
15,885,899 members
Articles / Database Development / SQL Server
Tip/Trick

Generate Data Dictionary from SQL Server

Rate me:
Please Sign up or sign in to vote.
4.89/5 (10 votes)
27 Feb 2013CPOL 101.6K   21   1
Easily find table description.

Introduction  

This tip shows how to find out table description and dependency with other tables.

Using the code

In any SQL Server database (any version of SQL Server) just create a Stored Procedure [spGenerateDBDictionary] that is given as attachment, and exec [spGenerateDBDictionary]. Then the procedure will return tables information with table name, data, attributes, data types, IsNullable info, primary key, foreign key constraints, any reference with another table, and the details description, but remember that the description will come from the description field where you give any description at the time of table creation.

SQL
USE [Database_Name]
-- =============================================
-- Author:JOHIR
-- Create date: 01/12/2012
-- Description:	GENERATE DATA DICTIONARY FROM SQL SERVER
-- =============================================
CREATE proc [dbo].[spGenerateDBDictionary] 
AS
BEGIN

select a.name [Table],b.name [Attribute],c.name [DataType],b.isnullable [Allow Nulls?],CASE WHEN 
d.name is null THEN 0 ELSE 1 END [PKey?],
CASE WHEN e.parent_object_id is null THEN 0 ELSE 1 END [FKey?],CASE WHEN e.parent_object_id 
is null THEN '-' ELSE g.name  END [Ref Table],
CASE WHEN h.value is null THEN '-' ELSE h.value END [Description]
from sysobjects as a
join syscolumns as b on a.id = b.id
join systypes as c on b.xtype = c.xtype 
left join (SELECT  so.id,sc.colid,sc.name 
      FROM    syscolumns sc
      JOIN sysobjects so ON so.id = sc.id
      JOIN sysindexkeys si ON so.id = si.id 
                    and sc.colid = si.colid
      WHERE si.indid = 1) d on a.id = d.id and b.colid = d.colid
left join sys.foreign_key_columns as e on a.id = e.parent_object_id and b.colid = e.parent_column_id    
left join sys.objects as g on e.referenced_object_id = g.object_id  
left join sys.extended_properties as h on a.id = h.major_id and b.colid = h.minor_id
where a.type = 'U' order by a.name

END

License

This article, along with any associated source code and files, is licensed under The Code Project Open License (CPOL)


Written By
Software Developer Bitopi Group
Bangladesh Bangladesh
More than 5 Years of experience of Software Development area including both Desktop and web based application in the several domain including Banking, Garments Industries etc.

Comments and Discussions

 
PraiseComment Pin
Member 1002399610-Feb-22 18:44
Member 1002399610-Feb-22 18:44 

General General    News News    Suggestion Suggestion    Question Question    Bug Bug    Answer Answer    Joke Joke    Praise Praise    Rant Rant    Admin Admin   

Use Ctrl+Left/Right to switch messages, Ctrl+Up/Down to switch threads, Ctrl+Shift+Left/Right to switch pages.