1
|
|
2
|
|
3
|
CREATE PROC [dbo].[sp_generate_inserts]
|
4
|
(
|
5
|
@table_name varchar(776), -- The table/view for which the INSERT statements will be generated using the existing data
|
6
|
@target_table varchar(776) = NULL, -- Use this parameter to specify a different table name into which the data will be inserted
|
7
|
@include_column_list bit = 1, -- Use this parameter to include/ommit column list in the generated INSERT statement
|
8
|
@from varchar(800) = NULL, -- Use this parameter to filter the rows based on a filter condition (using WHERE)
|
9
|
@include_timestamp bit = 0, -- Specify 1 for this parameter, if you want to include the TIMESTAMP/ROWVERSION column's data in the INSERT statement
|
10
|
@debug_mode bit = 0, -- If @debug_mode is set to 1, the SQL statements constructed by this procedure will be printed for later examination
|
11
|
@owner varchar(64) = NULL, -- Use this parameter if you are not the owner of the table
|
12
|
@ommit_images bit = 0, -- Use this parameter to generate INSERT statements by omitting the 'image' columns
|
13
|
@ommit_identity bit = 0, -- Use this parameter to ommit the identity columns
|
14
|
@top int = NULL, -- Use this parameter to generate INSERT statements only for the TOP n rows
|
15
|
@cols_to_include varchar(8000) = NULL, -- List of columns to be included in the INSERT statement
|
16
|
@cols_to_exclude varchar(8000) = NULL, -- List of columns to be excluded from the INSERT statement
|
17
|
@disable_constraints bit = 0, -- When 1, disables foreign key constraints and enables them after the INSERT statements
|
18
|
@ommit_computed_cols bit = 0 -- When 1, computed columns will not be included in the INSERT statement
|
19
|
|
20
|
)
|
21
|
AS
|
22
|
BEGIN
|
23
|
|
24
|
/***********************************************************************************************************
|
25
|
Procedure: sp_generate_inserts (Build 22)
|
26
|
(Copyright © 2002 Narayana Vyas Kondreddi. All rights reserved.)
|
27
|
|
28
|
Purpose: To generate INSERT statements from existing data.
|
29
|
These INSERTS can be executed to regenerate the data at some other location.
|
30
|
This procedure is also useful to create a database setup, where in you can
|
31
|
script your data along with your table definitions.
|
32
|
|
33
|
Written by: Narayana Vyas Kondreddi
|
34
|
http://vyaskn.tripod.com
|
35
|
http://vyaskn.tripod.com/code/generate_inserts.txt
|
36
|
|
37
|
Acknowledgements:
|
38
|
Divya Kalra -- For beta testing
|
39
|
Mark Charsley -- For reporting a problem with scripting uniqueidentifier columns with NULL values
|
40
|
Artur Zeygman -- For helping me simplify a bit of code for handling non-dbo owned tables
|
41
|
Joris Laperre -- For reporting a regression bug in handling text/ntext columns
|
42
|
|
43
|
Tested on: SQL Server 7.0 and SQL Server 2000
|
44
|
|
45
|
Date created: January 17th 2001 21:52 GMT
|
46
|
|
47
|
Date modified: May 1st 2002 19:50 GMT
|
48
|
|
49
|
Email: vyaskn@hotmail.com
|
50
|
|
51
|
NOTE: This procedure may not work with tables with too many columns.
|
52
|
Results can be unpredictable with huge text columns or SQL Server 2000's sql_variant data types
|
53
|
Whenever possible, Use @include_column_list parameter to ommit column list in the INSERT statement, for better results
|
54
|
IMPORTANT: This procedure is not tested with internation data (Extended characters or Unicode). If needed
|
55
|
you might want to convert the datatypes of character variables in this procedure to their respective unicode counterparts
|
56
|
like nchar and nvarchar
|
57
|
|
58
|
|
59
|
Example 1: To generate INSERT statements for table 'titles':
|
60
|
|
61
|
EXEC sp_generate_inserts 'titles'
|
62
|
|
63
|
Example 2: To ommit the column list in the INSERT statement: (Column list is included by default)
|
64
|
IMPORTANT: If you have too many columns, you are advised to ommit column list, as shown below,
|
65
|
to avoid erroneous results
|
66
|
|
67
|
EXEC sp_generate_inserts 'titles', @include_column_list = 0
|
68
|
|
69
|
Example 3: To generate INSERT statements for 'titlesCopy' table from 'titles' table:
|
70
|
|
71
|
EXEC sp_generate_inserts 'titles', 'titlesCopy'
|
72
|
|
73
|
Example 4: To generate INSERT statements for 'titles' table for only those titles
|
74
|
which contain the word 'Computer' in them:
|
75
|
NOTE: Do not complicate the FROM or WHERE clause here. It's assumed that you are good with T-SQL if you are using this parameter
|
76
|
|
77
|
EXEC sp_generate_inserts 'titles', @from = "from titles where title like '%Computer%'"
|
78
|
|
79
|
Example 5: To specify that you want to include TIMESTAMP column's data as well in the INSERT statement:
|
80
|
(By default TIMESTAMP column's data is not scripted)
|
81
|
|
82
|
EXEC sp_generate_inserts 'titles', @include_timestamp = 1
|
83
|
|
84
|
Example 6: To print the debug information:
|
85
|
|
86
|
EXEC sp_generate_inserts 'titles', @debug_mode = 1
|
87
|
|
88
|
Example 7: If you are not the owner of the table, use @owner parameter to specify the owner name
|
89
|
To use this option, you must have SELECT permissions on that table
|
90
|
|
91
|
EXEC sp_generate_inserts Nickstable, @owner = 'Nick'
|
92
|
|
93
|
Example 8: To generate INSERT statements for the rest of the columns excluding images
|
94
|
When using this otion, DO NOT set @include_column_list parameter to 0.
|
95
|
|
96
|
EXEC sp_generate_inserts imgtable, @ommit_images = 1
|
97
|
|
98
|
Example 9: To generate INSERT statements excluding (ommiting) IDENTITY columns:
|
99
|
(By default IDENTITY columns are included in the INSERT statement)
|
100
|
|
101
|
EXEC sp_generate_inserts mytable, @ommit_identity = 1
|
102
|
|
103
|
Example 10: To generate INSERT statements for the TOP 10 rows in the table:
|
104
|
|
105
|
EXEC sp_generate_inserts mytable, @top = 10
|
106
|
|
107
|
Example 11: To generate INSERT statements with only those columns you want:
|
108
|
|
109
|
EXEC sp_generate_inserts titles, @cols_to_include = "'title','title_id','au_id'"
|
110
|
|
111
|
Example 12: To generate INSERT statements by omitting certain columns:
|
112
|
|
113
|
EXEC sp_generate_inserts titles, @cols_to_exclude = "'title','title_id','au_id'"
|
114
|
|
115
|
Example 13: To avoid checking the foreign key constraints while loading data with INSERT statements:
|
116
|
|
117
|
EXEC sp_generate_inserts titles, @disable_constraints = 1
|
118
|
|
119
|
Example 14: To exclude computed columns from the INSERT statement:
|
120
|
EXEC sp_generate_inserts MyTable, @ommit_computed_cols = 1
|
121
|
***********************************************************************************************************/
|
122
|
|
123
|
SET NOCOUNT ON
|
124
|
|
125
|
--Making sure user only uses either @cols_to_include or @cols_to_exclude
|
126
|
IF ((@cols_to_include IS NOT NULL) AND (@cols_to_exclude IS NOT NULL))
|
127
|
BEGIN
|
128
|
RAISERROR('Use either @cols_to_include or @cols_to_exclude. Do not use both the parameters at once',16,1)
|
129
|
RETURN -1 --Failure. Reason: Both @cols_to_include and @cols_to_exclude parameters are specified
|
130
|
END
|
131
|
|
132
|
--Making sure the @cols_to_include and @cols_to_exclude parameters are receiving values in proper format
|
133
|
IF ((@cols_to_include IS NOT NULL) AND (PATINDEX('''%''',@cols_to_include) = 0))
|
134
|
BEGIN
|
135
|
RAISERROR('Invalid use of @cols_to_include property',16,1)
|
136
|
PRINT 'Specify column names surrounded by single quotes and separated by commas'
|
137
|
PRINT 'Eg: EXEC sp_generate_inserts titles, @cols_to_include = "''title_id'',''title''"'
|
138
|
RETURN -1 --Failure. Reason: Invalid use of @cols_to_include property
|
139
|
END
|
140
|
|
141
|
IF ((@cols_to_exclude IS NOT NULL) AND (PATINDEX('''%''',@cols_to_exclude) = 0))
|
142
|
BEGIN
|
143
|
RAISERROR('Invalid use of @cols_to_exclude property',16,1)
|
144
|
PRINT 'Specify column names surrounded by single quotes and separated by commas'
|
145
|
PRINT 'Eg: EXEC sp_generate_inserts titles, @cols_to_exclude = "''title_id'',''title''"'
|
146
|
RETURN -1 --Failure. Reason: Invalid use of @cols_to_exclude property
|
147
|
END
|
148
|
|
149
|
|
150
|
--Checking to see if the database name is specified along wih the table name
|
151
|
--Your database context should be local to the table for which you want to generate INSERT statements
|
152
|
--specifying the database name is not allowed
|
153
|
IF (PARSENAME(@table_name,3)) IS NOT NULL
|
154
|
BEGIN
|
155
|
RAISERROR('Do not specify the database name. Be in the required database and just specify the table name.',16,1)
|
156
|
RETURN -1 --Failure. Reason: Database name is specified along with the table name, which is not allowed
|
157
|
END
|
158
|
|
159
|
--Checking for the existence of 'user table' or 'view'
|
160
|
--This procedure is not written to work on system tables
|
161
|
--To script the data in system tables, just create a view on the system tables and script the view instead
|
162
|
|
163
|
IF @owner IS NULL
|
164
|
BEGIN
|
165
|
IF ((OBJECT_ID(@table_name,'U') IS NULL) AND (OBJECT_ID(@table_name,'V') IS NULL))
|
166
|
BEGIN
|
167
|
RAISERROR('User table or view not found.',16,1)
|
168
|
PRINT 'You may see this error, if you are not the owner of this table or view. In that case use @owner parameter to specify the owner name.'
|
169
|
PRINT 'Make sure you have SELECT permission on that table or view.'
|
170
|
RETURN -1 --Failure. Reason: There is no user table or view with this name
|
171
|
END
|
172
|
END
|
173
|
ELSE
|
174
|
BEGIN
|
175
|
IF NOT EXISTS (SELECT 1 FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = @table_name AND (TABLE_TYPE = 'BASE TABLE' OR TABLE_TYPE = 'VIEW') AND TABLE_SCHEMA = @owner)
|
176
|
BEGIN
|
177
|
RAISERROR('User table or view not found.',16,1)
|
178
|
PRINT 'You may see this error, if you are not the owner of this table. In that case use @owner parameter to specify the owner name.'
|
179
|
PRINT 'Make sure you have SELECT permission on that table or view.'
|
180
|
RETURN -1 --Failure. Reason: There is no user table or view with this name
|
181
|
END
|
182
|
END
|
183
|
|
184
|
--Variable declarations
|
185
|
DECLARE @Column_ID int,
|
186
|
@Column_List varchar(8000),
|
187
|
@Column_Name varchar(128),
|
188
|
@Start_Insert varchar(786),
|
189
|
@Data_Type varchar(128),
|
190
|
@Actual_Values varchar(8000), --This is the string that will be finally executed to generate INSERT statements
|
191
|
@IDN varchar(128) --Will contain the IDENTITY column's name in the table
|
192
|
|
193
|
--Variable Initialization
|
194
|
SET @IDN = ''
|
195
|
SET @Column_ID = 0
|
196
|
SET @Column_Name = ''
|
197
|
SET @Column_List = ''
|
198
|
SET @Actual_Values = ''
|
199
|
|
200
|
IF @owner IS NULL
|
201
|
BEGIN
|
202
|
SET @Start_Insert = 'INSERT INTO ' + '[' + RTRIM(COALESCE(@target_table,@table_name)) + ']'
|
203
|
END
|
204
|
ELSE
|
205
|
BEGIN
|
206
|
SET @Start_Insert = 'INSERT ' + '[' + LTRIM(RTRIM(@owner)) + '].' + '[' + RTRIM(COALESCE(@target_table,@table_name)) + ']'
|
207
|
END
|
208
|
|
209
|
|
210
|
--To get the first column's ID
|
211
|
|
212
|
SELECT @Column_ID = MIN(ORDINAL_POSITION)
|
213
|
FROM INFORMATION_SCHEMA.COLUMNS (NOLOCK)
|
214
|
WHERE TABLE_NAME = @table_name AND
|
215
|
(@owner IS NULL OR TABLE_SCHEMA = @owner)
|
216
|
|
217
|
|
218
|
|
219
|
--Loop through all the columns of the table, to get the column names and their data types
|
220
|
WHILE @Column_ID IS NOT NULL
|
221
|
BEGIN
|
222
|
SELECT @Column_Name = QUOTENAME(COLUMN_NAME),
|
223
|
@Data_Type = DATA_TYPE
|
224
|
FROM INFORMATION_SCHEMA.COLUMNS (NOLOCK)
|
225
|
WHERE ORDINAL_POSITION = @Column_ID AND
|
226
|
TABLE_NAME = @table_name AND
|
227
|
(@owner IS NULL OR TABLE_SCHEMA = @owner)
|
228
|
|
229
|
|
230
|
|
231
|
IF @cols_to_include IS NOT NULL --Selecting only user specified columns
|
232
|
BEGIN
|
233
|
IF CHARINDEX( '''' + SUBSTRING(@Column_Name,2,LEN(@Column_Name)-2) + '''',@cols_to_include) = 0
|
234
|
BEGIN
|
235
|
GOTO SKIP_LOOP
|
236
|
END
|
237
|
END
|
238
|
|
239
|
IF @cols_to_exclude IS NOT NULL --Selecting only user specified columns
|
240
|
BEGIN
|
241
|
IF CHARINDEX( '''' + SUBSTRING(@Column_Name,2,LEN(@Column_Name)-2) + '''',@cols_to_exclude) <> 0
|
242
|
BEGIN
|
243
|
GOTO SKIP_LOOP
|
244
|
END
|
245
|
END
|
246
|
|
247
|
--Making sure to output SET IDENTITY_INSERT ON/OFF in case the table has an IDENTITY column
|
248
|
IF (SELECT COLUMNPROPERTY( OBJECT_ID(QUOTENAME(COALESCE(@owner,USER_NAME())) + '.' + @table_name),SUBSTRING(@Column_Name,2,LEN(@Column_Name) - 2),'IsIdentity')) = 1
|
249
|
BEGIN
|
250
|
IF @ommit_identity = 0 --Determing whether to include or exclude the IDENTITY column
|
251
|
SET @IDN = @Column_Name
|
252
|
ELSE
|
253
|
GOTO SKIP_LOOP
|
254
|
END
|
255
|
|
256
|
--Making sure whether to output computed columns or not
|
257
|
IF @ommit_computed_cols = 1
|
258
|
BEGIN
|
259
|
IF (SELECT COLUMNPROPERTY( OBJECT_ID(QUOTENAME(COALESCE(@owner,USER_NAME())) + '.' + @table_name),SUBSTRING(@Column_Name,2,LEN(@Column_Name) - 2),'IsComputed')) = 1
|
260
|
BEGIN
|
261
|
GOTO SKIP_LOOP
|
262
|
END
|
263
|
END
|
264
|
|
265
|
--Tables with columns of IMAGE data type are not supported for obvious reasons
|
266
|
IF(@Data_Type in ('image'))
|
267
|
BEGIN
|
268
|
IF (@ommit_images = 0)
|
269
|
BEGIN
|
270
|
RAISERROR('Tables with image columns are not supported.',16,1)
|
271
|
PRINT 'Use @ommit_images = 1 parameter to generate INSERTs for the rest of the columns.'
|
272
|
PRINT 'DO NOT ommit Column List in the INSERT statements. If you ommit column list using @include_column_list=0, the generated INSERTs will fail.'
|
273
|
RETURN -1 --Failure. Reason: There is a column with image data type
|
274
|
END
|
275
|
ELSE
|
276
|
BEGIN
|
277
|
GOTO SKIP_LOOP
|
278
|
END
|
279
|
END
|
280
|
|
281
|
|
282
|
--Determining the data type of the column and depending on the data type, the VALUES part of
|
283
|
--the INSERT statement is generated. Care is taken to handle columns with NULL values. Also
|
284
|
--making sure, not to lose any data from flot, real, money, smallmomey, datetime columns
|
285
|
SET @Actual_Values = @Actual_Values +
|
286
|
CASE
|
287
|
WHEN @Data_Type IN ('char','varchar','nchar','nvarchar')
|
288
|
THEN
|
289
|
'COALESCE(''N'''''' + REPLACE(RTRIM(' + @Column_Name + '),'''''''','''''''''''')+'''''''',''NULL'')'
|
290
|
WHEN @Data_Type IN ('datetime','smalldatetime','date','datetime2')
|
291
|
THEN
|
292
|
'COALESCE(''N'''''' + RTRIM(CONVERT(char,' + @Column_Name + '))+'''''''',''NULL'')'
|
293
|
WHEN @Data_Type IN ('uniqueidentifier')
|
294
|
THEN
|
295
|
'COALESCE('''''''' + REPLACE(CONVERT(char(255),RTRIM(' + @Column_Name + ')),'''''''','''''''''''')+'''''''',''NULL'')'
|
296
|
WHEN @Data_Type IN ('text','ntext')
|
297
|
THEN
|
298
|
'COALESCE('''''''' + REPLACE(CONVERT(char(8000),' + @Column_Name + '),'''''''','''''''''''')+'''''''',''NULL'')'
|
299
|
WHEN @Data_Type IN ('binary','varbinary')
|
300
|
THEN
|
301
|
'COALESCE(RTRIM(CONVERT(char,' + 'CONVERT(int,' + @Column_Name + '))),''NULL'')'
|
302
|
WHEN @Data_Type IN ('timestamp','rowversion')
|
303
|
THEN
|
304
|
CASE
|
305
|
WHEN @include_timestamp = 0
|
306
|
THEN
|
307
|
'''DEFAULT'''
|
308
|
ELSE
|
309
|
'COALESCE(RTRIM(CONVERT(char,' + 'CONVERT(int,' + @Column_Name + '))),''NULL'')'
|
310
|
END
|
311
|
WHEN @Data_Type IN ('float','real','money','smallmoney')
|
312
|
THEN
|
313
|
'COALESCE(LTRIM(RTRIM(' + 'CONVERT(char, ' + @Column_Name + ',2)' + ')),''NULL'')'
|
314
|
ELSE
|
315
|
'COALESCE(LTRIM(RTRIM(' + 'CONVERT(char, ' + @Column_Name + ')' + ')),''NULL'')'
|
316
|
END + '+' + ''',''' + ' + '
|
317
|
|
318
|
|
319
|
|
320
|
--Generating the column list for the INSERT statement
|
321
|
SET @Column_List = @Column_List + @Column_Name + ','
|
322
|
|
323
|
SKIP_LOOP: --The label used in GOTO
|
324
|
|
325
|
SELECT @Column_ID = MIN(ORDINAL_POSITION)
|
326
|
FROM INFORMATION_SCHEMA.COLUMNS (NOLOCK)
|
327
|
WHERE TABLE_NAME = @table_name AND
|
328
|
ORDINAL_POSITION > @Column_ID AND
|
329
|
(@owner IS NULL OR TABLE_SCHEMA = @owner)
|
330
|
|
331
|
|
332
|
--Loop ends here!
|
333
|
END
|
334
|
|
335
|
--To get rid of the extra characters that got concatenated during the last run through the loop
|
336
|
SET @Column_List = LEFT(@Column_List,len(@Column_List) - 1)
|
337
|
SET @Actual_Values = LEFT(@Actual_Values,len(@Actual_Values) - 6)
|
338
|
|
339
|
IF LTRIM(@Column_List) = ''
|
340
|
BEGIN
|
341
|
RAISERROR('No columns to select. There should at least be one column to generate the output',16,1)
|
342
|
RETURN -1 --Failure. Reason: Looks like all the columns are ommitted using the @cols_to_exclude parameter
|
343
|
END
|
344
|
|
345
|
--Forming the final string that will be executed, to output the INSERT statements
|
346
|
IF (@include_column_list <> 0)
|
347
|
BEGIN
|
348
|
SET @Actual_Values =
|
349
|
'SELECT ' +
|
350
|
CASE WHEN @top IS NULL OR @top < 0 THEN '' ELSE ' TOP ' + LTRIM(STR(@top)) + ' ' END +
|
351
|
'''' + RTRIM(@Start_Insert) +
|
352
|
' ''+' + '''(' + RTRIM(@Column_List) + '''+' + ''')''' +
|
353
|
' +''VALUES(''+ ' + @Actual_Values + '+'')''' + ' ' +
|
354
|
COALESCE(@from,' FROM ' + CASE WHEN @owner IS NULL THEN '' ELSE '[' + LTRIM(RTRIM(@owner)) + '].' END + '[' + rtrim(@table_name) + ']' + '(NOLOCK)')
|
355
|
END
|
356
|
ELSE IF (@include_column_list = 0)
|
357
|
BEGIN
|
358
|
SET @Actual_Values =
|
359
|
'SELECT ' +
|
360
|
CASE WHEN @top IS NULL OR @top < 0 THEN '' ELSE ' TOP ' + LTRIM(STR(@top)) + ' ' END +
|
361
|
'''' + RTRIM(@Start_Insert) +
|
362
|
' '' +''VALUES(''+ ' + @Actual_Values + '+'')''' + ' ' +
|
363
|
COALESCE(@from,' FROM ' + CASE WHEN @owner IS NULL THEN '' ELSE '[' + LTRIM(RTRIM(@owner)) + '].' END + '[' + rtrim(@table_name) + ']' + '(NOLOCK)')
|
364
|
END
|
365
|
|
366
|
--Determining whether to ouput any debug information
|
367
|
IF @debug_mode =1
|
368
|
BEGIN
|
369
|
PRINT '/*****START OF DEBUG INFORMATION*****'
|
370
|
PRINT 'Beginning of the INSERT statement:'
|
371
|
PRINT @Start_Insert
|
372
|
PRINT ''
|
373
|
PRINT 'The column list:'
|
374
|
PRINT @Column_List
|
375
|
PRINT ''
|
376
|
PRINT 'The SELECT statement executed to generate the INSERTs'
|
377
|
PRINT @Actual_Values
|
378
|
PRINT ''
|
379
|
PRINT '*****END OF DEBUG INFORMATION*****/'
|
380
|
PRINT ''
|
381
|
END
|
382
|
|
383
|
PRINT '--INSERTs generated by ''sp_generate_inserts'' stored procedure written by Vyas'
|
384
|
PRINT '--Build number: 22'
|
385
|
PRINT '--Problems/Suggestions? Contact Vyas @ vyaskn@hotmail.com'
|
386
|
PRINT '--http://vyaskn.tripod.com'
|
387
|
PRINT ''
|
388
|
PRINT 'SET NOCOUNT ON'
|
389
|
PRINT ''
|
390
|
|
391
|
|
392
|
--Determining whether to print IDENTITY_INSERT or not
|
393
|
IF (@IDN <> '')
|
394
|
BEGIN
|
395
|
PRINT 'SET IDENTITY_INSERT ' + QUOTENAME(COALESCE(@owner,USER_NAME())) + '.' + QUOTENAME(@table_name) + ' ON'
|
396
|
PRINT 'GO'
|
397
|
PRINT ''
|
398
|
END
|
399
|
|
400
|
|
401
|
IF @disable_constraints = 1 AND (OBJECT_ID(QUOTENAME(COALESCE(@owner,USER_NAME())) + '.' + @table_name, 'U') IS NOT NULL)
|
402
|
BEGIN
|
403
|
IF @owner IS NULL
|
404
|
BEGIN
|
405
|
SELECT 'ALTER TABLE ' + QUOTENAME(COALESCE(@target_table, @table_name)) + ' NOCHECK CONSTRAINT ALL' AS '--Code to disable constraints temporarily'
|
406
|
END
|
407
|
ELSE
|
408
|
BEGIN
|
409
|
SELECT 'ALTER TABLE ' + QUOTENAME(@owner) + '.' + QUOTENAME(COALESCE(@target_table, @table_name)) + ' NOCHECK CONSTRAINT ALL' AS '--Code to disable constraints temporarily'
|
410
|
END
|
411
|
|
412
|
PRINT 'GO'
|
413
|
END
|
414
|
|
415
|
PRINT ''
|
416
|
PRINT 'PRINT ''Inserting values into ' + '[' + RTRIM(COALESCE(@target_table,@table_name)) + ']' + ''''
|
417
|
|
418
|
|
419
|
--All the hard work pays off here!!! You'll get your INSERT statements, when the next line executes!
|
420
|
EXEC (@Actual_Values)
|
421
|
|
422
|
PRINT 'PRINT ''Done'''
|
423
|
PRINT ''
|
424
|
|
425
|
|
426
|
IF @disable_constraints = 1 AND (OBJECT_ID(QUOTENAME(COALESCE(@owner,USER_NAME())) + '.' + @table_name, 'U') IS NOT NULL)
|
427
|
BEGIN
|
428
|
IF @owner IS NULL
|
429
|
BEGIN
|
430
|
SELECT 'ALTER TABLE ' + QUOTENAME(COALESCE(@target_table, @table_name)) + ' CHECK CONSTRAINT ALL' AS '--Code to enable the previously disabled constraints'
|
431
|
END
|
432
|
ELSE
|
433
|
BEGIN
|
434
|
SELECT 'ALTER TABLE ' + QUOTENAME(@owner) + '.' + QUOTENAME(COALESCE(@target_table, @table_name)) + ' CHECK CONSTRAINT ALL' AS '--Code to enable the previously disabled constraints'
|
435
|
END
|
436
|
|
437
|
PRINT 'GO'
|
438
|
END
|
439
|
|
440
|
PRINT ''
|
441
|
IF (@IDN <> '')
|
442
|
BEGIN
|
443
|
PRINT 'SET IDENTITY_INSERT ' + QUOTENAME(COALESCE(@owner,USER_NAME())) + '.' + QUOTENAME(@table_name) + ' OFF'
|
444
|
PRINT 'GO'
|
445
|
END
|
446
|
|
447
|
PRINT 'SET NOCOUNT OFF'
|
448
|
|
449
|
|
450
|
SET NOCOUNT OFF
|
451
|
RETURN 0 --Success. We are done!
|
452
|
END
|
453
|
|
454
|
|
455
|
GO
|
456
|
|