Error Description :
We have more than 100 of records in a csv file which we are processing through a script. At the first execution let
say it generates trigger exception for five records ... when I execute the script second time those five records
are not throwing any exception but may be some other records. But consecutive trigger exception is not happening for any record . If a particular record is throwing exception at first attempt then in the second attempts it's not throwing the trigger exception.
Input file
PROPRTY_ID,NAME,OLD STREET,CITY,STATE,ZIP,NEW STREET,NEW CITY,NEW STATE,NEW ZIP
88527091,SAM PAUL SUMMU ,1061 XYZ,CITY1,ST,95626,5512 XX YY ZZ,TOWN,PA,12345-9812
.
.
.
Error :
88527091,SAM PAUL SUMMU ,1061 XYZ,CITY1,ST,95626,5512 XX YY ZZ,TOWN,PA,12345-9812 - PROPERTY Update Error : ORA-00001: unique constraint (PROD.PK_AUDIT_LOG) violated
ORA-06512: at "PROD.PROPERTY_AUD", line 159
ORA-04088: error during execution of trigger 'PROD.PROPERTY_AUD'
Connected to:
Oracle Database 11g Enterprise Edition Release 11.1.0.7.0 - 64bit Production
With the Partitioning, OLAP, Data Mining and Real Application Testing options
SQL> desc property
Name Null? Type
----------------------------------------- -------- ----------------------------
PROPERTY_ID NOT NULL NUMBER(20)
TYPE_CODE VARCHAR2(10)
TYPE_PREFIX VARCHAR2(10)
DWELLING_TYPE_CODE NOT NULL VARCHAR2(10)
DWELLING_TYPE_PREFIX NOT NULL VARCHAR2(10)
STREET_NUMBER VARCHAR2(25)
STREET_DIRECTION CHAR(2)
STREET_NAME NOT NULL VARCHAR2(45)
UNIT_NUMBER VARCHAR2(15)
CITY_CODE VARCHAR2(10)
STATE NOT NULL CHAR(2)
ZIP_CODE VARCHAR2(10)
UNIT_TYPE VARCHAR2(10)
UNIT_PREFIX VARCHAR2(10)
COUNTY_CODE VARCHAR2(10)
COUNTRY_CODE NOT NULL VARCHAR2(10)
SQUARE_FEET NUMBER(6)
NUMBER_MOTHER_LAW_UNITS NUMBER(6)
YEAR_BUILT DATE
PROPERTY_VALUE NUMBER(12)
ZIP_PLUS_4 VARCHAR2(4)
SFI_REQ_FLAG CHAR(1)
LAST_MODIFIED NOT NULL DATE
LAST_MODIFIED_BY VARCHAR2(31)
STANDARDIZED_STATUS VARCHAR2(10)
STANDARDIZED_DESC VARCHAR2(200)
SQL> desc audit_log
Name Null? Type
----------------------------------------- -------- ----------------------------
SEQ_NO NOT NULL NUMBER(20)
TABLE_NAME VARCHAR2(31)
USER_STAMP VARCHAR2(31)
TIME_STAMP DATE
TRAN_CODE CHAR(2)
RECORD1 VARCHAR2(2000)
RECORD2 VARCHAR2(2000)
FLAG_FLD CHAR(1)
SFI_FLAG_FLD CHAR(1)
ERROR_NUMBER NUMBER
Update Query which is getting executed :
UPDATE PROPERTY
SET DWELLING_TYPE_CODE = 'SFR',
DWELLING_TYPE_PREFIX = 'DWELLING',
STREET_NUMBER = NULL,
STREET_DIRECTION = NULL,
STREET_NAME = ln_new_street_name, -- <From input file>
UNIT_NUMBER = NULL,
CITY_CODE = ln_city_code, -- <From other Table>
STATE = ln_new_state, -- <From input file>
ZIP_CODE = ln_new_zip_code,
UNIT_TYPE = NULL,
UNIT_PREFIX = NULL,
COUNTY_CODE = ln_county_code, -- <From Other table>
COUNTRY_CODE = 1,
ZIP_PLUS_4 = ln_zip_plus_4 -- <From Input file>
WHERE PROPERTY_ID = ln_property_id; -- <From Other table>
*NOTE :* Property.LAST_MODIFIED field is auto populate through other trigger. It does not causing any problem.
This might be helpful :
SQL> select OWNER, CONSTRAINT_NAME, TABLE_NAME,COLUMN_NAME from dba_cons_columns where CONSTRAINT_NAME='PK_AUDIT_LOG';
OWNER CONSTRAINT_NAME TABLE_NAME COLUMN_NAME
------------------------------ ------------------------------ ------------- -----------------
PROD PK_AUDIT_LOG AUDIT_LOG SEQ_NO
PROD_ARCH PK_AUDIT_LOG AUDIT_LOG SEQ_NO
SQL> select SEQ_NO, trim(RECORD1), trim(RECORD2),TIME_STAMP
from audit_log where RECORD1 like '%BUTTE%' order by TIME_STAMP;
SEQ_NO
-------
1675677212
TRIM(RECORD1)
--------------
00000000000031814095...SFR .DWELLING ...5512 BUTTE VIEW CT ..15532
.CA.95765 ...1377 .1 .....5000..20100922.SUSMSAHA ..
TRIM(RECORD2)
--------------
00000000000031814095...SFR .DWELLING ...5512 BUTTE VIEW CT ..15532
.CA.95765 ...1377 .1 .....5000..20100922.SUSMSAHA ..
TIME_STAMP
-----------
22-sep-2010
Trigger Body which is fired and throwing the exception :
create or replace trigger PROPERTY_AUD
before insert or update on PROPERTY
for each row
declare
rec1 varchar2(2000);
rec2 varchar2(2000);
tcode char(1);
ln_seq_id NUMBER:=Null;
ls_sql VARCHAR2(2000):=Null;
begin
select temp_audit_seq.nextval into ln_seq_id from dual;
rec1 := null;
rec2 := null;
if user = 'NONREP_USER' then
return;
end if;
if (dbms_reputil.from_remote = FALSE) then
:NEW.last_modified := sysdate;
if (user = 'SALESFORCE_SYNC') then
:new.last_modified_by := NVL(:new.last_modified_by,USER);
else
:new.last_modified_by := user;
end if;
end if;
if inserting then
rec1 :=
LPAD(:new.PROPERTY_ID, 20, '0' ) || '.' ||
RPAD(:new.TYPE_CODE, 10, ' ' ) || '.' ||
RPAD(:new.TYPE_PREFIX, 10, ' ' ) || '.' ||
RPAD(:new.DWELLING_TYPE_CODE, 10, ' ' ) || '.' ||
RPAD(:new.DWELLING_TYPE_PREFIX, 10, ' ' ) || '.' ||
RPAD(:new.STREET_NUMBER, 25, ' ' ) || '.' ||
RPAD(:new.STREET_DIRECTION, 2, ' ' ) || '.' ||
RPAD(:new.STREET_NAME, 45, ' ' ) || '.' ||
RPAD(:new.UNIT_NUMBER, 15, ' ' ) || '.' ||
RPAD(:new.CITY_CODE, 10, ' ' ) || '.' ||
RPAD(:new.STATE, 2, ' ' ) || '.' ||
RPAD(:new.ZIP_CODE, 10, ' ' ) || '.' ||
RPAD(:new.UNIT_TYPE, 10, ' ' ) || '.' ||
RPAD(:new.UNIT_PREFIX, 10, ' ' ) || '.' ||
RPAD(:new.COUNTY_CODE, 10, ' ' ) || '.' ||
RPAD(:new.COUNTRY_CODE, 10, ' ' ) || '.' ||
LPAD(:new.SQUARE_FEET, 6, '0' ) || '.' ||
LPAD(:new.NUMBER_MOTHER_LAW_UNITS, 6, '0' ) || '.' ||
TO_CHAR(:new.YEAR_BUILT, 'YYYYMMDD') || '.' ||
LPAD(:new.PROPERTY_VALUE, 12, '0' ) || '.' ||
RPAD(:new.ZIP_PLUS_4, 4, ' ' ) || '.' ||
RPAD(:new.SFI_REQ_FLAG, 1, ' ' ) || '.' ||
TO_CHAR(:new.LAST_MODIFIED, 'YYYYMMDD') || '.' ||
RPAD(:new.LAST_MODIFIED_BY, 31, ' ' ) || '.' ||
RPAD(:new.STANDARDIZED_STATUS, 10, ' ' ) || '.' ||
RPAD(:new.STANDARDIZED_DESC, 200, ' ' );
tcode := 'I';
elsif deleting then
rec1 :=
LPAD(:new.PROPERTY_ID, 20, '0' ) || '.' ||
RPAD(:new.TYPE_CODE, 10, ' ' ) || '.' ||
RPAD(:new.TYPE_PREFIX, 10, ' ' ) || '.' ||
RPAD(:new.DWELLING_TYPE_CODE, 10, ' ' ) || '.' ||
RPAD(:new.DWELLING_TYPE_PREFIX, 10, ' ' ) || '.' ||
RPAD(:new.STREET_NUMBER, 25, ' ' ) || '.' ||
RPAD(:new.STREET_DIRECTION, 2, ' ' ) || '.' ||
RPAD(:new.STREET_NAME, 45, ' ' ) || '.' ||
RPAD(:new.UNIT_NUMBER, 15, ' ' ) || '.' ||
RPAD(:new.CITY_CODE, 10, ' ' ) || '.' ||
RPAD(:new.STATE, 2, ' ' ) || '.' ||
RPAD(:new.ZIP_CODE, 10, ' ' ) || '.' ||
RPAD(:new.UNIT_TYPE, 10, ' ' ) || '.' ||
RPAD(:new.UNIT_PREFIX, 10, ' ' ) || '.' ||
RPAD(:new.COUNTY_CODE, 10, ' ' ) || '.' ||
RPAD(:new.COUNTRY_CODE, 10, ' ' ) || '.' ||
LPAD(:new.SQUARE_FEET, 6, '0' ) || '.' ||
LPAD(:new.NUMBER_MOTHER_LAW_UNITS, 6, '0' ) || '.' ||
TO_CHAR(:new.YEAR_BUILT, 'YYYYMMDD') || '.' ||
LPAD(:new.PROPERTY_VALUE, 12, '0' ) || '.' ||
RPAD(:new.ZIP_PLUS_4, 4, ' ' ) || '.' ||
RPAD(:new.SFI_REQ_FLAG, 1, ' ' ) || '.' ||
TO_CHAR(:new.LAST_MODIFIED, 'YYYYMMDD') || '.' ||
RPAD(:new.LAST_MODIFIED_BY, 31, ' ' ) || '.' ||
RPAD(:new.STANDARDIZED_STATUS, 10, ' ' ) || '.' ||
RPAD(:new.STANDARDIZED_DESC, 200, ' ' );
tcode := 'D';
else
rec1 :=
LPAD(:old.PROPERTY_ID, 20, '0' ) || '.' ||
RPAD(:old.TYPE_CODE, 10, ' ' ) || '.' ||
RPAD(:old.TYPE_PREFIX, 10, ' ' ) || '.' ||
RPAD(:old.DWELLING_TYPE_CODE, 10, ' ' ) || '.' ||
RPAD(:old.DWELLING_TYPE_PREFIX, 10, ' ' ) || '.' ||
RPAD(:old.STREET_NUMBER, 25, ' ' ) || '.' ||
RPAD(:old.STREET_DIRECTION, 2, ' ' ) || '.' ||
RPAD(:old.STREET_NAME, 45, ' ' ) || '.' ||
RPAD(:old.UNIT_NUMBER, 15, ' ' ) || '.' ||
RPAD(:old.CITY_CODE, 10, ' ' ) || '.' ||
RPAD(:old.STATE, 2, ' ' ) || '.' ||
RPAD(:old.ZIP_CODE, 10, ' ' ) || '.' ||
RPAD(:old.UNIT_TYPE, 10, ' ' ) || '.' ||
RPAD(:old.UNIT_PREFIX, 10, ' ' ) || '.' ||
RPAD(:old.COUNTY_CODE, 10, ' ' ) || '.' ||
RPAD(:old.COUNTRY_CODE, 10, ' ' ) || '.' ||
LPAD(:old.SQUARE_FEET, 6, '0' ) || '.' ||
LPAD(:old.NUMBER_MOTHER_LAW_UNITS, 6, '0' ) || '.' ||
TO_CHAR(:new.YEAR_BUILT, 'YYYYMMDD') || '.' ||
LPAD(:old.PROPERTY_VALUE, 12, '0' ) || '.' ||
RPAD(:old.ZIP_PLUS_4, 4, ' ' ) || '.' ||
RPAD(:old.SFI_REQ_FLAG, 1, ' ' ) || '.' ||
TO_CHAR(:new.LAST_MODIFIED, 'YYYYMMDD') || '.' ||
RPAD(:old.LAST_MODIFIED_BY, 31, ' ' ) || '.' ||
RPAD(:old.STANDARDIZED_STATUS, 10, ' ' ) || '.' ||
RPAD(:old.STANDARDIZED_DESC, 200, ' ' );
rec2 :=
LPAD(:new.PROPERTY_ID, 20, '0' ) || '.' ||
RPAD(:new.TYPE_CODE, 10, ' ' ) || '.' ||
RPAD(:new.TYPE_PREFIX, 10, ' ' ) || '.' ||
RPAD(:new.DWELLING_TYPE_CODE, 10, ' ' ) || '.' ||
RPAD(:new.DWELLING_TYPE_PREFIX, 10, ' ' ) || '.' ||
RPAD(:new.STREET_NUMBER, 25, ' ' ) || '.' ||
RPAD(:new.STREET_DIRECTION, 2, ' ' ) || '.' ||
RPAD(:new.STREET_NAME, 45, ' ' ) || '.' ||
RPAD(:new.UNIT_NUMBER, 15, ' ' ) || '.' ||
RPAD(:new.CITY_CODE, 10, ' ' ) || '.' ||
RPAD(:new.STATE, 2, ' ' ) || '.' ||
RPAD(:new.ZIP_CODE, 10, ' ' ) || '.' ||
RPAD(:new.UNIT_TYPE, 10, ' ' ) || '.' ||
RPAD(:new.UNIT_PREFIX, 10, ' ' ) || '.' ||
RPAD(:new.COUNTY_CODE, 10, ' ' ) || '.' ||
RPAD(:new.COUNTRY_CODE, 10, ' ' ) || '.' ||
LPAD(:new.SQUARE_FEET, 6, '0' ) || '.' ||
LPAD(:new.NUMBER_MOTHER_LAW_UNITS, 6, '0' ) || '.' ||
TO_CHAR(:new.YEAR_BUILT, 'YYYYMMDD') || '.' ||
LPAD(:new.PROPERTY_VALUE, 12, '0' ) || '.' ||
RPAD(:new.ZIP_PLUS_4, 4, ' ' ) || '.' ||
RPAD(:new.SFI_REQ_FLAG, 1, ' ' ) || '.' ||
TO_CHAR(:new.LAST_MODIFIED, 'YYYYMMDD') || '.' ||
RPAD(:new.LAST_MODIFIED_BY, 31, ' ' ) || '.' ||
RPAD(:new.STANDARDIZED_STATUS, 10, ' ' ) || '.' ||
RPAD(:new.STANDARDIZED_DESC, 200, ' ' );
tcode := 'U';
end if;
ls_sql :='
INSERT INTO AUDIT_LOG
( seq_no,
table_name,
user_stamp,
time_stamp,
tran_code,
record1,
record2)
VALUES
( :id,
:s_table_name,
:s_user_name,
:d_sysdate,
:s_tcode,
:s_rec1,
:s_rec2
)';
EXECUTE IMMEDIATE ls_sql
USING ln_seq_id,
'PROPERTY',
user,
sysdate,
tcode,
rec1,
rec2;
end;
Your suggestion is highly appreciated ..
Edited by: Bipul on Sep 23, 2010 12:40 AM