Click here to Skip to main content
Click here to Skip to main content

Generating INSERT statements in SQL Server

By , 16 Jan 2005
Rate this:
Please Sign up or sign in to vote.

Introduction

The stored procedure InsertGenerator generates the INSERT..VALUES statements for the specified table name.

Background

SQL Server doesn’t allow generation of INSERT statements for the table data, when Generate SQL Script option is selected. The workaround is to make use of DTS for transferring data across servers. However, there exists a need to generate INSERT statements from the tables for porting data. Simplest example is when small or large amount of data needs to be taken out on a removable storage media and copied to a remote location, INSERT..VALUES statements come handy.

Using the code

This small yet useful stored procedure will take as parameter the table name and generates the INSERT SQL statements for the same. The output can be redirected to either text format (Ctrl+T in Query Analyzer) or Output to a text file. The procedure accepts an input varchar type parameter that has to be the table name under consideration for statement generation.

CREATE PROC InsertGenerator
(@tableName varchar(100)) as

Then it includes a cursor to fetch column specific information (column name and the data type thereof) from information_schema.columns pseudo entity and loop through for building the INSERT and VALUES clauses of an INSERT DML statement.

--Declare a cursor to retrieve column specific information 
--for the specified table
DECLARE cursCol CURSOR FAST_FORWARD FOR 
SELECT column_name,data_type FROM information_schema.columns 
    WHERE table_name = @tableName
OPEN cursCol
DECLARE @string nvarchar(3000) --for storing the first half 
                               --of INSERT statement
DECLARE @stringData nvarchar(3000) --for storing the data 
                                   --(VALUES) related statement
DECLARE @dataType nvarchar(1000) --data types returned 
                                 --for respective columns
SET @string='INSERT '+@tableName+'('
SET @stringData=''

DECLARE @colName nvarchar(50)

FETCH NEXT FROM cursCol INTO @colName,@dataType

IF @@fetch_status<>0
    begin
    print 'Table '+@tableName+' not found, processing skipped.'
    close curscol
    deallocate curscol
    return
END

WHILE @@FETCH_STATUS=0
BEGIN
IF @dataType in ('varchar','char','nchar','nvarchar')
BEGIN
    SET @stringData=@stringData+'''''''''+
            isnull('+@colName+','''')+'''''',''+'
END
ELSE
if @dataType in ('text','ntext') --if the datatype 
                                 --is text or something else 
BEGIN
    SET @stringData=@stringData+'''''''''+
          isnull(cast('+@colName+' as varchar(2000)),'''')+'''''',''+'
END
ELSE
IF @dataType = 'money' --because money doesn't get converted 
                       --from varchar implicitly
BEGIN
    SET @stringData=@stringData+'''convert(money,''''''+
        isnull(cast('+@colName+' as varchar(200)),''0.0000'')+''''''),''+'
END
ELSE 
IF @dataType='datetime'
BEGIN
    SET @stringData=@stringData+'''convert(datetime,''''''+
        isnull(cast('+@colName+' as varchar(200)),''0'')+''''''),''+'
END
ELSE 
IF @dataType='image' 
BEGIN
    SET @stringData=@stringData+'''''''''+
       isnull(cast(convert(varbinary,'+@colName+') 
       as varchar(6)),''0'')+'''''',''+'
END
ELSE --presuming the data type is int,bit,numeric,decimal 
BEGIN
    SET @stringData=@stringData+'''''''''+
          isnull(cast('+@colName+' as varchar(200)),''0'')+'''''',''+'
END

SET @string=@string+@colName+','

FETCH NEXT FROM cursCol INTO @colName,@dataType
END

After both of the clauses are built, the VALUES clause contains a trailing comma which needs to be replaced with a single quote. The prefixed clause will only face removal of the trailing comma.

DECLARE @Query nvarchar(4000) -- provide for the whole query, 
                              -- you may increase the size

SET @query ='SELECT '''+substring(@string,0,len(@string)) + ') 
    VALUES(''+ ' + substring(@stringData,0,len(@stringData)-2)+'''+'')'' 
    FROM '+@tableName
exec sp_executesql @query --load and run the built query

Eventually, close and de-allocate the cursor created for columns information.

CLOSE cursCol
DEALLOCATE cursCol

After the procedure is compiled and created, just run it in Query Analyzer by using the following syntax:

InsertGenerator <tablename>

E.g.:

USE pubs
GO
InsertGenerator employee 
GO

Then copy the INSERT statements and run’em in the query analyzer.

Before the INSERTs are run, SET IDENTITY_INSERT <TABLENAME>ON should be passed for adding values in an identity-based column.

Points of Interest

D: T-SQL lovers might wish to extend this procedure for providing support for binary data types such as IMAGE etc.

History

  • Ver 0.1b added Dec 5, 03.

License

This article, along with any associated source code and files, is licensed under The Code Project Open License (CPOL)

About the Author

Sumit Amar .
Software Developer (Senior)
United States United States
Sumit Amar started programming in BASIC at the age of 14 in 1993, then moved on to C/UNIX.
Later in 1999, he started developing commercial applications in J2SE, J2EE and Perl. He started developing applications in .NET with ASP+ (later renamed to ASP.NET) in December 2000 with public Beta 1. He's continuing development in .NET (ASP.NET, C#) ever since.
 
He has an MBA degree in IT and Systems besides his 200+ certifications including MCSD.NET, SCJP, MCTS, MCITP (Administrator and Developer), SCWCD, OCP-DBA and numerous Brainbench certifications (Transcript ID 2232802, World rank 3).
 
He is a Research Software Development Engineer at Microsoft Corporation, Redmond WA, where he works majorly on AJAX, .NET, SOAP, Web Services and Secure applications.

Comments and Discussions

 
GeneralThanks a lot PinmemberRakeshKr11-Jun-13 1:48 
QuestionGenerate insert for varbinary fields PinprofessionalDiana NoWay16-Apr-13 9:28 
QuestionThanks PinmemberEddy Nijs15-Oct-12 20:42 
Generalthnks PinmemberPayitax123316-Aug-12 15:03 
GeneralMy vote of 5 PinmemberPayitax123316-Aug-12 15:01 
QuestionAwesome! Pinmemberjaaaaaac3-Jul-12 4:50 
Questioni would say AWESOME dude PinmemberNikhil Bhivgade25-Jun-12 1:13 
NewsSQL Server Management Studio does this. PinmemberAlexandru Lungu2-May-12 1:50 
QuestionNULLs are not handled correctly. Causing issues with nullabel UniqueIdentifier columns. PinmemberRS Reddy220-Apr-12 12:30 
AnswerRe: NULLs are not handled correctly. Causing issues with nullabel UniqueIdentifier columns. Pinmemberbencejoful12-Jun-12 8:17 
SuggestionReady to use Stored Procedure for generating INSERT statements PinmemberMohammed_Rashid12-Mar-12 21:04 
Questionsimply awesome man PinmemberFarhan Asif12-Mar-12 4:09 
QuestionAnother tool with more features PinmemberRishikesh_716-Feb-12 3:42 
QuestionGenerate Insert script using C# : Check this out PinmemberRishikesh_716-Feb-12 3:39 
GeneralMy vote of 5 [modified] PinmemberAmol_B7-Feb-12 1:00 
GeneralMy vote of 5 Pinmemberbtrain24-Jan-12 12:51 
QuestionHow to add a WHERE param PinmemberMember 63398310-Jan-12 2:47 
AnswerRe: How to add a WHERE param PinmemberHawkeye367718-Apr-12 12:00 
GeneralExcellent! Thanks for sharing PinmemberNatreen12-Dec-11 2:57 
GeneralThanks! PinmemberMember 84519141-Dec-11 15:29 
QuestionThanks lot Pinmemberbasheer97127-Oct-11 0:44 
QuestionThank you, Thank You :) PinmemberBasil Ntinga20-Oct-11 20:33 
QuestionHandling XML Datatype PinmemberBadcop66619-Jun-11 12:45 
AnswerRe: Handling XML Datatype PinmemberBadcop66619-Jun-11 15:42 
GeneralRe: Handling XML Datatype PinmemberBadcop66619-Jun-11 15:45 

General General    News News    Suggestion Suggestion    Question Question    Bug Bug    Answer Answer    Joke Joke    Rant Rant    Admin Admin   

Use Ctrl+Left/Right to switch messages, Ctrl+Up/Down to switch threads, Ctrl+Shift+Left/Right to switch pages.

| Advertise | Privacy | Mobile
Web02 | 2.8.140421.2 | Last Updated 17 Jan 2005
Article Copyright 2003 by Sumit Amar .
Everything else Copyright © CodeProject, 1999-2014
Terms of Use
Layout: fixed | fluid