├── README.md
├── Refer this for latest changes - LatestMigrationScript.sql
├── Step 1- Prerequisite.sql
├── Step 2- Create schema and table.sql
├── Step 3- Export all data to csv.sql
├── Step 4- Generate COPY script for PostgreSQL.sql
├── Step 5- Verify data after export.sql
├── Step 6- Create all PK and unique constraint.sql
├── Step 7- Create all foreign keys.sql
└── Step 8- Create all non clustered and filter indexes.sql
/README.md:
--------------------------------------------------------------------------------
1 | # SQLtoPostgresMigrationScript
2 |
3 | Watch video for use this scripts: https://youtu.be/YKJub0zVztE
4 |
5 | Free tool for SQL Server to PostgreSQL migration: https://youtu.be/FYqrSojiMEQ
6 |
7 | Note:
8 | I also provide commercial support. Please contact if needed.
9 | If you find this solution helpful than donate comfortable amount on papal to my email ID or link https://www.paypal.me/bimlamehla.
10 | Donation is not mandatory, it is just a request to support free tutorials.
11 |
--------------------------------------------------------------------------------
/Refer this for latest changes - LatestMigrationScript.sql:
--------------------------------------------------------------------------------
1 | --Step 1:
2 | create function [dbo].[GetString]
3 | (
4 | @value as nvarchar(max)
5 | )
6 | returns nvarchar(max)
7 | as
8 | begin
9 | return case when @value is null then 'null' when @value = '' then '""' else '"'+ replace(@value,'"','""') + '"' end
10 | end
11 |
12 |
13 | --Step 2:
14 | -- SQL varbinary to bytea postgresql
15 | -- master.dbo.fn_varbintohexstr
16 | -- encode(decode('68656C6C6F','hex'),'escape')
17 | --Schema script
18 | declare @databaseName varchar(100)
19 |
20 | set @databaseName = DB_NAME()
21 |
22 | declare @TableToInclude table (TableName varchar(200))
23 |
24 |
25 | select 'create schema ' + name + '; ALTER SCHEMA public OWNER TO postgres;'
26 | from sys.schemas
27 | where name not like 'db[_]%'
28 | and name <> 'sys'
29 | and name <> 'INFORMATION_SCHEMA'
30 |
31 | --Table script
32 | select cast('create table ' + (
33 | lower(case TABLE_SCHEMA
34 | when 'dbo'
35 | then 'public'
36 | else TABLE_SCHEMA
37 | end
38 | + '.' + table_name)) + char(13) + '(' + STUFF(
39 | (
40 | select lower(', ' + char(13) + (
41 | case column_name
42 | when 'order'
43 | then '"order"'
44 | when 'default'
45 | then '"default"'
46 | when 'offset'
47 | then '"offset"'
48 | else column_name
49 | end
50 | ) + (
51 | case
52 | when DATA_TYPE in (
53 | 'nvarchar'
54 | ,'varchar'
55 | ,'char'
56 | ,'nchar'
57 | )
58 | and CHARACTER_MAXIMUM_LENGTH <> - 1
59 | and CHARACTER_MAXIMUM_LENGTH < 8000
60 | then ' varchar(' + cast(isnull(CHARACTER_MAXIMUM_LENGTH + 100, 8000) as varchar(10)) + ')'
61 | when DATA_TYPE in (
62 | 'nvarchar'
63 | ,'text'
64 | ,'varchar'
65 | ,'char'
66 | ,'nchar'
67 | ,'ntext'
68 | )
69 | or CHARACTER_MAXIMUM_LENGTH = - 1
70 | then ' text'
71 | when DATA_TYPE = 'decimal'
72 | then ' Numeric(' + cast(NUMERIC_PRECISION as varchar(2)) + ',' + cast(numeric_scale as varchar(2)) + ')'
73 | when DATA_TYPE = 'bit'
74 | then ' Boolean' + iif(COLUMN_default = '((0))', ' default false', iif(COLUMN_default = '((1))', ' default true', ''))
75 | when DATA_TYPE = 'tinyint'
76 | then ' smallint' + iif(COLUMN_default is not null, ' default ' + replace(replace(COLUMN_default, '((', ''), '))', ''), '')
77 | when DATA_TYPE = 'date'
78 | then ' date'
79 | when DATA_TYPE = 'datetime'
80 | or DATA_TYPE = 'datetime2'
81 | or DATA_TYPE = 'datetimeoffset'
82 | then ' timestamptz'
83 | when DATA_TYPE = 'timestamp'
84 | then ' bytea'
85 | when DATA_TYPE = 'uniqueidentifier'
86 | then ' UUID'
87 | when DATA_TYPE in (
88 | 'money'
89 | ,'smallmoney'
90 | )
91 | then ' Numeric(8,2)'
92 | when DATA_TYPE in (
93 | 'binary'
94 | ,'varbinary'
95 | ,'image'
96 | )
97 | then ' bytea'
98 | else ' ' + case COLUMNPROPERTY(OBJECT_ID(TABLE_SCHEMA + '.' + TABLE_NAME), COLUMN_NAME, 'IsIdentity')
99 | when 1
100 | then 'serial'
101 | else DATA_TYPE
102 | end
103 | end + iif(IS_Nullable = 'NO', ' not null', ' null') + iif(COLUMN_default = '(newid())', ' default uuid_generate_v1()', ''))
104 | )
105 | from INFORMATION_SCHEMA.COLUMNS
106 | where (
107 | table_name = Results.table_name
108 | and TABLE_SCHEMA = Results.TABLE_SCHEMA
109 | )
110 | for xml PATH('')
111 | ,TYPE
112 | ).value('(./text())[1]', 'VARCHAR(MAX)'), 1, 2, '') + char(13) + ');'+ char(13) + char(13) as xml)
113 | from INFORMATION_SCHEMA.COLUMNS Results
114 | where OBJECT_ID(TABLE_SCHEMA + '.' + table_name) not in (
115 | select object_id
116 | from sys.views
117 | )
118 | and TABLE_SCHEMA + '.' + table_name in (
119 | select tablename
120 | from @TableToInclude
121 | )
122 | or (
123 | select count(1)
124 | from @TableToInclude
125 | ) = 0
126 | group by Results.TABLE_SCHEMA
127 | ,table_name
128 | for xml PATH('')
129 |
130 |
131 | --Step 3:
132 | declare @databaseName varchar(100)
133 | declare @folderPath varchar(100)='C:\GPESDB\CRDB\'
134 | set @databaseName = DB_NAME()
135 |
136 | declare @TableToInclude Table
137 | (
138 | TableName varchar(200)
139 | )
140 |
141 | --Export query prepration
142 | select ROW_NUMBER() over (
143 | order by (
144 | select 1
145 | )
146 | ) rownum
147 | ,'select * FROM ' + @databaseName + '.' + '[' + SCHEMA_NAME(schema_id) + '].[' + t.name + ']' as col1
148 | ,'select ' + STUFF((
149 | select ',' + case
150 | when DATA_TYPE = 'datetime'
151 | or DATA_TYPE = 'datetime2'
152 | then ' Isnull(nullif(convert(nvarchar(28),' + COLUMN_NAME + + ' ,121) ,' + char(39) + char(39) + '), ' + char(39) + 'null' + char(39) + ')'
153 | when DATA_TYPE = 'varchar'
154 | or DATA_TYPE = 'nvarchar' then @databaseName + '.dbo.GetString(' + COLUMN_NAME + ')'
155 | when DATA_TYPE = 'xml'
156 | then @databaseName + '.dbo.GetString(' + ' Isnull(nullif(cast(' + COLUMN_NAME + + ' as nvarchar(max)) ,' + char(39) + char(39) + '), ' + char(39) + 'null' + char(39) + ')' + ')'
157 | when DATA_TYPE = 'binary'
158 | or DATA_TYPE = 'varbinary'
159 | or DATA_TYPE = 'image'
160 | or DATA_TYPE = 'timestamp'
161 | then 'substring(master.dbo.fn_varbintohexstr(' + COLUMN_NAME + '), 3, len(master.dbo.fn_varbintohexstr(' + COLUMN_NAME + ')))'
162 | else ' Isnull(nullif(cast(' + COLUMN_NAME + + ' as nvarchar(max)) ,' + char(39) + char(39) + '), ' + char(39) + 'null' + char(39) + ')'
163 | end
164 | from INFORMATION_SCHEMA.COLUMNS
165 | where TABLE_NAME = t.name
166 | and TABLE_SCHEMA = schema_name(schema_id)
167 | order by table_schema
168 | ,table_name
169 | ,ordinal_position
170 | for xml PATH('')
171 | ), 1, 1, '') + ' FROM ' + @databaseName + '.' + '[' + SCHEMA_NAME(schema_id) + '].[' + t.name + ']' as col2
172 | ,SCHEMA_NAME(schema_id) + '."' + t.name + '"' as col3
173 | into tempQueries
174 | from sys.tables t
175 | where schema_name(schema_id)+'.'+name in(select tablename from @TableToInclude)
176 | or (select count(1) from @TableToInclude)=0
177 |
178 | select * into tempQueriesCopy from tempQueries
179 |
180 | --drop table tempQueriesCopy
181 | --select * from tempQueries
182 | --Export with bcp script
183 | declare @query1 varchar(MAX)
184 | declare @query2 varchar(MAX)
185 | declare @table varchar(MAX)
186 | declare @row int = 0
187 |
188 | while exists (
189 | select top 1 rownum
190 | from tempQueries
191 | )
192 | begin
193 | select top 1 @query1 = col2
194 | ,@query2 = col2
195 | ,@row = rownum
196 | ,@table = col3
197 | from tempQueries
198 |
199 | declare @sql varchar(8000) = ''
200 |
201 | select @sql = 'bcp "' + @query2 + '" queryout "' + @folderPath + replace( @table,'"','') + '.csv" -c -t~ -T -w -S' + @@servername
202 |
203 | print @sql
204 |
205 | exec master..xp_cmdshell @sql
206 |
207 | delete
208 | from tempQueries
209 | where rownum = @row
210 | end
211 |
212 |
213 | ---- To allow advanced options to be changed.
214 | --EXEC sp_configure 'show advanced options', 1;
215 | --GO
216 | ---- To update the currently configured value for advanced options.
217 | --RECONFIGURE;
218 | --GO
219 | ---- To enable the feature.
220 | --EXEC sp_configure 'xp_cmdshell', 1;
221 | --GO
222 | ---- To update the currently configured value for this feature.
223 | --RECONFIGURE;
224 | --GO
225 |
226 |
227 |
228 | --Step 4:
229 | declare @folderPath varchar(100)='C:\GPESDB\CRDB\'
230 | --Copy script
231 | select 'Copy ' + replace(col3, '"', '') + char(13) + 'From ' + char(39) + @folderPath + replace(col3, '"', '') + '.csv' + char(39) + ' DELIMITER ' + char(39) + '~' + char(39) + ' null as ' + char(39) + 'null' + char(39) + ' encoding ' + char(39) + 'windows-1251' + char(39) + ' CSV;' + char(13) + 'select 1;' + char(13)
232 | from tempQueriesCopy
233 | where col3 not in (
234 | select TABLE_SCHEMA + '.' + char(34) + TABLE_NAME + char(34)
235 | from INFORMATION_SCHEMA.COLUMNS
236 | where DATA_TYPE = 'varbinary'
237 | )
238 |
239 |
240 | drop table tempQueries
241 | drop table tempQueriesCopy
242 |
243 | --Step 5:
244 | --PostgreSQL Server Query to get table and row counts
245 | --Ref. Link https://www.periscopedata.com/blog/exact-row-counts-for-every-database-table
246 |
247 | --Function
248 | create or replace function
249 | count_rows(schema text, tablename text) returns integer
250 | as
251 | $body$
252 | declare
253 | result integer;
254 | query varchar;
255 | begin
256 | query := 'SELECT count(1) FROM ' || schema || '.' || tablename;
257 | execute query into result;
258 | return result;
259 | end;
260 | $body$
261 | language plpgsql;
262 |
263 |
264 | --Query
265 | select
266 | table_schema,
267 | table_name,
268 | count_rows(table_schema, table_name)
269 | from information_schema.tables
270 | where
271 | table_schema not in ('pg_catalog', 'information_schema')
272 | and table_type='BASE TABLE'
273 | order by 3 desc
274 |
275 |
276 | --SQL Server Query to get table and row counts
277 | --Ref. Link https://blog.sqlauthority.com/2017/05/24/sql-server-find-row-count-every-table-database-efficiently/
278 |
279 | SELECT SCHEMA_NAME(schema_id) AS [SchemaName],
280 | [Tables].name AS [TableName],
281 | SUM([Partitions].[rows]) AS [TotalRowCount]
282 | FROM sys.tables AS [Tables]
283 | JOIN sys.partitions AS [Partitions]
284 | ON [Tables].[object_id] = [Partitions].[object_id]
285 | AND [Partitions].index_id IN ( 0, 1 )
286 | -- WHERE [Tables].name = N'name of the table'
287 | GROUP BY SCHEMA_NAME(schema_id), [Tables].name;
288 |
289 | --Step 6:
290 | --Ref. link: https://www.mssqltips.com/sqlservertip/3443/script-all-primary-keys-unique-constraints-and-foreign-keys-in-a-sql-server-database-using-tsql/
291 | --Export all PK and unique constraints
292 | declare @SchemaName varchar(100)
293 | declare @TableName varchar(256)
294 | declare @IndexName varchar(256)
295 | declare @ColumnName varchar(100)
296 | declare @is_unique_constraint varchar(100)
297 | declare @IndexTypeDesc varchar(100)
298 | declare @FileGroupName varchar(100)
299 | declare @is_disabled varchar(100)
300 | declare @IndexOptions varchar(max)
301 | declare @IndexColumnId int
302 | declare @IsDescendingKey int
303 | declare @IsIncludedColumn int
304 | declare @TSQLScripCreationIndex varchar(max)
305 | declare @TSQLScripDisableIndex varchar(max)
306 | declare @is_primary_key varchar(100)
307 | declare @TableToInclude Table
308 | (
309 | TableName varchar(200)
310 | )
311 |
312 |
313 | declare CursorIndex cursor for
314 | select schema_name(t.schema_id) [schema_name], t.name, ix.name,
315 | case when ix.is_unique_constraint = 1 then ' UNIQUE ' else '' END
316 | ,case when ix.is_primary_key = 1 then ' PRIMARY KEY ' else '' END
317 | , ix.type_desc,
318 | case when ix.is_padded=1 then 'PAD_INDEX = ON, ' else 'PAD_INDEX = OFF, ' end
319 | + case when ix.allow_page_locks=1 then 'ALLOW_PAGE_LOCKS = ON, ' else 'ALLOW_PAGE_LOCKS = OFF, ' end
320 | + case when ix.allow_row_locks=1 then 'ALLOW_ROW_LOCKS = ON, ' else 'ALLOW_ROW_LOCKS = OFF, ' end
321 | + case when INDEXPROPERTY(t.object_id, ix.name, 'IsStatistics') = 1 then 'STATISTICS_NORECOMPUTE = ON, ' else 'STATISTICS_NORECOMPUTE = OFF, ' end
322 | + case when ix.ignore_dup_key=1 then 'IGNORE_DUP_KEY = ON, ' else 'IGNORE_DUP_KEY = OFF, ' end
323 | + 'SORT_IN_TEMPDB = OFF, FILLFACTOR =' + CAST(ix.fill_factor AS VARCHAR(3)) AS IndexOptions
324 | , FILEGROUP_NAME(ix.data_space_id) FileGroupName
325 | from sys.tables t
326 | inner join sys.indexes ix on t.object_id=ix.object_id
327 | where ix.type>0 and (ix.is_primary_key=1 or ix.is_unique_constraint=1) --and schema_name(tb.schema_id)= @SchemaName and tb.name=@TableName
328 | and t.is_ms_shipped=0 and t.name<>'sysdiagrams'and
329 | ( schema_name(t.schema_id)+'.'+t.name in(select tablename from @TableToInclude)
330 | or (select count(1) from @TableToInclude)=0)
331 | order by schema_name(t.schema_id), t.name, ix.name
332 | open CursorIndex
333 | fetch next from CursorIndex into @SchemaName, @TableName, @IndexName, @is_unique_constraint, @is_primary_key, @IndexTypeDesc, @IndexOptions, @FileGroupName
334 | while (@@fetch_status=0)
335 | begin
336 | declare @IndexColumns varchar(max)
337 | declare @IncludedColumns varchar(max)
338 | set @IndexColumns=''
339 | set @IncludedColumns=''
340 | declare CursorIndexColumn cursor for
341 | select col.name, ixc.is_descending_key, ixc.is_included_column
342 | from sys.tables tb
343 | inner join sys.indexes ix on tb.object_id=ix.object_id
344 | inner join sys.index_columns ixc on ix.object_id=ixc.object_id and ix.index_id= ixc.index_id
345 | inner join sys.columns col on ixc.object_id =col.object_id and ixc.column_id=col.column_id
346 | where ix.type>0 and (ix.is_primary_key=1 or ix.is_unique_constraint=1)
347 | and schema_name(tb.schema_id)=@SchemaName and tb.name=@TableName and ix.name=@IndexName
348 | order by ixc.index_column_id
349 | open CursorIndexColumn
350 | fetch next from CursorIndexColumn into @ColumnName, @IsDescendingKey, @IsIncludedColumn
351 | while (@@fetch_status=0)
352 | begin
353 | if @IsIncludedColumn=0
354 | set @IndexColumns=@IndexColumns + (case @ColumnName when 'order' then '"order"' when 'Default' then '"Default"'
355 | when 'offset' then '"offset"'
356 | else @ColumnName end) +',' --+ case when @IsDescendingKey=1 then ' DESC, ' else ' ASC, ' end
357 | else
358 | set @IncludedColumns=@IncludedColumns + (case @ColumnName when 'order' then '"order"' when 'Default' then '"Default"'
359 | when 'offset' then '"offset"'
360 | else @ColumnName end) +', '
361 |
362 | fetch next from CursorIndexColumn into @ColumnName, @IsDescendingKey, @IsIncludedColumn
363 | end
364 | close CursorIndexColumn
365 | deallocate CursorIndexColumn
366 | set @IndexColumns = substring(@IndexColumns, 1, len(@IndexColumns)-1)
367 | set @IncludedColumns = case when len(@IncludedColumns) >0 then substring(@IncludedColumns, 1, len(@IncludedColumns)-1) else '' end
368 | -- print @IndexColumns
369 | -- print @IncludedColumns
370 |
371 | set @TSQLScripCreationIndex =''
372 | set @TSQLScripDisableIndex =''
373 | set @TSQLScripCreationIndex='ALTER TABLE '+ @SchemaName +'.'+ @TableName + ' ADD CONSTRAINT ' + replace(replace(replace(replace(@IndexName,'Registration','reg'),'Patient','pat'),'Additional','add'),'Organisation','') + @is_unique_constraint + @is_primary_key + + '('+@IndexColumns+') '+
374 | case when len(@IncludedColumns)>0 then CHAR(13) +'INCLUDE (' + @IncludedColumns+ ')' else '' end + '; ' + char(13) + ' select 1;' -- + CHAR(13)+'WITH (' + @IndexOptions+ ') ON ' + QUOTENAME(@FileGroupName) + ';'
375 |
376 | print @TSQLScripCreationIndex
377 | print @TSQLScripDisableIndex
378 |
379 | fetch next from CursorIndex into @SchemaName, @TableName, @IndexName, @is_unique_constraint, @is_primary_key, @IndexTypeDesc, @IndexOptions, @FileGroupName
380 |
381 | end
382 | close CursorIndex
383 | deallocate CursorIndex
384 |
385 |
386 |
387 | --Step 7:
388 | --Ref. link: https://www.mssqltips.com/sqlservertip/3441/script-out-all-sql-server-indexes-in-a-database-using-tsql/
389 | --Exporting all indexes
390 | declare @SchemaName varchar(100)declare @TableName varchar(256)
391 | declare @IndexName varchar(256)
392 | declare @ColumnName varchar(100)
393 | declare @is_unique varchar(100)
394 | declare @IndexTypeDesc varchar(100)
395 | declare @FileGroupName varchar(100)
396 | declare @is_disabled varchar(100)
397 | declare @IndexOptions varchar(max)
398 | declare @IndexColumnId int
399 | declare @IsDescendingKey int
400 | declare @IsIncludedColumn int
401 | declare @TSQLScripCreationIndex varchar(max)
402 | declare @TSQLScripDisableIndex varchar(max)
403 | declare @filter_definition varchar(max)
404 |
405 | declare @BoolColumns table
406 | (
407 | colValue varchar(200),
408 | colReplaceValue varchar(200)
409 | )
410 | insert into @BoolColumns
411 | select distinct COLUMN_NAME+'=(0)',COLUMN_NAME+'=false' from INFORMATION_SCHEMA.COLUMNS where DATA_TYPE='bit'
412 | union
413 | select distinct COLUMN_NAME+'=(1)',COLUMN_NAME+'=true' from INFORMATION_SCHEMA.COLUMNS where DATA_TYPE='bit'
414 |
415 | declare @TableToInclude Table
416 | (
417 | TableName varchar(200)
418 | )
419 |
420 |
421 | declare CursorIndex cursor for
422 | select schema_name(t.schema_id) [schema_name], t.name, ix.name,
423 | case when ix.is_unique = 1 then 'UNIQUE ' else '' END
424 | , ix.type_desc,
425 | case when ix.is_padded=1 then 'PAD_INDEX = ON, ' else 'PAD_INDEX = OFF, ' end
426 | + case when ix.allow_page_locks=1 then 'ALLOW_PAGE_LOCKS = ON, ' else 'ALLOW_PAGE_LOCKS = OFF, ' end
427 | + case when ix.allow_row_locks=1 then 'ALLOW_ROW_LOCKS = ON, ' else 'ALLOW_ROW_LOCKS = OFF, ' end
428 | + case when INDEXPROPERTY(t.object_id, ix.name, 'IsStatistics') = 1 then 'STATISTICS_NORECOMPUTE = ON, ' else 'STATISTICS_NORECOMPUTE = OFF, ' end
429 | + case when ix.ignore_dup_key=1 then 'IGNORE_DUP_KEY = ON, ' else 'IGNORE_DUP_KEY = OFF, ' end
430 | + 'SORT_IN_TEMPDB = OFF, FILLFACTOR =' + CAST(ix.fill_factor AS VARCHAR(3)) AS IndexOptions
431 | , ix.is_disabled , FILEGROUP_NAME(ix.data_space_id) FileGroupName,
432 | filter_definition
433 | from sys.tables t
434 | inner join sys.indexes ix on t.object_id=ix.object_id
435 | where ix.type>0 and ix.is_primary_key=0 and ix.is_unique_constraint=0 --and schema_name(tb.schema_id)= @SchemaName and tb.name=@TableName
436 | and t.is_ms_shipped=0 and t.name<>'sysdiagrams'
437 | and
438 | ( schema_name(t.schema_id)+'.'+t.name in(select tablename from @TableToInclude)
439 | or (select count(1) from @TableToInclude)=0)
440 | order by schema_name(t.schema_id), t.name, ix.name
441 |
442 | open CursorIndex
443 | fetch next from CursorIndex into @SchemaName, @TableName, @IndexName, @is_unique, @IndexTypeDesc, @IndexOptions,@is_disabled, @FileGroupName,@filter_definition
444 |
445 | while (@@fetch_status=0)
446 | begin
447 | declare @IndexColumns varchar(max)
448 | declare @IncludedColumns varchar(max)
449 | declare @DType varchar(max)
450 | set @IndexColumns=''
451 | set @IncludedColumns=''
452 |
453 | declare CursorIndexColumn cursor for
454 | select col.name, ixc.is_descending_key, ixc.is_included_column
455 | from sys.tables tb
456 | inner join sys.indexes ix on tb.object_id=ix.object_id
457 | inner join sys.index_columns ixc on ix.object_id=ixc.object_id and ix.index_id= ixc.index_id
458 | inner join sys.columns col on ixc.object_id =col.object_id and ixc.column_id=col.column_id
459 | inner JOIN sys.types AS ty ON ty.user_type_id=col.user_type_id
460 | where ix.type>0 and (ix.is_primary_key=0 or ix.is_unique_constraint=0)
461 | and schema_name(tb.schema_id)=@SchemaName and tb.name=@TableName and ix.name=@IndexName
462 | order by ixc.index_column_id
463 |
464 | open CursorIndexColumn
465 | fetch next from CursorIndexColumn into @ColumnName, @IsDescendingKey, @IsIncludedColumn
466 |
467 | while (@@fetch_status=0)
468 | begin
469 | if @IsIncludedColumn=0
470 | set @IndexColumns=@IndexColumns + @ColumnName + case when @IsDescendingKey=1 then ' DESC, ' else ' ASC, ' end
471 | else
472 | set @IncludedColumns=@IncludedColumns + @ColumnName +', '
473 |
474 | fetch next from CursorIndexColumn into @ColumnName, @IsDescendingKey, @IsIncludedColumn
475 | end
476 |
477 | close CursorIndexColumn
478 | deallocate CursorIndexColumn
479 |
480 | set @IndexColumns = substring(@IndexColumns, 1, len(@IndexColumns)-1)
481 | set @IncludedColumns = case when len(@IncludedColumns) >0 then substring(@IncludedColumns, 1, len(@IncludedColumns)-1) else '' end
482 |
483 | --set @filter_definition = replace(replace(replace(replace(replace(@filter_definition, '[', ''), ']', ''), '(1)', 'true'), '(0)', 'false'), '=', ' = ')
484 | set @filter_definition = replace(replace(@filter_definition, '[', ''), ']', '')
485 | select @filter_definition = replace(@filter_definition,colValue,colReplaceValue) from @BoolColumns
486 |
487 | set @TSQLScripCreationIndex =''
488 | set @TSQLScripDisableIndex =''
489 | set @TSQLScripCreationIndex='CREATE '+ @is_unique + ' INDEX idx_' + replace(replace(replace(replace(@IndexName,'Registration','reg'),'Patient','pat'),'Additional','add'),'Organisation','org') +' ON ' + @SchemaName +'.'+ @TableName + '('+@IndexColumns+') '+
490 | case when len(@IncludedColumns)>0 then CHAR(13) +'INCLUDE (' + @IncludedColumns+ ')' else '' end + case when @filter_definition is null then '' else ' where ' + @filter_definition end + ';' + char(13) + 'select 1;' + CHAR(13) --+'WITH (' + @IndexOptions+ ') ON ' + QUOTENAME(@FileGroupName) + ';'
491 |
492 | print @TSQLScripCreationIndex
493 | print @TSQLScripDisableIndex
494 |
495 | fetch next from CursorIndex into @SchemaName, @TableName, @IndexName, @is_unique, @IndexTypeDesc, @IndexOptions,@is_disabled, @FileGroupName, @filter_definition
496 |
497 | end
498 | close CursorIndex
499 | deallocate CursorIndex
500 |
501 |
502 | --Step 8:
503 | --Ref. link: https://www.mssqltips.com/sqlservertip/3443/script-all-primary-keys-unique-constraints-and-foreign-keys-in-a-sql-server-database-using-tsql/
504 | --Export all foreign keys
505 | declare @ForeignKeyID int
506 | declare @ForeignKeyName varchar(4000)
507 | declare @ParentTableName varchar(4000)
508 | declare @ParentColumn varchar(4000)
509 | declare @ReferencedTable varchar(4000)
510 | declare @ReferencedColumn varchar(4000)
511 | declare @StrParentColumn varchar(max)
512 | declare @StrReferencedColumn varchar(max)
513 | declare @ParentTableSchema varchar(4000)
514 | declare @ReferencedTableSchema varchar(4000)
515 | declare @TSQLCreationFK varchar(max)
516 |
517 | declare @TableToInclude Table
518 | (
519 | TableName varchar(200)
520 | )
521 |
522 |
523 |
524 | --Written by Percy Reyes www.percyreyes.com
525 | declare CursorFK cursor for select object_id--, name, object_name( parent_object_id)
526 | from sys.foreign_keys
527 | where
528 | ( schema_name(schema_id)+'.'+ object_name( parent_object_id) in(select tablename from @TableToInclude)
529 | or (select count(1) from @TableToInclude)=0)
530 | open CursorFK
531 | fetch next from CursorFK into @ForeignKeyID
532 | while (@@FETCH_STATUS=0)
533 | begin
534 | set @StrParentColumn=''
535 | set @StrReferencedColumn=''
536 | declare CursorFKDetails cursor for
537 | select fk.name ForeignKeyName, schema_name(t1.schema_id) ParentTableSchema,
538 | object_name(fkc.parent_object_id) ParentTable, c1.name ParentColumn,schema_name(t2.schema_id) ReferencedTableSchema,
539 | object_name(fkc.referenced_object_id) ReferencedTable,c2.name ReferencedColumn
540 | from --sys.tables t inner join
541 | sys.foreign_keys fk
542 | inner join sys.foreign_key_columns fkc on fk.object_id=fkc.constraint_object_id
543 | inner join sys.columns c1 on c1.object_id=fkc.parent_object_id and c1.column_id=fkc.parent_column_id
544 | inner join sys.columns c2 on c2.object_id=fkc.referenced_object_id and c2.column_id=fkc.referenced_column_id
545 | inner join sys.tables t1 on t1.object_id=fkc.parent_object_id
546 | inner join sys.tables t2 on t2.object_id=fkc.referenced_object_id
547 | where fk.object_id=@ForeignKeyID
548 |
549 | open CursorFKDetails
550 | fetch next from CursorFKDetails into @ForeignKeyName, @ParentTableSchema, @ParentTableName, @ParentColumn, @ReferencedTableSchema, @ReferencedTable, @ReferencedColumn
551 | while (@@FETCH_STATUS=0)
552 | begin
553 | set @StrParentColumn=@StrParentColumn + ', ' + @ParentColumn
554 | set @StrReferencedColumn=@StrReferencedColumn + ', ' + @ReferencedColumn
555 |
556 | fetch next from CursorFKDetails into @ForeignKeyName, @ParentTableSchema, @ParentTableName, @ParentColumn, @ReferencedTableSchema, @ReferencedTable, @ReferencedColumn
557 | end
558 | close CursorFKDetails
559 | deallocate CursorFKDetails
560 | --print @StrParentColumn
561 | --print @StrReferencedColumn
562 | set @StrParentColumn=substring(@StrParentColumn,2,len(@StrParentColumn))
563 | set @StrReferencedColumn=substring(@StrReferencedColumn,2,len(@StrReferencedColumn))
564 | set @TSQLCreationFK='ALTER TABLE '+ case @ParentTableSchema when 'dbo' then 'public' else @ParentTableSchema end +'.'+ @ParentTableName +' ADD CONSTRAINT '+ replace(replace(replace(replace(@ForeignKeyName,'Registration','reg'),'Patient','pat'),'Additional','add'),'Organisation','org')
565 | + ' FOREIGN KEY('+ltrim(@StrParentColumn)+') '+ char(13) +'REFERENCES '+ case @ReferencedTableSchema when 'dbo' then 'public' else @ReferencedTableSchema end +'.'+ @ReferencedTable+' ('+ltrim(@StrReferencedColumn)+');' + char(13)+'select 1;'
566 |
567 | if not exists
568 | (select * from @TableToInclude where tablename = @ParentTableSchema + '.' + @ParentTableName )
569 | or
570 | not exists
571 | (select * from @TableToInclude where tablename = @ReferencedTableSchema + '.' + @ReferencedTable )
572 | print @TSQLCreationFK
573 |
574 | fetch next from CursorFK into @ForeignKeyID
575 | end
576 | close CursorFK
577 | deallocate CursorFK
578 |
--------------------------------------------------------------------------------
/Step 1- Prerequisite.sql:
--------------------------------------------------------------------------------
1 | create function [dbo].[GetString]
2 | (
3 | @value as nvarchar(max)
4 | )
5 | returns nvarchar(max)
6 | as
7 | begin
8 | return case when @value is null then 'null' when @value = '' then '""' else '"'+ replace(@value,'"','""""') + '"' end
9 | end
--------------------------------------------------------------------------------
/Step 2- Create schema and table.sql:
--------------------------------------------------------------------------------
1 | -- SQL varbinary to bytea postgresql
2 | -- master.dbo.fn_varbintohexstr
3 | -- encode(decode('68656C6C6F','hex'),'escape')
4 | --Schema script
5 | declare @databaseName varchar(100)
6 |
7 | set @databaseName = DB_NAME()
8 |
9 | select 'create schema ' + name + '; ALTER SCHEMA public OWNER TO postgres;'
10 | from sys.schemas
11 | where name not like 'db[_]%'
12 | and name <> 'sys'
13 | and name <> 'INFORMATION_SCHEMA'
14 |
15 | --Table script
16 | select cast('create table ' + TABLE_SCHEMA + '.' + table_name + char(13) + '(' + STUFF((
17 | select ', ' + char(13) + column_name + (
18 | case
19 | when DATA_TYPE in (
20 | 'nvarchar'
21 | ,'varchar',
22 | 'char',
23 | 'nchar'
24 | )
25 | and CHARACTER_MAXIMUM_LENGTH <> - 1 and CHARACTER_MAXIMUM_LENGTH < 8000
26 | then ' varchar(' + cast(isnull(CHARACTER_MAXIMUM_LENGTH, 8000) as varchar(10)) + ')'
27 | when DATA_TYPE in (
28 | 'nvarchar'
29 | ,'text'
30 | ,'varchar',
31 | 'char',
32 | 'nchar',
33 | 'ntext'
34 | )
35 | or CHARACTER_MAXIMUM_LENGTH = - 1
36 | then ' text'
37 | when DATA_TYPE = 'decimal'
38 | then ' Numeric(' + cast(NUMERIC_PRECISION as varchar(2)) + ',' + cast(numeric_scale as varchar(2)) + ')'
39 | when DATA_TYPE = 'bit'
40 | then ' Boolean' + iif(COLUMN_DEFAULT = '((0))', ' Default false', iif(COLUMN_DEFAULT = '((1))', ' Default true', ''))
41 | when DATA_TYPE = 'tinyint'
42 | then ' smallint' + iif(COLUMN_DEFAULT is not null, ' Default ' + replace(replace(COLUMN_DEFAULT, '((', ''), '))', ''), '')
43 | when DATA_TYPE = 'date'
44 | then ' date'
45 | when DATA_TYPE = 'datetime'
46 | or DATA_TYPE = 'datetime2'
47 | then ' timestamptz'
48 | when DATA_TYPE = 'uniqueidentifier'
49 | then ' UUID'
50 | when DATA_TYPE in (
51 | 'money'
52 | ,'smallmoney'
53 | )
54 | then ' Numeric(8,2)'
55 | when DATA_TYPE in (
56 | 'binary'
57 | ,'varbinary'
58 | ,'image'
59 | )
60 | then ' BYTEA'
61 | else ' ' + case COLUMNPROPERTY(OBJECT_ID(TABLE_SCHEMA + '.' + TABLE_NAME), COLUMN_NAME, 'IsIdentity')
62 | when 1
63 | then 'SERIAL'
64 | else DATA_TYPE
65 | end
66 | end
67 | )
68 | from INFORMATION_SCHEMA.COLUMNS
69 | where (
70 | table_name = Results.table_name
71 | and TABLE_SCHEMA = Results.TABLE_SCHEMA
72 | )
73 | for xml PATH('')
74 | ,TYPE
75 | ).value('(./text())[1]', 'VARCHAR(MAX)'), 1, 2, '') + char(13) + ');' + char(13) as xml)
76 | from INFORMATION_SCHEMA.COLUMNS Results
77 | where TABLE_NAME not in (
78 | select [name]
79 | from sys.views
80 | )
81 | group by Results.TABLE_SCHEMA
82 | ,table_name
83 | for xml PATH('')
--------------------------------------------------------------------------------
/Step 3- Export all data to csv.sql:
--------------------------------------------------------------------------------
1 | declare @databaseName varchar(100)
2 | declare @folderPath varchar(100)='C:\Data\'
3 | set @databaseName = DB_NAME()
4 |
5 |
6 | --Export query prepration
7 | select ROW_NUMBER() over (
8 | order by (
9 | select 1
10 | )
11 | ) rownum
12 | ,'select * FROM ' + @databaseName + '.' + '[' + SCHEMA_NAME(schema_id) + '].[' + t.name + ']' as col1
13 | ,'select ' + STUFF((
14 | select ',' + case
15 | when DATA_TYPE = 'datetime'
16 | or DATA_TYPE = 'datetime2'
17 | then ' Isnull(nullif(convert(nvarchar(28),' + COLUMN_NAME + + ' ,121) ,' + char(39) + char(39) + '), ' + char(39) + 'null' + char(39) + ')'
18 | when DATA_TYPE = 'varchar'
19 | or DATA_TYPE = 'nvarchar'
20 | then @databaseName + '.dbo.GetString(' + COLUMN_NAME + ')'
21 | when DATA_TYPE = 'binary'
22 | or DATA_TYPE = 'varbinary'
23 | or DATA_TYPE = 'image'
24 | then 'substring(master.dbo.fn_varbintohexstr(' + COLUMN_NAME + '), 3, len(master.dbo.fn_varbintohexstr(' + COLUMN_NAME + ')))'
25 | else ' Isnull(nullif(cast(' + COLUMN_NAME + + ' as nvarchar(max)) ,' + char(39) + char(39) + '), ' + char(39) + 'null' + char(39) + ')'
26 | end
27 | from INFORMATION_SCHEMA.COLUMNS
28 | where TABLE_NAME = t.name
29 | and TABLE_SCHEMA = schema_name(schema_id)
30 | order by table_schema
31 | ,table_name
32 | ,ordinal_position
33 | for xml PATH('')
34 | ), 1, 1, '') + ' FROM ' + @databaseName + '.' + '[' + SCHEMA_NAME(schema_id) + '].[' + t.name + ']' as col2
35 | ,SCHEMA_NAME(schema_id) + '."' + t.name + '"' as col3
36 | into tempQueries
37 | from sys.tables t
38 |
39 | select * into tempQueriesCopy from tempQueries
40 | --Export with bcp script
41 | declare @query1 varchar(MAX)
42 | declare @query2 varchar(MAX)
43 | declare @table varchar(MAX)
44 | declare @row int = 0
45 |
46 | while exists (
47 | select top 1 rownum
48 | from tempQueries
49 | )
50 | begin
51 | select top 1 @query1 = col2
52 | ,@query2 = col2
53 | ,@row = rownum
54 | ,@table = col3
55 | from tempQueries
56 |
57 | declare @sql varchar(8000) = ''
58 |
59 | select @sql = 'bcp "' + @query2 + '" queryout "' + @folderPath + replace( @table,'"','') + '.csv" -c -t~ -T -S' + @@servername
60 |
61 | print @sql
62 |
63 | exec master..xp_cmdshell @sql
64 |
65 | delete
66 | from tempQueries
67 | where rownum = @row
68 | end
69 |
70 |
71 | ---- To allow advanced options to be changed.
72 | --EXEC sp_configure 'show advanced options', 1;
73 | --GO
74 | ---- To update the currently configured value for advanced options.
75 | --RECONFIGURE;
76 | --GO
77 | ---- To enable the feature.
78 | --EXEC sp_configure 'xp_cmdshell', 1;
79 | --GO
80 | ---- To update the currently configured value for this feature.
81 | --RECONFIGURE;
82 | --GO
--------------------------------------------------------------------------------
/Step 4- Generate COPY script for PostgreSQL.sql:
--------------------------------------------------------------------------------
1 | declare @folderPath varchar(100)='C:\Data\'
2 | --Copy script
3 | select 'Copy ' + replace(col3, '"', '') + char(13) + 'From ' + char(39) + @folderPath + replace(col3, '"', '') + '.csv' + char(39) + ' DELIMITER ' + char(39) + '~' + char(39) + ' null as ' + char(39) + 'null' + char(39) + ' encoding ' + char(39) + 'windows-1251' + char(39) + ' CSV;' + char(13) + 'select 1;' + char(13)
4 | from tempQueriesCopy
5 | where col3 not in (
6 | select TABLE_SCHEMA + '.' + char(34) + TABLE_NAME + char(34)
7 | from INFORMATION_SCHEMA.COLUMNS
8 | where DATA_TYPE = 'varbinary'
9 | )
10 |
11 |
12 | drop table tempQueries
13 | drop table tempQueriesCopy
--------------------------------------------------------------------------------
/Step 5- Verify data after export.sql:
--------------------------------------------------------------------------------
1 | --PostgreSQL Server Query to get table and row counts
2 | --Ref. Link https://www.periscopedata.com/blog/exact-row-counts-for-every-database-table
3 |
4 | --Function
5 | create or replace function
6 | count_rows(schema text, tablename text) returns integer
7 | as
8 | $body$
9 | declare
10 | result integer;
11 | query varchar;
12 | begin
13 | query := 'SELECT count(1) FROM ' || schema || '.' || tablename;
14 | execute query into result;
15 | return result;
16 | end;
17 | $body$
18 | language plpgsql;
19 |
20 |
21 | --Query
22 | select
23 | table_schema,
24 | table_name,
25 | count_rows(table_schema, table_name)
26 | from information_schema.tables
27 | where
28 | table_schema not in ('pg_catalog', 'information_schema')
29 | and table_type='BASE TABLE'
30 | order by 3 desc
31 |
32 |
33 | --SQL Server Query to get table and row counts
34 | --Ref. Link https://blog.sqlauthority.com/2017/05/24/sql-server-find-row-count-every-table-database-efficiently/
35 |
36 | SELECT SCHEMA_NAME(schema_id) AS [SchemaName],
37 | [Tables].name AS [TableName],
38 | SUM([Partitions].[rows]) AS [TotalRowCount]
39 | FROM sys.tables AS [Tables]
40 | JOIN sys.partitions AS [Partitions]
41 | ON [Tables].[object_id] = [Partitions].[object_id]
42 | AND [Partitions].index_id IN ( 0, 1 )
43 | -- WHERE [Tables].name = N'name of the table'
44 | GROUP BY SCHEMA_NAME(schema_id), [Tables].name;
45 |
46 |
--------------------------------------------------------------------------------
/Step 6- Create all PK and unique constraint.sql:
--------------------------------------------------------------------------------
1 | --Ref. link: https://www.mssqltips.com/sqlservertip/3443/script-all-primary-keys-unique-constraints-and-foreign-keys-in-a-sql-server-database-using-tsql/
2 | --Export all PK and unique constraints
3 | declare @SchemaName varchar(100)
4 | declare @TableName varchar(256)
5 | declare @IndexName varchar(256)
6 | declare @ColumnName varchar(100)
7 | declare @is_unique_constraint varchar(100)
8 | declare @IndexTypeDesc varchar(100)
9 | declare @FileGroupName varchar(100)
10 | declare @is_disabled varchar(100)
11 | declare @IndexOptions varchar(max)
12 | declare @IndexColumnId int
13 | declare @IsDescendingKey int
14 | declare @IsIncludedColumn int
15 | declare @TSQLScripCreationIndex varchar(max)
16 | declare @TSQLScripDisableIndex varchar(max)
17 | declare @is_primary_key varchar(100)
18 |
19 | declare CursorIndex cursor for
20 | select schema_name(t.schema_id) [schema_name], t.name, ix.name,
21 | case when ix.is_unique_constraint = 1 then ' UNIQUE ' else '' END
22 | ,case when ix.is_primary_key = 1 then ' PRIMARY KEY ' else '' END
23 | , ix.type_desc,
24 | case when ix.is_padded=1 then 'PAD_INDEX = ON, ' else 'PAD_INDEX = OFF, ' end
25 | + case when ix.allow_page_locks=1 then 'ALLOW_PAGE_LOCKS = ON, ' else 'ALLOW_PAGE_LOCKS = OFF, ' end
26 | + case when ix.allow_row_locks=1 then 'ALLOW_ROW_LOCKS = ON, ' else 'ALLOW_ROW_LOCKS = OFF, ' end
27 | + case when INDEXPROPERTY(t.object_id, ix.name, 'IsStatistics') = 1 then 'STATISTICS_NORECOMPUTE = ON, ' else 'STATISTICS_NORECOMPUTE = OFF, ' end
28 | + case when ix.ignore_dup_key=1 then 'IGNORE_DUP_KEY = ON, ' else 'IGNORE_DUP_KEY = OFF, ' end
29 | + 'SORT_IN_TEMPDB = OFF, FILLFACTOR =' + CAST(ix.fill_factor AS VARCHAR(3)) AS IndexOptions
30 | , FILEGROUP_NAME(ix.data_space_id) FileGroupName
31 | from sys.tables t
32 | inner join sys.indexes ix on t.object_id=ix.object_id
33 | where ix.type>0 and (ix.is_primary_key=1 or ix.is_unique_constraint=1) --and schema_name(tb.schema_id)= @SchemaName and tb.name=@TableName
34 | and t.is_ms_shipped=0 and t.name<>'sysdiagrams'
35 | order by schema_name(t.schema_id), t.name, ix.name
36 | open CursorIndex
37 | fetch next from CursorIndex into @SchemaName, @TableName, @IndexName, @is_unique_constraint, @is_primary_key, @IndexTypeDesc, @IndexOptions, @FileGroupName
38 | while (@@fetch_status=0)
39 | begin
40 | declare @IndexColumns varchar(max)
41 | declare @IncludedColumns varchar(max)
42 | set @IndexColumns=''
43 | set @IncludedColumns=''
44 | declare CursorIndexColumn cursor for
45 | select col.name, ixc.is_descending_key, ixc.is_included_column
46 | from sys.tables tb
47 | inner join sys.indexes ix on tb.object_id=ix.object_id
48 | inner join sys.index_columns ixc on ix.object_id=ixc.object_id and ix.index_id= ixc.index_id
49 | inner join sys.columns col on ixc.object_id =col.object_id and ixc.column_id=col.column_id
50 | where ix.type>0 and (ix.is_primary_key=1 or ix.is_unique_constraint=1)
51 | and schema_name(tb.schema_id)=@SchemaName and tb.name=@TableName and ix.name=@IndexName
52 | order by ixc.index_column_id
53 | open CursorIndexColumn
54 | fetch next from CursorIndexColumn into @ColumnName, @IsDescendingKey, @IsIncludedColumn
55 | while (@@fetch_status=0)
56 | begin
57 | if @IsIncludedColumn=0
58 | set @IndexColumns=@IndexColumns + @ColumnName +',' --+ case when @IsDescendingKey=1 then ' DESC, ' else ' ASC, ' end
59 | else
60 | set @IncludedColumns=@IncludedColumns + @ColumnName +', '
61 |
62 | fetch next from CursorIndexColumn into @ColumnName, @IsDescendingKey, @IsIncludedColumn
63 | end
64 | close CursorIndexColumn
65 | deallocate CursorIndexColumn
66 | set @IndexColumns = substring(@IndexColumns, 1, len(@IndexColumns)-1)
67 | set @IncludedColumns = case when len(@IncludedColumns) >0 then substring(@IncludedColumns, 1, len(@IncludedColumns)-1) else '' end
68 | -- print @IndexColumns
69 | -- print @IncludedColumns
70 |
71 | set @TSQLScripCreationIndex =''
72 | set @TSQLScripDisableIndex =''
73 | set @TSQLScripCreationIndex='ALTER TABLE '+ @SchemaName +'.'+ @TableName + ' ADD CONSTRAINT ' + @IndexName + @is_unique_constraint + @is_primary_key + + '('+@IndexColumns+') '+
74 | case when len(@IncludedColumns)>0 then CHAR(13) +'INCLUDE (' + @IncludedColumns+ ')' else '' end + '; ' + char(13) + ' select 1;' -- + CHAR(13)+'WITH (' + @IndexOptions+ ') ON ' + QUOTENAME(@FileGroupName) + ';'
75 |
76 | print @TSQLScripCreationIndex
77 | print @TSQLScripDisableIndex
78 |
79 | fetch next from CursorIndex into @SchemaName, @TableName, @IndexName, @is_unique_constraint, @is_primary_key, @IndexTypeDesc, @IndexOptions, @FileGroupName
80 |
81 | end
82 | close CursorIndex
83 | deallocate CursorIndex
--------------------------------------------------------------------------------
/Step 7- Create all foreign keys.sql:
--------------------------------------------------------------------------------
1 | --Ref. link: https://www.mssqltips.com/sqlservertip/3443/script-all-primary-keys-unique-constraints-and-foreign-keys-in-a-sql-server-database-using-tsql/
2 | --Export all foreign keys
3 | declare @ForeignKeyID int
4 | declare @ForeignKeyName varchar(4000)
5 | declare @ParentTableName varchar(4000)
6 | declare @ParentColumn varchar(4000)
7 | declare @ReferencedTable varchar(4000)
8 | declare @ReferencedColumn varchar(4000)
9 | declare @StrParentColumn varchar(max)
10 | declare @StrReferencedColumn varchar(max)
11 | declare @ParentTableSchema varchar(4000)
12 | declare @ReferencedTableSchema varchar(4000)
13 | declare @TSQLCreationFK varchar(max)
14 | --Written by Percy Reyes www.percyreyes.com
15 | declare CursorFK cursor for select object_id--, name, object_name( parent_object_id)
16 | from sys.foreign_keys
17 | open CursorFK
18 | fetch next from CursorFK into @ForeignKeyID
19 | while (@@FETCH_STATUS=0)
20 | begin
21 | set @StrParentColumn=''
22 | set @StrReferencedColumn=''
23 | declare CursorFKDetails cursor for
24 | select fk.name ForeignKeyName, schema_name(t1.schema_id) ParentTableSchema,
25 | object_name(fkc.parent_object_id) ParentTable, c1.name ParentColumn,schema_name(t2.schema_id) ReferencedTableSchema,
26 | object_name(fkc.referenced_object_id) ReferencedTable,c2.name ReferencedColumn
27 | from --sys.tables t inner join
28 | sys.foreign_keys fk
29 | inner join sys.foreign_key_columns fkc on fk.object_id=fkc.constraint_object_id
30 | inner join sys.columns c1 on c1.object_id=fkc.parent_object_id and c1.column_id=fkc.parent_column_id
31 | inner join sys.columns c2 on c2.object_id=fkc.referenced_object_id and c2.column_id=fkc.referenced_column_id
32 | inner join sys.tables t1 on t1.object_id=fkc.parent_object_id
33 | inner join sys.tables t2 on t2.object_id=fkc.referenced_object_id
34 | where fk.object_id=@ForeignKeyID
35 | open CursorFKDetails
36 | fetch next from CursorFKDetails into @ForeignKeyName, @ParentTableSchema, @ParentTableName, @ParentColumn, @ReferencedTableSchema, @ReferencedTable, @ReferencedColumn
37 | while (@@FETCH_STATUS=0)
38 | begin
39 | set @StrParentColumn=@StrParentColumn + ', ' + @ParentColumn
40 | set @StrReferencedColumn=@StrReferencedColumn + ', ' + @ReferencedColumn
41 |
42 | fetch next from CursorFKDetails into @ForeignKeyName, @ParentTableSchema, @ParentTableName, @ParentColumn, @ReferencedTableSchema, @ReferencedTable, @ReferencedColumn
43 | end
44 | close CursorFKDetails
45 | deallocate CursorFKDetails
46 |
47 | set @StrParentColumn=substring(@StrParentColumn,2,len(@StrParentColumn)-1)
48 | set @StrReferencedColumn=substring(@StrReferencedColumn,2,len(@StrReferencedColumn)-1)
49 | set @TSQLCreationFK='ALTER TABLE '+ @ParentTableSchema+'.'+ @ParentTableName +' ADD CONSTRAINT '+ @ForeignKeyName
50 | + ' FOREIGN KEY('+ltrim(@StrParentColumn)+') '+ char(13) +'REFERENCES '+ @ReferencedTableSchema +'.'+ @ReferencedTable+' ('+ltrim(@StrReferencedColumn)+');' + char(13)+'select 1;'
51 |
52 | print @TSQLCreationFK
53 |
54 | fetch next from CursorFK into @ForeignKeyID
55 | end
56 | close CursorFK
57 | deallocate CursorFK
--------------------------------------------------------------------------------
/Step 8- Create all non clustered and filter indexes.sql:
--------------------------------------------------------------------------------
1 | --Ref. link: https://www.mssqltips.com/sqlservertip/3441/script-out-all-sql-server-indexes-in-a-database-using-tsql/
2 | --Exporting all indexes
3 | declare @SchemaName varchar(100)declare @TableName varchar(256)
4 | declare @IndexName varchar(256)
5 | declare @ColumnName varchar(100)
6 | declare @is_unique varchar(100)
7 | declare @IndexTypeDesc varchar(100)
8 | declare @FileGroupName varchar(100)
9 | declare @is_disabled varchar(100)
10 | declare @IndexOptions varchar(max)
11 | declare @IndexColumnId int
12 | declare @IsDescendingKey int
13 | declare @IsIncludedColumn int
14 | declare @TSQLScripCreationIndex varchar(max)
15 | declare @TSQLScripDisableIndex varchar(max)
16 | declare @filter_definition varchar(max)
17 |
18 | declare CursorIndex cursor for
19 | select schema_name(t.schema_id) [schema_name], t.name, ix.name,
20 | case when ix.is_unique = 1 then 'UNIQUE ' else '' END
21 | , ix.type_desc,
22 | case when ix.is_padded=1 then 'PAD_INDEX = ON, ' else 'PAD_INDEX = OFF, ' end
23 | + case when ix.allow_page_locks=1 then 'ALLOW_PAGE_LOCKS = ON, ' else 'ALLOW_PAGE_LOCKS = OFF, ' end
24 | + case when ix.allow_row_locks=1 then 'ALLOW_ROW_LOCKS = ON, ' else 'ALLOW_ROW_LOCKS = OFF, ' end
25 | + case when INDEXPROPERTY(t.object_id, ix.name, 'IsStatistics') = 1 then 'STATISTICS_NORECOMPUTE = ON, ' else 'STATISTICS_NORECOMPUTE = OFF, ' end
26 | + case when ix.ignore_dup_key=1 then 'IGNORE_DUP_KEY = ON, ' else 'IGNORE_DUP_KEY = OFF, ' end
27 | + 'SORT_IN_TEMPDB = OFF, FILLFACTOR =' + CAST(ix.fill_factor AS VARCHAR(3)) AS IndexOptions
28 | , ix.is_disabled , FILEGROUP_NAME(ix.data_space_id) FileGroupName,
29 | filter_definition
30 | from sys.tables t
31 | inner join sys.indexes ix on t.object_id=ix.object_id
32 | where ix.type>0 and ix.is_primary_key=0 and ix.is_unique_constraint=0 --and schema_name(tb.schema_id)= @SchemaName and tb.name=@TableName
33 | and t.is_ms_shipped=0 and t.name<>'sysdiagrams'
34 | order by schema_name(t.schema_id), t.name, ix.name
35 |
36 | open CursorIndex
37 | fetch next from CursorIndex into @SchemaName, @TableName, @IndexName, @is_unique, @IndexTypeDesc, @IndexOptions,@is_disabled, @FileGroupName,@filter_definition
38 |
39 | while (@@fetch_status=0)
40 | begin
41 | declare @IndexColumns varchar(max)
42 | declare @IncludedColumns varchar(max)
43 |
44 | set @IndexColumns=''
45 | set @IncludedColumns=''
46 |
47 | declare CursorIndexColumn cursor for
48 | select col.name, ixc.is_descending_key, ixc.is_included_column
49 | from sys.tables tb
50 | inner join sys.indexes ix on tb.object_id=ix.object_id
51 | inner join sys.index_columns ixc on ix.object_id=ixc.object_id and ix.index_id= ixc.index_id
52 | inner join sys.columns col on ixc.object_id =col.object_id and ixc.column_id=col.column_id
53 | where ix.type>0 and (ix.is_primary_key=0 or ix.is_unique_constraint=0)
54 | and schema_name(tb.schema_id)=@SchemaName and tb.name=@TableName and ix.name=@IndexName
55 | order by ixc.index_column_id
56 |
57 | open CursorIndexColumn
58 | fetch next from CursorIndexColumn into @ColumnName, @IsDescendingKey, @IsIncludedColumn
59 |
60 | while (@@fetch_status=0)
61 | begin
62 | if @IsIncludedColumn=0
63 | set @IndexColumns=@IndexColumns + @ColumnName + case when @IsDescendingKey=1 then ' DESC, ' else ' ASC, ' end
64 | else
65 | set @IncludedColumns=@IncludedColumns + @ColumnName +', '
66 |
67 | fetch next from CursorIndexColumn into @ColumnName, @IsDescendingKey, @IsIncludedColumn
68 | end
69 |
70 | close CursorIndexColumn
71 | deallocate CursorIndexColumn
72 |
73 | set @IndexColumns = substring(@IndexColumns, 1, len(@IndexColumns)-1)
74 | set @IncludedColumns = case when len(@IncludedColumns) >0 then substring(@IncludedColumns, 1, len(@IncludedColumns)-1) else '' end
75 |
76 | set @filter_definition = replace(replace(replace(replace(replace(@filter_definition, '[', ''), ']', ''), '(1)', 'true'), '(0)', 'false'), '=', ' = ')
77 |
78 | set @TSQLScripCreationIndex =''
79 | set @TSQLScripDisableIndex =''
80 | set @TSQLScripCreationIndex='CREATE '+ @is_unique + ' INDEX idx_' +@IndexName +' ON ' + @SchemaName +'.'+ @TableName + '('+@IndexColumns+') '+
81 | case when len(@IncludedColumns)>0 then CHAR(13) +'INCLUDE (' + @IncludedColumns+ ')' else '' end + case when @filter_definition is null then '' else ' where ' + @filter_definition end + ';' + char(13) + 'select 1;' + CHAR(13) --+'WITH (' + @IndexOptions+ ') ON ' + QUOTENAME(@FileGroupName) + ';'
82 |
83 | print @TSQLScripCreationIndex
84 | print @TSQLScripDisableIndex
85 |
86 | fetch next from CursorIndex into @SchemaName, @TableName, @IndexName, @is_unique, @IndexTypeDesc, @IndexOptions,@is_disabled, @FileGroupName, @filter_definition
87 |
88 | end
89 | close CursorIndex
90 | deallocate CursorIndex
--------------------------------------------------------------------------------