Home Forums SQL Server 2005 Backups how to take script for database table data RE: how to take script for database table data

  • Long time ago I found this script on the internet. I don't know where, so I can't give credit to the creator. This script has served me well in creating INSERT statements.

    DECLARE@table_name varchar(776)

    DECLARE@schema varchar(64)

    -- enter a schema name below if the table is not in the default one

    --SET @schema = 'schema_name'

    SET @table_name = 'table_name'

    DECLARE@target_table varchar(776)

    DECLARE@include_column_list bit

    DECLARE@from varchar(800)

    DECLARE@include_timestamp bit

    DECLARE@debug_mode bit

    DECLARE@ommit_images bit

    DECLARE@ommit_identity bit

    DECLARE@top int

    DECLARE@cols_to_include varchar(8000)

    DECLARE@cols_to_exclude varchar(8000)

    DECLARE@disable_constraints bit

    DECLARE@ommit_computed_cols bit

    SET @include_column_list = 1

    SET NOCOUNT ON

    --Making sure user only uses either @cols_to_include or @cols_to_exclude

    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)

    END

    --Making sure the @cols_to_include and @cols_to_exclude parameters are receiving values in proper format

    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''"'

    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''"'

    END

    --Checking to see if the database name is specified along wih the table name

    --Your database context should be local to the table for which you want to generate INSERT statements

    --specifying the database name is not allowed

    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)

    END

    --Checking for the existence of 'user table' or 'view'

    --This procedure is not written to work on system tables

    --To script the data in system tables, just create a view on the system tables and script the view instead

    IF @schema 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 @schema parameter to specify the owner name.'

    PRINT 'Make sure you have SELECT permission on that table or view.'

    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 = @schema)

    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 @schema parameter to specify the owner name.'

    PRINT 'Make sure you have SELECT permission on that table or view.'

    END

    END

    --Variable declarations

    DECLARE@Column_ID int,

    @Column_List varchar(8000),

    @Column_Name varchar(128),

    @Start_Insert varchar(max),

    @Data_Type varchar(128),

    @Actual_Values varchar(8000),--This is the string that will be finally executed to generate INSERT statements

    @IDN varchar(128)--Will contain the IDENTITY column's name in the table

    --Variable Initialization

    SET @IDN = ''

    SET @Column_ID = 0

    SET @Column_Name = ''

    SET @Column_List = ''

    SET @Actual_Values = ''

    IF @schema IS NULL

    BEGIN

    SET @Start_Insert = 'INSERT INTO ' + '[' + RTRIM(COALESCE(@target_table,@table_name)) + ']'

    END

    ELSE

    BEGIN

    SET @Start_Insert = 'INSERT ' + '[' + LTRIM(RTRIM(@schema)) + '].' + '[' + RTRIM(COALESCE(@target_table,@table_name)) + ']'

    END

    --To get the first column's ID

    SELECT@Column_ID = MIN(ORDINAL_POSITION)

    FROMINFORMATION_SCHEMA.COLUMNS (NOLOCK)

    WHERE TABLE_NAME = @table_name AND

    (@schema IS NULL OR TABLE_SCHEMA = @schema)

    --Loop through all the columns of the table, to get the column names and their data types

    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

    (@schema IS NULL OR TABLE_SCHEMA = @schema)

    IF @cols_to_include IS NOT NULL --Selecting only user specified columns

    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 --Selecting only user specified columns

    BEGIN

    IF CHARINDEX( '''' + SUBSTRING(@Column_Name,2,LEN(@Column_Name)-2) + '''',@cols_to_exclude) <> 0

    BEGIN

    GOTO SKIP_LOOP

    END

    END

    --Making sure to output SET IDENTITY_INSERT ON/OFF in case the table has an IDENTITY column

    IF (SELECT COLUMNPROPERTY( OBJECT_ID(QUOTENAME(COALESCE(@schema,USER_NAME())) + '.' + @table_name),SUBSTRING(@Column_Name,2,LEN(@Column_Name) - 2),'IsIdentity')) = 1

    BEGIN

    IF @ommit_identity = 0 --Determing whether to include or exclude the IDENTITY column

    SET @IDN = @Column_Name

    ELSE

    GOTO SKIP_LOOP

    END

    --Making sure whether to output computed columns or not

    IF @ommit_computed_cols = 1

    BEGIN

    IF (SELECT COLUMNPROPERTY( OBJECT_ID(QUOTENAME(COALESCE(@schema,USER_NAME())) + '.' + @table_name),SUBSTRING(@Column_Name,2,LEN(@Column_Name) - 2),'IsComputed')) = 1

    BEGIN

    GOTO SKIP_LOOP

    END

    END

    --Tables with columns of IMAGE data type are not supported for obvious reasons

    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.'

    END

    ELSE

    BEGIN

    GOTO SKIP_LOOP

    END

    END

    --Determining the data type of the column and depending on the data type, the VALUES part of

    --the INSERT statement is generated. Care is taken to handle columns with NULL values. Also

    --making sure, not to lose any data from flot, real, money, smallmomey, datetime columns

    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 + '+' + ''',''' + ' + '

    --Generating the column list for the INSERT statement

    SET @Column_List = @Column_List + @Column_Name + ','

    SKIP_LOOP: --The label used in GOTO

    SELECT @Column_ID = MIN(ORDINAL_POSITION)

    FROM INFORMATION_SCHEMA.COLUMNS (NOLOCK)

    WHERE TABLE_NAME = @table_name AND

    ORDINAL_POSITION > @Column_ID AND

    (@schema IS NULL OR TABLE_SCHEMA = @schema)

    --Loop ends here!

    END

    --To get rid of the extra characters that got concatenated during the last run through the loop

    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)

    END

    --Forming the final string that will be executed, to output the INSERT statements

    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 @schema IS NULL THEN '' ELSE '[' + LTRIM(RTRIM(@schema)) + '].' 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 @schema IS NULL THEN '' ELSE '[' + LTRIM(RTRIM(@schema)) + '].' END + '[' + rtrim(@table_name) + ']' + '(NOLOCK)')

    END

    --Determining whether to ouput any debug information

    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 ''

    --Determining whether to print IDENTITY_INSERT or not

    IF (@IDN <> '')

    BEGIN

    PRINT 'SET IDENTITY_INSERT ' + QUOTENAME(COALESCE(@schema,USER_NAME())) + '.' + QUOTENAME(@table_name) + ' ON'

    PRINT 'GO'

    PRINT ''

    END

    IF @disable_constraints = 1 AND (OBJECT_ID(QUOTENAME(COALESCE(@schema,USER_NAME())) + '.' + @table_name, 'U') IS NOT NULL)

    BEGIN

    IF @schema 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(@schema) + '.' + 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)) + ']' + ''''

    PRINT ''

    PRINT '-- remove REMARK signs in next line if target needs to be cleared before insert'

    PRINT '-- TRUNCATE TABLE [' + RTRIM(COALESCE(@target_table,@table_name)) + ']'

    --All the hard work pays off here!!! You'll get your INSERT statements, when the next line executes!

    EXEC (@Actual_Values)

    PRINT 'PRINT ''Done'''

    PRINT ''

    IF @disable_constraints = 1 AND (OBJECT_ID(QUOTENAME(COALESCE(@schema,USER_NAME())) + '.' + @table_name, 'U') IS NOT NULL)

    BEGIN

    IF @schema 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(@schema) + '.' + 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(@schema,USER_NAME())) + '.' + QUOTENAME(@table_name) + ' OFF'

    PRINT 'GO'

    END

    PRINT 'SET NOCOUNT OFF'

    SET NOCOUNT OFF

    ** Don't mistake the ‘stupidity of the crowd’ for the ‘wisdom of the group’! **