May 7, 2014 at 8:38 am
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. ;)
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 Modens splitter http://www.sqlservercentral.com/articles/Tally+Table/72993/.
Cross Tabs and Pivots, Part 1 – Converting Rows to Columns - http://www.sqlservercentral.com/articles/T-SQL/63681/
Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs - http://www.sqlservercentral.com/articles/Crosstab/65048/
Understanding and Using APPLY (Part 1) - http://www.sqlservercentral.com/articles/APPLY/69953/
Understanding and Using APPLY (Part 2) - http://www.sqlservercentral.com/articles/APPLY/69954/
May 7, 2014 at 8:54 am
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 ??
May 7, 2014 at 9:16 am
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 Modens splitter http://www.sqlservercentral.com/articles/Tally+Table/72993/.
Cross Tabs and Pivots, Part 1 – Converting Rows to Columns - http://www.sqlservercentral.com/articles/T-SQL/63681/
Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs - http://www.sqlservercentral.com/articles/Crosstab/65048/
Understanding and Using APPLY (Part 1) - http://www.sqlservercentral.com/articles/APPLY/69953/
Understanding and Using APPLY (Part 2) - http://www.sqlservercentral.com/articles/APPLY/69954/
May 7, 2014 at 9:36 am
Thanks Sean !
May 7, 2014 at 9:59 am
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 🙂 .. Visit www.sqlsaga.com for more t-sql code snippets and BI related how to articles.
May 7, 2014 at 10:04 am
a4apple (5/7/2014)
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)
This was mentioned already more than once. This is an example of a catch-all query. They work but usually have some negative performance implications. You can read more about this type of query here.
http://sqlinthewild.co.za/index.php/2009/03/19/catch-all-queries/[/url]
_______________________________________________________________
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 Modens splitter http://www.sqlservercentral.com/articles/Tally+Table/72993/.
Cross Tabs and Pivots, Part 1 – Converting Rows to Columns - http://www.sqlservercentral.com/articles/T-SQL/63681/
Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs - http://www.sqlservercentral.com/articles/Crosstab/65048/
Understanding and Using APPLY (Part 1) - http://www.sqlservercentral.com/articles/APPLY/69953/
Understanding and Using APPLY (Part 2) - http://www.sqlservercentral.com/articles/APPLY/69954/
May 7, 2014 at 12:07 pm
Sean Lange (5/7/2014)
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.
Ah... understood. Thanks, Sean.
--Jeff Moden
Change is inevitable... Change for the better is not.
Viewing 7 posts - 16 through 21 (of 21 total)
You must be logged in to reply to this topic. Login to reply