Monday, February 23, 2009

Remote dependencies

When changing plsql code in a production system the dependencies between objects can cause some programs to be invalidated. Making sure all programs are valid before opening the system to users is very important for application availability. Oracle automatically compiles invalid programs on their first execution, but a successfull compilation may not be possible because the error may need code correction or the compilation may cause library cache locks when applications are running.

Dependencies between plsql programs residing in the same database are easy to handle. When you compile a program the programs dependent on that one are invalidated right away and we can see the invalid programs and compile or correct them before opening the system to the users.

If you have db links and if your plsql programs are dependent on programs residing in other databases you have a problem handling the invalidations. There is an initialization parameter named remote_dependencies_mode that handles this dependency management. If it is set to TIMESTAMP the timestamp of the local program is compared to that of the remote program. If the remote program's timestamp is more recent than the local program, the local program is invalidated in the first run. If the parameter is set to SIGNATURE the remote program's signature (number and types of parameters, subprogram names, etc...) is checked, if there has been a change the local program is invalidated in the first run.

The problem here is; if you change the remote program's signature or timestamp you cannot see that the local program is invalidated because it will wait for the first execution to be invalidated. If you open the system to the users before correcting this you may face a serious application problem leading to downtime.

Here is a simple test case to see the problem.




I start by creating a plsql package in the database TEST.

SQL> create package test_pack as
2 procedure test_proc(a number);
3 end;
4 /

Package created.

SQL> create package body test_pack as
2 procedure test_proc(a number) is
3 begin
4 null;
5 end;
6 end;
7 /

Package body created.


On another database let's create a database link pointing to the remote database TEST, create a synonym for the remote package and create a local package calling the remote one.

SQL> create database link test.world connect to yas identified by yas using 'TEST';

Database link created.

SQL> select * from dual@yas.world;

D
-
X

SQL> create synonym test_pack for test_pack@yasbs.world;

Synonym created.

SQL> create package local_pack as
2 procedure local_test(a number);
3 end;
4 /

Package created.

SQL> r
1 create or replace package body local_pack as
2 procedure local_test(a number) is
3 begin
4 test_pack.test_proc(1);
5 end;
6* end;

Package body created.


If we look at the status of this local package we see that it is valid.


SQL> col object_name format a30
SQL> r
1* select status,object_name,object_type from user_objects where object_name='LOCAL_PACK'

STATUS OBJECT_NAME OBJECT_TYPE
------- ------------------------------ ------------------
VALID LOCAL_PACK PACKAGE
VALID LOCAL_PACK PACKAGE BODY


We can execute it without any problems.


SQL> exec LOCAL_PACK.local_test(1);

PL/SQL procedure successfully completed.


Now, let's change the remote package code including the package specification.


SQL> create or replace package test_pack as
2 procedure test_proc(b number,a number default 1);
3 end;
4 /

Package created.

SQL> create or replace package body test_pack as
2 procedure test_proc(b number,a number default 1) is
3 begin
4 null;
5 end;
6 end;
7 /

Package body created.


When we look at the local package we see its status as valid.


SQL> r
1* select status,object_name,object_type from user_objects where object_name='LOCAL_PACK'

STATUS OBJECT_NAME OBJECT_TYPE
------- ------------------------------ ------------------
VALID LOCAL_PACK PACKAGE
VALID LOCAL_PACK PACKAGE BODY


But when it is executed we get an error.


SQL> exec LOCAL_PACK.local_test(1);
BEGIN LOCAL_PACK.local_test(1); END;

*
ERROR at line 1:
ORA-04068: existing state of packages has been discarded
ORA-04062: signature of package "YASBS.TEST_PACK" has been changed
ORA-06512: at "YASBS.LOCAL_PACK", line 4
ORA-06512: at line 1


SQL> select status,object_name,object_type from user_objects where object_name='LOCAL_PACK';

STATUS OBJECT_NAME OBJECT_TYPE
------- ------------------------------ ------------------
VALID LOCAL_PACK PACKAGE
INVALID LOCAL_PACK PACKAGE BODY

SQL> exec LOCAL_PACK.local_test(1);

PL/SQL procedure successfully completed.

SQL> select status,object_name,object_type from user_objects where object_name='LOCAL_PACK';

STATUS OBJECT_NAME OBJECT_TYPE
------- ------------------------------ ------------------
VALID LOCAL_PACK PACKAGE
VALID LOCAL_PACK PACKAGE BODY


The second execution compiles the package and returns the status to valid.

How can we know beforehand that the local program will be invalidated on the first execution? The only way I can think of is to check the dependencies across all databases involved. By collecting all rows from dba_dependencies from all databases we can see that when the remote program is changed the programs on other databases that use this remote program will be invalidated when they are executed. Then we can compile these programs and see if they compile without errors.

Database links may be very annoying sometimes, this case is just one of them.