Click here to monitor SSC
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


forming a dynamic query


forming a dynamic query

Author
Message
ChrisM@Work
ChrisM@Work
SSCrazy Eights
SSCrazy Eights (9K reputation)SSCrazy Eights (9K reputation)SSCrazy Eights (9K reputation)SSCrazy Eights (9K reputation)SSCrazy Eights (9K reputation)SSCrazy Eights (9K reputation)SSCrazy Eights (9K reputation)SSCrazy Eights (9K reputation)

Group: General Forum Members
Points: 8957 Visits: 19014
You have three options: dynamic sql, a catch-all query, or using IF blocks to test the parameters and run whichever query fits the parameters.
Catch-all queries are popular but come with a cost, which you can read about here.
Using IF blocks is almost always the most performant method but you then have to maintain a number of queries each differing only in the WHERE clause.
Dynamic sql can certainly deal with your requirement but usually require a little more work than the other two methods. Try composing the different queries corresponding to the different parameters, something like your last post but with real column and table names, then use this as a template for building and testing your dynamic sql. Test each piece using PRINT.

“Write the query the simplest way. If through testing it becomes clear that the performance is inadequate, consider alternative query forms.” - Gail Shaw

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
Exploring Recursive CTEs by Example Dwain Camps
Jeff Moden
Jeff Moden
SSC-Forever
SSC-Forever (44K reputation)SSC-Forever (44K reputation)SSC-Forever (44K reputation)SSC-Forever (44K reputation)SSC-Forever (44K reputation)SSC-Forever (44K reputation)SSC-Forever (44K reputation)SSC-Forever (44K reputation)

Group: General Forum Members
Points: 44994 Visits: 39880
Sean Lange (5/1/2014)
The first and the biggest issue is this is wide open to sql injection.


In most cases, I'd strongly agree with you but... with two DATE, one INT, and one CHAR(1) parameters, I'd have to say that SQL Injection is impossible for the given code.

As to whether or not dynamic SQL is required for the original query or not goes, I'd have to agree with you and the others... NOT. :-)

--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.
Although they tell us that they want it real bad, our primary goal is to ensure that we dont actually give it to them that way.
Although change is inevitable, change for the better is not.
Just because you can do something in PowerShell, doesnt mean you should. Wink

Helpful Links:
How to post code problems
How to post performance problems
Forum FAQs
ChrisM@Work
ChrisM@Work
SSCrazy Eights
SSCrazy Eights (9K reputation)SSCrazy Eights (9K reputation)SSCrazy Eights (9K reputation)SSCrazy Eights (9K reputation)SSCrazy Eights (9K reputation)SSCrazy Eights (9K reputation)SSCrazy Eights (9K reputation)SSCrazy Eights (9K reputation)

Group: General Forum Members
Points: 8957 Visits: 19014
Jeff Moden (5/6/2014)
Sean Lange (5/1/2014)
The first and the biggest issue is this is wide open to sql injection.


In most cases, I'd strongly agree with you but... with two DATE, one INT, and one CHAR(1) parameters, I'd have to say that SQL Injection is impossible for the given code.

As to whether or not dynamic SQL is required for the original query or not goes, I'd have to agree with you and the others... NOT. :-)


The question is too vague and unstructured to provide anything more than a guess, so here goes:
IF @type <> '' AND @cid <> ''
SELECT * FROM tbl
WHERE [date] BETWEEN @frmdt AND @todt
   AND cid = @cid
   AND [type] = @type

IF @type <> ''
SELECT * FROM tbl
WHERE [date] BETWEEN @frmdt AND @todt
   AND [type] = @type

IF @cid <> ''
SELECT * FROM tbl
WHERE [date] BETWEEN @frmdt AND @todt
   AND cid = @cid

IF @type = '' AND @cid = ''
SELECT * FROM tbl
WHERE [date] BETWEEN @frmdt AND @todt



“Write the query the simplest way. If through testing it becomes clear that the performance is inadequate, consider alternative query forms.” - Gail Shaw

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
Exploring Recursive CTEs by Example Dwain Camps
Sean Lange
Sean Lange
SSCoach
SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)

Group: General Forum Members
Points: 16542 Visits: 16997
Jeff Moden (5/6/2014)
Sean Lange (5/1/2014)
The first and the biggest issue is this is wide open to sql injection.


In most cases, I'd strongly agree with you but... with two DATE, one INT, and one CHAR(1) parameters, I'd have to say that SQL Injection is impossible for the given code.

As to whether or not dynamic SQL is required for the original query or not goes, I'd have to agree with you and the others... NOT. :-)


Yes I even said as much in my post. However, the OP is struggling with a concept here and we all know what happens when you have dynamic sql that is working and somebody comes along and adds another value to the mix. At some point they will add a varchar to the mix and because the initial work was done in a format that allows it this will be wide open. Or the other side of that is that they will use this same technique on another process because it worked here. I am just trying to help the OP learn a better way of doing this so that in the future their code will be safe. :-)

--edit--

fixed a spelling error.

_______________________________________________________________

Need help? Help us help you.

Read the article at http://www.sqlservercentral.com/articles/Best+Practices/61537/ for best practices on asking questions.

Need to split a string? Try Jeff Moden's splitter.

Cross Tabs and Pivots, Part 1 – Converting Rows to Columns
Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs
Understanding and Using APPLY (Part 1)
Understanding and Using APPLY (Part 2)
homebrew01
homebrew01
SSCrazy
SSCrazy (3K reputation)SSCrazy (3K reputation)SSCrazy (3K reputation)SSCrazy (3K reputation)SSCrazy (3K reputation)SSCrazy (3K reputation)SSCrazy (3K reputation)SSCrazy (3K reputation)

Group: General Forum Members
Points: 2980 Visits: 9071
Could someone include the "how" and "why" that dynamic SQL is vulnerable to SQL injection ?



Sean Lange
Sean Lange
SSCoach
SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)

Group: General Forum Members
Points: 16542 Visits: 16997
homebrew01 (5/7/2014)
Could someone include the "how" and "why" that dynamic SQL is vulnerable to SQL injection ?


Well because of the datatypes presented here it really isn't vulnerable to sql injection. However, whenever I see somebody executing parameters to a stored proc the lights and sirens blaze loudly because the technique is incredibly dangerous.

Here is an example of dynamic sql that is very similar to the code posted in this thread.


create table InjectTest
(
   SomeValue varchar(50)
)

insert InjectTest
select 'Here I am.'

go

select * from InjectTest

go
create procedure IsThisVulnerable
(
   @MyValue varchar(50)
) as
   declare @SQL nvarchar(max)
   set @SQL = 'select * from sys.objects where name = ''' + @MyValue + ''''
   
   select @SQL
   exec(@SQL)
   
go

--So the example here is simplified but demonstrates sql injection
--Consider what happens when we execute this proc with these parameters.

exec IsThisVulnerable ''';drop table InjectTest--'

select * from InjectTest

--Now let's get really nasty. We will use sql injection to make the proc drop itself. Wink

select * from sys.objects where name = 'IsThisVulnerable'

go

exec IsThisVulnerable ''';drop proc IsThisVulnerable--'

go

select * from sys.objects where name = 'IsThisVulnerable'



Try this out on a sandbox database. This code will create a table and proc. Then actually remove all those object using sql injection.

_______________________________________________________________

Need help? Help us help you.

Read the article at http://www.sqlservercentral.com/articles/Best+Practices/61537/ for best practices on asking questions.

Need to split a string? Try Jeff Moden's splitter.

Cross Tabs and Pivots, Part 1 – Converting Rows to Columns
Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs
Understanding and Using APPLY (Part 1)
Understanding and Using APPLY (Part 2)
homebrew01
homebrew01
SSCrazy
SSCrazy (3K reputation)SSCrazy (3K reputation)SSCrazy (3K reputation)SSCrazy (3K reputation)SSCrazy (3K reputation)SSCrazy (3K reputation)SSCrazy (3K reputation)SSCrazy (3K reputation)

Group: General Forum Members
Points: 2980 Visits: 9071
How would the hacker pass that variable to the stored procedure ? If it's part of a form on a website, then hackers can enter character strings. But if the procedure is deeper in the application ??



Sean Lange
Sean Lange
SSCoach
SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)

Group: General Forum Members
Points: 16542 Visits: 16997
homebrew01 (5/7/2014)
How would the hacker pass that variable to the stored procedure ? If it's part of a form on a website, then hackers can enter character strings. But if the procedure is deeper in the application ??


Don't think about where the procedure can be accessed from. That is dangerous. Just because today the procedure isn't available from a web form doesn't mean that tomorrow it won't be. Remember that dynamic sql can be parameterized.

Taking the same dynamic sql we can easily parameterize it. Now this code is injection proof. When using dynamic sql it is not hard to write code that is injection proof.


alter procedure IsThisVulnerable
(
   @MyValue varchar(50)
) as
   declare @SQL nvarchar(max)
   set @SQL = 'select * from sys.objects where name = @MyValue'
   
   exec sp_executesql @SQL, N'@MyValue varchar(50)', @MyValue = @MyValue
   
go

exec IsThisVulnerable ''';drop proc IsThisVulnerable--'

exec IsThisVulnerable 'IsThisVulnerable'




_______________________________________________________________

Need help? Help us help you.

Read the article at http://www.sqlservercentral.com/articles/Best+Practices/61537/ for best practices on asking questions.

Need to split a string? Try Jeff Moden's splitter.

Cross Tabs and Pivots, Part 1 – Converting Rows to Columns
Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs
Understanding and Using APPLY (Part 1)
Understanding and Using APPLY (Part 2)
homebrew01
homebrew01
SSCrazy
SSCrazy (3K reputation)SSCrazy (3K reputation)SSCrazy (3K reputation)SSCrazy (3K reputation)SSCrazy (3K reputation)SSCrazy (3K reputation)SSCrazy (3K reputation)SSCrazy (3K reputation)

Group: General Forum Members
Points: 2980 Visits: 9071
Thanks Sean !



a4apple
a4apple
SSC-Enthusiastic
SSC-Enthusiastic (170 reputation)SSC-Enthusiastic (170 reputation)SSC-Enthusiastic (170 reputation)SSC-Enthusiastic (170 reputation)SSC-Enthusiastic (170 reputation)SSC-Enthusiastic (170 reputation)SSC-Enthusiastic (170 reputation)SSC-Enthusiastic (170 reputation)

Group: General Forum Members
Points: 170 Visits: 406
I believe you can write this query without using DYNAMIC SQL. but the only part that confuses me is @CID. You specified it as integer, and you are passing a name to it.

You can write something like this

SELECT *
FROM [Transaction]
WHERE Transdt BETWEEN CONVERT(VARCHAR (10),@transfrmdt,111) AND CONVERT(VARCHAR (10),@transtodt,111)
AND (@Cid IS NULL OR Cid = @cid)
AND (NULLIF(@Type, '') IS NULL OR [Type] = @Type)



Good Luck Smile .. Visit www.sqlsaga.com for more t-sql code snippets and BI related how to articles.
Go


Permissions

You can't post new topics.
You can't post topic replies.
You can't post new polls.
You can't post replies to polls.
You can't edit your own topics.
You can't delete your own topics.
You can't edit other topics.
You can't delete other topics.
You can't edit your own posts.
You can't edit other posts.
You can't delete your own posts.
You can't delete other posts.
You can't post events.
You can't edit your own events.
You can't edit other events.
You can't delete your own events.
You can't delete other events.
You can't send private messages.
You can't send emails.
You can read topics.
You can't vote in polls.
You can't upload attachments.
You can download attachments.
You can't post HTML code.
You can't edit HTML code.
You can't post IFCode.
You can't post JavaScript.
You can post emoticons.
You can't post or upload images.

Select a forum

































































































































































SQLServerCentral


Search