September 14, 2012 at 12:50 pm
I was hoping to confirm that while SQL injection is possible with dynamic queries that don't use parameterized queries, ownership chains are broken when using the dynamic query, so the only risk would be if that account had more than SELECT permissions on the underlying tables.
For instance, if I had a user called "TestUser" that had db_datareader access to a database (e.g., DatabaseA") and execute permissions on a stored procedure (e.g., spA), it would not be possible for "TestUser" to pass a parameter to spA that could modify any tables in DatabaseA if spA was using only dynamic queries?
Here is an example:
CREATE DATABASE DatabaseA;
GO
CREATE TABLE TableA ( ColumnA VARCHAR(255) )
GO
INSERT INTO TableA VALUES ('ABC');
INSERT INTO TableA VALUES ('DEF');
INSERT INTO TableA VALUES ('GHI');
INSERT INTO TableA VALUES ('JKL');
GRANT SELECT ON OBJECT::dbo.TableA TO [Test\TestUser];
GO
CREATE PROCEDURE spA
@paramA VARCHAR(255)
AS
BEGIN
EXEC('SELECT * FROM tableA WHERE ColumnA = ''' + @paramA + '''');
END
GO
GRANT EXECUTE ON dbo.spA TO [Test\TestUser];
Then to test whether or not we can do bad things, I ran this query as Test\TestUser:
EXEC dbo.spA 'ABC'';DROP TABLE TableA;SELECT ''';
I just want to confirm whether or not there is no risk, other than SELECTing data that we've already granted access to. The stored procedure comes from a vendor and it does not use parameterized queries because they have a dynamic list of columns. They do however use only dynamic queries, and their account only has read-only access to the underlying tables and only execute permissions on the stored procedure.
I know that my specific example doesn't work because I do get an error about insufficient permissions, but I just wanted to confirm my understanding that there isn't a risk that I'm unaware of because this is all new to me.
September 17, 2012 at 7:24 am
Dynamic SQL does break the ownership chain established when exectuing the proc. A new ownership chain can be established later in the call stack but at the end of the day the login/user executing the proc only has the rights they have in the instance, i.e. Dynamic SQL will not elevate their rights in any way.
There are no special teachers of virtue, because virtue is taught by the whole community.
--Plato
September 20, 2012 at 11:11 am
Just a little side comment. If you want to avoid having to grant permissions to the explicit tables, views etc used in the dynamic query, you can sign the procedure with a certificate that is linked to a user with permissions on the explicit objects in the dynamic SQL.
http://msdn.microsoft.com/en-us/library/ms181700.aspx
The downside is that the signature is removed if you ALTER the procedure, and you have to sign it again.
But if you are using any kind of automated deployment, then you can add the signing steps in there.
We have used it successfully on many procedures with dynamic sql.
Viewing 3 posts - 1 through 2 (of 2 total)
You must be logged in to reply to this topic. Login to reply