4.2 NDS Statement SummaryOne of the nicest things about NDS is its simplicity. Unlike DBMS_SQL, which has dozens of programs and lots of rules to follow, NDS has been integrated into the PL/SQL language by adding one new statement, EXECUTE IMMEDIATE, and by enhancing the existing OPEN FOR statement:
4.2.1 The EXECUTE IMMEDIATE StatementUse EXECUTE IMMEDIATE to execute (immediately!) the specified SQL statement. Here is the syntax of this statement: EXECUTE IMMEDIATE SQL_string [INTO { define_variable [, define_variable ]... | record }] [USING [IN | OUT | IN OUT] bind_argument [, [IN | OUT | IN OUT] bind_argument ]...];
You can use EXECUTE IMMEDIATE for any SQL statement or PL/SQL block, except for multiple-row queries. If SQL_string ends with a semicolon, it will be treated as a PL/SQL block; otherwise, it will be treated as either DML (Data Manipulation Language -- SELECT, INSERT, UPDATE, or DELETE) or DDL (Data Definition Language, such as CREATE TABLE). The string may contain placeholders for bind arguments, but you cannot use bind values to pass in the names of schema objects, such as table names or column names. When the statement is executed, the runtime engine replaces each placeholder (an identifier with a colon in front of it, such as :salary_value) in the SQL string with its corresponding bind argument (by position). You can pass numeric, date, and string expressions. You cannot, however, pass a Boolean, because it is a PL/SQL datatype. Nor can you pass a NULL literal value. Instead, you must pass a variable of the correct type that has a value of NULL. NDS supports all SQL datatypes available in Oracle8 i . So, for example, define variables and bind arguments can be collections, large objects (LOBs), instances of an object type, and REFs. On the other hand, NDS does not support datatypes that are specific to PL/SQL, such as Booleans, index-by tables, and user-defined record types. The INTO clause may, however, contain a PL/SQL record. Let's take a look at a few examples:
4.2.2 The OPEN FOR StatementThe OPEN FOR statement is not brand-new to PL/SQL in Oracle8 i ; it was first offered in Oracle7 to support cursor variables. Now it is deployed in an especially elegant fashion to implement multiple-row dynamic queries. With DBMS_SQL, you go through a particularly painful series of steps to implement multirow queries: parse, bind, define each column individually, execute, fetch, extract each column value individually. My gosh, what a lot of code to write! For native dynamic SQL, Oracle took an existing feature and syntax -- that of cursor variables -- and extended it in a very natural way to support dynamic SQL. The next section explores multirow queries in detail; let's take a look now specifically at the syntax of the OPEN FOR statement: OPEN { cursor_variable | : host_cursor_variable } FOR SQL_string [USING bind_argument [, bind_argument ]...];
Many PL/SQL developers are not very familiar with cursor variables, so a quick review is in order (for lots more details, check out Chapter 6 of Oracle PL/SQL Programming, 2nd Edition . A cursor variable is a variable of type REF CURSOR, or referenced cursor. Here is an example of a declaration of a cursor variable based on a "weak" REF CURSOR (the sort you will use for NDS): DECLARE TYPE cv_type IS REF CURSOR; cv cv_type; A cursor variable points to a cursor object; it is, however, a variable. You can have more than one variable pointing to the same cursor object, you can assign one cursor variable to another, and so on. Once you have declared a cursor variable, you can assign a value to it by referencing it in an OPEN FOR statement: DECLARE TYPE cv_type IS REF CURSOR; cv cv_type; BEGIN OPEN cv FOR SELECT COUNT(guns) FROM charlton_heston_home; In this example, the query is static -- it is not contained in single quotes, and it is frozen at compilation time. That is the only way we have been able to work with cursor variables until Oracle8 i . Now we can use the same syntax as before, but the query can be a literal or an expression, as in the following: OPEN dyncur FOR SQL_string; or, to show the use of a bind argument: OPEN dyncur FOR 'SELECT none_of_the_above FROM senate_candidates WHERE state = :your_state_here' USING state_in; Once you have opened the query with the OPEN FOR statement, the syntax used to fetch rows, close the cursor variable and check the attributes of the cursor are all the same as for static cursor variables -- and hardcoded explicit cursors, for that matter. The next section demonstrates all of this syntax through examples. To summarize, there are two differences between the OPEN FOR statement for static and dynamic SQL: Copyright (c) 2000 O'Reilly & Associates. All rights reserved. |
|