May 17, 2018 at 10:34 am
I have a procedure that takes various parameters, but it falls over on the ELSE clause where I have "SET @Where = 'WHERE Name = @ItemNameInput';"
Can someone else have a look at what the issue is? Partial T-SQL as follows...
DECLARE @sql NVARCHAR(4000);
DECLARE @InsertInto NVARCHAR(4000);
DECLARE @Select NVARCHAR(4000);
DECLARE @Where NVARCHAR(4000);
(Sorry, no idea why formatting doesn't work for me.)
May 17, 2018 at 10:39 am
replace
SET @Where = ' WHERE Name LIKE %';
with
SET @Where = ' WHERE Name LIKE ''%''';
May 17, 2018 at 10:42 am
Joe, yes, that will of course be another issue when the issue with "WHERE Name = @ItemNameInput" is resolved -- thanks for catching that.
Any ideas about the "WHERE Name = @ItemNameInput" issue?
May 17, 2018 at 10:48 am
ktrammen - Thursday, May 17, 2018 10:42 AMJoe, yes, that will of course be another issue when the issue with "WHERE Name = @ItemNameInput" is resolved -- thanks for catching that.Any ideas about the "WHERE Name = @ItemNameInput" issue?
You're missing the space before the WHERE (or after Items)
May 17, 2018 at 10:55 am
May 17, 2018 at 11:08 am
This is how I would write your code that you posted. I understand that you are putting pieces together, but I think this helps illustrate what you are attempting to accomplish a little easier. Also, your EXEC sp_executesql is not correct and if it was working, I'm not sure how or why.
-- your exec: EXEC sp_executesql @sql, N'@SearchResultsSetID INT', @SearchResultsSetID, '@ItemNameInput NVARCHAR(100)', @ItemNameInput;
DECLARE @SQLCmd NVARCHAR(MAX)
, @SQLParm NVARCHAR(MAX);
SET @SQLParm = N'@SearchResultsSetID INT, @ItemNameInput NVARCHAR(100)';
SET @SQLCmd = N'
INSERT INTO SearchResults (
SearchResultsSetID
, ItemID)
SELECT
@SearchResultsSetID
, ID
FROM
Items
WHERE
Name LIKE CASE WHEN @ItemNameInput = ''''
THEN ''%''
ELSE @ItemNameInput -- as long as there is no wild card in the input value this works like an =
END;';
PRINT @SQLCmd;
EXEC [sys].[sp_executesql] @stmt = @SQLCmd
, @params = @SQLParm
, @SearchResultsSetID = @SearchResultsSetID
, @ItemNameInput = @ItemNameInput;
May 17, 2018 at 11:13 am
Thom A - Thursday, May 17, 2018 10:55 AMPRINT @sql;
Your best friend when debugging dynamic SQL. Debug the SQL output from the PRINT, and then propagate any fixes the the SQL that generated your dynamic SQL.
Although I used PRINT in the code I posted I actually use the following to look at the dynamic SQL I normally write as sometimes (usually) longer than can be fully output by PRINT in SSMS:
if @pDebug = 1
select cast('<![CDATA[' + @SQLCmd + ']]>' as xml);
May 17, 2018 at 11:21 am
Changed my code some:
-- your exec: EXEC sp_executesql @sql, N'@SearchResultsSetID INT', @SearchResultsSetID, '@ItemNameInput NVARCHAR(100)', @ItemNameInput;
DECLARE @SQLCmd NVARCHAR(MAX)
, @SQLParm NVARCHAR(MAX)
, @ItemNameInput NVARCHAR(100) = '';
SET @SQLParm = N'@SearchResultsSetID INT, @ItemNameInput NVARCHAR(100)';
SET @SQLCmd = N'
INSERT INTO SearchResults (
SearchResultsSetID
, ItemID)
SELECT
@SearchResultsSetID
, ID
FROM
Items
WHERE
Name' + CASE WHEN @ItemNameInput = '' THEN N' LIKE ''%''' ELSE N' = @ItemNameInput;' END;
PRINT @SQLCmd;
select cast('<![CDATA[' + @SQLCmd + ']]>' as xml);
EXEC [sys].[sp_executesql] @stmt = @SQLCmd
, @params = @SQLParm
, @SearchResultsSetID = @SearchResultsSetID
, @ItemNameInput = @ItemNameInput;
May 22, 2018 at 7:52 am
This was removed by the editor as SPAM
May 22, 2018 at 7:58 am
This was removed by the editor as SPAM
May 22, 2018 at 7:59 am
This was removed by the editor as SPAM
Viewing 11 posts - 1 through 10 (of 10 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