DBAsupport.com Forums - Powered by vBulletin
Results 1 to 5 of 5

Thread: help with pl/sql

  1. #1
    Join Date
    Nov 2000
    Posts
    205
    Hello there,

    I need help with the following:

    I need to write a stored procedure to:

    There are two tables CAT and CAT_REL
    (only listing impt fields)

    CAT has (id, child_count)
    CAT_REL has (parent_cat_id)

    I want to count (*) from CAT_REL, where CAT.id = CAT_REL.parent_cat_id) and compare it to the CAT.child_count field and ensure that they are the same, if not update CAT.id to be set to this.

    eg,
    CAT
    id child_count
    1 4
    2 3

    CAT_REL
    parent_cat_id some_other_field
    1 assas
    1 rwer
    1 fsdfsd
    1 ds
    2 sdfds
    2 fdf
    2 ewa

    id is unique in CAT table and the child_count is meant to store the number of records in the CAT_REL table per id.

    I have pathetic knowledge in PL/SQL so any help would be appreciated.

    thanks in advance,
    Nirasha

  2. #2
    Join Date
    Nov 2000
    Location
    greenwich.ct.us
    Posts
    9,092
    Perfect place for a trigger. Create a trigger on CAT_REL and unconditionally update CAT after insert.
    Jeff Hunter

  3. #3
    Join Date
    Jan 2001
    Posts
    28
    Remember to have the trigger for a delete as well.
    - Mayur.

  4. #4
    Join Date
    Nov 2000
    Posts
    205
    Thanks, I actually thought of that and spoke to the dev guys but they have code to cater for it, this is for the exceptional cases.

    I need it and really need your help.

    Thanks,
    Nirasha

  5. #5
    Join Date
    Jan 2001
    Posts
    28
    Try this out Nirasha,

    declare

    cursor cur_cat is
    select id, child_count
    from cat
    FOR UPDATE OF child_count
    order by id;

    v_count NUMBER;

    BEGIN
    FOR v_rec IN cur_cat LOOP
    SELECT COUNT(*) INTO v_count
    FROM cat_rel
    WHERE parent_cat_id = v_rec.id;

    IF v_rec.child_count <> v_count THEN
    UPDATE cat
    SET child_count = v_count
    WHERE CURRENT OF cur_cat;
    END IF;
    END LOOP;
    END;
    /
    - Mayur.

Posting Permissions

  • You may not post new threads
  • You may not post replies
  • You may not post attachments
  • You may not edit your posts
  •  


Click Here to Expand Forum to Full Width