Pro*Fortran Supplement to the Oracle Precompilers | Library |
Product |
Contents |
Index |
The Pro*FORTRAN Precompiler is not case-sensitive; however, some compilers are. If your compiler is case-sensitive, you must declare and reference variables in the same uppercase/lowercase format. Check your FORTRAN compiler user's guide.
No more than one statement can appear on a single line.
The following example shows all three styles of comments:
EXEC SQL SELECT ENAME, SAL
C Assign column values to host variables.
1 INTO :ENAM, :ESAL -- output host variables
2 FROM EMP
3 /* Use input host variable in
4 search condition */
5 WHERE DEPTNO = :DNUM
You cannot nest comments. Blank lines are treated as comments, but are not allowed within a continued statement.
* Retrieve employee data.
EXEC SQL SELECT EMPNO, ENAME, JOB, SAL
1 INTO :ENUM, :ENAM, :EJOB, :ESAL
2 FROM EMP
3 WHERE DEPTNO = :DNUM
To continue a string literal from one line to the next, code the literal through column 72. On the next line, code a continuation character and the rest of the literal. An example follows:
* Execute dynamic SQL statement.
EXEC SQL EXECUTE IMMEDIATE 'UPDATE EMP SET COMM = 500 WHERE
1 DEPTNO=20'
Most FORTRAN implementations allow up to 19 continuation lines. Check your FORTRAN compiler user's guide.
* Display employee name.
IF (ENAM .LT. 'ZZZZZ') THEN
PRINT *, ' Employee Name: ', ENAM
END IF
SQL also uses apostrophes to delimit string literals, as in
* Retrieve employee data.
EXEC SQL SELECT ENAME, SAL
1 INTO :ENAM, :ESAL
2 FROM EMP
3 WHERE JOB = 'CLERK'
But SQL uses quotation marks to delimit identifiers containing special or lowercase characters, as in
* Create table.
EXEC SQL CREATE TABLE "Emp2" (EMPNO NUMBER(4), ...)
SQL Operators | FORTRAN Operators |
NOT | .NOT. |
AND | .AND. |
OR | .OR. |
-- | .EQV. |
-- | .NEQV. |
SQL Operators | FORTRAN Operators |
= | .EQ. |
< >, !=, ^= | .NE. |
> | .GT. |
< | .LT. |
>= | .GE. |
<= | .LE. |
Logical and relational FORTRAN operators are not allowed in SQL statements.
For example, if your FORTRAN compiler cannot handle string literals longer than 512 characters, specify MAXLITERAL=512. Check your FORTRAN compiler user's guide.
If a program unit contains SQL statements, it must
* Insert row into employee table.
500 EXEC SQL INSERT INTO EMP (EMPNO, ENAME, JOB, DEPTNO)
1 VALUES (:ENUM, :ENAM, :EJOB, :DNUM)
And, you can reference statement labels in a WHENEVER DO or WHENEVER GOTO statement, as this example shows:
* Handle SQL execution errors.
EXEC SQL WHENEVER SQLERROR GOTO 900
...
* SQLEMC stores the Oracle error code and message.
900 WRITE (*, 8500) SQLEMC
8500 FORMAT (1X, 70A1)
...
Statement labels must be coded in columns 1 through 5, and must not appear in continuation lines. Statement labels may consist of alphanumeric characters, only; the special characters, underscore ( _ ), hyphen (-), and dollar sign ($) are not allowed.
The Pro*FORTRAN Precompiler does not use statement labels in generated code. Therefore, the BEGLABEL and ENDLABEL options that were available in earlier Pro*FORTRAN versions are not supported in this version and will return an informational message if found.
* Delete employee.
EXEC SQL DELETE FROM EMP WHERE EMPNO = :ENUM
However, a continuation character on the next line overrides an end-of-line.
EXEC SQL BEGIN DECLARE SECTION
and ends with the statement
EXEC SQL END DECLARE SECTION
Between these two statements only the following are allowed:
* Copy in the SQL Communications Area (SQLCA)
* and the Oracle Communications Area (ORACA).
EXEC SQL INCLUDE SQLCA
EXEC SQL INCLUDE ORACA
You can INCLUDE any file. When you precompile your Pro*FORTRAN program, each EXEC SQL INCLUDE statement is replaced by a copy of the file named in the statement.
INCLUDE=path
where path defaults to the current directory.
The precompiler first searches the current directory, then the directory specified by the INCLUDE option, and finally the directory for standard INCLUDE files. You need not specify a path for standard files such as the SQLCA and ORACA. However, a path is required for nonstandard files unless they are stored in the current directory.
You can also specify multiple paths on the command line, as follows:
... INCLUDE=<path1> INCLUDE=<path2> ...
When multiple paths are specified, the precompiler searches the current directory first, then the path1 directory, then the path2 directory, and so on. The directory containing standard INCLUDE files is searched last. The path syntax is system specific. Check the Oracle installation or user's guide for your system.
Variable Declaration | Description |
BYTE var CHARACTER var | single character |
CHARACTER var*n CHARACTER*n var | n-byte character string |
CHARACTER(*) var | character string |
INTEGER var INTEGER*2 var INTEGER*4 var | default-length integer 2-byte integer 4-byte integer |
LOGICAL var LOGICAL*1 var LOGICAL*2 var LOGICAL*4 var | single character 2-byte character string 4-byte character string |
REAL var REAL*4 var REAL*8 var DOUBLE PRECISION var | 4-byte real number 8-byte real number |
VARCHAR*n | <= 32765-byte, variable length character string (3) |
SQLCURSOR | cursor variable |
Notes:
Internal Type | FORTRAN Type | Description |
CHAR(x) (1) VARCHAR2(y) (1) | BYTE CHARACTER CHARACTER*n VARCHAR*n var1, var2, var3 | single character variable-length string variable-length string variable-length string |
NUMBER NUMBER (p,s) (2) | CHARACTER*n var
CHARACTER var *n
CHARACTER(*) DOUBLE PRECISION INTEGER INTEGER*2 INTEGER*4 LOGICAL var LOGICAL*1 var LOGICAL*2 var LOGICAL*4 var REAL REAL*4 REAL*8 VARCHAR*n var1, var2, var3 | n-byte character string (3)
character string (as parameter) 8-byte float number integer (default size) 2-byte integer 4-byte integer single character 2-byte character string 4-byte character string float number 4-byte float number 8-byte float number variable-length string |
DATE (4) LONG RAW (1) LONG RAW ROWID (5) MLSLABEL (6) | CHARACTER*n var CHARACTER*n var VARCHAR*n var1, var2, var3 | n-byte character string n-byte variable-length string variable-length string |
CURSOR | SQLCURSOR | cursor variable |
Notes:
* Declare host variables.
EXEC SQL BEGIN DECLARE SECTION
INTEGER*4 ENUM
CHARACTER*10 ENAM
REAL*4 ESAL
INTEGER*2 DNUM
CHARACTER*15 DNAM
EXEC SQL END DECLARE SECTION
You can also declare one-dimensional arrays of FORTRAN types, as the next example shows:
* Declare host arrays.
EXEC SQL BEGIN DECLARE SECTION
INTEGER*4 ENUM(100)
CHARACTER*10 ENAM(100)
REAL*4 ESAL(100)
EXEC SQL END DECLARE SECTION
* Declare host variables.
EXEC SQL BEGIN DECLARE SECTION
...
REAL*4 ESAL, ECOM, EBON
EXEC SQL END DECLARE SECTION
which is equivalent to
* Declare host variables.
EXEC SQL BEGIN DECLARE SECTION
...
REAL*4 ESAL
REAL*4 ECOM
REAL*4 EBON
EXEC SQL END DECLARE SECTION
* Declare host variables.
EXEC SQL BEGIN DECLARE SECTION
...
REAL*4 MINSAL
REAL*4 MAXSAL
DATA MINSAL, MAXSAL /1000.00, 5000.00/
EXEC SQL END DECLARE SECTION
DATA statements must come before the first executable FORTRAN statement but after any variable and PARAMETER declarations. Later in your program, you can change the values of variables initialized by a DATA statement. You cannot, however, reuse a DATA statement to reset the changed values.
* Declare host variables.
EXEC SQL BEGIN DECLARE SECTION
CHARACTER*5 UID
CHARACTER*5 PWD
PARAMETER (UID = 'SCOTT', PWD = 'TIGER')
EXEC SQL END DECLARE SECTION
* Declare host variables.
EXEC SQL BEGIN DECLARE SECTION
INTEGER*4 ENUM
CHARACTER*10 ENAM
REAL*4 ESAL
REAL*4 ECOM
EXEC SQL END DECLARE SECTION
* Define COMMON block.
COMMON /EMPBLK/ ENUM, ESAL, ECOM
In this example, EMPBLK is the COMMON block name. The names of COMMON blocks, subroutines, and functions are the only globally defined identifiers in a FORTRAN program. Avoid using blank COMMON blocks.
You make a COMMON block available to other program units by redefining it in those units. You must repeat the type declarations for variables in a COMMON block in all units where the block is used.
Only the order and datatypes of variables in the COMMON block matter, not their names. So, the variable names can differ from unit to unit. However, it is good programming practice to use the same names for corresponding variables in each occurrence of a COMMON block.
The following restrictions apply to COMMON blocks:
You can equivalence CHARACTER variables only to other CHARACTER variables. You cannot equivalence VARCHAR variables.
...
CALL LOGON (UID, PWD)
...
SUBROUTINE LOGON (UID, PWD)
* Declare host variables in subroutine.
EXEC SQL BEGIN DECLARE SECTION
CHARACTER*10 UID
CHARACTER*10 PWD
EXEC SQL END DECLARE SECTION
...
EXEC SQL CONNECT :UID IDENTIFIED BY :PWD
WRITE(*, 1000) UID
1000 FORMAT(/,' Connected to Oracle as user: ', A10, /)
RETURN
END
However, implicit declaration of host variables is not allowed; it triggers an "undeclared host variable" error message at precompile time. Every variable referenced in a SQL statement must be defined in the Declare Section.
Complex Numbers. In FORTRAN, complex numbers, that is, numbers with a real part and an imaginary part, are represented using the datatype COMPLEX. Pro*FORTRAN, however, does not support the use of COMPLEX host variables in SQL statements.
* Declare host variables.
EXEC SQL BEGIN DECLARE SECTION
INTEGER*4 ENUM
CHARACTER*10 ENAM
REAL*4 ESAL
CHARACTER*10 EJOB
EXEC SQL END DECLARE SECTION
...
WRITE (*, 3100)
3100 FORMAT (' Enter employee number: ')
READ (*, 3200) ENUM
3200 FORMAT (I4)
EXEC SQL SELECT ENAME, SAL, JOB
1 INTO :ENAM, :ESAL, :EJOB
2 FROM EMP
3 WHERE EMPNO = :ENUM
BONUS = ESAL / 10
...
Though it might be confusing, you can give a host variable the same name as an Oracle table or column, as the following example shows:
* Declare host variables.
EXEC SQL BEGIN DECLARE SECTION
INTEGER*4 ENUM
CHARACTER*10 ENAM
REAL*4 ESAL
EXEC SQL END DECLARE SECTION
...
EXEC SQL SELECT ENAME, SAL
1 INTO :ENAM, :ESAL
2 FROM EMP
3 WHERE EMPNO = :ENUM
You use indicator variables in the VALUES or SET clause to assign nulls to input host variables and in the INTO clause to detect nulls or truncated values in output host variables.
* Declare host and indicator variables.
EXEC SQL BEGIN DECLARE SECTION
INTEGER*4 ENUM
CHARACTER*10 ENAM
REAL*4 ESAL
REAL*4 ECOM
INTEGER*2 IESAL
INTEGER*2 IECOM
EXEC SQL END DECLARE SECTION
You can define an indicator variable anywhere in the Declare Section. It need not follow its associated host variable.
* Retrieve employee data.
EXEC SQL SELECT SAL, COMM
1 INTO :ESAL, :ECOM:IECOM
2 FROM EMP
3 WHERE EMPNO = :ENUM
* When an indicator variable equals -1, its associated
* host variable is null.
IF (IECOM .EQ. -1) THEN
PAY = ESAL
ELSE
PAY = ESAL + ECOM
END IF
To improve readability, you can precede any indicator variable with the optional keyword INDICATOR. You must still prefix the indicator variable with a colon. The correct syntax is
:<host_variable> INDICATOR :<indicator_variable>
which is equivalent to
:<host_variable>:<indicator_variable>
You can use both forms of expression in your host program.
* Set indicator variable.
IECOM = -1
EXEC SQL DELETE FROM EMP WHERE COMM = :ECOM:IECOM
The correct syntax follows:
EXEC SQL DELETE FROM EMP WHERE COMM IS NULL
ORA-01405: fetched column value is NULL
When precompiling with MODE=ORACLE and DBMS=V7 specified, you can disable the ORA-01405 message by also specifying UNSAFE_NULL=YES on the command line. For more information, see the Programmer's Guide to the Oracle Precompilers.
ORA-01406: fetched column value was truncated
However, when MODE={ANSI|ANSI14|ANSI13}, no error is generated. Values for indicator variables are discussed in Chapter 3 of the Programmer's Guide to the Oracle Precompilers.
* Declare and dimension host arrays.
EXEC SQL BEGIN DECLARE SECTION
INTEGER*4 ENUM(50)
CHARACTER*10 ENAM(50)
REAL*4 ESAL(50)
EXEC SQL END DECLARE SECTION
* Invalid dimensioning of host array
EXEC SQL BEGIN DECLARE SECTION
...
REAL*4 VECTOR(0:10)
EXEC SQL END DECLARE SECTION
Multi-dimensional host arrays are not allowed. Thus, the two-dimensional host array declared in the following example is invalid:
* Invalid declaration of host array
EXEC SQL BEGIN DECLARE SECTION
...
REAL*4 MATRIX(50, 100)
EXEC SQL END DECLARE SECTION
You cannot dimension host arrays using the FORTRAN DIMENSION statement. For example, the following usage is invalid:
* Invalid use of DIMENSION statement
EXEC SQL BEGIN DECLARE SECTION
REAL*4 ESAL
REAL*4 ECOM
DIMENSION ESAL(50), ECOM(50)
EXEC SQL END DECLARE SECTION
Also, you cannot dimension a host array in a COMMON statement.
* Declare host arrays.
EXEC SQL BEGIN DECLARE SECTION
INTEGER*4 ENUM(100)
CHARACTER*10 ENAM(100)
INTEGER*4 DNUM(100)
REAL*4 ECOM(50)
EXEC SQL END DECLARE SECTION
...
* Populate host arrays here.
...
EXEC SQL INSERT INTO EMP (EMPNO, ENAME, COMM, DEPTNO)
1 VALUES (:ENUM, :ENAM, :ECOM, :DNUM)
Host arrays must not be subscripted in SQL statements. For example, the following INSERT statement is invalid:
* Declare host arrays.
EXEC SQL BEGIN DECLARE SECTION
INTEGER*4 ENUM(50)
REAL*4 ESAL(50)
INTEGER*4 DNUM(50)
EXEC SQL END DECLARE SECTION
...
DO 200 J = 1, 50
* Invalid use of host arrays
EXEC SQL INSERT INTO EMP (EMPNO, SAL, DEPTNO)
1 VALUES (:ENUM(J), :ESAL(J), :DNUM(J))
200 CONTINUE
You need not process host arrays in a loop. Instead, use unsubscripted array names in your SQL statement. Oracle treats a SQL statement containing host arrays of dimension n like the same statement executed n times with n different scalar variables. For more information, see Chapter 8 of the Programmer's Guide to the Oracle Precompilers.
* Declare host and indicator arrays.
EXEC SQL BEGIN DECLARE SECTION
INTEGER*4 ENUM(50)
INTEGER*4 DNUM(50)
REAL*4 ECOM(50)
INTEGER*2 IECOM(50) -- indicator array
EXEC SQL END DECLARE SECTION
...
* Populate the host and indicator arrays. To insert
* a null into the COMM column, assign -1 to the
* appropriate element in the indicator array.
...
EXEC SQL INSERT INTO EMP (EMPNO, DEPTNO, COMM)
1 VALUES (:ENUM, :DNUM, :ECOM:IECOM)
The dimension of the indicator array must be greater than, or equal to, the dimension of the host array.
* Declare a VARCHAR.
EXEC SQL BEGIN DECLARE SECTION
VARCHAR*<n> <VARNAM>, <VARLEN>, <VARARR>
EXEC SQL END DECLARE SECTION
n
Is the maximum length of the VARCHAR; n must be in the range 1 through 32765.
VARNAM
Is the name used to reference the VARCHAR in SQL statements; it is called an aggregate name because it identifies a set of variables.
VARLEN
Is a 2-byte signed integer variable that stores the actual length of the string variable.
VARARR
Is the string variable used in FORTRAN statements.
The advantage of using VARCHAR variables is that you can explicitly set and reference VARLEN. With input host variables, Oracle reads the value of VARLEN and uses that many characters of VARARR. With output host variables, Oracle sets VARLEN to the length of the character string stored in VARARR.
You can declare a VARCHAR only in the Declare Section. In the following example, you declare a VARCHAR named EJOB with a maximum length of 15 characters:
* Declare a VARCHAR.
EXEC SQL BEGIN DECLARE SECTION
...
VARCHAR*15 EJOB, EJOBL, EJOBA
EXEC SQL END DECLARE SECTION
The precompiler expands this declaration to
* Expanded VARCHAR declaration
INTEGER*2 EJOBL
LOGICAL*1 EJOBA(15)
INTEGER*2 SQXXX(2)
EQUIVALENCE (SQXXX(1), EJOBL), (SQXXX(2), EJOBA(1))
where SQXXX is an array generated by the precompiler and XXX denotes three arbitrary characters. Notice that the aggregate name EJOB is not declared. The EQUIVALENCE statement forces the compiler to store EJOBL and EJOBA contiguously.
* Declare host variables.
EXEC SQL BEGIN DECLARE SECTION
...
INTEGER*4 ENUM
VARCHAR*15 EJOB, EJOBL, EJOBA
EXEC SQL END DECLARE SECTION
...
EXEC SQL SELECT JOB
1 INTO :EJOB
2 FROM EMP
3 WHERE EMPNO = :ENUM
After the query executes, EJOBL holds the actual length of the character string retrieved from the database and stored in EJOBA. In FORTRAN statements, you reference VARCHAR variables using the length variable and string variable names, as this example shows:
* Display job title.
WRITE (*, 5200) (EJOBA(J), J = 1, EJOBL)
5200 FORMAT (15A1)
...
With other host languages, the maximum length of a VARCHAR character string is 65533 bytes. If you want to use 65533-byte VARCHAR variables, try the technique shown in the following example:
* Declare a VARCHAR.
EXEC SQL BEGIN DECLARE SECTION
...
VARCHAR*65533 BUF, BUFL, BUFA
EXEC SQL END DECLARE SECTION
...
* Equivalence two 2-byte integers to one 4-byte integer.
INTEGER*2 INT2(2)
INTEGER*4 INT4
EQUIVALENCE (INT2(1), INT4)
INTEGER*4 I
...
INT4 = 65533
* Set the VARCHAR length variable equal to the
* equivalenced value of INT4.
BUFL = INT2(1)
DO 100 I = 1, 65533
BUFA(I) = 32
100 CONTINUE
EXEC SQL INSERT INTO LONG_TABLE VALUES (:BUF)
...
BUFL = 0
EXEC SQL SELECT COL1 INTO :BUF FROM LONG_TABLE
INT2(1) = BUFL
...
Note: The way integers are stored varies from system to system. On some systems, the least significant digits are stored at the low address; on other systems they are stored at the high address. In the last example, this determines whether the length is stored in INT2(1) or INT2(2).
With respect to character handling, MODE={ANSI14|ANSI13} is equivalent to MODE=ORACLE. The MODE option affects character data on input (from host variables to Oracle) and on output (from Oracle to host variables).
Note: The MODE option does not affect the way Pro*FORTRAN handles VARCHAR host variables.
When MODE=ANSI, trailing blanks are never stripped.
Make sure that the input value is not trailed by extraneous characters. For example, nulls are not stripped and are inserted into the database. Normally, this is not a problem because when a value is READ into or assigned to a CHARACTER*n variable, FORTRAN appends blanks up to the length of the variable.
The following example illustrates the point:
* Declare host variables
EXEC SQL BEGIN DECLARE SECTION
CHARACTER ENAM *10, EJOB *8
...
EXEC SQL END DECLARE SECTION
...
WRITE (*, 300)
300 FORMAT (/, '$Employee name? ')
* Assume the name 'MILLER' is entered
READ (*, 400)
400 FORMAT (A10)
EJOB = 'SALES'
EXEC SQL INSERT INTO emp (empno, ename, deptno, job)
VALUES (1234, :ENAM, 20, :EJOB)
If you precompile the last example with MODE=ORACLE and the target database columns are VARCHAR2, the program interface strips the trailing blanks on input and inserts just the 6-character string "MILLER" and the 5-character string "SALES" into the database. However, if the target database columns are CHAR, the strings are blank-padded to the width of the columns.
If you precompile the last example with MODE=ANSI and the JOB column is defined as CHAR(10), the value inserted into that column is "SALES#####" (five trailing blanks). However, if the JOB column is defined as VARCHAR2(10), the value inserted is "SALES###" (three trailing blanks) because the host variable is a CHARACTER*8. This might not be what you want, so be careful.
* Declare host variables.
EXEC SQL BEGIN DECLARE SECTION
INTEGER*4 ENUM
VARCHAR*15 EJOB, EJOBL, EJOBA
INTEGER*2 IEJOB
INTEGER*4 DNUM
EXEC SQL END DECLARE SECTION
...
WRITE (*, 4300)
4300 FORMAT (/, ' Enter job title: ')
READ (*, 4400) EJOBA
4400 FORMAT (15A1)
* Scan backward for last non-blank character, then
* set length to that position. If input is all blank,
* set indicator variable to -1 to indicate a null.
DO 5000 J = 15, 1, -1
IF (EJOBA(J) .NE. ' ') GOTO 5100
5000 CONTINUE
J = 0
5100 IF (J .EQ. 0) THEN
IEJOB = -1
ELSE
IEJOB = 0
END IF
EJOBL = J
EXEC SQL INSERT INTO EMP (EMPNO, JOB, DEPTNO)
1 VALUES (:ENUM, :EJOB:IEJOB, :DNUM)
* Declare host variables.
EXEC SQL BEGIN DECLARE SECTION
INTEGER*4 ENUM
VARCHAR*15 EJOB, EJOBL, EJOBA
INTEGER*4 ESAL
EXEC SQL END DECLARE SECTION
...
EXEC SQL SELECT JOB, SAL INTO :EJOB, :ESAL FROM EMP
1 WHERE EMPNO = :ENUM
...
IF (EJOBL .EQ. 0) GOTO ...
...
An advantage of VARCHAR variables over fixed-length strings is that the length of the value returned by Oracle is available right away. With fixed-length strings, to get the length of the value, your program must count the number of characters. (The intrinsic function LEN returns the length of a string including blanks, not its current length.)
These internal datatypes can be quite different from FORTRAN datatypes. For example, FORTRAN has no equivalent to the NUMBER datatype, which was specially designed for portability and high precision.
Name | Code | Description |
CHAR | 1 96 | <= 65535-byte, variable-length character string (1) <= 65535-byte, fixed-length character string (1) |
CHARF | 96 | <= 65535-byte, fixed-length character string |
CHARZ | 97 | <= 65535-byte, fixed-length, null-terminated string (2) |
DATE | 12 | 7-byte, fixed-length date/time value |
DECIMAL | 7 | COBOL packed decimal |
DISPLAY | 91 | COBOL numeric character string |
FLOAT | 4 | 4-byte or 8-byte floating-point number |
INTEGER | 3 | 2-byte or 4-byte signed integer |
LONG | 8 | <= 2147483647-byte, fixed-length string |
LONG RAW | 24 | <= 217483647-byte, fixed-length binary data |
LONG VARCHAR | 94 | <= 217483643-byte, variable-length string |
LONG VARRAW | 95 | <= 217483643-byte, variable-length binary data |
MLSLABEL | 106 | 2..5-byte, variable-length binary data |
NUMBER | 2 | integer or floating-point number |
RAW | 23 | <= 65535-byte, fixed-length binary data (2) |
ROWID | 11 | (typically) 13-byte, fixed-length binary value |
STRING | 5 | <= 65535-byte, null-terminated character string (2) |
UNSIGNED | 68 | 2-byte or 4-byte unsigned integer |
VARCHAR | 9 | <= 65533-byte, variable-length character string |
VARCHAR2 | 1 | <= 65535-byte, variable-length character string (2) |
VARNUM | 6 | variable-length binary number |
VARRAW | 15 | <= 65533-byte, variable-length binary data |
Notes:
Before assigning a SELECTed column value to an output host variable, Oracle must convert the internal datatype of the source column to the datatype of the host variable. Likewise, before assigning or comparing the value of an input host variable to a column, Oracle must convert the external datatype of the host variable to the internal datatype of the target column.
Conversions between internal and external datatypes follow the usual data conversion rules. For example, you can convert a CHAR value of "1234" to a INTEGER*2 value. You cannot, however, convert a CHAR value of "65543" (number too large) or "10F" (number not decimal) to a INTEGER*2 value. Likewise, you cannot convert a CHARACTER*n value that contains alphabetic characters to a NUMBER value.
For more information about datatype conversion, see Chapter 3 of the Programmer's Guide to the Oracle Precompilers.
With the VAR statement, you can override the default assignments by equivalencing host variables to Oracle external datatypes in the Declare Section. The syntax you use is
EXEC SQL
VAR <host_variable>
IS <ext_type_name> [({<length> | <precision>,<scale>})]
where host_variable is an input or output host variable (or host array) declared earlier in the Declare Section, ext_type_name is the name of a valid external datatype, and length is an integer literal specifying a valid length in bytes.
When ext_type_name is FLOAT, use length; when ext_type_name is DECIMAL, you must specify precision and scale instead of length.
Host variable equivalencing is useful in several ways. For example, you can use it when you want Oracle to store but not interpret data. Suppose you want to store a host array of 4-byte integers in a RAW database column. Simply equivalence the host array to the RAW external datatype, as follows:
EXEC SQL BEGIN DECLARE SECTION
INTEGER*4 ENUM(50)
...
* Reset default datatype (INTEGER) to RAW.
EXEC SQL VAR ENUM IS RAW (200);
EXEC SQL END DECLARE SECTION
...
With host arrays, the length you specify must match the buffer size required to hold the array. In the last example, you specified a length of 200, which is the buffer size required to hold 50 4-byte integers.
For more information about datatype equivalencing, see Chapter 3 in the Programmer's Guide to the Oracle Precompilers.
To embed a PL/SQL block in your host program, declare the variables to be shared with PL/SQL and bracket the PL/SQL block with the EXEC SQL EXECUTE and END-EXEC keywords.
The advantages of cursor variables are
EXEC SQL BEGIN DECLARE SECTION
...
SQLCURSOR CURVAR
...
EXEC SQL END DECLARE SECTION
A SQLCURSOR variable is implemented using a FORTRAN INTEGER*4 array in the code that Pro*FORTRAN generates. A cursor variable is just like any other Pro*FORTRAN host variable.
EXEC SQL ALLOCATE :CURVAR
Allocating a cursor variable does not require a call to the server, either at precompile time or at run time.
Warning: Allocating a cursor variable does cause heap memory to be used. For this reason, avoid allocating a cursor variable in a program loop.
CREATE PACKAGE demo_cur_pkg AS
TYPE EmpName IS RECORD (name VARCHAR2(10));
TYPE cur_type IS REF CURSOR RETURN EmpName;
PROCEDURE open_emp_cur (
curs IN OUT curtype,
dept_num IN NUMBER);
END;
CREATE PACKAGE BODY demo_cur_pkg AS
CREATE PROCEDURE open_emp_cur (
curs IN OUT curtype,
dept_num IN NUMBER) IS
BEGIN
OPEN curs FOR
SELECT ename FROM emp
WHERE deptno = dept_num
ORDER BY ename ASC;
END;
END;
After this package has been stored, you can open the variable curs by calling the open_emp_cur stored procedure from your Pro*FORTRAN program, and FETCH from the cursor variable ECUR in the program. For example:
EXEC SQL BEGIN DECLARE SECTION
SQLCURSOR ECUR
INTEGER*4 DNUM
VARCHAR*10 ENAM, ENAML, ENAMA
EXEC SQL END DECLARE SECTION
...
* Allocate the cursor variable.
EXEC SQL ALLOCATE :ECUR
...
DNUM=30
* Open the cursor on the Oracle7 Server.
EXEC SQL EXECUTE
1 BEGIN
2 demo_cur_pkg.open_emp_cur(:ECUR, :DNUM);
3 END;
4 END-EXEC
EXEC SQL WHENEVER NOTFOUND DO CALL SIGNOFF
*
1000 EXEC SQL FETCH :ECUR INTO :ENAM
PRINT *, "Employee Name: ", ENAM
GOTO 1000
...
EXEC SQL EXECUTE
1 BEGIN
2 OPEN :ECUR FOR SELECT ENAME FROM EMP
3 WHERE DEPTNO = :DNUM;
4 END;
5 END-EXEC
...
EXEC SQL FETCH :ECUR INTO :EINFO:IEINFO
Before you can FETCH from a cursor variable, the variable must be initialized and opened. You cannot FETCH from an unopened cursor variable.
EXEC SQL BEGIN DECLARE SECTION
* Declare the cursor variable.
SQLCURSOR ECUR
...
EXEC SQL END DECLARE SECTION
* Allocate and open the cursor variable, then
* fetch one or more rows.
...
* Close the cursor variable.
EXEC SQL CLOSE :ECUR
CONNECT SCOTT/TIGER CREATE OR REPLACE PACKAGE emp_demo_pkg AS TYPE emp_cur_type IS REF CURSOR RETURN emp%ROWTYPE; PROCEDURE open_cur ( cursor IN OUT emp_cur_type, dept_num IN number); END emp_demo_pkg; / CREATE OR REPLACE PACKAGE BODY emp_demo_pkg AS PROCEDURE open_cur ( cursor IN OUT emp_cur_type, dept_num IN number) IS BEGIN OPEN cursor FOR SELECT * FROM emp WHERE deptno = dept_num ORDER BY ename ASC; END; END emp_demo_pkg; /
PROGRAM SAMPLE11 EXEC SQL BEGIN DECLARE SECTION * Declare the cursor variable. SQLCURSOR ECUR * EMPINFO INTEGER ENUM CHARACTER*10 ENAM VARCHAR*9 EJOB, EJOBL, EJOBA INTEGER EMGR VARCHAR*10 EDAT, EDATL, EDATA REAL ESAL REAL ECOM INTEGER EDEP * EMPINFO INDICATORS INTEGER*2 IENUM INTEGER*2 IENAM INTEGER*2 IEJOB INTEGER*2 IEMGR INTEGER*2 IEDAT INTEGER*2 IESAL INTEGER*2 IECOM INTEGER*2 IEDEP EXEC SQL END DECLARE SECTION EXEC SQL INCLUDE SQLCA COMMON /CURSOR/ ECUR EXEC SQL WHENEVER SQLERROR DO CALL SQLERR * LOG ON TO ORACLE. CALL LOGON * Initialize the cursor variable. EXEC SQL ALLOCATE :ECUR TYPE 1000 1000 FORMAT (/, 'Enter department number (0 to exit): ', $) ACCEPT 1100, EDEP 1100 FORMAT (I10) IF (EDEP .LE. 0) THEN CALL SIGNOFF ENDIF
* Open the cursor by calling a PL/SQL stored procedure. EXEC SQL EXECUTE 1 BEGIN 2 emp_demo_pkg.open_cur (:ECUR, :EDEP); 3 END; 4 END-EXEC PRINT 1200, EDEP 1200 FORMAT (/, 'For department ', I, ':',/) PRINT 1300 1300 FORMAT (/, 'EMPLOYEE SALARY COMMISSION', + /, '---------- ---------- ----------') * Fetch data from the cursor into the host variables. 2000 EXEC SQL WHENEVER NOT FOUND DO CALL SIGNOFF EXEC SQL FETCH :ECUR 1 INTO :ENUM:IENUM, 2 :ENAM:IENAM, 3 :EJOB:IEJOB, 4 :EMGR:IEMGR, 5 :EDAT:IEDAT, 6 :ESAL:IESAL, 7 :ECOM:IECOM, 8 :EDEP:IEDEP * Check for commission and print results. IF (IECOM .EQ. 0) THEN PRINT 2100, ENAM, ESAL, ECOM 2100 FORMAT (A10, 2X, F10.2, 2X, F10.2) ELSE PRINT 2200, ENAM, ESAL 2200 FORMAT (A10, 2X, F10.2, 2X, ' N/A') ENDIF GOTO 2000 END * LOG ON TO ORACLE. SUBROUTINE LOGON EXEC SQL BEGIN DECLARE SECTION CHARACTER*10 UID CHARACTER*10 PWD EXEC SQL END DECLARE SECTION EXEC SQL INCLUDE SQLCA UID = 'SCOTT' PWD = 'TIGER' EXEC SQL CONNECT :UID IDENTIFIED BY :PWD PRINT 3000, UID 3000 FORMAT (/, 'CONNECTED TO ORACLE AS USER: ', A) END
* Close the cursor variable. SUBROUTINE SIGNOFF EXEC SQL BEGIN DECLARE SECTION SQLCURSOR ECUR EXEC SQL END DECLARE SECTION EXEC SQL INCLUDE SQLCA COMMON /CURSOR/ ECUR EXEC SQL CLOSE :ECUR PRINT 4100 4100 FORMAT (/, 'HAVE A GOOD DAY.', /) EXEC SQL COMMIT WORK RELEASE STOP END SUBROUTINE SQLERR EXEC SQL INCLUDE SQLCA EXEC SQL WHENEVER SQLERROR CONTINUE PRINT*, ' ' PRINT *, 'ORACLE ERROR DETECTED: ' PRINT '(70A1)', SQLEMC PRINT*, ' ' EXEC SQL ROLLBACK WORK RELEASE STOP END
* Log on to Oracle.
EXEC SQL CONNECT :UID IDENTIFIED BY :PWD
where UID and PWD are CHARACTER or VARCHAR host variables. Alternatively, you can use the statement
* Log on to Oracle.
EXEC SQL CONNECT :UIDPWD
where the host variable UIDPWD contains your username and password separated by a slash (/).
The CONNECT statement must be the first SQL statement executed by the program. That is, other executable SQL statements can positionally, but not logically, precede the CONNECT statement.
To supply the Oracle username and password separately, you define two host variables in the Declare Section as character strings or VARCHAR variables. If you supply a userid containing both username and password, only one host variable is needed.
Make sure to set the username and password variables before the CONNECT is executed or it will fail. Your program can prompt for the values or you can hard code them as follows:
* Declare host variables.
EXEC SQL BEGIN DECLARE SECTION
CHARACTER*5 UID
CHARACTER*5 PWD
...
EXEC SQL END DECLARE SECTION
UID = 'SCOTT'
PWD = 'TIGER'
* Handle logon errors.
EXEC SQL WHENEVER SQLERROR GOTO ...
EXEC SQL CONNECT :UID IDENTIFIED BY :PWD
However, you cannot hard code a username and password into the CONNECT statement or use quoted literals. For example, both of the following statements are invalid:
* Invalid CONNECT statements
EXEC SQL CONNECT SCOTT IDENTIFIED BY TIGER
EXEC SQL CONNECT 'SCOTT' IDENTIFIED BY 'TIGER'
<prefix><username>
where prefix is the value of the Oracle initialization parameter OS_AUTHENT_PREFIX (the default value is OPS$) and username is your operating system user or task name. For example, if the prefix is OPS$, your user name is TBARNES, and OPS$TBARNES is a valid Oracle userid, you log on to Oracle as user OPS$TBARNES.
To take advantage of the automatic logon feature, you simply pass a slash (/) character to the precompiler, as follows:
* Declare host variables.
EXEC SQL BEGIN DECLARE SECTION
...
CHARACTER*1 ORAID
EXEC SQL END DECLARE SECTION
ORAID = '/'
EXEC SQL CONNECT :ORAID
This automatically connects you as user OPS$username. For example, if your operating system username is RHILL, and OPS$RHILL is a valid Oracle username, connecting with a slash (/) automatically logs you on to Oracle as user OPS$RHILL.
You can also pass a character string to the precompiler. However, the string cannot contain trailing blanks. For example, the following CONNECT statement will fail:
* Declare host variables.
EXEC SQL BEGIN DECLARE SECTION
...
CHARACTER*5 ORAID
EXEC SQL END DECLARE SECTION
ORAID = '/ '
EXEC SQL CONNECT :ORAID
For more information about operating system authentication, see the Oracle7 Server Administrator's Guide.
* Declare host variables.
EXEC SQL BEGIN DECLARE SECTION
CHARACTER*5 UID
CHARACTER*5 PWD
CHARACTER*12 DBSTR1
CHARACTER*12 DBSTR2
EXEC SQL END DECLARE SECTION
UID = 'SCOTT'
PWD = 'TIGER'
DBSTR1 = 'NEWYORK'
DBSTR2 = 'BOSTON'
* Give each database connection a unique name.
EXEC SQL DECLARE DBNAM1 DATABASE
EXEC SQL DECLARE DBNAM2 DATABASE
* Connect to the two non-default databases.
EXEC SQL CONNECT :UID IDENTIFIED BY :PWD
1 AT DBNAM1 USING :DBSTR1
EXEC SQL CONNECT :UID IDENTIFIED BY :PWD
1 AT DBNAM2 USING :DBSTR2
The string syntax in DBSTR1 and DBSTR2 depends on your network driver and how it is configured. DBNAM1 and DBNAM2 name the non-default connections; they can be undeclared identifiers or host variables.
For step-by-step instructions on connecting to Oracle via SQL*Net, see Chapter 3 in the Programmer's Guide to the Oracle Precompilers
Prev Next |
Copyright © 1996 Oracle Corporation. All Rights Reserved. |
Library |
Product |
Contents |
Index |