Skip to content

Instantly share code, notes, and snippets.

@random82
Created February 4, 2019 06:06
Show Gist options
  • Save random82/e3ef88e92ab8cd850c9f86e69d87a4de to your computer and use it in GitHub Desktop.
Save random82/e3ef88e92ab8cd850c9f86e69d87a4de to your computer and use it in GitHub Desktop.
Generate SQL tables schema checksums
WITH cte_tableScripts AS (
SELECT
so.name AS TableName,
'CREATE TABLE [' + so.name + '] (' + o.list + ')' + CASE WHEN tc.Constraint_Name IS NULL THEN '' ELSE 'ALTER TABLE ' + so.Name + ' ADD CONSTRAINT ' + tc.Constraint_Name + ' PRIMARY KEY ' + ' (' + LEFT(j.List, Len(j.List)-1) + ')' END AS Script
FROM sysobjects so
CROSS apply
(SELECT
' ['+column_name+'] ' +
data_type + CASE data_type
WHEN 'sql_variant' THEN ''
WHEN 'text' THEN ''
WHEN 'ntext' THEN ''
WHEN 'xml' THEN ''
WHEN 'decimal' THEN '(' + cast(numeric_precision AS varchar) + ', ' + cast(numeric_scale AS varchar) + ')'
ELSE coalesce('('+CASE WHEN character_maximum_length = -1 THEN 'MAX' ELSE cast(character_maximum_length AS varchar) END +')','') END + ' ' +
CASE WHEN EXISTS (
SELECT id FROM syscolumns
where object_name(id)=so.name
AND name=column_name
AND columnproperty(id,name,'IsIdentity') = 1
) THEN
'IDENTITY(' +
cast(ident_seed(so.name) AS varchar) + ',' +
cast(ident_incr(so.name) AS varchar) + ')'
ELSE ''
END + ' ' +
(CASE WHEN IS_NULLABLE = 'No' THEN 'NOT ' ELSE '' END ) + 'NULL ' +
CASE WHEN information_schema.columns.COLUMN_DEFAULT IS NOT NULL THEN 'DEFAULT '+ information_schema.columns.COLUMN_DEFAULT ELSE '' END + ', '
FROM information_schema.columns where table_name = so.name
order by ordinal_position
FOR XML PATH('')) o (list)
LEFT JOIN
information_schema.table_constraints tc
ON tc.Table_name = so.Name
AND tc.Constraint_Type = 'PRIMARY KEY'
CROSS APPLY
(SELECT '[' + Column_Name + '], '
FROM information_schema.key_column_usage kcu
WHERE kcu.Constraint_Name = tc.Constraint_Name
ORDER BY
ORDINAL_POSITION
FOR XML PATH('')) j (list)
WHERE xtype = 'U'
AND NAME NOT IN ('dtproperties')
)
SELECT
TableName,
Script,
HASHBYTES('SHA1', Script) AS SHA
FROM cte_tableScripts
Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment