************************************************************************* ** ** Source File Name = joinsql.sqb ** ** Licensed Materials - Property of IBM ** ** (C) COPYRIGHT International Business Machines Corp. 1995, 2000 ** All Rights Reserved. ** ** US Government Users Restricted Rights - Use, duplication or ** disclosure restricted by GSA ADP Schedule Contract with IBM Corp. ** ** ** PURPOSE: an example of using advanced SQL statements. ** The advanced SQL statement to be executed and displayed ** is : ** WITH ** DEPT_MGR AS ** ( SELECT DEPTNO, DEPTNAME, EMPNO, LASTNAME, FIRSTNME, ** PHONENO FROM DEPARTMENT D, EMPLOYEE E ** WHERE D.MGRNO=E.EMPNO AND E.JOB='MANAGER' ** ), ** DEPT_NO_MGR AS ** ( SELECT DEPTNO, DEPTNAME, MGRNO AS EMPNO ** FROM DEPARTMENT ** EXCEPT ALL ** SELECT DEPTNO, DEPTNAME, EMPNO ** FROM DEPT_MGR ** ), ** MGR_NO_DEPT (DEPTNO, EMPNO, LASTNAME, FIRSTNME, PHONENO) AS ** ( SELECT WORKDEPT, EMPNO, LASTNAME, FIRSTNME, PHONENO ** FROM EMPLOYEE ** WHERE JOB='MANAGER' ** EXCEPT ALL ** SELECT DEPTNO,EMPNO, LASTNAME, FIRSTNME, PHONENO ** FROM DEPT_MGR ** ) ** SELECT DEPTNO, DEPTNAME, EMPNO, LASTNAME, FIRSTNME, PHONENO ** FROM DEPT_MGR ** UNION ALL ** SELECT DEPTNO, DEPTNAME, EMPNO, ** CAST(NULL AS VARCHAR(15)) AS LASTNAME, ** CAST(NULL AS VARCHAR(12)) AS FIRSTNME, ** CAST(NULL AS CHAR(4)) AS PHONENO ** FROM DEPT_NO_MGR ** UNION ALL ** SELECT DEPTNO, ** CAST(NULL AS VARCHAR(29)) AS DEPTNAME, ** EMPNO, LASTNAME, FIRSTNME, PHONENO ** FROM MGR_NO_DEPT; ** ** For more information about these samples see the README file. ** ** For more information on Programming in COBOL, see the: ** - "Programming in COBOL" section of the Application Development Guide. ** ** For more information on Building COBOL Applications, see the: ** - "Building COBOL Applications" section of the Application Building Guide. ** ** For more information on the SQL language see the SQL Reference. ** ************************************************************************* Identification Division. Program-ID. "joinsql". Data Division. Working-Storage Section. copy "sqlenv.cbl". copy "sql.cbl". copy "sqlca.cbl". EXEC SQL BEGIN DECLARE SECTION END-EXEC. 01 userid pic x(8). 01 passwd. 49 passwd-length pic s9(4) comp-5 value 0. 49 passwd-name pic x(18). 01 deptno pic x(3). 01 d-ind pic s9(4) comp-5 value 0. 01 deptname pic x(29). 01 dn-ind pic s9(4) comp-5 value 0. 01 empno pic x(6). 01 e-ind pic s9(4) comp-5 value 0. 01 lastname. 49 lastname-len pic s9(4) comp-5 value 15. 49 lastname-name pic x(15). 01 l-ind pic s9(4) comp-5 value 0. 01 firstname. 49 firstname-len pic s9(4) comp-5 value 12. 49 firstname-name pic x(12). 01 f-ind pic s9(4) comp-5 value 0. 01 phoneno pic x(4). 01 p-ind pic s9(4) comp-5 value 0. EXEC SQL END DECLARE SECTION END-EXEC. 77 errloc pic x(80). 77 counter pic s9(4) comp-5 value 0. Procedure Division. Main Section. display "Sample COBOL program: JOINSQL". * Get database connection information. display "Enter your user id (default none): " with no advancing. accept userid. if userid = spaces EXEC SQL CONNECT TO sample END-EXEC else display "Enter your password : " with no advancing accept passwd-name. * Passwords in a CONNECT statement must be entered in a VARCHAR format * with the length of the input string. inspect passwd-name tallying passwd-length for characters before initial " ". display " ". EXEC SQL CONNECT TO sample USER :userid USING :passwd END-EXEC. move "CONNECT TO" to errloc. call "checkerr" using SQLCA errloc. * declare the cursor for the advanced SQL statement. EXEC SQL DECLARE c1 CURSOR FOR WITH DEPT_MGR AS (SELECT DEPTNO, DEPTNAME, EMPNO, LASTNAME, FIRSTNME, PHONENO FROM DEPARTMENT D, EMPLOYEE E WHERE D.MGRNO=E.EMPNO AND E.JOB='MANAGER'), DEPT_NO_MGR AS (SELECT DEPTNO, DEPTNAME, MGRNO AS EMPNO FROM DEPARTMENT EXCEPT ALL SELECT DEPTNO, DEPTNAME, EMPNO FROM DEPT_MGR), MGR_NO_DEPT (DEPTNO, EMPNO, LASTNAME, FIRSTNME, PHONENO) AS (SELECT WORKDEPT, EMPNO, LASTNAME, FIRSTNME, PHONENO FROM EMPLOYEE WHERE JOB='MANAGER' EXCEPT ALL SELECT DEPTNO,EMPNO, LASTNAME, FIRSTNME, PHONENO FROM DEPT_MGR) SELECT DEPTNO, DEPTNAME, EMPNO, LASTNAME, FIRSTNME, PHONENO FROM DEPT_MGR UNION ALL SELECT DEPTNO, DEPTNAME, EMPNO, CAST(NULL AS VARCHAR(15)) AS LASTNAME, CAST(NULL AS VARCHAR(12)) AS FIRSTNME, CAST(NULL AS CHAR(4)) AS PHONENO FROM DEPT_NO_MGR END-EXEC. EXEC SQL OPEN c1 END-EXEC. move "OPEN" to errloc. call "checkerr" using SQLCA errloc. display "DEPTNO DEPTNAME EMPNO LASTNAME - " FIRSTNAME PHONENO". display "==================================================== - "=========================". * FETCH the rows from the table corresponding to the SQL statement. perform Fetch-Loop thru End-Fetch-Loop until SQLCODE not equal 0. display " ", counter, " record(s) selected". EXEC SQL CONNECT RESET END-EXEC. move "CONNECT RESET" to errloc. call "checkerr" using SQLCA errloc. End-Main. go to End-Prog. Fetch-Loop Section. move spaces to phoneno. EXEC SQL FETCH c1 INTO :deptno:d-ind, :deptname:dn-ind, :empno:e-ind, :lastname:l-ind, :firstname:f-ind, :phoneno:p-ind END-EXEC. if SQLCODE not equal 0 display " " go to End-Fetch-Loop. if l-ind not equal 0 move " " to lastname-name move 1 to lastname-len. if f-ind not equal 0 move " " to firstname-name move 1 to firstname-len. display deptno, " ", deptname, " ", empno, " ", lastname-name(1:lastname-len), " ", firstname-name(1:firstname-len), " ", phoneno. add 1 to counter. End-Fetch-Loop. exit. End-Prog. stop run.