Re: Debug DDL trigger

  • From: rjamya <rjamya@xxxxxxxxx>
  • To: Dave.Herring@xxxxxxxxxx
  • Date: Mon, 22 Aug 2005 22:37:13 -0400

With all due respect, first of all get rid of the exception clause. This 
thing alone has helped me find 99% of the issues where "this stupid trigger 
doesn't fire" is the catch phrase. Once you see the error, rest is easy.

As a boundary condition, what error do you think you will get if my table 
name is exactly (or more than) 27 characters long? Also I'd prefer to get 
rid of the WHEN clause of the trigger and add that to the WHERE clause.

Raj

On 8/22/05, Herring Dave - dherri <Dave.Herring@xxxxxxxxxx> wrote:
> 
>  Folks,
> 
>  I'm having a rough time trying to figure out how to debug a DDL trigger. 
> I'm on Oracle 9.2.0.4 <http://9.2.0.4>, under Tru64 5.1. I've written a 
> trigger whose purpose is to make a backup copy of a table in one schema into 
> another, before the table gets dropped. The problem is, as far as I can 
> tell, the trigger is never fired. I've validated that the trigger exists and 
> is enabled, but can't get any further. Is there a way to trace how triggers 
> get chosen to be fired by Oracle?
> 
>  Here's the trigger's text:
> 
>  CREATE OR REPLACE TRIGGER sys.cp_tab_before_drop_btg
> 
> BEFORE drop ON dherri.SCHEMA
> 
> WHEN ( ora_dict_obj_type = 'TABLE'
> 
> AND ( ora_dict_obj_name LIKE 'SCORE\_ACCT\_TB\_%' ESCAPE '\'
> 
> )
> 
> )
> 
> DECLARE
> 
> PRAGMA AUTONOMOUS_TRANSACTION;
> 
> v_datestamp DATE := sysdate;
> 
> v_ddl_stmt VARCHAR2(4000);
> 
> v_ora_error NUMBER;
> 
> v_procedure_name VARCHAR2(30) := 'CP_TAB_BEFORE_DROP_BTG';
> 
> v_procedure_owner VARCHAR2(30) := 'SYS';
> 
> v_table_count PLS_INTEGER := 1;
> 
>  BEGIN
> 
> INSERT INTO dherri.aud_plsql_error_tb values ('SYS','Test: Before 
> SELECT',1,sysdate);
> 
> COMMIT;
> 
>  /*
> 
> * Validate the table to be dropped does exist.
> 
> */
> 
> SELECT COUNT(*) INTO v_table_count
> 
> FROM dba_tables
> 
> WHERE owner = ora_dict_obj_owner
> 
> AND table_name = ora_dict_obj_name;
> 
>  IF v_table_count > 0 THEN
> 
> INSERT INTO dherri.aud_plsql_error_tb values ('SYS','Test: Within 
> IF-TEST',v_table_count,sysdate);
> 
> COMMIT;
> 
>  v_ddl_stmt := 'CREATE TABLE dherri.'||ora_dict_obj_name||'_bkp PCTFREE 0 
> AS SELECT * FROM dherri.'||ora_dict_obj_name||';';
> 
> EXECUTE IMMEDIATE v_ddl_stmt;
> 
> END IF;
> 
>  EXCEPTION
> 
> WHEN OTHERS THEN
> 
> v_ora_error := ABS(SQLCODE);
> 
> INSERT INTO dherri.aud_plsql_error_tb VALUES (v_procedure_owner, 
> v_procedure_name, v_ora_error, sysdate);
> 
> END;
> 
> /
> 
>  Dave
> 
> -------------------------------------
> 
> Dave Herring, DBA
> 
> Acxiom Corporation
> 
> 3333 Finley
> 
> Downers Grove, IL 60515
> 
> wk: 630.944.4762
> 
> <mailto:dherri@xxxxxxxxxx <dherri@xxxxxxxxxx>>
> 
> -------------------------------------
> 
>  **************************************************************************
> The information contained in this communication is confidential, is
> intended only for the use of the recipient named above, and may be legally
> privileged.
> 
> If the reader of this message is not the intended recipient, you are
> hereby notified that any dissemination, distribution or copying of this
> communication is strictly prohibited.
> 
> If you have received this communication in error, please resend this
> communication to the sender and delete the original message or any copy
> of it from your computer system.
> 
> Thank You.
> **************************************************************************
> 
> 


-- 
------------------------------
select standard_disclaimer from company_requirements where category = 
'MANDATORY';

Other related posts: