|
|
|
This procedure generates INSERT statements using existing data from the given tables and views. Later, you can use these INSERT statements to generate the data. It's very useful when you have to ship or package a database application. This procedure also comes in handy when you have to send sample data to your vendor or technical support provider for troubleshooting purposes.
Advantages: Data from both tables and views can be scripted No CURSORs are used Table names and column names with spaces are handled All datatypes are handled except images, large text and binary columns with more than 4 bytes NULLs are gracefully handled Timestamp columns are handled Identity columns are handled Very flexible and configurable Non-dbo owned tables are handled Computed columns are handled You can filter the rows for which you want to generate INSERTs
Usage:
Example 1: To generate INSERT statements for table 'titles': |
Example 2: To ommit the column list in the INSERT statement: (Column list is included by default) NOTE: If you have too many columns, you are advised to ommit column list, as shown below, to avoid erroneous results |
Example 3: To generate INSERT statements for 'titlesCopy' table from 'titles' table: |
Example 4: To generate INSERT statements for 'titles' table for only those titles which contain the word 'Computer' in them: |
Example 5: To specify that you want to include TIMESTAMP column's data as well in the INSERT statement: NOTE: By default TIMESTAMP column's data is not scripted |
Example 6: To print the debug information: |
Example 7: If you are not the owner of the table, use @owner parameter to specify the owner name: NOTE: To use this option, you must have SELECT permissions on that table |
Example 8: To generate INSERT statements for the rest of the columns excluding images: NOTE: When using this otion, DO NOT set @include_column_list parameter to 0 |
Example 9: To generate INSERT statements for the rest of the columns excluding IDENTITY column: |
Example 10: To generate INSERT statements for the top 10 rows in the table: |
Example 11: To generate INSERT statements only with the columns you want: |
Example 12: To generate INSERT statements by ommitting some columns: |
Example 13: To avoid checking the foreign key constraints while loading data with INSERT statements: NOTE: The @disable_constraints option will disable foreign key constraints, by assuming that the source data is valid and referentially sound |
Example 14: To avoid scripting data from computed columns: |
NOTE: Please see the code and read the comments to understand more about how this procedure works!
To generate INSERT statements for all the tables in your database, execute the following query in that database, which will output the commands, that you need to execute for the same: |
Click here to copy the following block | SELECT 'EXEC sp_generate_inserts ' + '[' + name + ']' + ',@owner = ' + '[' + RTRIM(USER_NAME(uid)) + '],' + '@ommit_images = 1, @disable_constraints = 1' FROM sysobjects WHERE type = 'U' AND OBJECTPROPERTY(id,'ismsshipped') = 0 |
Click here to copy the following block | SET NOCOUNT ON GO
PRINT 'Using Master database' USE master GO
PRINT 'Checking for the existence of this procedure' IF (SELECT OBJECT_ID('sp_generate_inserts','P')) IS NOT NULL BEGIN PRINT 'Procedure already exists. So, dropping it' DROP PROC sp_generate_inserts END GO
EXEC master.dbo.sp_MS_upd_sysobj_category 1 GO
CREATE PROC sp_generate_inserts ( @table_name varchar(776), @target_table varchar(776) = NULL, @include_column_list bit = 1, @from varchar(800) = NULL, @include_timestamp bit = 0, @debug_mode bit = 0, @owner varchar(64) = NULL, @ommit_images bit = 0, @ommit_identity bit = 0, @top int = NULL, @cols_to_include varchar(8000) = NULL, @cols_to_exclude varchar(8000) = NULL, @disable_constraints bit = 0, @ommit_computed_cols bit = 0 ) AS BEGIN
SET NOCOUNT ON
IF ((@cols_to_include IS NOT NULL) AND (@cols_to_exclude IS NOT NULL)) BEGIN RAISERROR('Use either @cols_to_include or @cols_to_exclude. Do not use both the parameters at once',16,1) RETURN -1 END
IF ((@cols_to_include IS NOT NULL) AND (PATINDEX('''%''',@cols_to_include) = 0)) BEGIN RAISERROR('Invalid use of @cols_to_include property',16,1) PRINT 'Specify column names surrounded by single quotes and separated by commas' PRINT 'Eg: EXEC sp_generate_inserts titles, @cols_to_include = "''title_id'',''title''"' RETURN -1 END
IF ((@cols_to_exclude IS NOT NULL) AND (PATINDEX('''%''',@cols_to_exclude) = 0)) BEGIN RAISERROR('Invalid use of @cols_to_exclude property',16,1) PRINT 'Specify column names surrounded by single quotes and separated by commas' PRINT 'Eg: EXEC sp_generate_inserts titles, @cols_to_exclude = "''title_id'',''title''"' RETURN -1 END
IF (PARSENAME(@table_name,3)) IS NOT NULL BEGIN RAISERROR('Do not specify the database name. Be in the required database and just specify the table name.',16,1) RETURN -1 END
IF @owner IS NULL BEGIN IF ((OBJECT_ID(@table_name,'U') IS NULL) AND (OBJECT_ID(@table_name,'V') IS NULL)) BEGIN RAISERROR('User table or view not found.',16,1) 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.' PRINT 'Make sure you have SELECT permission on that table or view.' RETURN -1 END END ELSE BEGIN 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) BEGIN RAISERROR('User table or view not found.',16,1) 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.' PRINT 'Make sure you have SELECT permission on that table or view.' RETURN -1 END END
DECLARE @Column_ID int, @Column_List varchar(8000), @Column_Name varchar(128), @Start_Insert varchar(786), @Data_Type varchar(128), @Actual_Values varchar(8000), @IDN varchar(128)
SET @IDN = '' SET @Column_ID = 0 SET @Column_Name = '' SET @Column_List = '' SET @Actual_Values = ''
IF @owner IS NULL BEGIN SET @Start_Insert = 'INSERT INTO ' + '[' + RTRIM(COALESCE(@target_table,@table_name)) + ']' END ELSE BEGIN SET @Start_Insert = 'INSERT ' + '[' + LTRIM(RTRIM(@owner)) + '].' + '[' + RTRIM(COALESCE(@target_table,@table_name)) + ']' END
SELECT @Column_ID = MIN(ORDINAL_POSITION) FROM INFORMATION_SCHEMA.COLUMNS (NOLOCK) WHERE TABLE_NAME = @table_name AND (@owner IS NULL OR TABLE_SCHEMA = @owner)
WHILE @Column_ID IS NOT NULL BEGIN SELECT @Column_Name = QUOTENAME(COLUMN_NAME), @Data_Type = DATA_TYPE FROM INFORMATION_SCHEMA.COLUMNS (NOLOCK) WHERE ORDINAL_POSITION = @Column_ID AND TABLE_NAME = @table_name AND (@owner IS NULL OR TABLE_SCHEMA = @owner)
IF @cols_to_include IS NOT NULL BEGIN IF CHARINDEX( '''' + SUBSTRING(@Column_Name,2,LEN(@Column_Name)-2) + '''',@cols_to_include) = 0 BEGIN GOTO SKIP_LOOP END END
IF @cols_to_exclude IS NOT NULL BEGIN IF CHARINDEX( '''' + SUBSTRING(@Column_Name,2,LEN(@Column_Name)-2) + '''',@cols_to_exclude) <> 0 BEGIN GOTO SKIP_LOOP END END
IF (SELECT COLUMNPROPERTY( OBJECT_ID(QUOTENAME(COALESCE(@owner,USER_NAME())) + '.' + @table_name),SUBSTRING(@Column_Name,2,LEN(@Column_Name) - 2),'IsIdentity')) = 1 BEGIN IF @ommit_identity = 0 SET @IDN = @Column_Name ELSE GOTO SKIP_LOOP END IF @ommit_computed_cols = 1 BEGIN IF (SELECT COLUMNPROPERTY( OBJECT_ID(QUOTENAME(COALESCE(@owner,USER_NAME())) + '.' + @table_name),SUBSTRING(@Column_Name,2,LEN(@Column_Name) - 2),'IsComputed')) = 1 BEGIN GOTO SKIP_LOOP END END IF(@Data_Type in ('image')) BEGIN IF (@ommit_images = 0) BEGIN RAISERROR('Tables with image columns are not supported.',16,1) PRINT 'Use @ommit_images = 1 parameter to generate INSERTs for the rest of the columns.' 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.' RETURN -1 END ELSE BEGIN GOTO SKIP_LOOP END END
SET @Actual_Values = @Actual_Values + CASE WHEN @Data_Type IN ('char','varchar','nchar','nvarchar') THEN 'COALESCE('''''''' + REPLACE(RTRIM(' + @Column_Name + '),'''''''','''''''''''')+'''''''',''NULL'')' WHEN @Data_Type IN ('datetime','smalldatetime') THEN 'COALESCE('''''''' + RTRIM(CONVERT(char,' + @Column_Name + ',109))+'''''''',''NULL'')' WHEN @Data_Type IN ('uniqueidentifier') THEN 'COALESCE('''''''' + REPLACE(CONVERT(char(255),RTRIM(' + @Column_Name + ')),'''''''','''''''''''')+'''''''',''NULL'')' WHEN @Data_Type IN ('text','ntext') THEN 'COALESCE('''''''' + REPLACE(CONVERT(char(8000),' + @Column_Name + '),'''''''','''''''''''')+'''''''',''NULL'')' WHEN @Data_Type IN ('binary','varbinary') THEN 'COALESCE(RTRIM(CONVERT(char,' + 'CONVERT(int,' + @Column_Name + '))),''NULL'')' WHEN @Data_Type IN ('timestamp','rowversion') THEN CASE WHEN @include_timestamp = 0 THEN '''DEFAULT''' ELSE 'COALESCE(RTRIM(CONVERT(char,' + 'CONVERT(int,' + @Column_Name + '))),''NULL'')' END WHEN @Data_Type IN ('float','real','money','smallmoney') THEN 'COALESCE(LTRIM(RTRIM(' + 'CONVERT(char, ' + @Column_Name + ',2)' + ')),''NULL'')' ELSE 'COALESCE(LTRIM(RTRIM(' + 'CONVERT(char, ' + @Column_Name + ')' + ')),''NULL'')' END + '+' + ''',''' + ' + ' SET @Column_List = @Column_List + @Column_Name + ','
SKIP_LOOP:
SELECT @Column_ID = MIN(ORDINAL_POSITION) FROM INFORMATION_SCHEMA.COLUMNS (NOLOCK) WHERE TABLE_NAME = @table_name AND ORDINAL_POSITION > @Column_ID AND (@owner IS NULL OR TABLE_SCHEMA = @owner)
END
SET @Column_List = LEFT(@Column_List,len(@Column_List) - 1) SET @Actual_Values = LEFT(@Actual_Values,len(@Actual_Values) - 6)
IF LTRIM(@Column_List) = '' BEGIN RAISERROR('No columns to select. There should at least be one column to generate the output',16,1) RETURN -1 END
IF (@include_column_list <> 0) BEGIN SET @Actual_Values = 'SELECT ' + CASE WHEN @top IS NULL OR @top < 0 THEN '' ELSE ' TOP ' + LTRIM(STR(@top)) + ' ' END + '''' + RTRIM(@Start_Insert) + ' ''+' + '''(' + RTRIM(@Column_List) + '''+' + ''')''' + ' +''VALUES(''+ ' + @Actual_Values + '+'')''' + ' ' + COALESCE(@from,' FROM ' + CASE WHEN @owner IS NULL THEN '' ELSE '[' + LTRIM(RTRIM(@owner)) + '].' END + '[' + rtrim(@table_name) + ']' + '(NOLOCK)') END ELSE IF (@include_column_list = 0) BEGIN SET @Actual_Values = 'SELECT ' + CASE WHEN @top IS NULL OR @top < 0 THEN '' ELSE ' TOP ' + LTRIM(STR(@top)) + ' ' END + '''' + RTRIM(@Start_Insert) + ' '' +''VALUES(''+ ' + @Actual_Values + '+'')''' + ' ' + COALESCE(@from,' FROM ' + CASE WHEN @owner IS NULL THEN '' ELSE '[' + LTRIM(RTRIM(@owner)) + '].' END + '[' + rtrim(@table_name) + ']' + '(NOLOCK)') END
IF @debug_mode =1 BEGIN PRINT '/*****START OF DEBUG INFORMATION*****' PRINT 'Beginning of the INSERT statement:' PRINT @Start_Insert PRINT '' PRINT 'The column list:' PRINT @Column_List PRINT '' PRINT 'The SELECT statement executed to generate the INSERTs' PRINT @Actual_Values PRINT '' PRINT '*****END OF DEBUG INFORMATION*****/' PRINT '' END PRINT '--INSERTs generated by ''sp_generate_inserts'' stored procedure written by Vyas' PRINT '--Build number: 22' PRINT '--Problems/Suggestions? Contact Vyas @ vyaskn@hotmail.com' PRINT '--http://vyaskn.tripod.com' PRINT '' PRINT 'SET NOCOUNT ON' PRINT ''
IF (@IDN <> '') BEGIN PRINT 'SET IDENTITY_INSERT ' + QUOTENAME(COALESCE(@owner,USER_NAME())) + '.' + QUOTENAME(@table_name) + ' ON' PRINT 'GO' PRINT '' END
IF @disable_constraints = 1 AND (OBJECT_ID(QUOTENAME(COALESCE(@owner,USER_NAME())) + '.' + @table_name, 'U') IS NOT NULL) BEGIN IF @owner IS NULL BEGIN SELECT 'ALTER TABLE ' + QUOTENAME(COALESCE(@target_table, @table_name)) + ' NOCHECK CONSTRAINT ALL' AS '--Code to disable constraints temporarily' END ELSE BEGIN SELECT 'ALTER TABLE ' + QUOTENAME(@owner) + '.' + QUOTENAME(COALESCE(@target_table, @table_name)) + ' NOCHECK CONSTRAINT ALL' AS '--Code to disable constraints temporarily' END
PRINT 'GO' END
PRINT '' PRINT 'PRINT ''Inserting values into ' + '[' + RTRIM(COALESCE(@target_table,@table_name)) + ']' + ''''
EXEC (@Actual_Values)
PRINT 'PRINT ''Done''' PRINT ''
IF @disable_constraints = 1 AND (OBJECT_ID(QUOTENAME(COALESCE(@owner,USER_NAME())) + '.' + @table_name, 'U') IS NOT NULL) BEGIN IF @owner IS NULL BEGIN SELECT 'ALTER TABLE ' + QUOTENAME(COALESCE(@target_table, @table_name)) + ' CHECK CONSTRAINT ALL' AS '--Code to enable the previously disabled constraints' END ELSE BEGIN SELECT 'ALTER TABLE ' + QUOTENAME(@owner) + '.' + QUOTENAME(COALESCE(@target_table, @table_name)) + ' CHECK CONSTRAINT ALL' AS '--Code to enable the previously disabled constraints' END
PRINT 'GO' END
PRINT '' IF (@IDN <> '') BEGIN PRINT 'SET IDENTITY_INSERT ' + QUOTENAME(COALESCE(@owner,USER_NAME())) + '.' + QUOTENAME(@table_name) + ' OFF' PRINT 'GO' END
PRINT 'SET NOCOUNT OFF'
SET NOCOUNT OFF RETURN 0 END
GO
PRINT 'Created the procedure' GO
EXEC master.dbo.sp_MS_upd_sysobj_category 2 GO
PRINT 'Granting EXECUTE permission on sp_generate_inserts to all users' GRANT EXEC ON sp_generate_inserts TO public
SET NOCOUNT OFF GO
PRINT 'Done' |
|
|
|
Submitted By :
Nayan Patel
(Member Since : 5/26/2004 12:23:06 PM)
|
|
|
Job Description :
He is the moderator of this site and currently working as an independent consultant. He works with VB.net/ASP.net, SQL Server and other MS technologies. He is MCSD.net, MCDBA and MCSE. In his free time he likes to watch funny movies and doing oil painting. |
View all (893) submissions by this author
(Birth Date : 7/14/1981 ) |
|
|