DB2 Sensitive Scroll Cursor Example


Input -

employee_details table

Scenario1 - Declare the sensitive scroll cursor for updating column manager_id of employee_details table.

   EXEC SQL 
	DECLARE E1 SENSITIVE SCROLL CURSOR FOR
     	SELECT EMP_NAME,
               MANAGER_ID
     	FROM   EMPLOYEE_DETAILS
        FOR    UPDATE OF MANAGER_ID
   END-EXEC.

Scenario2 - Declare the sensitive scroll cursor for updating all columns of the employee_details table.

   EXEC SQL 
	DECLARE E2 SENSITIVE SCROLL CURSOR FOR
     	SELECT EMP_ID,
               EMP_NAME,
               DESIGNATION,
               MANAGER_ID,
               DATE_OF_HIRE,
               SALARY,
               DEPT_ID
     	FROM   EMPLOYEE_DETAILS 
     	FOR UPDATE 
   END-EXEC.

Scenario3 - Declare the sensitive scroll readonly cursor for designation "FRESHER" in department 1000 of employee_details table.

   EXEC SQL 
	DECLARE E3 SCROLL CURSOR FOR
     	SELECT EMP_ID,
               EMP_NAME,
               DESIGNATION
     	FROM   EMPLOYEE_DETAILS 
     	WHERE  DESIGNATION = "FRESHER"
		AND    DEPT_ID = 1000
     	FOR    READ ONLY 
   END-EXEC.

Scenario4 - Declare the sensitive scroll readonly cursor for designation "FRESHER" in departments 1000 and 2000 of the employee_details table.

   EXEC SQL 
	DECLARE E4 SCROLL CURSOR FOR
     	SELECT EMP_ID,
               EMP_NAME,
               DESIGNATION
     	FROM   EMPLOYEE_DETAILS 
     	WHERE  DESIGNATION = "FRESHER"
		AND    DEPT_ID IN (1000, 2000)
		ORDER  BY DEPT_ID ASC
     	FOR    READ ONLY 
   END-EXEC.

Practical Example -


Scenario - The below example describes how the sensitive scroll cursor is coded in the COBOL + DB2 program.

Requirement - Hike the salary of TESTER(s) by 1000.

SENSITIVE SCROLL CURSOR Example Code -

----+----1----+----2----+----3----+----4----+----5----+
       IDENTIFICATION DIVISION.
       PROGRAM-ID. CSENSITS.

       ENVIRONMENT DIVISION.
       DATA DIVISION.
       WORKING-STORAGE SECTION.

           EXEC SQL
             INCLUDE SQLCA
           END-EXEC.

           EXEC SQL 
             INCLUDE EMPLDET
           END-EXEC.

      * DECLARING UPDATE   CURSOR
           EXEC SQL
                DECLARE CSR1 SENSITIVE SCROLL CURSOR FOR
                SELECT EMP_ID,
                       EMP_NAME,
                       DESIGNATION,
                       MANAGER_ID,
                       SALARY
                 FROM  EMPLOYEE_DETAILS
                WHERE  DESIGNATION = 'TESTER'
                  AND  DEPT_ID = 2000 
                  FOR  UPDATE OF SALARY 
           END-EXEC.

        01 WS-VAR.
           05 WS-UCNT          PIC 9(02) VALUE ZEROES.
           05 WS-UPDATED-SAL   PIC S9(5)V9(2) USAGE COMP-3.

       PROCEDURE DIVISION.
 
      * OPENING CURSOR   
           EXEC SQL
                OPEN CSR1
           END-EXEC.
  
      * FETCHING CURSOR LOOP UNTIL END OF RESULT TABLE
           DISPLAY "FETCH CUSOR BEFORE UPDATE...".
           DISPLAY "-----------------------------------------------".

           IF SQLCODE EQUAL ZERO
              PERFORM FETCH-EMP-DETAILS
                 THRU FETCH-EMP-DETAILS-EXIT
                UNTIL SQLCODE NOT EQUAL 0
           END-IF.

           DISPLAY "NO OF ROWS UPDATED:  ", WS-UCNT.
 
      * PLACING THE CURSOR AGAIN TO THE BEGINNING OF THE RESULT TABLE
           PERFORM SCROLL-TO-START-OF-RT
              THRU SCROLL-TO-START-OF-RT-EXIT

      * FETCHING CURSOR LOOP UNTIL END OF RESULT TABLE  
           DISPLAY " ".
           DISPLAY "FETCH CUSOR AFTER UPDATE...". 
           DISPLAY "-----------------------------------------------".

           IF SQLCODE EQUAL ZERO
              PERFORM FETCH-EMP-DETAILS-FB 
                 THRU FETCH-EMP-DETAILS-FB-EXIT 
                UNTIL SQLCODE NOT EQUAL 0 
           END-IF.

      * CLOSING CURSOR 
           EXEC SQL
                CLOSE CSR1
           END-EXEC.

           STOP RUN.

       FETCH-EMP-DETAILS. 

      * FETCH CURSOR 
           EXEC SQL
                FETCH CSR1
                INTO   :EMP-ID,
                       :EMP-NAME,
                       :DESIGNATION,
                       :MANAGER-ID
                       :MANAGER-ID-NI,
                       :SALARY 
           END-EXEC.

           EVALUATE SQLCODE
               WHEN ZERO
                    DISPLAY EMP-ID " : " EMP-NAME " : " DESIGNATION
      -             " : " MANAGER-ID " : " SALARY
                    PERFORM UPDATE-EMP-DETAILS
                       THRU UPDATE-EMP-DETAILS-EXIT
               WHEN 100 
                    CONTINUE
               WHEN OTHER
                    DISPLAY "DB2 ERROR:  ", SQLCODE
           END-EVALUATE.
 
       FETCH-EMP-DETAILS-EXIT.
           EXIT.

       UPDATE-EMP-DETAILS.
   
           COMPUTE WS-UPDATED-SAL = SALARY + 1000
 
           EXEC SQL
                UPDATE EMPLOYEE_DETAILS
                   SET SALARY = :WS-UPDATED-SAL 
                 WHERE CURRENT OF CSR1
           END-EXEC

           EVALUATE SQLCODE
               WHEN ZERO
                    COMPUTE WS-UCNT = WS-UCNT + 1
               WHEN 100
                    DISPLAY "UPDATING ROW NOT FOUND"
               WHEN OTHER
                    DISPLAY "DB2 ERROR: ", SQLCODE 
           END-EVALUATE.

       UPDATE-EMP-DETAILS-EXIT. 
           EXIT.

       SCROLL-TO-START-OF-RT.

      * FETCH CURSOR  
           EXEC SQL
                FETCH BEFORE FROM CSR1 
           END-EXEC. 

           EVALUATE SQLCODE
               WHEN ZERO
               WHEN 100
                    CONTINUE
               WHEN OTHER 
                    DISPLAY "DB2 ERROR:  ", SQLCODE 
           END-EVALUATE.
  
       SCROLL-TO-START-OF-RT-EXIT. 
           EXIT.

       FETCH-EMP-DETAILS-FB.

      * FETCH CURSOR
           EXEC SQL
                FETCH CSR1 
                INTO   :EMP-ID,
                       :EMP-NAME,
                       :DESIGNATION,
                       :MANAGER-ID
                       :MANAGER-ID-NI,
                       :SALARY 
           END-EXEC.

           EVALUATE SQLCODE
               WHEN ZERO 
                    DISPLAY EMP-ID " : " EMP-NAME " : " DESIGNATION
      -             " : " MANAGER-ID " : " SALARY
               WHEN 100 
                    CONTINUE
               WHEN OTHER
                    DISPLAY "DB2 ERROR:  ", SQLCODE
           END-EVALUATE.

       FETCH-EMP-DETAILS-FB-EXIT.
           EXIT.

Output -

SENSITIVE SCROLL CURSOR Program Output