Programmer's Guide to the Oracle Precompilers, 1.8 | Library |
Product |
Contents |
Index |
However, some applications must accept (or build) and process a variety of SQL statements at run time. For example, a general-purpose report writer must build different SELECT statements for the various reports it generates. In this case, the statement's makeup is unknown until run time. Such statements can, and probably will, change from execution to execution. They are aptly called dynamic SQL statements.
Unlike static SQL statements, dynamic SQL statements are not embedded in your source program. Instead, they are stored in character strings input to or built by the program at run time. They can be entered interactively or read from a file.
For example, your program might simply prompt users for a search condition to be used in the WHERE clause of a SELECT, UPDATE, or DELETE statement. A more complex program might allow users to choose from menus listing SQL operations, table and view names, column names, and so on. Thus, dynamic SQL lets you write highly flexible applications.
However, some dynamic queries require complex coding, the use of special data structures, and more runtime processing. While you might not notice the added processing time, you might find the coding difficult unless you fully understand dynamic SQL concepts and methods.
'DELETE FROM EMP WHERE MGR = :mgr_number AND JOB = :job_title'
'DELETE FROM EMP WHERE MGR = :m AND JOB = :j'
Next, Oracle binds the host variables to the SQL statement. That is, Oracle gets the addresses of the host variables so that it can read or write their values.
Then Oracle executes the SQL statement. That is, Oracle does what the SQL statement requested, such as deleting rows from a table.
The SQL statement can be executed repeatedly using new values for the host variables.
The four methods are increasingly general. That is, Method 2 encompasses Method 1, Method 3 encompasses Methods 1 and 2, and so on. However, each method is most useful for handling a certain kind of SQL statement, as Table 10 - 1 shows:
Method | Kind of SQL Statement |
1 | nonquery without input host variables |
2 | nonquery with known number of input host variables |
3 | query with known number of select-list items and input host variables |
4 | query with unknown number of select-list items or input host variables |
The term select-list item includes column names and expressions.
'DELETE FROM EMP WHERE DEPTNO = 20'
'GRANT SELECT ON EMP TO scott'
With Method 1, the SQL statement is parsed every time it is executed (unless you specify HOLD_CURSOR=YES).
'INSERT INTO EMP (ENAME, JOB) VALUES (:emp_name, :job_title)'
'DELETE FROM EMP WHERE EMPNO = :emp_number'
With Method 2, the SQL statement is parsed just once (unless you specify RELEASE_CURSOR=YES), but it can be executed many times with different values for the host variables. SQL data definition statements such as CREATE are executed when they are PREPAREd.
'SELECT DEPTNO, MIN(SAL), MAX(SAL) FROM EMP GROUP BY DEPTNO'
'SELECT ENAME, EMPNO FROM EMP WHERE DEPTNO = :dept_number'
'INSERT INTO EMP (<unknown>) VALUES (<unknown>)'
'SELECT <unknown> FROM EMP WHERE DEPTNO = 20'
Method 4 is required for dynamic SQL statements that contain an unknown number of select-list items or input host variables.
With Methods 2 and 3, the number of placeholders for input host variables and the datatypes of the input host variables must be known at precompile time.
Each succeeding method imposes fewer constraints on your application, but is more difficult to code. As a rule, use the simplest method you can. However, if a dynamic SQL statement will be executed repeatedly by Method 1, use Method 2 instead to avoid reparsing for each execution.
Method 4 provides maximum flexibility, but requires complex coding and a full understanding of dynamic SQL concepts. In general, use Method 4 only if you cannot use Methods 1, 2, or 3. The decision logic in Figure 10 - 1 will help you choose the correct method.
Do not null-terminate the host string. Oracle does not recognize the null terminator as an end-of-string sentinel. Instead, Oracle treats it as part of the SQL statement.
If you use a VARCHAR variable to store the dynamic SQL statement, make sure the length of the VARCHAR is set (or reset) correctly before you execute the PREPARE or EXECUTE IMMEDIATE statement.
EXECUTE resets the SQLWARN warning flags in the SQLCA. So, to catch mistakes such as an unconditional update (caused by omitting a WHERE clause), check the SQLWARN flags after executing the PREPARE statement but before executing the EXECUTE statement.
Figure 10 - 1. Choosing the Right Method
'DELETE FROM table_name WHERE column_name = constant'
'CREATE TABLE table_name ...'
'DROP INDEX index_name'
'UPDATE table_name SET column_name = constant'
'GRANT SELECT ON table_name TO username'
'REVOKE RESOURCE FROM username'
The syntax of the EXECUTE IMMEDIATE statement follows:
EXEC SQL EXECUTE IMMEDIATE { :host_string | string_literal };
In the following example, you use the host variable sql_stmt to store SQL statements input by the user:
EXEC SQL BEGIN DECLARE SECTION;
...
sql_stmt CHARACTER(120);
EXEC SQL END DECLARE SECTION;
...
LOOP
display 'Enter SQL statement: ';
read sql_stmt;
IF sql_stmt is empty THEN
exit loop;
ENDIF;
-- sql_stmt now contains the text of a SQL statement
EXEC SQL EXECUTE IMMEDIATE :sql_stmt;
ENDLOOP;
You can also use string literals, as the following example shows:
EXEC SQL EXECUTE IMMEDIATE 'REVOKE RESOURCE FROM MILLER';
Because EXECUTE IMMEDIATE parses the input SQL statement before every execution, Method 1 is best for statements that are executed only once. Data definition statements usually fall into this category.
EXEC SQL BEGIN DECLARE SECTION;
username CHARACTER(20);
password CHARACTER(20);
update_stmt CHARACTER(120);
EXEC SQL END DECLARE SECTION;
search_cond CHARACTER(40);
EXEC SQL INCLUDE SQLCA;
display 'Username? ';
read username;
display 'Password? ';
read password;
EXEC SQL WHENEVER SQLERROR GOTO sql_error;
EXEC SQL CONNECT :username IDENTIFIED BY :password;
display 'Connected to Oracle';
set update_stmt = 'UPDATE EMP SET COMM = 500 WHERE ';
display 'Enter a search condition for the following statement:';
display update_stmt;
read search_cond;
concatenate update_stmt, search_cond;
EXEC SQL EXECUTE IMMEDIATE :update_stmt;
EXEC SQL COMMIT WORK RELEASE;
exit program;
sql_error:
EXEC SQL WHENEVER SQLERROR CONTINUE;
EXEC SQL ROLLBACK WORK RELEASE;
display 'Processing error';
exit program with an error;
With Method 2, the SQL statement can contain placeholders for input host variables and indicator variables. You can PREPARE the SQL statement once, then EXECUTE it repeatedly using different values of the host variables. Also, you need not rePREPARE the SQL statement after a COMMIT or ROLLBACK (unless you log off and reconnect).
Note that you can use EXECUTE for nonqueries with Method 4.
The syntax of the PREPARE statement follows:
EXEC SQL PREPARE statement_name
FROM { :host_string | string_literal };
PREPARE parses the SQL statement and gives it a name.
The statement_name is an identifier used by the precompiler, not a host or program variable, and should not be declared in the Declare Section. It simply designates the PREPAREd statement you want to EXECUTE.
The syntax of the EXECUTE statement is
EXEC SQL EXECUTE statement_name [USING host_variable_list];
where host_variable_list stands for the following syntax:
:host_variable1[:indicator1] [, host_variable2[:indicator2], ...]
EXECUTE executes the parsed SQL statement, using the values supplied for each input host variable. In the following example, the input SQL statement contains the placeholder n:
EXEC SQL BEGIN DECLARE SECTION;
...
emp_number INTEGER;
delete_stmt CHARACTER(120);
EXEC SQL END DECLARE SECTION;
search_cond CHARACTER(40);
...
set delete_stmt = 'DELETE FROM EMP WHERE EMPNO = :n AND ';
display 'Complete the following statement's search condition:';
display delete_stmt;
read search_cond;
concatenate delete_stmt, search_cond;
EXEC SQL PREPARE sql_stmt FROM :delete_stmt;
LOOP
display 'Enter employee number: ';
read emp_number;
IF emp_number = 0 THEN
exit loop;
EXEC SQL EXECUTE sql_stmt USING :emp_number;
ENDLOOP;
With Method 2, you must know the datatypes of input host variables at precompile time. In the last example, emp_number was declared as type INTEGER. It could also have been declared as type CHARACTER or REAL, because Oracle supports all these datatype conversions to the NUMBER datatype.
Every placeholder in the PREPAREd dynamic SQL statement must correspond to a host variable in the USING clause. So, if the same placeholder appears two or more times in the PREPAREd statement, each appearance must correspond to a host variable in the USING clause. If one of the host variables in the USING clause is an array, all must be arrays.
The names of the placeholders need not match the names of the host variables. However, the order of the placeholders in the PREPAREd dynamic SQL statement must match the order of corresponding host variables in the USING clause.
To specify nulls, you can associate indicator variables with host variables in the USING clause. For more information, see "Using Indicator Variables" .
EXEC SQL BEGIN DECLARE SECTION;
username CHARACTER(20);
password CHARACTER(20);
sql_stmt CHARACTER(80);
empno INTEGER VALUE 1234;
deptno1 INTEGER VALUE 97;
deptno2 INTEGER VALUE 99;
EXEC SQL END DECLARE SECTION;
EXEC SQL INCLUDE SQLCA;
EXEC ORACLE OPTION (ORACA=YES);
EXEC SQL WHENEVER SQLERROR GOTO sql_error;
display 'Username? ';
read username;
display 'Password? ';
read password;
EXEC SQL CONNECT :username IDENTIFIED BY :password;
display 'Connected to Oracle';
set sql_stmt = 'INSERT INTO EMP (EMPNO, DEPTNO) VALUES (:v1, :v2)';
display "V1 = ", empno, "V2 = ", deptno1;
EXEC SQL PREPARE S FROM :sql_stmt;
EXEC SQL EXECUTE S USING :empno, :deptno1;
set empno = empno + 1;
display "V1 = ", empno, "V2 = ", deptno2;
EXEC SQL EXECUTE S USING :empno, :deptno2;
set sql_stmt = 'DELETE FROM EMP WHERE DEPTNO = :v1 OR DEPTNO = :v2")';
display "V1 = ", deptno1, "V2 = ", deptno2;
EXEC SQL PREPARE S FROM :sql_stmt;
EXEC SQL EXECUTE S USING :deptno1, :deptno2;
EXEC SQL COMMIT WORK RELEASE;
exit program;
sql_error:
EXEC SQL WHENEVER SQLERROR CONTINUE;
display 'Processing error';
EXEC SQL ROLLBACK WORK RELEASE;
exit program with an error;
For Method 3, the number of columns in the query select list and the number of placeholders for input host variables must be known at precompile time. However, the names of database objects such as tables and columns need not be specified until run time (they cannot duplicate the names of host variables). Clauses that limit, group, and sort query results (such as WHERE, GROUP BY, and ORDER BY) can also be specified at run time.
With Method 3, you use the following sequence of embedded SQL statements:
PREPARE statement_name FROM { :host_string | string_literal };
DECLARE cursor_name CURSOR FOR statement_name;
OPEN cursor_name [USING host_variable_list];
FETCH cursor_name INTO host_variable_list;
CLOSE cursor_name;
Now let us look at what each statement does.
set select_stmt = 'SELECT MGR, JOB FROM EMP WHERE SAL < :salary';
EXEC SQL PREPARE sql_stmt FROM :select_stmt;
Commonly, the query WHERE clause is input from a terminal at run time or is generated by the application.
The identifier sql_stmt is not a host or program variable, but must be unique. It designates a particular dynamic SQL statement.
EXEC SQL DECLARE emp_cursor CURSOR FOR sql_stmt;
The identifiers sql_stmt and emp_cursor are not host or program variables, but must be unique. If you declare two cursors using the same statement name, the precompiler considers the two cursor names synonymous. For example, if you execute the statements
EXEC SQL PREPARE sql_stmt FROM :select_stmt;
EXEC SQL DECLARE emp_cursor FOR sql_stmt;
EXEC SQL PREPARE sql_stmt FROM :delete_stmt;
EXEC SQL DECLARE dept_cursor FOR sql_stmt;
when you OPEN emp_cursor, you will process the dynamic SQL statement stored in delete_stmt, not the one stored in select_stmt.
In our example, OPEN allocates emp_cursor and assigns the host variable salary to the WHERE clause, as follows:
EXEC SQL OPEN emp_cursor USING :salary;
In our example, FETCH returns a row from the active set and assigns the values of columns MGR and JOB to host variables mgr_number and job_title, as follows:
EXEC SQL FETCH emp_cursor INTO :mgr_number, :job_title;
EXEC SQL CLOSE emp_cursor;
EXEC SQL BEGIN DECLARE SECTION;
username CHARACTER(20);
password CHARACTER(20);
dept_number INTEGER;
emp_name CHARACTER(10);
salary REAL;
select_stmt CHARACTER(120);
EXEC SQL END DECLARE SECTION;
search_cond CHARACTER(40);
EXEC SQL INCLUDE SQLCA;
display 'Username? ';
read username;
display 'Password? ';
read password;
EXEC SQL WHENEVER SQLERROR GOTO sql_error;
EXEC SQL CONNECT :username IDENTIFIED BY :password;
display 'Connected to Oracle';
set select_stmt = 'SELECT ENAME,SAL FROM EMP WHERE ';
display 'Enter a search condition for the following statement:';
display select_stmt;
read search_cond;
concatenate select_stmt, search_cond;
EXEC SQL PREPARE sql_stmt FROM :select_stmt;
EXEC SQL DECLARE emp_cursor CURSOR FOR sql_stmt;
EXEC SQL OPEN emp_cursor;
EXEC SQL WHENEVER NOT FOUND GOTO no_more;
display 'Employee Salary';
display '-------- ------';
LOOP
EXEC SQL FETCH emp_cursor INTO :emp_name, :salary;
display emp_name, salary;
ENDLOOP;
no_more:
EXEC SQL CLOSE emp_cursor;
EXEC SQL COMMIT WORK RELEASE;
exit program;
sql_error:
EXEC SQL WHENEVER SQLERROR CONTINUE;
EXEC SQL ROLLBACK WORK RELEASE;
exit program with an error;
There is a kind of dynamic SQL statement that your program cannot process using Method 3. When the number of select-list items or placeholders for input host variables is unknown until run time, your program must use a descriptor. A descriptor is an area of memory used by your program and Oracle to hold a complete description of the variables in a dynamic SQL statement.
Recall that for a multirow query, you FETCH selected column values INTO a list of declared output host variables. If the select list is unknown, the host-variable list cannot be established at precompile time by the INTO clause. For example, you know the following query returns two column values:
SELECT ENAME, EMPNO FROM EMP WHERE DEPTNO = :dept_number;
However, if you let the user define the select list, you might not know how many column values the query will return.
Likewise, if a dynamic SQL statement contains an unknown number of placeholders for input host variables, the host-variable list cannot be established at precompile time by the USING clause.
To process the dynamic SQL statement, your program must issue the DESCRIBE BIND VARIABLES command and declare another kind of SQLDA called a bind descriptor to hold descriptions of the placeholders for the input host variables. (Input host variables are also called bind variables.)
If your program has more than one active SQL statement (it might have OPENed two or more cursors, for example), each statement must have its own SQLDA(s). However, non-concurrent cursors can reuse SQLDAs. There is no set limit on the number of SQLDAs in a program.
If you supply a select descriptor, the DESCRIBE SELECT LIST statement examines each select-list item in a PREPAREd dynamic query to determine its name, datatype, constraints, length, scale, and precision. It then stores this information in the select descriptor.
If you supply a bind descriptor, the DESCRIBE BIND VARIABLES statement examines each placeholder in a PREPAREd dynamic SQL statement to determine its name, length, and the datatype of its associated input host variable. It then stores this information in the bind descriptor for your use. For example, you might use placeholder names to prompt the user for the values of input host variables.
SQLDA variables are not defined in the Declare Section.
Though SQLDAs differ among host languages, a generic select SQLDA contains the following information about a query select list:
EXEC SQL PREPARE statement_name
FROM { :host_string | string_literal };
EXEC SQL DECLARE cursor_name CURSOR FOR statement_name;
EXEC SQL DESCRIBE BIND VARIABLES FOR statement_name
INTO bind_descriptor_name;
EXEC SQL OPEN cursor_name
[USING DESCRIPTOR bind_descriptor_name];
EXEC SQL DESCRIBE [SELECT LIST FOR] statement_name
INTO select_descriptor_name;
EXEC SQL FETCH cursor_name
USING DESCRIPTOR select_descriptor_name;
EXEC SQL CLOSE cursor_name;
Select and bind descriptors need not work in tandem. If the number of columns in a query select list is known, but the number of placeholders for input host variables is unknown, you can use the Method 4 OPEN statement with the following Method 3 FETCH statement:
EXEC SQL FETCH emp_cursor INTO host_variable_list;
Conversely, if the number of placeholders for input host variables is known, but the number of columns in the select list is unknown, you can use the following Method 3 OPEN statement with the Method 4 FETCH statement:
EXEC SQL OPEN cursor_name [USING host_variable_list];
Note that EXECUTE can be used for nonqueries with Method 4.
To learn how these statements allow your program to process dynamic SQL statements using descriptors, see your host-language supplement.
EXEC SQL [AT db_name] DECLARE statement_name STATEMENT;
where db_name and statement_name are identifiers used by th precompiler, not host or program variables.
DECLARE STATEMENT declares the name of a dynamic SQL statement so that the statement can be referenced by PREPARE, EXECUTE, DECLARE CURSOR, and DESCRIBE. It is required if you want to execute the dynamic SQL statement at a non-default database. An example using Method 2 follows:
EXEC SQL AT remote_db DECLARE sql_stmt STATEMENT;
EXEC SQL PREPARE sql_stmt FROM :sql_string;
EXEC SQL EXECUTE sql_stmt;
In the example, remote_db tells Oracle where to EXECUTE the SQL statement.
With Methods 3 and 4, DECLARE STATEMENT is also required if the DECLARE CURSOR statement precedes the PREPARE statement, as shown in the following example:
EXEC SQL DECLARE sql_stmt STATEMENT;
EXEC SQL DECLARE emp_cursor CURSOR FOR sql_stmt;
EXEC SQL PREPARE sql_stmt FROM :sql_string;
The usual sequence of statements is
EXEC SQL PREPARE sql_stmt FROM :sql_string;
EXEC SQL DECLARE emp_cursor CURSOR FOR sql_stmt;
EXEC SQL EXECUTE statement_name USING host_array_list;
where host_array_list contains one or more host arrays. With Method 3, use the following syntax:
OPEN cursor_name USING host_array_list;
To use output host arrays with Method 3, use the following syntax:
FETCH cursor_name INTO host_array_list;
With Method 4, you must use the optional FOR clause to tell Oracle the size of your input or output host array. To learn how this is done, see your host-language supplement.
However, there are two differences in the way the precompiler handles SQL and PL/SQL:
You must put all host variables in the USING clause. When the PL/SQL string is EXECUTEd, host variables in the USING clause replace corresponding placeholders in the PREPAREd string. Though the precompiler treats all PL/SQL host variables as input host variables, values are assigned correctly. Input (program) values are assigned to input host variables, and output (column) values are assigned to output host variables.
Every placeholder in the PREPAREd PL/SQL string must correspond to a host variable in the USING clause. So, if the same placeholder appears two or more times in the PREPAREd string, each appearance must correspond to a host variable in the USING clause.
To use Method 4, you set up one bind descriptor for all the input and output host variables. Executing DESCRIBE BIND VARIABLES stores information about input and output host variables in the bind descriptor. Because the precompiler treats all PL/SQL host variables as input host variables, executing DESCRIBE SELECT LIST has no effect.
The use of bind descriptors with Method 4 is detailed in your host-language supplement.
Attention: In dynamic SQL Method 4, a host array cannot be bound to a PL/SQL procedure with a parameter of type "table."
Prev Next |
Copyright © 1996 Oracle Corporation. All Rights Reserved. |
Library |
Product |
Contents |
Index |