October 6, 2013 at 12:06 pm
i have a stored procedure where the customername parameter is a comma separated
i am calling that parameter in the dynamic where clause the problem is am getting the error unclosed single quotation,reason am getting that error because
values of customer names column are as follow
Will o'smith
Roa's
so the customer name parameter is comma separated and used in the where clause
October 6, 2013 at 12:25 pm
Lucky9 (10/6/2013)
i have a stored procedure where the customername parameter is a comma separatedi am calling that parameter in the dynamic where clause the problem is am getting the error unclosed single quotation,reason am getting that error because
values of customer names column are as follow
Will o'smith
Roa's
so the customer name parameter is comma separated and used in the where clause
Without the query, we'd only be guessing. Please post the query and the comma separated parameter.
--Jeff Moden
Change is inevitable... Change for the better is not.
October 6, 2013 at 12:32 pm
There are several options:
(a) formatting the single quotes to be used in dynamic SQL using the REPLACE function:
DECLARE @param VARCHAR(50)
DECLARE @param2 NVARCHAR(50)
SET @param ='Will o''smith,Roa''s'
SELECT @param
SELECT @param2 = 'SELECT ''' + REPLACE(@param,'''','''''') +'''';
SELECT @param2
exec sp_executesql @param2
(b) replace the single quotes in your parameter list and in the query (or add a separate computed colum that would replace the single qoute by e.g. an underscore)
or
(c) use the DelimitedSplit function referenced in my signature to split the comma separated list and call this function in an OUTER APPLY (or CROSS APPLY).
My personal preference would be option (c), since
(a) contains a bunch of security issues (e.g. the parameter could be "Will o'smith,Roa's; drop table users --") and I try to avoid dynamic SQL where I have alternatives and
(b) would modify (or hold modified) data just because of the way a query is written...
October 6, 2013 at 4:38 pm
Just a reminder to remember not to use anything from the parameters in direct concatenation in the dynamic SQL. Poorly formed dynamic SQL is still the leading cause of hack-attacks.
--Jeff Moden
Change is inevitable... Change for the better is not.
October 6, 2013 at 6:48 pm
Jeff Moden (10/6/2013)
Just a reminder to remember not to use anything from the parameters in direct concatenation in the dynamic SQL. Poorly formed dynamic SQL is still the leading cause of hack-attacks.
Agree to jeff 🙂
October 7, 2013 at 7:57 am
A simple way to debug dynamic SQL is to simply print it out. Then copy/paste the output into a New Query window and see where your errors are.
I'm not a big fan of dynamic SQL but others before me were. There are so many times I have debugged dynamic SQL in that fashion.
FYI, right now if I have to resort to dynamic SQL it is only in one-off scripts for a single purpose.
Kurt
Kurt W. Zimmerman
SR DBA
Lefrak Organization
New York, NY
http://www.linkedin.com/in/kurtwzimmerman
October 7, 2013 at 7:31 pm
Kurt W. Zimmerman (10/7/2013)
A simple way to debug dynamic SQL is to simply print it out. Then copy/paste the output into a New Query window and see where your errors are.I'm not a big fan of dynamic SQL but others before me were. There are so many times I have debugged dynamic SQL in that fashion.
FYI, right now if I have to resort to dynamic SQL it is only in one-off scripts for a single purpose.
Kurt
Anytime I write a SP that uses dynamic SQL I include a @debug parameter so that I can EXEC the SP with @debug=1 to print the SQL. Unfortunately, if it gets too long there are limitations on what can display in the Messages pane (4000 characters I think).
My thought question: Have you ever been told that your query runs too fast?
My advice:
INDEXing a poor-performing query is like putting sugar on cat food. Yeah, it probably tastes better but are you sure you want to eat it?
The path of least resistance can be a slippery slope. Take care that fixing your fixes of fixes doesn't snowball and end up costing you more than fixing the root cause would have in the first place.
Need to UNPIVOT? Why not CROSS APPLY VALUES instead?[/url]
Since random numbers are too important to be left to chance, let's generate some![/url]
Learn to understand recursive CTEs by example.[/url]
[url url=http://www.sqlservercentral.com/articles/St
October 8, 2013 at 5:40 am
dwain.c (10/7/2013)
Unfortunately, if it gets too long there are limitations on what can display in the Messages pane (4000 characters I think).
So don't do that anymore. 😉 I got this tip from opc.three.
--===== Declare a demonstration variable to store
-- a long string in.
DECLARE @SomeLongString VARCHAR(MAX)
;
--===== This just builds a long string of SELECTs.
-- Don't ever do something like this with
-- public facing string parameters because
-- it is concatenated dynamic SQL.
WITH
cteTally AS
(
SELECT TOP 1000
N = ROW_NUMBER()OVER(ORDER BY (SELECT 1))
FROM master.sys.all_columns ac1
CROSS JOIN master.sys.all_columns ac2
)
SELECT @SomeLongString
= ISNULL(@SomeLongString,'--')
+ REPLACE(REPLACE('
SELECT "This is string #<<N>>";
'
,'"','''')
,'<<N>>',RIGHT(N+10000,4))
FROM cteTally
OPTION (MAXDOP 1)
;
--===== Show the length of the string.
SELECT LengthOfString = LEN(@SomeLongString)
;
--===== Now, display the string in its entirety.
-- Run the code in the grid mode and then click on the XML to see
-- it all with indents and line breaks preserved.
SELECT @SomeLongString AS [processing-instruction(SomeMeaninglessLabel)]
FOR XML PATH(''), TYPE
;
--Jeff Moden
Change is inevitable... Change for the better is not.
October 8, 2013 at 6:13 am
Kurt W. Zimmerman (10/7/2013)
I'm not a big fan of dynamic SQL but others before me were.
I'm a big fan for a couple of reasons...
1. A lot of front-end developers don't know how to write proper, safe, and performant complex T-SQL especially when it things like "catch-all" queries. I'd rather see that type of code in the back-end rather than as embedded code.
Here's the best article ever on "catch-all" queries that are actually SQL Injection Proof.
http://sqlinthewild.co.za/index.php/2009/03/19/catch-all-queries/
2. It really helps as a DBA for creating things like index maintenance, etc, etc.
A lot of people have a bit of a problem writing and debugging dynamic SQL. I normally just write code that works well for a single iteration of whatever I'm trying to do and then parameterize it. I normally use the methods that Gail shows in her "Catch-All" query article but I do substitute double quotes for single quotes and simply replace them at run time. Makes for some really clean and easy to read/write dynamic code.
I say "normally" because I do have to occasionally write some non-public-facing SQL that traverses tables and databases. Heh... and, no... I don't use sp_MSForEachTable or sp_MSForEachDB.
--Jeff Moden
Change is inevitable... Change for the better is not.
October 8, 2013 at 9:09 am
Don't get me wrong, Dynamic SQL has it's place along with Cursors. However I have seen dynamic SQL used in places where it was not truly needed. Case in point, I found that one of the most critical processes in an application, the nightly billing cycle utilized dynamic sql. I found it to clutter the procedure cache to a point where it actually affected overall performance to the application. Once I found this I simply cleared procedure cache to regain performance.
To put it another way, I will use dynamic SQL for utility processing along with cursors. I avoid putting dynamic SQL & cursors in the main stream, core applications.
So, yes, I do write dynamic SQL and I do use cursors. I just try to find ways avoiding those constructs unless I have no other way around using or if it is simply a one-off process where performance is not a factor.
Kurt
Kurt W. Zimmerman
SR DBA
Lefrak Organization
New York, NY
http://www.linkedin.com/in/kurtwzimmerman
October 8, 2013 at 10:21 am
dwain.c (10/7/2013)
Kurt W. Zimmerman (10/7/2013)
A simple way to debug dynamic SQL is to simply print it out. Then copy/paste the output into a New Query window and see where your errors are.I'm not a big fan of dynamic SQL but others before me were. There are so many times I have debugged dynamic SQL in that fashion.
FYI, right now if I have to resort to dynamic SQL it is only in one-off scripts for a single purpose.
Kurt
Anytime I write a SP that uses dynamic SQL I include a @debug parameter so that I can EXEC the SP with @debug=1 to print the SQL. Unfortunately, if it gets too long there are limitations on what can display in the Messages pane (4000 characters I think).
I do this as well. It has saved a lot of time debugging some of the more complex SPs. Great tip.
Kurt
Kurt W. Zimmerman
SR DBA
Lefrak Organization
New York, NY
http://www.linkedin.com/in/kurtwzimmerman
October 9, 2013 at 12:25 pm
Jeff Moden (10/8/2013)
dwain.c (10/7/2013)
Unfortunately, if it gets too long there are limitations on what can display in the Messages pane (4000 characters I think).So don't do that anymore. 😉 I got this tip from opc.three.
--===== Declare a demonstration variable to store
-- a long string in.
DECLARE @SomeLongString VARCHAR(MAX)
;
--===== This just builds a long string of SELECTs.
-- Don't ever do something like this with
-- public facing string parameters because
-- it is concatenated dynamic SQL.
WITH
cteTally AS
(
SELECT TOP 1000
N = ROW_NUMBER()OVER(ORDER BY (SELECT 1))
FROM master.sys.all_columns ac1
CROSS JOIN master.sys.all_columns ac2
)
SELECT @SomeLongString
= ISNULL(@SomeLongString,'--')
+ REPLACE(REPLACE('
SELECT "This is string #<<N>>";
'
,'"','''')
,'<<N>>',RIGHT(N+10000,4))
FROM cteTally
OPTION (MAXDOP 1)
;
--===== Show the length of the string.
SELECT LengthOfString = LEN(@SomeLongString)
;
--===== Now, display the string in its entirety.
-- Run the code in the grid mode and then click on the XML to see
-- it all with indents and line breaks preserved.
SELECT @SomeLongString AS [processing-instruction(SomeMeaninglessLabel)]
FOR XML PATH(''), TYPE
;
Woah 😎
Viewing 12 posts - 1 through 11 (of 11 total)
You must be logged in to reply to this topic. Login to reply