×
INTELLIGENT WORK FORUMS
FOR COMPUTER PROFESSIONALS

Log In

Come Join Us!

Are you a
Computer / IT professional?
Join Tek-Tips Forums!
  • Talk With Other Members
  • Be Notified Of Responses
    To Your Posts
  • Keyword Search
  • One-Click Access To Your
    Favorite Forums
  • Automated Signatures
    On Your Posts
  • Best Of All, It's Free!
  • Students Click Here

*Tek-Tips's functionality depends on members receiving e-mail. By joining you are opting in to receive e-mail.

Posting Guidelines

Promoting, selling, recruiting, coursework and thesis posting is forbidden.

Students Click Here

Jobs

Trigger -
2

Trigger -

Trigger -

(OP)
Hi,

I have a trigger which fires on change in certain fields & inserts the old field data in a history table.
If the field has value (e.g.college name) & I replace it with null, a record is inserted with the member id in the history table but the old value (college name) is not inserted. This happens with any of fields. Please find below the code. This happens only if the field data is blank/null.
for e.g. if the college ADD1 has data "12th Street, Mumbai" & while updating the field, I blank it/remove "12th Street, Mumbai". So it has to update the history table with "12th Street, Mumbai" but it doesn't - inserts a record in the history table with member id. What changes do I need to do to get the old value updated in the history table.

-----------------------------------------------------
create or replace trigger "TGR_STUDENT_MST_CHG"
before Update or Insert of
MEMBER_ID,
COLLEGE_NAME,
COLLEGE_ADD1,
on T_STUDENT_MST
for each row

declare

VCOLLEGENAME t_student_mst.COLLEGE_NAME%type;
VCOLLEGEADD1 t_student_mst.COLLEGE_ADD1%type;

begin

if (:old.COLLEGE_NAME <> :new.COLLEGE_NAME) then
VCOLLEGENAME := :old.COLLEGE_NAME ;
else VCOLLEGENAME := null ;
end if;

if (:OLD.COLLEGE_ADD1 <> :NEW.COLLEGE_ADD1) then
VCOLLEGEADD1 := :OLD.COLLEGE_ADD1;
else VCOLLEGEADD1 := null ;
end if;

if updating then
insert into T_STUDENT_HST (
MEMBER_ID,
COLLEGE_NAME,
COLLEGE_ADD1)

values (:old.member_id,
VCOLLEGENAME,
VCOLLEGEADD1);

end if ;

end TGR_STUDENT_MST_CHG;
---------------------------------------------


TIA,
Raj

RE: Trigger -

Just a guess here, but I would be very tempted to try:

if (:OLD.COLLEGE_ADD1 <> :NEW.COLLEGE_ADD1) 
    OR (:NEW.COLLEGE_ADD1 IS NULL) then
   VCOLLEGEADD1 := :OLD.COLLEGE_ADD1;
else VCOLLEGEADD1 := null ;
end if;
 


---- Andy

There is a great need for a sarcasm font.

RE: Trigger -

(OP)
Thanx Andy, it did work smile

RE: Trigger -

Great! I'm glad it works for you.
Like one of my teachers said: "Nothing equals to NULL, not even a NULL".
That's why equating or comparing anything with NULLs are tricky.


---- Andy

There is a great need for a sarcasm font.

RE: Trigger -

This is how I would do it. Since you are only doing anything on update, do not fire on insert.

CODE

CREATE OR REPLACE TRIGGER "TGR_STUDENT_MST_CHG"
    BEFORE UPDATE OF Member_id, College_name, College_add1
    ON T_student_mst
    FOR EACH ROW

DECLARE
    Vcollegename   T_student_mst.College_name%TYPE;
    Vcollegeadd1   T_student_mst.College_add1%TYPE;
BEGIN
    Vcollegename := NULL;
    Vcollegeadd1 := NULL;

    IF NVL (:old.College_name, '  ') <> NVL (:new.College_name, '  ')
    THEN
        Vcollegename := :old.College_name;
    END IF;

    IF NVL (:old.College_add1, '  ') <> NVL (:new.College_add1, '  ')
    THEN
        Vcollegeadd1 := :old.College_add1;
    END IF;

    INSERT INTO T_student_hst (Member_id, College_name, College_add1)
         VALUES (:old.Member_id, Vcollegename, Vcollegeadd1);
END Tgr_student_mst_chg; 

Bill
Lead Application Developer
New York State, USA

RE: Trigger -

(OP)
Thanks Beilstwh.

Red Flag This Post

Please let us know here why this post is inappropriate. Reasons such as off-topic, duplicates, flames, illegal, vulgar, or students posting their homework.

Red Flag Submitted

Thank you for helping keep Tek-Tips Forums free from inappropriate posts.
The Tek-Tips staff will check this out and take appropriate action.

Reply To This Thread

Posting in the Tek-Tips forums is a member-only feature.

Click Here to join Tek-Tips and talk with other members! Already a Member? Login

Close Box

Join Tek-Tips® Today!

Join your peers on the Internet's largest technical computer professional community.
It's easy to join and it's free.

Here's Why Members Love Tek-Tips Forums:

Register now while it's still free!

Already a member? Close this window and log in.

Join Us             Close