WINDOWS下的程序员出身,偶尔也写一些linux平台下小程序, 后转行数据库行业,专注于ORACLE和DB2的运维和优化。 同时也是ios移动开发者。欢迎志同道合的朋友一起研究技术。 数据库技术交流群:58308065,23618606
全部博文(599)
分类: Oracle
2012-04-28 11:23:04
Best practices for managing old and new information and preventing FORALL errors
I want to audit updates to a table, including the before and after values of each column in my table. To do this, I would love to pass :NEW and :OLD as arguments to procedures, but that doesn't seem to work. I'd really like to avoid hard-coding column names, because then I run into compilation issues when columns are added, dropped, or renamed. Is this possible? This is how I am currently doing things:
CREATE TABLE load_a (
a1 VARCHAR2 (10), a2 VARCHAR2 (10) )
/
CREATE OR REPLACE TRIGGER ins_load_a
AFTER UPDATE
ON scott.load_a
FOR EACH ROW
DECLARE
a_rec scott.load_a%ROWTYPE;
BEGIN
a_rec.a1 := :OLD.a1;
a_rec.a2 := :OLD.a2;
save_old_values (a_rec);
END;
/
The bad news is that up through Oracle Database 10g, you cannot pass :OLD and :NEW as arguments to procedures. The good news is that at least you don't have to write all the code needed to accomplish your goal.
Let's take a step back: you want to pass the old and new values available inside a trigger to a stored procedure to process the data (write the information to a log table, execute validation logic, and so on). You cannot pass :OLD and :NEW as records; instead, you must copy the individual fields of those pseudorecords to a real record that can be passed to the procedure.
It certainly is tedious and time-consuming to write that code yourself, especially for tables with many columns. Fortunately, it is quite easy to generate the code you desire.
I offer you the gen_audit_trigger_text procedure shown in Listing 1 to help you achieve your goal. I ran this program for the employees table and, after some formatting, had the resulting code shown in Listing 2.
Code Listing 1: gen_audit_trigger_text
CREATE OR REPLACE PROCEDURE gen_audit_trigger_text (
table_in IN VARCHAR2
, owner_in IN VARCHAR2 := USER
, program_name_in IN VARCHAR2 := 'process_data'
)
IS
c_rowtype CONSTANT VARCHAR2 (100) := table_in || '%ROWTYPE';
l_columns DBMS_SQL.varchar2s;
PROCEDURE gen_copy_proc (old_or_new_in IN VARCHAR2)
IS
BEGIN
DBMS_OUTPUT.put_line ( 'FUNCTION copy_'
|| old_or_new_in
|| ' RETURN '
|| c_rowtype
|| ' IS l_return '
|| c_rowtype
|| '; BEGIN '
);
FOR indx IN 1 .. l_columns.COUNT
LOOP
DBMS_OUTPUT.put_line ( ' l_return.'
|| l_columns (indx)
|| ' := '
|| ':'
|| old_or_new_in
|| '.'
|| l_columns (indx)
|| ';'
);
END LOOP;
DBMS_OUTPUT.put_line ('RETURN l_return;');
DBMS_OUTPUT.put_line ('END copy_' || old_or_new_in || ';');
END gen_copy_proc;
BEGIN
SELECT LOWER (column_name) column_name
BULK COLLECT INTO l_columns
FROM all_tab_columns
WHERE owner = UPPER (owner_in) AND table_name = UPPER (table_in);
DBMS_OUTPUT.put_line ('DECLARE');
DBMS_OUTPUT.put_line (' my_Old ' || table_in || '%ROWTYPE;');
DBMS_OUTPUT.put_line (' my_New ' || table_in || '%ROWTYPE;');
gen_copy_proc ('old');
gen_copy_proc ('new');
DBMS_OUTPUT.put_line ('BEGIN');
DBMS_OUTPUT.put_line (' my_Old := copy_Old ();');
DBMS_OUTPUT.put_line (' my_New := copy_New ();');
DBMS_OUTPUT.put_line (' ' || program_name_in || '(my_Old, my_new);');
DBMS_OUTPUT.put_line ('END;');
END gen_audit_trigger_text;
/
Code Listing 2: Result of gen_audit_trigger_text procedure on employees table
DECLARE
my_old employees%ROWTYPE;
my_new employees%ROWTYPE;
FUNCTION copy_old
RETURN employees%ROWTYPE
IS
l_return employees%ROWTYPE;
BEGIN
l_return.employee_id := :OLD.employee_id;
l_return.first_name := :OLD.first_name;
l_return.last_name := :OLD.last_name;
l_return.email := :OLD.email;
l_return.phone_number := :OLD.phone_number;
l_return.hire_date := :OLD.hire_date;
l_return.job_id := :OLD.job_id;
l_return.salary := :OLD.salary;
l_return.commission_pct := :OLD.commission_pct;
l_return.manager_id := :OLD.manager_id;
l_return.department_id := :OLD.department_id;
RETURN l_return;
END copy_old;
FUNCTION copy_new
RETURN employees%ROWTYPE
IS
l_return employees%ROWTYPE;
BEGIN
l_return.employee_id := :NEW.employee_id;
l_return.first_name := :NEW.first_name;
l_return.last_name := :NEW.last_name;
l_return.email := :NEW.email;
l_return.phone_number := :NEW.phone_number;
l_return.hire_date := :NEW.hire_date;
l_return.job_id := :NEW.job_id;
l_return.salary := :NEW.salary;
l_return.commission_pct := :NEW.commission_pct;
l_return.manager_id := :NEW.manager_id;
l_return.department_id := :NEW.department_id;
RETURN l_return;
END copy_new;
BEGIN
my_old := copy_old ();
my_new := copy_new ();
process_data (my_old, my_new);
END;
You should be able to enhance gen_audit_trigger_text in a straightforward way to also generate the header of your trigger; I leave that as an exercise for the reader.
An Error FORALL?
We have been just amazed at how much better our programs perform when we use FORALL to do our inserts and updates. We are now building a new application on Oracle Database 10g Release 2, and we have run into a problem. In all previous usages of FORALL, we would generally take a collection that was populated with a BULK COLLECT and push it into one or more tables.
Now we have a more complicated scenario, in which we must go through our collection of "candidate" data for inserts and remove some (perhaps all) of the rows before doing the insert. When we try to use FORALL, we get this error message:
ORA-22160: element at index [2750] does
not exist
How can we avoid this error and get all our data inserted?
I agree that FORALL is wonderfulone of the most important enhancements to PL/SQL since Oracle8i was released. And back in Oracle8i and Oracle9i Database, it is true that the only format with which you could use FORALL was this:
FORALL index_variable
IN low_value .. high_value
And as in a "regular" numeric FOR loop, FORALL will iterate through each integer between low_value and high_value , using that integer to identify an element in all collections that are bound into the DML statement with the index_variable . If no element exists at a particular index value, Oracle Database raises an exception, as you can see in the example in Listing 3.
Code Listing 3: Raising ORA-22160
SQL> DECLARE
2 TYPE list_of_names_t IS TABLE OF VARCHAR2 (32767)
3 INDEX BY PLS_INTEGER;
4
5 happyfamily list_of_names_t;
6 BEGIN
7 happyfamily (1) := 'Eli';
8 happyfamily (2) := 'Chris';
9 happyfamily (3) := 'Veva';
10 happyfamily (5) := 'Steven';
11 FORALL indx IN happyfamily.FIRST .. happyfamily.LAST
12 INSERT INTO first_names
13 VALUES (happyfamily (indx));
14 END;
15 /
DECLARE
*
ERROR at line 1:
ORA-22160: element at index [4] does not exist
FORALL, in other words, requires a sequentially or densely filled collection. Now if you were still running Oracle8i or Oracle9i Database and wanted to fix this problem, you would have to copy the data from your sparsely filled collection over to one without any gaps. From a performance standpoint, this is nothing to worry about; manipulating collections is very fast. But it does involve writing and maintaining even more code.
In Oracle Database 10g, Oracle added two new clauses to the FORALL statement: INDICES OF and VALUES OF. They allow you to avoid the restriction on using densely filled collections. Instead of using an IN range of values, you can point to a collection (usually, but not necessarily, the same collection that is referenced inside the FORALL's DML statement) and say, in effect, "Use only those index values defined in that other collection" (INDICES OF) or "Use only index values that are found in the elements of that other collection" (VALUES OF).
Here is a rewrite of the code in Listing 3 that avoids the ORA-22160 error (notice the boldfaced lines):
DECLARE
TYPE list_of_names_t
IS TABLE OF VARCHAR2 (32767)
INDEX BY PLS_INTEGER;
happyfamily list_of_names_t;
BEGIN
happyfamily (1) := 'Eli';
happyfamily (2) := 'Chris';
happyfamily (3) := 'Veva';
happyfamily (5) := 'Steven';
FORALL indx
IN INDICES OF happyfamily
INSERT INTO first_names
VALUES (happyfamily (indx));
END;
/
That is an example of the simplest way to apply INDICES OF: "self- reference" the same collection used within the DML statement, to easily avoid errors due to sparseness in that collection.
Now let's take a look at VALUES OF. This clause comes in very handy when you want to use only a subset of the collection to be used within the DML statement.
Suppose, for example, that I have a procedure that accepts a collection of employee records and should insert only records for employees with a salary of $10,000 or more. Listing 4 contains the package specification and the body for this employees_dml program.
Code Listing 4: Package and body for employees_dml
CREATE OR REPLACE PACKAGE employees_dml
IS
TYPE employees_aat IS TABLE OF employees%ROWTYPE
INDEX BY PLS_INTEGER;
PROCEDURE insert_some (employees_in IN employees_aat);
END employees_dml;
/
SQL>CREATE OR REPLACE PACKAGE BODY employees_dml
2 IS
3 PROCEDURE insert_some (employees_in IN employees_aat)
4 IS
5 TYPE index_values_aat IS TABLE OF PLS_INTEGER
6 INDEX BY PLS_INTEGER;
7
8 l_values_of index_values_aat;
9 l_index PLS_INTEGER;
10 BEGIN
11 -- Only insert those employees with a salary >= 10000.
12 l_index := employees_in.FIRST;
13
14 WHILE (l_index IS NOT NULL)
15 LOOP
16 IF employees_in (l_index).salary >= 10000
17 THEN
18 l_values_of (l_values_of.COUNT + 1) := l_index;
19 END IF;
20
21 l_index := employees_in.NEXT (l_index);
22 END LOOP;
23
24 FORALL indx IN VALUES OF l_values_of
25 INSERT INTO employees
26 VALUES employees_in (indx);
27 END insert_some;
28 END employees_dml;
Lines 5 through 9 in Listing 4 declare the VALUES OF collection, a collection of PLS_INTEGER values. Then in my WHILE loop (lines 14 through 22), I populate a row in l_values_of with the index value from employees_in, only if the salary in that record is at least $10,000.
Thus, when I get to the FORALL statement (lines 24 through 26), the VALUES OF clause ensures that all other employee records are ignored.
If you have the standard Oracle employees table installed with default data, you can run the script in Listing 5 to verify the behavior of the employees_dml package.
Code Listing 5: Verifying behavior of employees_dml package
SELECT COUNT(*)
FROM employees
WHERE salary < 10000
/
DECLARE
l_employees employees_dml.employees_aat;
BEGIN
SELECT *
BULK COLLECT INTO l_employees
FROM employees;
DELETE FROM employees;
employees_dml.insert_some (l_employees);
END;
/
SELECT COUNT(*)
FROM employees
WHERE salary < 10000
/
ROLLBACK
/
COUNT(*)
-------------------------
88
1 row selected.
PL/SQL procedure successfully completed.
COUNT(*)
-------------------------
0
1 row selected.
Rollback complete.
Finally, you can also use INDICES OF with an entirely different collection that serves as a kind of filter for the collections used in the DML statement.
Listing 6 shows an example of this approach.
Code Listing 6: Using INDICES OF as a filter
SQL> DECLARE
2 TYPE employee_aat IS TABLE OF employees.employee_id%TYPE
3 INDEX BY PLS_INTEGER;
4
5 l_employees employee_aat;
6
7 TYPE boolean_aat IS TABLE OF Boolean
8 INDEX BY PLS_INTEGER;
9
10 l_employee_indices boolean_aat;
11 BEGIN
12 l_employees (1) := 137;
13 l_employees (100) := 126;
14 l_employees (500) := 147;
15 --
16 l_employee_indices (1) := false;
17 l_employee_indices (500) := TRUE;
18 l_employee_indices (799) := null;
19 --
20 FORALL l_index IN INDICES OF l_employee_indices
21 BETWEEN 1 AND 500
22 UPDATE employees
23 SET salary = 10000
24 WHERE employee_id = l_employees (l_index);
25 END;
In this code, I use the index values of defined elements in the l_employee_indices collection to specify which elements of the l_employees collection to use in my update statement. Note that on line 21 of Listing 6, I include a BETWEEN clause to constrain which of the index values of l_employee_indices will be used. So INDICES OF should fix your problem in this case.
Using Encapsulation Without Privileges
I have taken to heart your advice about writing SQL statements (don't write SQL in application-level code; hide it behind a packaged API, with as much of it generated as possible). I also decided (and I am a team leader, so my decision carries some weight) to go the full route, and I revoked privileges on the tables, so my developers have no choice but to use the encapsulation packages.
Here's my problem: another of your best practices is to avoid hard-coded declarations and to anchor variables back to database tables and columns with %TYPE and %ROWTYPE. But my people can't do that, because I revoked privileges and they need the SELECT privilege on a table to do that.
What's a best-practice-oriented guy supposed to do?
So nice to hear that you are going the encapsulation route! I have used it myself in recent years in every single one of my development projects, and I really can't imagine going back to the "old way" of writing all the SQL statements every time I need them.
And I am very impressed to hear about your decision to revoke table privileges. That's a hard thing to do, but once the revocation is in place, it can greatly improve the robustness of your application.
Yet, as you point out, it leads to an interesting conflict of best practices.
Here's how I resolve this problem: I generate three table API packages for each of my tables:
· A change package that implements all the basic INSERT, UPDATE, and DELETE operations
· A query package that gives me a wide range of functions for querying data from the table
· A types package that creates a set of subtypes , which in essence hide the %TYPE and %ROWTYPE declarations and ensure that I don't even need SELECT authority on tables to build high-quality code
How does it work? Simple.
Suppose I am building an application to maintain a category of things my company sells. One of my tables is cat_tools, which contains information about tools. The table has a name, a description, and a universal_id (primary key, defined as a GUID, or globally unique identifier). Listing 7, includes a portion of the types package for this table.
Code Listing 7: Creating a type package as an API
CREATE OR REPLACE PACKAGE cat_tools_tp
IS
SUBTYPE cat_tools_rt IS cat_tools%ROWTYPE;
SUBTYPE universal_id_t IS cat_tools.universal_id%TYPE;
SUBTYPE name_t IS cat_tools.NAME%TYPE;
SUBTYPE description_t IS cat_tools.description%TYPE;
TYPE table_refcur IS REF CURSOR
RETURN cat_tools%ROWTYPE;
TYPE cat_tools_tc IS TABLE OF cat_tools%ROWTYPE
INDEX BY PLS_INTEGER;
TYPE universal_id_cc IS TABLE OF cat_tools.universal_id%TYPE
INDEX BY BINARY_INTEGER;
END cat_tools_tp;
/
So now assume that the cat_tools table and both the cat_tools_tp (types) and cat_tools_qp (query) packages are defined in the CATALOG schema. I grant EXECUTE on cat_tools_tp and cat_tools_qp to HR. Then from HR, I can write the block of code in Listing 8.
Code Listing 8: Access using the type and query packages
DECLARE
/* A string to hold the assertion name */
l_name CATALOG.cat_tools_tp.name_t;
/* A collection to hold the set of tools rows. */
l_tools CATALOG.cat_tools_tp.cat_tools_tc;
BEGIN
/* The allrows function retrieves all rows from cat_tools. */
l_tools := CATALOG.cat_tools_qp.allrows;
/* Assign each name from collection to local variable. */
FOR indx IN 1 .. l_tools.COUNT
LOOP
l_name := l_tools (indx).NAME;
END LOOP;
END;
/
As you can see, even though the HR schema has no access to the cat_tools table, I am able to declare variables by using datatypes that are anchored (indirectly) to the table and its columns. I can also query the contents of the table.
And if the table ever changes, the types package will also change (that is, you will regenerate it). All programs that reference this package will then have to be recompiled; thus, you have the same dependencies you would have with %ROWTYPE and %TYPE declarations.