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

Cursor from variable Expand / Collapse
Author
Message
Posted Thursday, May 8, 2014 4:13 AM
Right there with Babe

Right there with BabeRight there with BabeRight there with BabeRight there with BabeRight there with BabeRight there with BabeRight there with BabeRight there with Babe

Group: General Forum Members
Last Login: Wednesday, November 26, 2014 2:44 AM
Points: 769, Visits: 856
Hi all,

I am using a cursor (i know - but this is actually something that is a procedural loop).

So effectively i have a table of names of stored procedures. I now have a store proc that loops around these procs and runs each one in order.

Now i am thinking i would like to be able to set the table it loops around in a variable at the start - is it possible to do this? So effectively use a tablename in a variable to use in the sql to define a cursor?

Many thanks

Dan
Post #1568812
Posted Thursday, May 8, 2014 4:21 AM
SSCrazy

SSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazy

Group: General Forum Members
Last Login: Today @ 4:49 AM
Points: 2,532, Visits: 7,083
danielfountain (5/8/2014)
Hi all,

I am using a cursor (i know - but this is actually something that is a procedural loop).

So effectively i have a table of names of stored procedures. I now have a store proc that loops around these procs and runs each one in order.

Now i am thinking i would like to be able to set the table it loops around in a variable at the start - is it possible to do this? So effectively use a tablename in a variable to use in the sql to define a cursor?

Many thanks

Dan


Passing the table name in a variable means that you will have to do this with dynamic sql. No problems there and straight forward really. Complexities start to pop up though if the tables have different structure, column names, data types etc..
Post #1568815
Posted Thursday, May 8, 2014 4:37 AM
Right there with Babe

Right there with BabeRight there with BabeRight there with BabeRight there with BabeRight there with BabeRight there with BabeRight there with BabeRight there with Babe

Group: General Forum Members
Last Login: Wednesday, November 26, 2014 2:44 AM
Points: 769, Visits: 856
Hi,

To answer your question - the tables will all be identical, just with different procedures within.

I have done dynamic SQL before with sp_executesql however i cant work out the way to use that as a cursor?

Thanks for your advice.

Dan
Post #1568819
Posted Thursday, May 8, 2014 5:05 AM
SSCrazy

SSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazy

Group: General Forum Members
Last Login: Today @ 4:49 AM
Points: 2,532, Visits: 7,083
To get you started


Sample data
USE tempdb;
GO

IF EXISTS (SELECT * FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = N'TBL_STOREDPROC_001' AND TABLE_SCHEMA = N'dbo')
DROP TABLE dbo.TBL_STOREDPROC_001;
IF EXISTS (SELECT * FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = N'TBL_STOREDPROC_002' AND TABLE_SCHEMA = N'dbo')
DROP TABLE dbo.TBL_STOREDPROC_002;

CREATE TABLE dbo.TBL_STOREDPROC_001
(
STOREDPROC_ID INT IDENTITY(1,1) PRIMARY KEY CLUSTERED NOT NULL
,STOREDPROC_NAME NVARCHAR(1024) NOT NULL
);

CREATE TABLE dbo.TBL_STOREDPROC_002
(
STOREDPROC_ID INT IDENTITY(1,1) PRIMARY KEY CLUSTERED NOT NULL
,STOREDPROC_NAME NVARCHAR(1024) NOT NULL
);

INSERT INTO dbo.TBL_STOREDPROC_001 (STOREDPROC_NAME)
VALUES
('STORED PROC 1 FROM TABLE 1')
,('STORED PROC 2 FROM TABLE 1')
,('STORED PROC 3 FROM TABLE 1');

INSERT INTO dbo.TBL_STOREDPROC_002 (STOREDPROC_NAME)
VALUES
('STORED PROC 1 FROM TABLE 2')
,('STORED PROC 2 FROM TABLE 2')
,('STORED PROC 3 FROM TABLE 2');


Simple code example
USE tempdb;
GO

DECLARE @TABLE_NAME NVARCHAR(1024) = N'dbo.TBL_STOREDPROC_002';

DECLARE @SQL_STR NVARCHAR(MAX) = REPLACE(N'

DECLARE @PROC_NAME NVARCHAR(MAX) = N'''';
DECLARE R_SET CURSOR FAST_FORWARD FOR
SELECT
N''EXEC '' + TP.STOREDPROC_NAME + NCHAR(59)
FROM {{@TABLE_NAME}} TP
ORDER BY TP.STOREDPROC_ID;
OPEN R_SET;
FETCH NEXT FROM R_SET INTO @PROC_NAME;
WHILE @@FETCH_STATUS = 0
BEGIN
PRINT @PROC_NAME;
FETCH NEXT FROM R_SET INTO @PROC_NAME;
END

CLOSE R_SET;
DEALLOCATE R_SET;
',N'{{@TABLE_NAME}}',@TABLE_NAME);

EXEC (@SQL_STR);

Post #1568823
Posted Thursday, May 8, 2014 7:46 AM


SSChampion

SSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampion

Group: General Forum Members
Last Login: Yesterday @ 2:50 PM
Points: 13,325, Visits: 12,811
danielfountain (5/8/2014)
Hi all,

I am using a cursor (i know - but this is actually something that is a procedural loop).

So effectively i have a table of names of stored procedures. I now have a store proc that loops around these procs and runs each one in order.

Now i am thinking i would like to be able to set the table it loops around in a variable at the start - is it possible to do this? So effectively use a tablename in a variable to use in the sql to define a cursor?

Many thanks

Dan


You might be surprised. From your description I don't think you need a cursor. Unless there are parameters derived from another source you could do this using dynamic sql in a single step. It might be possible even if the parameters do come from elsewhere. Without some details around what you are doing though it is hard to say.


_______________________________________________________________

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)
Post #1568892
Posted Thursday, May 8, 2014 4:04 PM
SSCrazy

SSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazy

Group: General Forum Members
Last Login: Yesterday @ 4:19 PM
Points: 2,328, Visits: 3,505
You can use a GLOBAL cursor and use dynamic SQL just to declare the cursor. You can process it in static code, including deallocating the cursor at the end.

SQL DBA,SQL Server MVP('07, '08, '09)

Carl Sagan said: "There is no such thing as a dumb question." Sagan obviously never watched a congressional hearing!
Post #1569103
Posted Friday, May 9, 2014 8:06 AM


SSC-Dedicated

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

Group: General Forum Members
Last Login: Yesterday @ 8:47 PM
Points: 35,770, Visits: 32,436
Just remember that if you use a GLOBAL cursor, there could be a serious amount of contention between concurrent runs.

p.s. I love the tagline in your signature!


--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."

(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 #1569291
« Prev Topic | Next Topic »

Add to briefcase

Permissions Expand / Collapse