July 21, 2012 at 1:49 am
I'm trying to perform a dynamic pivot on a table that has data with a forward slash in it. SQL complains about the SELECT statement with:
Incorrect syntax near '/'.
Can I format my SELECT statement to handle the forward slash. Thanks for any help.
Create TABLE #TempSymbolList
(
TempSymbol nvarchar(MAX)
);
INSERT INTO #TempSymbolList (TempSymbol) VALUES ('NZD/USD')
INSERT INTO #TempSymbolList (TempSymbol) VALUES ('AUD/USD')
INSERT INTO #TempSymbolList (TempSymbol) VALUES ('USD/JPY')
DECLARE @Info NVARCHAR(MAX)
DECLARE @InfoPvt NVARCHAR(MAX)
DECLARE @SQL NVARCHAR(MAX)
SELECT @Info = STUFF(( SELECT ', ' + 'MAX(' + TempSymbol + ') As ['+ TempSymbol + ']'
FROM #TempSymbolList
FOR XML PATH('') ), 1, 1, '')
SELECT @InfoPvt = STUFF(( SELECT ', ' + TempSymbol FROM #TempSymbolList
FOR XML PATH('') ), 1, 1, '')
SELECT @Info;
SELECT @InfoPvt;
SET @SQL = N'SELECT fxDate, ' + @Info + ' FROM
(SELECT A.* FROM DataQuote AS A
JOIN #TempSymbolList AS B ON A.fxSymbol = B.TempSymbol) AS C
PIVOT
(MAX(fxClose) FOR fxSymbol IN (' +@InfoPvt+ ')) pvt
GROUP BY fxDate'
EXEC sp_executesql @SQL
DROP TABLE #TempSymbolList
July 21, 2012 at 4:42 am
You'll need to wrap the column names (as you build them up for the pivot) in []
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 21, 2012 at 11:23 am
GilaMonster (7/21/2012)
You'll need to wrap the column names (as you build them up for the pivot) in []
I'm not sure I know what you mean?
July 21, 2012 at 12:43 pm
SELECT @Info = STUFF(( SELECT ', ' + 'MAX([' + TempSymbol + ']) As ['+ TempSymbol + ']'
FROM #TempSymbolList
FOR XML PATH('') ), 1, 1, '')
SELECT @InfoPvt = STUFF(( SELECT ', [' + TempSymbol + ']' FROM #TempSymbolList
FOR XML PATH('') ), 1, 1, '')
Untested of course.
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 21, 2012 at 1:36 pm
GilaMonster (7/21/2012)
SELECT @Info = STUFF(( SELECT ', ' + 'MAX([' + TempSymbol + ']) As ['+ TempSymbol + ']'
FROM #TempSymbolList
FOR XML PATH('') ), 1, 1, '')
SELECT @InfoPvt = STUFF(( SELECT ', [' + TempSymbol + ']' FROM #TempSymbolList
FOR XML PATH('') ), 1, 1, '')
Untested of course.
GilaMonster, thanks for your help, but that didn't work. I now get the following:
Msg 207, Level 16, State 1, Line 1
Invalid column name 'NZD'.
Msg 207, Level 16, State 1, Line 1
Invalid column name 'USD'.
Msg 207, Level 16, State 1, Line 1
Invalid column name 'AUD'.
Msg 207, Level 16, State 1, Line 1
Invalid column name 'USD'.
Msg 207, Level 16, State 1, Line 1
Invalid column name 'USD'.
Msg 207, Level 16, State 1, Line 1
Invalid column name 'JPY'.
I think the problem is formatting the string as an "XML PATH" with the forward slash. Could that be the problem? and is there an alternate way to write @info-2 and @InfoPvt?
July 21, 2012 at 2:28 pm
Please post definitions for the tables involved and some sample data.
Also, instead of EXECing the string, print it and post the output.
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 21, 2012 at 2:50 pm
GilaMonster (7/21/2012)
Please post definitions for the tables involved and some sample data.Also, instead of EXECing the string, print it and post the output.
I found the problem. I need brackets [] in MAX portion of @info-2. Thanks for your help.
SELECT @Info = STUFF(( SELECT ', ' + 'MAX([' + TempSymbol + ']) As ['+ TempSymbol + ']'
FROM #TempSymbolList
FOR XML PATH('') ), 1, 1, '')
July 21, 2012 at 3:09 pm
That was in the code I posted earlier.
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
Viewing 8 posts - 1 through 8 (of 8 total)
You must be logged in to reply to this topic. Login to reply
This website stores cookies on your computer.
These cookies are used to improve your website experience and provide more personalized services to you, both on this website and through other media.
To find out more about the cookies we use, see our Privacy Policy