SQL Clone
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


How to Build Dynamic Stored Procedures


How to Build Dynamic Stored Procedures

Author
Message
Robert Davis
Robert Davis
SSCrazy
SSCrazy (2.9K reputation)SSCrazy (2.9K reputation)SSCrazy (2.9K reputation)SSCrazy (2.9K reputation)SSCrazy (2.9K reputation)SSCrazy (2.9K reputation)SSCrazy (2.9K reputation)SSCrazy (2.9K reputation)

Group: General Forum Members
Points: 2866 Visits: 1623

>> A complex statement is difficult to read when it is pieced together with a bunch of CHAR, CAST, and CONVERT fuctions.

I disagree. I think it is easier to read considering I don't have to go to another part of the procedure and find the Replace statements to figure out what someone is trying to do with a particular portion of the dynamic statement.

Of course, the best solution to the nvarchar 4000 character limit is to use nvarchar(max) in SQL Server 2005.





My blog: SQL Soldier
Twitter: @SQLSoldier
My book: Pro SQL Server 2008 Mirroring
Microsoft Certified Master, SQL Server MVP
Database Engineer at BlueMountain Capital Management
WILLIAM MITCHELL
WILLIAM MITCHELL
SSCrazy
SSCrazy (2.2K reputation)SSCrazy (2.2K reputation)SSCrazy (2.2K reputation)SSCrazy (2.2K reputation)SSCrazy (2.2K reputation)SSCrazy (2.2K reputation)SSCrazy (2.2K reputation)SSCrazy (2.2K reputation)

Group: General Forum Members
Points: 2172 Visits: 3062

The "best" solution is not to use dynamic sql unless there is absolutely no other way to accomplish the desired result.

Dynamic sql is a total pain to maintain. I've slogged through other people's dynamic code and many times found a better way.

If you must write dynamic sql, you should embed a sample of the resulting sql statement in the sp, to help illustrate what's going on. A very simple example of that would be:

-- use the next invoice # as the seed, might look like:
-- ALTER TABLE tblFM_MPI ADD InvoiceNumber int IDENTITY (45969, 1)
SET @sql = N'ALTER TABLE tblFM_MPI DROP COLUMN InvoiceNumber'
EXEC ( @sql )
SET @sql = N'ALTER TABLE tblFM_MPI ADD InvoiceNumber int IDENTITY (' + CAST(@NextInv AS varchar(6)) + ', 1)'
EXEC ( @sql )


Robert Davis
Robert Davis
SSCrazy
SSCrazy (2.9K reputation)SSCrazy (2.9K reputation)SSCrazy (2.9K reputation)SSCrazy (2.9K reputation)SSCrazy (2.9K reputation)SSCrazy (2.9K reputation)SSCrazy (2.9K reputation)SSCrazy (2.9K reputation)

Group: General Forum Members
Points: 2866 Visits: 1623

On a related note, we have a project in development for our internal account managers and tech support team to be able to run any select query they want against our databases to help them resolve issues. The devloper asked me how she could go about making sure they didn't inadvertantly perform some query other than a select. My reply was to create a user account that had all privelages denied except for select and execute the procedure as that user account. Bear in mind that the AM's and tech support will be using a web app that is using an account whose only rights is to execute stored procedures.

This is the real code that was finally used, but is the initial test code I sent to the developer for testing how it would work. Bear in mind that this is SQL 2005 code.

Use master

-- Create server login for test

Create Login DBDataReaderOnly With Password = 'PeasPorridgeCold'

Use DemoDatabase

-- Create database user for login

Create User DBDataReader For Login DBDataReaderOnly With Default_Schema = dbo

-- Create databse role for easy assignment of permissions

Create Role db_DataReaderOnly

-- Grant select rights

Grant Select To db_DataReaderOnly

-- Deny all other permissions

Deny Execute, Insert, Update, Delete, References, Alter, Take Ownership, View Definition To db_DataReaderOnly

-- Assign user to the database role

Exec sp_addrolemember 'db_DataReaderOnly', 'DBDataReader'

Go

-- Create a test procedure

Create Procedure dbo.USP_DynamicDataTest

@SQL nvarchar(max)

With Execute As 'DBDataReader'

As

Exec sp_executesql @SQL

Go

-- Test new account, run each command individually

Exec dbo.USP_DynamicDataTest @SQL = 'Select * From TestTable with(nolock)'

Exec dbo.USP_DynamicDataTest @SQL = 'Delete Top (1) From TestTable'

Exec dbo.USP_DynamicDataTest @SQL = 'Drop Table TestTable'





My blog: SQL Soldier
Twitter: @SQLSoldier
My book: Pro SQL Server 2008 Mirroring
Microsoft Certified Master, SQL Server MVP
Database Engineer at BlueMountain Capital Management
markybse
markybse
Grasshopper
Grasshopper (15 reputation)Grasshopper (15 reputation)Grasshopper (15 reputation)Grasshopper (15 reputation)Grasshopper (15 reputation)Grasshopper (15 reputation)Grasshopper (15 reputation)Grasshopper (15 reputation)

Group: General Forum Members
Points: 15 Visits: 10
Does anyone actually test this code or is most of this stuff just rumors?
According to most of the information I should be able to create multiple variables...

DECLARE @SELECT varchar(100)
DECLARE @FROM varchar(100)
DECLARE @DynamicSQL1 varchar(8000)
DECLARE @DynamicSQL2 varchar(8000)
DECLARE @DynamicSQL3 varchar(8000)

SET @SELECT = 'SELECT '
SET @FROM = 'FROM DATA_SOURCE'

EXEC (@SELECT + @DynamicSQL1 + @DynamicSQL2 + @DynamicSQL3 + @FROM)


The exec statement only accesses the first 8000 characters and then shuts down.

What am I missing/
Scott Coleman
Scott Coleman
Hall of Fame
Hall of Fame (3.9K reputation)Hall of Fame (3.9K reputation)Hall of Fame (3.9K reputation)Hall of Fame (3.9K reputation)Hall of Fame (3.9K reputation)Hall of Fame (3.9K reputation)Hall of Fame (3.9K reputation)Hall of Fame (3.9K reputation)

Group: General Forum Members
Points: 3884 Visits: 1465
Seems to work for me in both SQL 2000 and SQL 2005. This code creates a 16,000+ character command that returns 16 996-char fields and one 3-char field as results.

DECLARE @v1 VARCHAR(8000), @v2 VARCHAR(8000)
SET @v1 = '''' + LEFT(REPLICATE('1234567890', 100), 996) + ''', '

SET @v2 = REPLICATE(@v1, 8)
SET @v1 = @v2

EXEC ('SELECT ' + @v1 + @v2 + '''xyz''')

Maybe there's a syntax error in your command.



markybse
markybse
Grasshopper
Grasshopper (15 reputation)Grasshopper (15 reputation)Grasshopper (15 reputation)Grasshopper (15 reputation)Grasshopper (15 reputation)Grasshopper (15 reputation)Grasshopper (15 reputation)Grasshopper (15 reputation)

Group: General Forum Members
Points: 15 Visits: 10
Thank you for the quick reply and yes, I tested your code and it works fine on my system so, in theory, I should have a syntax error.

Taking my example below, I mad a change...all the way down, the first exec line fails and the second exec line works. I am at a loss as to why.

DECLARE @SELECT varchar(100)
DECLARE @FROM varchar(100)
DECLARE @DynamicSQL1 varchar(8000)
DECLARE @DynamicSQL2 varchar(8000)
DECLARE @DynamicSQL3 varchar(8000)

SET @SELECT = 'SELECT '
SET @FROM = 'FROM DATA_SOURCE'

EXEC (@SELECT + @DynamicSQL1 + @DynamicSQL2 + @DynamicSQL3 + @FROM)
EXEC (@SELECT +''+ @DynamicSQL1 +''+ @DynamicSQL2 +''+ @DynamicSQL3 +''+ @FROM)
Michael Valentine Jones
Michael Valentine Jones
SSCertifiable
SSCertifiable (6K reputation)SSCertifiable (6K reputation)SSCertifiable (6K reputation)SSCertifiable (6K reputation)SSCertifiable (6K reputation)SSCertifiable (6K reputation)SSCertifiable (6K reputation)SSCertifiable (6K reputation)

Group: General Forum Members
Points: 5956 Visits: 11771
I made extensive use of stored procedures that created temporary stored procedures for reporting in a data mart application. This reason I did this was because there could be literally hundreds of different variations of the same basic report summarized along different dimensions and levels. The input parameters to the stored procedure specified the grouping/sorting levels that were required, and the stored procedure used that to generate the code.

It was easier to write one fairly complex procedure than it was to create hundreds of almost identical, simpler procedures for the different variations in the reports. The biggest advantage was that if there was a bug, I only had to fix it in one procedure instead of hundreds.
mark hutchinson
mark hutchinson
SSC-Enthusiastic
SSC-Enthusiastic (108 reputation)SSC-Enthusiastic (108 reputation)SSC-Enthusiastic (108 reputation)SSC-Enthusiastic (108 reputation)SSC-Enthusiastic (108 reputation)SSC-Enthusiastic (108 reputation)SSC-Enthusiastic (108 reputation)SSC-Enthusiastic (108 reputation)

Group: General Forum Members
Points: 108 Visits: 446
markybse (1/8/2008)


... the first exec line fails and the second exec line works. I am at a loss as to why.

DECLARE @SELECT varchar(100)
DECLARE @FROM varchar(100)
DECLARE @DynamicSQL1 varchar(8000)
DECLARE @DynamicSQL2 varchar(8000)
DECLARE @DynamicSQL3 varchar(8000)

SET @SELECT = 'SELECT '
SET @FROM = 'FROM DATA_SOURCE'

EXEC (@SELECT + @DynamicSQL1 + @DynamicSQL2 + @DynamicSQL3 + @FROM)
EXEC (@SELECT +''+ @DynamicSQL1 +''+ @DynamicSQL2 +''+ @DynamicSQL3 +''+ @FROM)



I'm not sure of the exact problem, but I'd guess it stems from one of two likely sources.
1. The @DynamicSQL# variables need an interceding space in order for their concatenation to result in syntactically correct SQL.
Try:
EXEC (@SELECT + ' ' + @DynamicSQL1 + ' ' + @DynamicSQL2 + ' ' + @DynamicSQL3 + ' ' + @FROM)

2. You are trying to concatenate Null values. The solution would be to recast the @DynamicSQL# as a space if the value is Null.



markybse
markybse
Grasshopper
Grasshopper (15 reputation)Grasshopper (15 reputation)Grasshopper (15 reputation)Grasshopper (15 reputation)Grasshopper (15 reputation)Grasshopper (15 reputation)Grasshopper (15 reputation)Grasshopper (15 reputation)

Group: General Forum Members
Points: 15 Visits: 10
I believe that the second portion, "trying to concactinate NULL values" could be a good start in finding out why it is not working. Thanks again.
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