Click here to monitor SSC
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


Generate Insert Statements Easily


Generate Insert Statements Easily

Author
Message
achigrik
achigrik
SSC Rookie
SSC Rookie (28 reputation)SSC Rookie (28 reputation)SSC Rookie (28 reputation)SSC Rookie (28 reputation)SSC Rookie (28 reputation)SSC Rookie (28 reputation)SSC Rookie (28 reputation)SSC Rookie (28 reputation)

Group: General Forum Members
Points: 28 Visits: 1
Comments posted to this topic are about the item Generate Insert Statements Easily



john.j.cunningham
john.j.cunningham
Forum Newbie
Forum Newbie (1 reputation)Forum Newbie (1 reputation)Forum Newbie (1 reputation)Forum Newbie (1 reputation)Forum Newbie (1 reputation)Forum Newbie (1 reputation)Forum Newbie (1 reputation)Forum Newbie (1 reputation)

Group: General Forum Members
Points: 1 Visits: 2
SELECT @exec_str = "SELECT 'INSERT INTO " + @TableName + " VALUES (' + "

line fails to compile in SQL Server Management Studio
RBarryYoung
RBarryYoung
SSChampion
SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)

Group: General Forum Members
Points: 10460 Visits: 9517
Try executing:
SET QUOTED_IDENTIFIER ON
GO


first.

Apparently, the author assumed this setting was already on, though it is not normally on and a bad practice in any event, IMHO.

-- RBarryYoung, (302)375-0451 blog: MovingSQL.com, Twitter: @RBarryYoung
Proactive Performance Solutions, Inc.
"Performance is our middle name."
Prasad Bhogadi
Prasad Bhogadi
Ten Centuries
Ten Centuries (1K reputation)Ten Centuries (1K reputation)Ten Centuries (1K reputation)Ten Centuries (1K reputation)Ten Centuries (1K reputation)Ten Centuries (1K reputation)Ten Centuries (1K reputation)Ten Centuries (1K reputation)

Group: General Forum Members
Points: 1001 Visits: 450
Even with SET QUOTED_IDENTIFIER ON, it doesnot compile. The query analyzer returns the following error message.

Server: Msg 207, Level 16, State 3, Procedure sp_DataAsInsCommand, Line 27
Invalid column name 'SELECT 'INSERT INTO '.
Server: Msg 207, Level 16, State 1, Procedure sp_DataAsInsCommand, Line 27
Invalid column name ' VALUES (' + '.

Prasad Bhogadi
www.inforaise.com
RBarryYoung
RBarryYoung
SSChampion
SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)

Group: General Forum Members
Points: 10460 Visits: 9517
My bad, I got it backwards. Try:

SET QUOTED_IDENTIFIER OFF


instead.

-- RBarryYoung, (302)375-0451 blog: MovingSQL.com, Twitter: @RBarryYoung
Proactive Performance Solutions, Inc.
"Performance is our middle name."
louis315
louis315
SSC Rookie
SSC Rookie (26 reputation)SSC Rookie (26 reputation)SSC Rookie (26 reputation)SSC Rookie (26 reputation)SSC Rookie (26 reputation)SSC Rookie (26 reputation)SSC Rookie (26 reputation)SSC Rookie (26 reputation)

Group: General Forum Members
Points: 26 Visits: 79
Didn't execute for me with either
SET QUOTED_IDENTIFIER OFF
or
SET QUOTED_IDENTIFIER ON

No good reason to use double quotes in this stored proc.



RBarryYoung
RBarryYoung
SSChampion
SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)

Group: General Forum Members
Points: 10460 Visits: 9517
louis315 (6/5/2008)
Didn't execute for me with either
SET QUOTED_IDENTIFIER OFF
or
SET QUOTED_IDENTIFIER ON

No good reason to use double quotes in this stored proc.


"SET QUOTED_IDENTIFIER OFF" works fine for me. What error do you get now?

-- RBarryYoung, (302)375-0451 blog: MovingSQL.com, Twitter: @RBarryYoung
Proactive Performance Solutions, Inc.
"Performance is our middle name."
louis315
louis315
SSC Rookie
SSC Rookie (26 reputation)SSC Rookie (26 reputation)SSC Rookie (26 reputation)SSC Rookie (26 reputation)SSC Rookie (26 reputation)SSC Rookie (26 reputation)SSC Rookie (26 reputation)SSC Rookie (26 reputation)

Group: General Forum Members
Points: 26 Visits: 79
Sorry, I moved on and banged out my own Insert-generating code using Information_Schema views instead of sysobjects and syscolumns.

I needed code to 1) generate conventional Inserts, 2) create and populate a table variable w/ Inserts, or 3) create a resultset by generating one Select stmt per table row, then sticking "UNION" between each Select.

I think the error I got from this guy's proc was "Invalid column name", or something like that. Might have been due to spaces in some of my table's column names...

Thanks for offering to help. I shouldn't have complained a/b this guy's code when I didn't need it anyway.



RBarryYoung
RBarryYoung
SSChampion
SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)

Group: General Forum Members
Points: 10460 Visits: 9517
Okey dokey

-- RBarryYoung, (302)375-0451 blog: MovingSQL.com, Twitter: @RBarryYoung
Proactive Performance Solutions, Inc.
"Performance is our middle name."
bakk
bakk
SSC Rookie
SSC Rookie (46 reputation)SSC Rookie (46 reputation)SSC Rookie (46 reputation)SSC Rookie (46 reputation)SSC Rookie (46 reputation)SSC Rookie (46 reputation)SSC Rookie (46 reputation)SSC Rookie (46 reputation)

Group: General Forum Members
Points: 46 Visits: 56
thats how it works for me
alter PROC p_adm_gen_insert
(@TableList varchar (8000)
)
AS
SET NOCOUNT ON
DECLARE @position int, @exec_str varchar (2000), @TableName varchar (50)
DECLARE @name varchar(128), @xtype int, @status tinyint, @IsIdentity tinyint
DECLARE @ColumnList varchar(8000)
SET @ColumnList=''
SELECT @TableList = @TableList + ','
SELECT @IsIdentity = 0
SELECT @position = PATINDEX('%,%', @TableList)
WHILE (@position <> 0)
BEGIN

SELECT @TableName = SUBSTRING(@TableList, 1, @position - 1)
SELECT @TableList = STUFF(@TableList, 1, PATINDEX('%,%', @TableList),'')
SELECT @position = PATINDEX('%,%', @TableList)

SELECT @exec_str = 'DECLARE fetch_cursor CURSOR FOR SELECT a.name, a.xtype, a.status FROM syscolumns a, sysobjects b WHERE a.id = b.id and b.name = ''' + @TableName + ''''
EXEC (@exec_str)
--print @exec_str
OPEN fetch_cursor
FETCH fetch_cursor INTO @name, @xtype, @status
IF (@status & 0x80) <> 0
BEGIN
SELECT @IsIdentity = 1
SELECT 'SET IDENTITY_INSERT ' + @TableName + ' ON'
SELECT 'GO'
END
SET @ColumnList=@ColumnList + @name +','
--SELECT @exec_str = 'SELECT ''INSERT INTO ' + @TableName + ' VALUES ('' + '
SET @exec_str = ''
Select ' -- The table name is: ' + @TableName
--text or ntext
IF (@xtype = 35) OR (@xtype = 99)
SELECT @exec_str = @exec_str + '''"None yet"'''
ELSE

--image
IF (@xtype = 34)
SELECT @exec_str = @exec_str + '"' + '0xFFFFFFFF' + '"'
ELSE

--smalldatetime or datetime
IF (@xtype = 58) OR (@xtype = 61)
SELECT @exec_str = @exec_str + 'Coalesce( + '''''''' + CONVERT(varchar,' + @name + ',109)' + ' + ''''''''' + ',''null'')'
ELSE

--varchar or char or nvarchar or nchar
IF (@xtype = 167) OR (@xtype = 175) OR (@xtype = 231) OR (@xtype = 239)
SELECT @exec_str = @exec_str + 'Coalesce(' + ''''''''' + ' + @name + ' + ''''''''' + ',''null'')'
ELSE

--uniqueidentifier
IF (@xtype = 36)
SELECT @exec_str = @exec_str + ' + Coalesce('''''''' + ' + ' + CONVERT(varchar(255),' + @name + ')' + ' + ''''''''' + ',''null'')'
ELSE

--binary or varbinary
IF (@xtype = 173) OR (@xtype = 165)
SELECT @exec_str = @exec_str + '"' + '0x0' + '"'
ELSE

SELECT @exec_str = @exec_str + 'Coalesce(CONVERT(varchar,' + @name + '), ''null'')'

WHILE @@FETCH_STATUS <> -1
BEGIN
FETCH fetch_cursor INTO @name, @xtype, @status
IF (@@FETCH_STATUS = -1) BREAK
IF (@status & 0x80) <> 0
BEGIN
SELECT @IsIdentity = 1
SELECT 'SET IDENTITY_INSERT ' + @TableName + ' ON'
SELECT 'GO'
END

SET @ColumnList=@ColumnList + @name +','

--text or ntext
IF (@xtype = 35) OR (@xtype = 99)
SELECT @exec_str = @exec_str + ' + '',''' + ' + ''"None yet"'''
ELSE

--image
IF (@xtype = 34)
SELECT @exec_str = @exec_str + ' + '','' + ' + '"' + '0xFFFFFFFF' + '"'
ELSE

--smalldatetime or datetime
IF (@xtype = 58) OR (@xtype = 61)
SELECT @exec_str = @exec_str + ' + '',''' + ' + Coalesce('''''''' + ' + ' + CONVERT(varchar,' + @name + ',109)' + ' + ''''''''' + ',''null'')'
ELSE

--varchar or char or nvarchar or nchar
IF (@xtype = 167) OR (@xtype = 175) OR (@xtype = 231) OR (@xtype = 239)
SELECT @exec_str = @exec_str + ' + '',''' + ' + Coalesce('''''''' + replace(' + @name + ' COLLATE database_default,'''''''','''''''''''') + ''''''''' + ',''null'')'
ELSE

--uniqueidentifier
IF (@xtype = 36)
SELECT @exec_str = @exec_str + ' + '',''' + ' + Coalesce('''''''' + ' + ' + CONVERT(varchar(255),' + @name + ')' + ' + ''''''''' + ',''null'')'
ELSE

--binary or varbinary
IF (@xtype = 173) OR (@xtype = 165)
SELECT @exec_str = @exec_str + ' + '','' + ' + '"' + '0x0' + '"'
ELSE

SELECT @exec_str = @exec_str + ' + '',''' + ' + Coalesce(CONVERT(varchar,' + @name + '), ''null'')'
END

CLOSE fetch_cursor
DEALLOCATE fetch_cursor

SELECT @exec_str = 'SELECT ''INSERT INTO ' + @TableName +'('+substring(@ColumnList,1,len(@ColumnList)-1) + ')
VALUES ('' + ' + @exec_str + '+ '')'' FROM ' + @TableName
EXEC(@exec_str)
--print (@exec_str)
SELECT 'GO'

IF @IsIdentity = 1
BEGIN
SELECT @IsIdentity = 0
SELECT 'SET IDENTITY_INSERT ' + @TableName + ' OFF'
SELECT 'GO'
END
END

--print @ColumnList





Go


Permissions

You can't post new topics.
You can't post topic replies.
You can't post new polls.
You can't post replies to polls.
You can't edit your own topics.
You can't delete your own topics.
You can't edit other topics.
You can't delete other topics.
You can't edit your own posts.
You can't edit other posts.
You can't delete your own posts.
You can't delete other posts.
You can't post events.
You can't edit your own events.
You can't edit other events.
You can't delete your own events.
You can't delete other events.
You can't send private messages.
You can't send emails.
You can read topics.
You can't vote in polls.
You can't upload attachments.
You can download attachments.
You can't post HTML code.
You can't edit HTML code.
You can't post IFCode.
You can't post JavaScript.
You can post emoticons.
You can't post or upload images.

Select a forum

































































































































































SQLServerCentral


Search