July 22, 2009 at 8:44 am
I have some SQL I'm going to put in a stored procedure which will insert records into a temp table. However, when I run the following, I recieve a message that the Select statement is not a valid identifier. It looks like it is truncating the statement. But, with the PRINT statement, I know that it is populating the variable just fine. Any ideas as to what I need to do? I've copied the SQL and the output I recieve below:
SQL
DECLARE @TreatyNumber As Varchar(20)
SET @TreatyNumber = '200704.2.6'
DECLARE @sql As Varchar(max)
SET @sql = 'SELECT vwT.TreatyNumber, topics.PieceTitle AS topic, subsection.PieceTitle AS Subtopic, question.PieceTitle AS SurveyQuestion, (CONVERT(Varchar, topics.PieceNumber) + CONVERT(Varchar, subsection.PieceNumber)) AS PartID, SAP.ColumnName
FROM Treaty.vwTreaty AS vwT INNER JOIN
Survey.vwSurveyInstance AS vwSI ON vwT.TreatySurveyInstanceId = vwSI.SurveyInstanceId INNER JOIN
Survey.vwSurveyTemplate AS vwST ON vwSI.SurveyInstanceSurveyTemplateId = vwST.SurveyTemplateId INNER JOIN
Survey.vwSurveyPiece topics ON vwST.SurveyTemplateId = topics.SurveyPieceSurveyTemplateId AND topics.SurveyPieceTypeIdCodeName = ' + '''' + 'Topic' + '''' + ' INNER JOIN
Survey.vwSurveyPiece AS subsection ON subsection.ParentSurveyPieceId = topics.SurveyPieceId AND subsection.SurveyPieceTypeIdCodeName = ' + '''' + 'Topic Subsection' + '''' + ' INNER JOIN
Survey.vwSurveyPiece AS question ON question.ParentSurveyPieceId = subsection.SurveyPieceId AND question.SurveyPieceTypeIdCodeName = ' + '''' + 'Question' + '''' + ' INNER JOIN
Survey.SurveyAnswerPart SAP ON question.SurveyPieceId = SAP.SurveyPieceId
WHERE vwT.TreatyNumber = ' + '''' + @TreatyNumber + '''' +
' ORDER BY topics.PieceNumber, subsection.PieceNumber, question.PieceNumber'
PRINT @sql
DECLARE @temp_provisions As Table (TreatyNum Varchar(20), topic Varchar(100), Subtopic Varchar(100), SurveyQuestion Varchar(100), SurveyPart Varchar(5), ColName Varchar(100))
INSERT INTO @temp_provisions
EXEC @sql
OUTPUT
SELECT vwT.TreatyNumber, topics.PieceTitle AS topic, subsection.PieceTitle AS Subtopic, question.PieceTitle AS SurveyQuestion, (CONVERT(Varchar, topics.PieceNumber) + CONVERT(Varchar, subsection.PieceNumber)) AS PartID, SAP.ColumnName
FROM Treaty.vwTreaty AS vwT INNER JOIN
Survey.vwSurveyInstance AS vwSI ON vwT.TreatySurveyInstanceId = vwSI.SurveyInstanceId INNER JOIN
Survey.vwSurveyTemplate AS vwST ON vwSI.SurveyInstanceSurveyTemplateId = vwST.SurveyTemplateId INNER JOIN
Survey.vwSurveyPiece topics ON vwST.SurveyTemplateId = topics.SurveyPieceSurveyTemplateId AND topics.SurveyPieceTypeIdCodeName = 'Topic' INNER JOIN
Survey.vwSurveyPiece AS subsection ON subsection.ParentSurveyPieceId = topics.SurveyPieceId AND subsection.SurveyPieceTypeIdCodeName = 'Topic Subsection' INNER JOIN
Survey.vwSurveyPiece AS question ON question.ParentSurveyPieceId = subsection.SurveyPieceId AND question.SurveyPieceTypeIdCodeName = 'Question' INNER JOIN
Survey.SurveyAnswerPart SAP ON question.SurveyPieceId = SAP.SurveyPieceId
WHERE vwT.TreatyNumber = '200704.2.6' ORDER BY topics.PieceNumber, subsection.PieceNumber, question.PieceNumber
Msg 203, Level 16, State 2, Line 21
The name 'SELECT vwT.TreatyNumber, topics.PieceTitle AS topic, subsection.PieceTitle AS Subtopic, question.PieceTitle AS SurveyQuestion, (CONVERT(Varchar, topics.PieceNumber) + CONVERT(Varchar, subsection.PieceNumber)) AS PartID, SAP.ColumnName
FROM Treaty.vwTreaty AS vwT INNER JOIN
Survey.vwSurveyInstance AS vwSI ON vwT.TreatySurveyInstanceId = vwSI.SurveyInstanceId INNER JOIN
Survey.vwSurveyTemplate AS vwST ON vwSI.SurveyInstanceSurveyTemplateId = vwST.SurveyTemplateId INNER JOIN
Survey.vwSurveyPiece topics ON vwST.SurveyTemplateId = topics.SurveyPieceSurveyTemplateId AND topics.SurveyPieceTypeIdCodeName = 'Topic' INNER JOIN
Survey.vw' is not a valid identifier.
July 22, 2009 at 9:25 am
Replace EXEC @sql with EXEC (@SQL)
Without the brackets, the assumption is that the content of the variable is a stored procedure name
Gail Shaw
Microsoft Certified Master: SQL Server, MVP, M.Sc (Comp Sci)
SQL In The Wild: Discussions on DB performance with occasional diversions into recoverability
July 22, 2009 at 10:00 am
The good thing about using sp_executesql is that you can pass the parameter value instead of completely building the string on the fly like this...
DECLARE @sql NVARCHAR(MAX)
DECLARE @TBL TABLE (i int)
SET @sql = 'SELECT message_id FROM sys.messages WHERE message_id < @ID'
INSERT INTO @TBL
EXEC sp_executesql @sql, N'@ID INT' , 1000
SELECT * FROM @TBL
July 22, 2009 at 10:11 am
Indeed. However looking I can't see any reason why this is dynamic SQL at all.
This should work just fine
DECLARE @TreatyNumber As Varchar(20)
SET @TreatyNumber = '200704.2.6'
DECLARE @temp_provisions As Table (
TreatyNum Varchar(20),
topic Varchar(100),
Subtopic Varchar(100),
SurveyQuestion Varchar(100),
SurveyPart Varchar(5),
ColName Varchar(100)
)
INSERT INTO @temp_provisions (TreatyNum, topic, Subtopic, SurveyQuestion, SurveyPart, ColName)
SELECT vwT.TreatyNumber, topics.PieceTitle AS topic, subsection.PieceTitle AS Subtopic, question.PieceTitle AS SurveyQuestion,
(CONVERT(Varchar, topics.PieceNumber) + CONVERT(Varchar, subsection.PieceNumber)) AS PartID,
SAP.ColumnName
FROM Treaty.vwTreaty AS vwT
INNER JOIN Survey.vwSurveyInstance AS vwSI ON vwT.TreatySurveyInstanceId = vwSI.SurveyInstanceId
INNER JOIN Survey.vwSurveyTemplate AS vwST ON vwSI.SurveyInstanceSurveyTemplateId = vwST.SurveyTemplateId
INNER JOIN Survey.vwSurveyPiece topics ON vwST.SurveyTemplateId = topics.SurveyPieceSurveyTemplateId
AND topics.SurveyPieceTypeIdCodeName = 'Topic'
INNER JOIN Survey.vwSurveyPiece AS subsection ON subsection.ParentSurveyPieceId = topics.SurveyPieceId
AND subsection.SurveyPieceTypeIdCodeName = 'Topic Subsection'
INNER JOIN Survey.vwSurveyPiece AS question ON question.ParentSurveyPieceId = subsection.SurveyPieceId
AND question.SurveyPieceTypeIdCodeName = 'Question'
INNER JOIN Survey.SurveyAnswerPart SAP ON question.SurveyPieceId = SAP.SurveyPieceId
WHERE vwT.TreatyNumber = @TreatyNumber
I've removed the order by as, unless there's an identity column on the table, the order of rows inserted is meaningless. Order by should be used on the select that reads from the table variable.
Gail Shaw
Microsoft Certified Master: SQL Server, MVP, M.Sc (Comp Sci)
SQL In The Wild: Discussions on DB performance with occasional diversions into recoverability
July 23, 2009 at 7:43 am
Actually, I pulled only that query out of my larger script. Other parts are using dynamic SQL. This one isn't. So you're right. But, I finally got it to work. I copied and pasted line-by-line into another query window. I had copied the core sql statement from a dataset I had previously built in SSRS. We think some rogue character might have gotten in there.
But, thanks for the posts. I appreciate seeing and learning from what others share.
October 4, 2012 at 12:46 am
BRACKETS! ๐
Thank you!
June 5, 2013 at 5:45 am
softtesting2012 (6/5/2013)
Invalid: exec @sqlqueryValid: exec (@sqlQuery)
Not necessarily so. Read Gail's post above.
For fast, accurate and documented assistance in answering your questions, please read this article.
Understanding and using APPLY, (I) and (II) Paul White
Hidden RBAR: Triangular Joins / The "Numbers" or "Tally" Table: What it is and how it replaces a loop Jeff Moden
June 5, 2013 at 5:58 am
Please note: 4 year old answered thread.
Gail Shaw
Microsoft Certified Master: SQL Server, MVP, M.Sc (Comp Sci)
SQL In The Wild: Discussions on DB performance with occasional diversions into recoverability
June 5, 2013 at 6:06 am
GilaMonster (6/5/2013)
Please note: 4 year old answered thread.
Outstanding work for one so young ๐
For fast, accurate and documented assistance in answering your questions, please read this article.
Understanding and using APPLY, (I) and (II) Paul White
Hidden RBAR: Triangular Joins / The "Numbers" or "Tally" Table: What it is and how it replaces a loop Jeff Moden
September 25, 2013 at 3:23 pm
Ken... You are a genius!!! Thank You very much!!!
Viewing 12 posts - 1 through 11 (of 11 total)
You must be logged in to reply to this topic. Login to reply