Results 1 to 7 of 7
  1. #1
    Join Date
    Apr 2002
    Location
    USA-CA
    Posts
    36

    Unanswered: question about sequences

    Hello,

    I have some question about sequencies.
    I write the following package in Oracle 9i
    and it complains about sequence:

    create or replace procedure Run_Me as

    run_dt date := '01-Jan-2004';

    begin

    EXECUTE IMMEDIATE('drop sequence sq1');

    EXECUTE IMMEDIATE('CREATE SEQUENCE sq1
    INCREMENT BY 1
    START WITH 1
    NOMAXVALUE
    NOCYCLE
    CACHE 10');

    update pscnv_products_in pi
    set pi.rec_source = 'IN'
    ;

    update pscnv_products_net nt
    set nt.rec_source = 'NT'
    ;

    insert into pscnv_products
    select pi.*, sq1.nextval, run_dt, '', '' from pscnv_products_in pi;
    ^
    sequence doesnot exist
    ORA - 02289


    insert into pscnv_products
    select nt.*, sq1.nextval, run_dt, '', '' from pscnv_products_net nt
    ;

    end ;

    How to fix it?

    Thanks in advance.

    John.
    John Smith

  2. #2
    Join Date
    Aug 2003
    Location
    Where the Surf Meets the Turf @Del Mar, CA
    Posts
    7,776
    Provided Answers: 1
    You can lead some folks to knowledge, but you can not make them think.
    The average person thinks he's above average!
    For most folks, they don't know, what they don't know.
    Good judgement comes from experience. Experience comes from bad judgement.

  3. #3
    Join Date
    Jan 2004
    Location
    Croatia, Europe
    Posts
    4,094
    Provided Answers: 4
    Sequence "sq1" is unknown during compilation. If it existed before trying to compile the procedure, it would be OK. That is, if you had something like this code below, you wouldn't encounter such an error:
    Code:
    create sequence sq1;
    
    create or replace procedure run_me as
    /* your code in here */
    end;
    /

  4. #4
    Join Date
    Apr 2004
    Posts
    246
    Why are you bothering with a sequence - it has no place in what you're doing. Sequences are meant to stay there, across transactions, so multiple sessions can access them, and be guaranteed unique number. Try this:

    insert into pscnv_products
    select pi.*, rownum, run_dt, '', '' from pscnv_products_in pi;

    last_num := sql%rowcount;

    insert into pscnv_products
    select nt.*, last_num + rownum, run_dt, '', '' from pscnv_products_net nt;
    Give a man a fish, you feed him for a day. Club him over the head with a fish, he'll leave you alone.

  5. #5
    Join Date
    Apr 2002
    Location
    USA-CA
    Posts
    36

    Whether is some way inside PL/SQL procedure to check if (Sequence "sq1" exist) then..

    Sequence "sq1" is unknown during compilation. If it existed before trying to compile the procedure, it would be OK. That is, if you had something like this code below, you wouldn't encounter such an error:

    Thanks. I see.

    Whether is some way inside PL/SQL procedure to check

    if (Sequence "sq1" exist)
    then
    ...
    end

    ?

    Thanks in advance.

    John.
    John Smith

  6. #6
    Join Date
    Jan 2004
    Location
    Croatia, Europe
    Posts
    4,094
    Provided Answers: 4
    I think not ... but, you could write your own function to check (any) sequence existence.
    Code:
    create or replace function seq_exists
      (par_seq_name user_sequences.sequence_type%type)
      return boolean 
      is
      l_count number(1);
    begin
      select count(*) into l_count
      from user_sequences
      where sequence_name = upper(par_seq_name);
    
      if l_count = 1 then
         return true;
      else
         return false;
      end if;
    end;
    /
    Then, your PL/SQL block which will be used to check sequence's existence would be
    Code:
    begin
      if seq_exists('SQ1')
      then
         dbms_output.put_line('It exists');
      else
         dbms_output.put_line('It does not exist');
      end if;
    end;
    /

  7. #7
    Join Date
    May 2004
    Location
    Dominican Republic
    Posts
    721
    I would rather handle it with exceptions:

    Code:
    SQL> set serveroutput on
    SQL> ed
    Wrote file afiedt.buf
    
      1  declare
      2   errorfound exception;
      3   pragma exception_init(errorfound,-02289);
      4  begin
      5   execute immediate 'drop sequence sq1';
      6   dbms_output.put_line('Sequence deleted.');
      7  exception
      8   when errorfound then
      9     dbms_output.put_line('Sequence doesn''t exists.');
     10* end;
    SQL> /
    Sequence doesn't exists.
    
    PL/SQL procedure successfully completed.
    
    SQL> create sequence sq1;
    
    Sequence created.
    
    SQL> declare
      2   errorfound exception;
      3   pragma exception_init(errorfound,-02289);
      4  begin
      5   execute immediate 'drop sequence sq1';
      6   dbms_output.put_line('Sequence deleted.');
      7  exception
      8   when errorfound then
      9     dbms_output.put_line('Sequence doesn''t exists.');
     10  end;
     11  /
    Sequence deleted.
    
    PL/SQL procedure successfully completed.
    
    SQL>

Posting Permissions

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