Cursor from variable

  • 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

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

    😎

  • 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

  • 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);

  • 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 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/

  • 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) "It's a dog-eat-dog world, and I'm wearing Milk-Bone underwear." "Norm", on "Cheers". Also from "Cheers", from "Carla": "You need to know 3 things about Tortelli men: Tortelli men draw women like flies; Tortelli men treat women like flies; Tortelli men's brains are in their flies".

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

    Change is inevitable... Change for the better is not.


    Helpful Links:
    How to post code problems
    How to Post Performance Problems
    Create a Tally Function (fnTally)

Viewing 7 posts - 1 through 6 (of 6 total)

You must be logged in to reply to this topic. Login to reply