sql cursor in stored procedure - not looping

  • I have a problem that I don't know how to solve.Since yesterday I've tried all the different approaches I could find and no success. I just can't see the problem. I have a procedure that accepts user's Code and prepares SQL statements for me depending on HierarchyFlag. The procedure works when a user has one profile. I need to loop through all user's profiles and prepare SQL statements for each profile. I checked the table variable on a test user and ih has a correct number of profiles (rows) - 2. So the procedure should loop through IFs twice but it doesn't. It works same like before, it runs one time and prepares statements for 1 user's profile. What am I not seeing? Please help.


    CREATE PROCEDURE [dbo].[TEST]
            @Code NVARCHAR(5)        
    AS

    DECLARE @profileName nvarchar(200);
    DECLARE @hierarchyFlag tinyint;
    DECLARE @db_cursor CURSOR;
    DECLARE @ProfileNameTable TABLE (ProfileName nvarchar(100))
    INSERT INTO @ProfileNameTable (ProfileName) SELECT CASE WHEN Code like '%S%' AND ProfileName NOT LIKE '%STUDENT%' THEN CONCAT(LTRIM(RTRIM(ProfileName)), '_STUDENT')
            ELSE LTRIM(RTRIM(ProfileName)) END AS ProfileName FROM [dbo].[Users_Exceptions] WHERE replace(ltrim(replace(Code, '0', ' ')), ' ', '0') = @Code AND ProfileName IS NOT NULL
            UNION
            SELECT ProfileName AS ProfileName FROM [dbo].[vProfile] WHERE replace(ltrim(replace(Code, '0', ' ')), ' ', '0') = @Code AND ProfileName IS NOT NULL AND OraUser IS NOT NULL

    /*
    SET @db_cursor = CURSOR FOR
    SELECT a.ProfileName FROM
        (SELECT HibisProfileName AS ProfileName FROM [dbo].[vSB_IdM_Hibis_Profile] WHERE replace(ltrim(replace(Code, '0', ' ')), ' ', '0') = @Code AND HibisProfileName IS NOT NULL AND OraUser IS NOT NULL
        UNION
        SELECT CASE WHEN Code like '%S%' AND ProfileName NOT LIKE '%STUDENT%' THEN CONCAT(LTRIM(RTRIM(ProfileName)), '_STUDENT')
            ELSE LTRIM(RTRIM(ProfileName)) END AS ProfileName FROM [dbo].[SB_Hibis_Users_Exceptions] WHERE replace(ltrim(replace(Code, '0', ' ')), ' ', '0') = @Code AND ProfileName IS NOT NULL) a;
    */
    SET @db_cursor = CURSOR FOR
    SELECT ProfileName FROM @ProfileNameTable

    OPEN @db_cursor;
    FETCH NEXT FROM @db_cursor INTO @profileName;

    WHILE @@FETCH_STATUS = 0
    BEGIN

        SET @hierarchyFlag = (SELECT TOP 1 HierarchyFlag FROM [dbo].[vSB_IdM_Hibis_Profile] WHERE ltrim(rtrim(HibisProfileName)) = @profileName AND HierarchyFlag IS NOT NULL);

        IF (@hierarchyFlag = 1)
            BEGIN
                SELECT 'insert into ban_nad (OP,NADREJEN,VODJA) VALUES (''' +replace(ltrim(replace(a.Code, '0', ' ')), ' ', '0')+''',''' +replace(ltrim(replace(b.Code, '0', ' ')), ' ', '0')+''',''0'');'
                FROM [dbo].[vProfile] a, [dbo].[vProfile] b
                WHERE a.Code <> b.Code AND ISNULL(@profileName, 'A') = ISNULL(b.HibisProfileName, 'A') AND replace(ltrim(replace(a.Code, '0', ' ')), ' ', '0') = @Code
                UNION
                SELECT 'insert into ban_nad (OP,NADREJEN,VODJA) VALUES (''' +replace(ltrim(replace(b.Code, '0', ' ')), ' ', '0')+''',''' +replace(ltrim(replace(a.code, '0', ' ')), ' ', '0')+''',''0'');'
                FROM [dbo].[vProfile] a, [dbo].[vProfile] b
                WHERE a.Code <> b.Code AND ISNULL(@profileName, 'A') = ISNULL(b.HibisProfileName, 'A') AND replace(ltrim(replace(a.Code, '0', ' ')), ' ', '0') = @Code
                UNION
                SELECT 'insert into ban_nad (OP,NADREJEN,VODJA) VALUES (''' +replace(ltrim(replace(dv.Code, '0', ' ')), ' ', '0')+''',null,''1'');'
                FROM [dbo].[vProfile] dv
                WHERE replace(ltrim(replace(dv.Code, '0', ' ')), ' ', '0') = @Code
                UNION
                SELECT 'insert into ban_nad (OP,NADREJEN,VODJA) VALUES (''' +replace(ltrim(replace(b.OP, '0', ' ')), ' ', '0')+''',''' +replace(ltrim(replace(a.code, '0', ' ')), ' ', '0')+''',''0'');'
                FROM [dbo].[vProfile] a, [dbo].[Hierarchy_Ex] b
                WHERE ISNULL(@profileName, 'A') = ISNULL(b.PROFILENAME, 'B') AND replace(ltrim(replace(a.Code, '0', ' ')), ' ', '0') = @Code
            END
        ELSE IF (@hierarchyFlag = 2)
            BEGIN
                SELECT 'insert into ban_nad (OP,NADREJEN,VODJA) VALUES (''' +replace(ltrim(replace(a.Code, '0', ' ')), ' ', '0')+''',''' +replace(ltrim(replace(b.Code, '0', ' ')), ' ', '0')+''',''0'');'
                FROM [dbo].[vProfile] a, [dbo].[vProfile] b
                WHERE a.Code <> b.Code AND ISNULL(@profileName, 'A') = CONCAT(ISNULL(b.HibisProfileName, 'A'), '_STUDENT') AND replace(ltrim(replace(a.Code, '0', ' ')), ' ', '0') = @Code
                UNION
                SELECT 'insert into ban_nad (OP,NADREJEN,VODJA) VALUES (''' +replace(ltrim(replace(dv.Code, '0', ' ')), ' ', '0')+''',null,''1'');'
                FROM [dbo].[vSB_IdM_Hibis_Profile] dv
                WHERE replace(ltrim(replace(dv.Code, '0', ' ')), ' ', '0') = @Code
                UNION
                SELECT 'insert into ban_nad (OP,NADREJEN,VODJA) VALUES (''' +replace(ltrim(replace(b.OP, '0', ' ')), ' ', '0')+''',''' +replace(ltrim(replace(a.code, '0', ' ')), ' ', '0')+''',''0'');'
                FROM [dbo].[vProfile] a, [dbo].[Hierarchy_Ex] b
                WHERE ISNULL(@profileName, 'A') = ISNULL(b.PROFILENAME, 'B') AND replace(ltrim(replace(a.Code, '0', ' ')), ' ', '0') = @Code
            END

        FETCH NEXT FROM @db_cursor INTO @profileName
    END

    CLOSE @db_cursor;
    DEALLOCATE @db_cursor;

  • The problem here is understanding what you have to do with a cursor.   In order to get the loop to work correctly, you have to be able to do your FETCH NEXT at the BEGINNING of the loop, as what happens in your code is that the last FETCH happens, but your code doesn't do anything with it because the last FETCH changes the value of @@FETCH_STATUS, and then the loop checks the value of that at the beginning of the loop, and immediately stops.   That's why you always have to process the first record BEFORE you enter your loop.

    Steve (aka sgmunson) 🙂 🙂 🙂
    Rent Servers for Income (picks and shovels strategy)

  • How did I miss that with all the reading about cursors... Thank you very much for the essential info about cursors.
    Is there an elegant solution or do I have to rewrite the whole code twice - before and after loop?

  • sani.bozic - Thursday, July 12, 2018 6:20 AM

    How did I miss that with all the reading about cursors... Thank you very much for the essential info about cursors.
    Is there an elegant solution or do I have to rewrite the whole code twice - before and after loop?

    I'm not aware of any way to avoid duplicating the code.   You have to initialize @@FETCH_STATUS before you can check it's value, and the only way to do that is via FETCH NEXT.   You could create a separate stored procedure whose parameters are entirely those defined for the cursor to deliver values into, and then execute that once before the loop, and then once inside the loop, and that would minimize code duplication, but that's a long way to go for not much savings, plus the overhead of another 2 procedure calls, or however many times the loop runs....

    Steve (aka sgmunson) 🙂 🙂 🙂
    Rent Servers for Income (picks and shovels strategy)

  • Thank you once again for your help. I went with creating 2 separate procedures, it does the job.

  • Although not considered "standard", I prefer this approach because (1) the FETCH only has to be written once (can't count the number of times someone changes only one FETCH when there are two causing issues and (2) it's much easier to skip to the next row because you don't have to issue a FETCH before exiting the logic (which can cause even more than 2 FETCHes to be used!).


    DECLARE ... CURSOR ...

    OPEN @db_cursor;

    WHILE 1 = 1
    BEGIN
      FETCH NEXT FROM ... INTO ...;
      IF @@FETCH_STATUS <> 0
          IF @@FETCH_STATUS = -1
              BREAK
          ELSE
              CONTINUE;
      IF <the_current_row_doesn't_need_processed>
          CONTINUE;
      ...process_the_current_row_here...
    END /*WHILE*/

    DEALLOCATE @db_cursor;

    SQL DBA,SQL Server MVP(07, 08, 09) A socialist is someone who will give you the shirt off *someone else's* back.

  • sani.bozic - Thursday, July 12, 2018 9:28 AM

    Thank you once again for your help. I went with creating 2 separate procedures, it does the job.

    You're very welcome.   And it now appears there IS a way to avoid it.   See Scott Pletcher's post above.  I had forgotten about testing the @@FETCH_STATUS for -1.   I wouldn't be all that worried about it not being considered standard.   It does eliminate the duplicated code.   However, I always prefer to avoid cursors unless there simply is NO other way to do something.   You may wish to see whether you actually need one or not.   There is almost always another way to skin the same cat without a cursor.

    Steve (aka sgmunson) 🙂 🙂 🙂
    Rent Servers for Income (picks and shovels strategy)

  • sgmunson - Thursday, July 12, 2018 12:06 PM

    sani.bozic - Thursday, July 12, 2018 9:28 AM

    Thank you once again for your help. I went with creating 2 separate procedures, it does the job.

    You're very welcome.   And it now appears there IS a way to avoid it.   See Scott Pletcher's post above.  I had forgotten about testing the @@FETCH_STATUS for -1.   I wouldn't be all that worried about it not being considered standard.   It does eliminate the duplicated code.   However, I always prefer to avoid cursors unless there simply is NO other way to do something.   You may wish to see whether you actually need one or not.   There is almost always another way to skin the same cat without a cursor.

    Yeah, -2 can get you if you just code "@@FETCH_STATUS <> 0".  By default, "If FORWARD_ONLY is specified without the STATIC, KEYSET, or DYNAMIC keywords, the cursor operates as a DYNAMIC cursor."  And I've seen some cases where that caused cursors to exit well before the entire set was processed. 

    So one needs to either explicitly force the cursor to not be able to get a -2 (rather tricky for many developers to be sure of anyway) or code an explicit check for it.  I just always code for it, then I never get unexpectedly burned even if the cursor reverts to dynamic from some changes to it.

    SQL DBA,SQL Server MVP(07, 08, 09) A socialist is someone who will give you the shirt off *someone else's* back.

  • I am sorry to disagree with my collegues, but your cursor progression was correct.  If you comment out references to your tables and put simple statements in instead you will see that the loop generates output for each value:


    DECLARE @profileName nvarchar(200);
    DECLARE @hierarchyFlag tinyint;
    DECLARE @db_cursor CURSOR;
    DECLARE @ProfileNameTable TABLE (ProfileName nvarchar(100));
    INSERT INTO @ProfileNameTable (ProfileName)
    /*SELECT CASE WHEN Code like '%S%' AND ProfileName NOT LIKE '%STUDENT%' THEN CONCAT(LTRIM(RTRIM(ProfileName)), '_STUDENT')
    ELSE LTRIM(RTRIM(ProfileName)) END AS ProfileName FROM [dbo].[Users_Exceptions] WHERE replace(ltrim(replace(Code, '0', ' ')), ' ', '0') = @Code AND ProfileName IS NOT NULL
    UNION
    SELECT ProfileName AS ProfileName FROM [dbo].[vProfile] WHERE replace(ltrim(replace(Code, '0', ' ')), ' ', '0') = @Code AND ProfileName IS NOT NULL AND OraUser IS NOT NULL*/
    VALUES ('Profile 1'), ('Profile 2');
    /*
    SET @db_cursor = CURSOR FOR
    SELECT a.ProfileName FROM
        (SELECT HibisProfileName AS ProfileName FROM [dbo].[vSB_IdM_Hibis_Profile] WHERE replace(ltrim(replace(Code, '0', ' ')), ' ', '0') = @Code AND HibisProfileName IS NOT NULL AND OraUser IS NOT NULL
       UNION
       SELECT CASE WHEN Code like '%S%' AND ProfileName NOT LIKE '%STUDENT%' THEN CONCAT(LTRIM(RTRIM(ProfileName)), '_STUDENT')
            ELSE LTRIM(RTRIM(ProfileName)) END AS ProfileName FROM [dbo].[SB_Hibis_Users_Exceptions] WHERE replace(ltrim(replace(Code, '0', ' ')), ' ', '0') = @Code AND ProfileName IS NOT NULL) a;
    */
    SET @db_cursor  = CURSOR FOR
    SELECT ProfileName FROM @ProfileNameTable

    OPEN @db_cursor;
    FETCH NEXT FROM @db_cursor INTO @profileName;
    WHILE @@FETCH_STATUS = 0
    BEGIN
      
    PRINT @profileName
    /*    SET @hierarchyFlag = (SELECT TOP 1 HierarchyFlag FROM [dbo].[vSB_IdM_Hibis_Profile] WHERE ltrim(rtrim(HibisProfileName)) = @profileName AND HierarchyFlag IS NOT NULL);
       IF (@hierarchyFlag = 1)
            BEGIN
              SELECT 'insert into ban_nad (OP,NADREJEN,VODJA) VALUES (''' +replace(ltrim(replace(a.Code, '0', ' ')), ' ', '0')+''',''' +replace(ltrim(replace(b.Code, '0', ' ')), ' ', '0')+''',''0'');'
              FROM [dbo].[vProfile] a, [dbo].[vProfile] b
              WHERE  a.Code <> b.Code AND ISNULL(@profileName, 'A') = ISNULL(b.HibisProfileName, 'A')  AND replace(ltrim(replace(a.Code, '0', ' ')), ' ', '0') = @Code
              UNION
                SELECT 'insert into ban_nad (OP,NADREJEN,VODJA) VALUES (''' +replace(ltrim(replace(b.Code, '0', ' ')), ' ', '0')+''',''' +replace(ltrim(replace(a.code, '0', ' ')), ' ', '0')+''',''0'');'
             FROM [dbo].[vProfile] a, [dbo].[vProfile] b
              WHERE a.Code <> b.Code AND ISNULL(@profileName, 'A') = ISNULL(b.HibisProfileName, 'A')  AND replace(ltrim(replace(a.Code, '0', ' ')), ' ', '0') = @Code
              UNION
              SELECT 'insert into ban_nad (OP,NADREJEN,VODJA) VALUES (''' +replace(ltrim(replace(dv.Code, '0', ' ')), ' ', '0')+''',null,''1'');'
              FROM [dbo].[vProfile] dv
              WHERE  replace(ltrim(replace(dv.Code, '0', ' ')), ' ', '0') = @Code
              UNION
              SELECT 'insert into ban_nad (OP,NADREJEN,VODJA) VALUES (''' +replace(ltrim(replace(b.OP, '0', ' ')), ' ', '0')+''',''' +replace(ltrim(replace(a.code, '0', ' ')), ' ', '0')+''',''0'');'
              FROM [dbo].[vProfile] a, [dbo].[Hierarchy_Ex] b
                WHERE ISNULL(@profileName, 'A') = ISNULL(b.PROFILENAME, 'B')  AND replace(ltrim(replace(a.Code, '0', ' ')), ' ', '0') = @Code
          END
      ELSE IF (@hierarchyFlag = 2)
            BEGIN
              SELECT 'insert into ban_nad (OP,NADREJEN,VODJA) VALUES (''' +replace(ltrim(replace(a.Code, '0', ' ')), ' ', '0')+''',''' +replace(ltrim(replace(b.Code, '0', ' ')), ' ', '0')+''',''0'');'
              FROM [dbo].[vProfile] a, [dbo].[vProfile] b
              WHERE a.Code <> b.Code AND ISNULL(@profileName, 'A') = CONCAT(ISNULL(b.HibisProfileName, 'A'), '_STUDENT')  AND replace(ltrim(replace(a.Code, '0', ' ')), ' ', '0') = @Code
              UNION
                SELECT 'insert into ban_nad (OP,NADREJEN,VODJA) VALUES (''' +replace(ltrim(replace(dv.Code, '0', ' ')), ' ', '0')+''',null,''1'');'
              FROM [dbo].[vSB_IdM_Hibis_Profile] dv
              WHERE  replace(ltrim(replace(dv.Code, '0', ' ')), ' ', '0') = @Code
              UNION
              SELECT 'insert into ban_nad (OP,NADREJEN,VODJA) VALUES (''' +replace(ltrim(replace(b.OP, '0', ' ')), ' ', '0')+''',''' +replace(ltrim(replace(a.code, '0', ' ')), ' ', '0')+''',''0'');'
              FROM [dbo].[vProfile] a, [dbo].[Hierarchy_Ex] b
              WHERE ISNULL(@profileName, 'A') = ISNULL(b.PROFILENAME, 'B')  AND replace(ltrim(replace(a.Code, '0', ' ')), ' ', '0') = @Code
          END
    */
      FETCH NEXT FROM @db_cursor INTO @profileName
    END
    CLOSE @db_cursor;
    DEALLOCATE @db_cursor;


    this outputs:
    (2 rows affected)
    Profile 1
    Profile 2

    As your table definitions and data are not listed - you will have to test which part is not causing the multiple result to be generated (or it could be your calling application only saving the first dataset, not both)

  • Shane you're right.
    What I need to do is check @hierarchyflag for each row (for each profile) and for some reason I keep getting the @hierarchyflag value of the first returned row. I'm setting the value of @hierarchyflag inside the while, so it should be different each time, since I get it from the @profileName. In my understanding, if @hierarchyflag for Profile 1 is 1 and @hierarchyflag for Profile 2 is 2, shouldn't this print out 
    'aaa'
    'bbb'
    Why am I getting
    'aaa'
    'aaa'?


    DECLARE @profileName nvarchar(200);
    DECLARE @hierarchyFlag tinyint;
    DECLARE @db_cursor CURSOR;
    DECLARE @ProfileNameTable TABLE (ProfileName nvarchar(100));
    INSERT INTO @ProfileNameTable (ProfileName) VALUES ('Profile 1'), ('Profile 2');

    SET @db_cursor = CURSOR FOR
    SELECT ProfileName FROM @ProfileNameTable

    OPEN @db_cursor;
    FETCH NEXT FROM @db_cursor INTO @profileName;

    WHILE @@FETCH_STATUS = 0
    BEGIN

    SET @hierarchyFlag = (SELECT TOP 1 HierarchyFlag FROM [dbo].[vSB_IdM_Hibis_Profile] WHERE ltrim(rtrim(HibisProfileName)) = @profileName);

     IF (@hierarchyFlag = 1)
            BEGIN
            PRINT 'aaa'
            END
     ELSE IF (@hierarchyFlag = 2)
            BEGIN
            PRINT 'bbb'
            END
     FETCH NEXT FROM @db_cursor INTO @profileName
    END
    CLOSE @db_cursor;
    DEALLOCATE @db_cursor;

  • sani.bozic your code looks correct and works - the only piece missing is "what is in the [dbo].[vSB_IdM_Hibis_Profile] table?"

    If I add your @hierarchyFlag value to the table variable and request that out
    DECLARE @profileName nvarchar(200);
    DECLARE @hierarchyFlag tinyint;
    DECLARE @db_cursor CURSOR;
    DECLARE @ProfileNameTable TABLE (ProfileName nvarchar(100), HierarchyFlag tinyint);
    INSERT INTO @ProfileNameTable (ProfileName, HierarchyFlag) VALUES ('Profile 1', 1), ('Profile 2', 2);
    SET @db_cursor  = CURSOR FOR
     SELECT ProfileName FROM @ProfileNameTable

    OPEN @db_cursor;
    FETCH NEXT FROM @db_cursor INTO @profileName;
    WHILE @@FETCH_STATUS = 0
    BEGIN
     SET @hierarchyFlag = (SELECT TOP 1 HierarchyFlag FROM @ProfileNameTable WHERE ltrim(rtrim(ProfileName)) = @profileName);
     IF (@hierarchyFlag = 1)
            BEGIN
            PRINT 'aaa'
            END
     ELSE IF (@hierarchyFlag = 2)
            BEGIN
            PRINT 'bbb'
            END
     FETCH NEXT FROM @db_cursor INTO @profileName
    END
    CLOSE @db_cursor;
    DEALLOCATE @db_cursor;
    Then I get the results that you expect:
    aaa
    bbb

    However if I change the insert to have multiple entries for each profile then the results can differ:
    INSERT INTO @ProfileNameTable (ProfileName, HierarchyFlag) VALUES ('Profile 1', 1), ('Profile 1', 2), ('Profile 2', 1), ('Profile 2', 2);
    This will return 4 lines of "aaa".

    So it comes down to what is in the [dbo].[vSB_IdM_Hibis_Profile] table? You will need to check the data in this table to ensure that your understanding of it is correct.

    Hope this helps

  • @shane I didn't think of that, thank you very much for your help!

Viewing 12 posts - 1 through 11 (of 11 total)

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