Click here to monitor SSC
SQLServerCentral is supported by Red Gate Software Ltd.
 
Log in  ::  Register  ::  Not logged in
 
 
 
        
Home       Members    Calendar    Who's On


Add to briefcase 12»»

single quotes Expand / Collapse
Author
Message
Posted Sunday, October 06, 2013 12:06 PM
SSC Journeyman

SSC JourneymanSSC JourneymanSSC JourneymanSSC JourneymanSSC JourneymanSSC JourneymanSSC JourneymanSSC Journeyman

Group: General Forum Members
Last Login: Sunday, February 16, 2014 9:35 PM
Points: 98, Visits: 297
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
Post #1501937
Posted Sunday, October 06, 2013 12:25 PM


SSC-Dedicated

SSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-Dedicated

Group: General Forum Members
Last Login: Yesterday @ 4:00 PM
Points: 35,967, Visits: 30,258
Lucky9 (10/6/2013)
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


Without the query, we'd only be guessing. Please post the query and the comma separated parameter.


--Jeff Moden
"RBAR is pronounced "ree-bar" and is a "Modenism" for "Row-By-Agonizing-Row".

First step towards the paradigm shift of writing Set Based code:
Stop thinking about what you want to do to a row... think, instead, of what you want to do to a column."

"Change is inevitable. Change for the better is not." -- 04 August 2013
(play on words) "Just because you CAN do something in T-SQL, doesn't mean you SHOULDN'T." --22 Aug 2013

Helpful Links:
How to post code problems
How to post performance problems
Post #1501944
Posted Sunday, October 06, 2013 12:32 PM


SSCertifiable

SSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiable

Group: General Forum Members
Last Login: Today @ 9:52 AM
Points: 6,932, Visits: 12,663
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...




Lutz
A pessimist is an optimist with experience.

How to get fast answers to your question
How to post performance related questions
Links for Tally Table , Cross Tabs and Dynamic Cross Tabs , Delimited Split Function
Post #1501945
Posted Sunday, October 06, 2013 4:38 PM


SSC-Dedicated

SSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-Dedicated

Group: General Forum Members
Last Login: Yesterday @ 4:00 PM
Points: 35,967, Visits: 30,258
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
"RBAR is pronounced "ree-bar" and is a "Modenism" for "Row-By-Agonizing-Row".

First step towards the paradigm shift of writing Set Based code:
Stop thinking about what you want to do to a row... think, instead, of what you want to do to a column."

"Change is inevitable. Change for the better is not." -- 04 August 2013
(play on words) "Just because you CAN do something in T-SQL, doesn't mean you SHOULDN'T." --22 Aug 2013

Helpful Links:
How to post code problems
How to post performance problems
Post #1501971
Posted Sunday, October 06, 2013 6:48 PM
SSC Journeyman

SSC JourneymanSSC JourneymanSSC JourneymanSSC JourneymanSSC JourneymanSSC JourneymanSSC JourneymanSSC Journeyman

Group: General Forum Members
Last Login: Monday, October 21, 2013 3:10 AM
Points: 81, Visits: 191
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


Post #1501977
Posted Monday, October 07, 2013 7:57 AM


SSC Eights!

SSC Eights!SSC Eights!SSC Eights!SSC Eights!SSC Eights!SSC Eights!SSC Eights!SSC Eights!

Group: General Forum Members
Last Login: 2 days ago @ 1:13 PM
Points: 958, Visits: 1,285
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
Post #1502146
Posted Monday, October 07, 2013 7:31 PM


Hall of Fame

Hall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of Fame

Group: General Forum Members
Last Login: Today @ 2:24 AM
Points: 3,591, Visits: 5,100
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 mantra: No loops! No CURSORs! No RBAR! Hoo-uh!

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?
Since random numbers are too important to be left to chance, let's generate some!
Learn to understand recursive CTEs by example.
Splitting strings based on patterns can be fast!
Post #1502446
Posted Tuesday, October 08, 2013 5:40 AM


SSC-Dedicated

SSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-Dedicated

Group: General Forum Members
Last Login: Yesterday @ 4:00 PM
Points: 35,967, Visits: 30,258
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
"RBAR is pronounced "ree-bar" and is a "Modenism" for "Row-By-Agonizing-Row".

First step towards the paradigm shift of writing Set Based code:
Stop thinking about what you want to do to a row... think, instead, of what you want to do to a column."

"Change is inevitable. Change for the better is not." -- 04 August 2013
(play on words) "Just because you CAN do something in T-SQL, doesn't mean you SHOULDN'T." --22 Aug 2013

Helpful Links:
How to post code problems
How to post performance problems
Post #1502555
Posted Tuesday, October 08, 2013 6:13 AM


SSC-Dedicated

SSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-Dedicated

Group: General Forum Members
Last Login: Yesterday @ 4:00 PM
Points: 35,967, Visits: 30,258
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
"RBAR is pronounced "ree-bar" and is a "Modenism" for "Row-By-Agonizing-Row".

First step towards the paradigm shift of writing Set Based code:
Stop thinking about what you want to do to a row... think, instead, of what you want to do to a column."

"Change is inevitable. Change for the better is not." -- 04 August 2013
(play on words) "Just because you CAN do something in T-SQL, doesn't mean you SHOULDN'T." --22 Aug 2013

Helpful Links:
How to post code problems
How to post performance problems
Post #1502569
Posted Tuesday, October 08, 2013 9:09 AM


SSC Eights!

SSC Eights!SSC Eights!SSC Eights!SSC Eights!SSC Eights!SSC Eights!SSC Eights!SSC Eights!

Group: General Forum Members
Last Login: 2 days ago @ 1:13 PM
Points: 958, Visits: 1,285
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
Post #1502674
« Prev Topic | Next Topic »

Add to briefcase 12»»

Permissions Expand / Collapse