Forum Stats

  • 3,838,084 Users
  • 2,262,326 Discussions
  • 7,900,498 Comments

Discussions

calling spool file and generated .sql file from a procedure/package

519811
519811 Member Posts: 24
edited Sep 18, 2008 1:38AM in SQL & PL/SQL
i found this code to disable all constraints.

set feedback off
set verify off
set echo off
prompt Finding constraints to disable...
set termout off
set pages 80
set heading off
set linesize 120
spool tmp_disable.sql;
select 'spool igen_disable.log;' from dual;
select 'ALTER TABLE '||substr(c.table_name,1,35)||
' DISABLE CONSTRAINT '||constraint_name||' ;'
from user_constraints c, user_tables u
where c.table_name = u.table_name;
--and c.constraint_type IN ('P','R','U');
select 'exit;' from dual;
set termout on
prompt Disabling constraints now...
set termout off
@tmp_disable.sql;
exit
/

however, there are other procedures that shall be done after disabling the constraints. I want to put them in one package. How do I call this from a procedure? When I tried to simply enclose it in a PROCEDURE format, the spool file command is not recognized. It returned error message. Hope anyone can help me with this. Thanks in advance.
Tagged:

Answers

  • BluShadow
    BluShadow Member, Moderator Posts: 42,121 Red Diamond
    The majority of those commands are SQL*Plus commands. That means that they are specific to SQL*Plus and are not part of SQL or PL/SQL which is what you write your procedures/packages with.

    Tell us more about what you are trying to achieve and we can advise the best way, because this may be that you put everything in a procedure and code the requirements to generate output or you put everything in a script and execute it via a job etc.
  • 221158
    221158 Member Posts: 154
    You can include the select statement in a cursor within a database procedure and use dynamic SQL (execute immediate to execute the DDL).

    Christopher Soza
    Oracle BI DBA
    Orix Consultancy Services Ltd
    b: http://sozaman.blogspot.com
  • 519811
    519811 Member Posts: 24
    The system setup is that from Oracle 10g database, data will be copied to locally deployed Oracle XE databases. In order to do that, tables in Oracle XE should be truncated. But before truncating the table, constraints should be disabled first.Then after inserting records from Oracle 10g, constraints shall be enabled again.

    I hope you could help me with this one. Thanks in advance.
  • Marwim
    Marwim Member Posts: 3,651 Gold Trophy
    edited Sep 18, 2008 1:38AM
    Hello sidkaterin,

    here is a package I use for development. Never give access to this package to a normal user!

    Regards
    Marcus
    CREATE OR REPLACE PACKAGE  my_trunc
    IS
    PROCEDURE disable_triggers;
    PROCEDURE enable_triggers;
    PROCEDURE disable_constraints;
    PROCEDURE enable_constraints;
    PROCEDURE truncate_table(p_tabelle IN VARCHAR2);
    
    END my_trunc;
    /
    
    CREATE OR REPLACE PACKAGE BODY my_trunc
    IS
    
    PROCEDURE disable_triggers
    IS
        cur_name                INTEGER;
        rows_processed          INTEGER;
    BEGIN
        cur_name := dbms_sql.open_cursor;
        FOR c_trg IN(
            SELECT  'ALTER TRIGGER ' || trigger_name || ' DISABLE ' stmnt
            FROM    user_triggers
            )
        LOOP
            dbms_sql.parse (
                     cur_name
                    ,c_trg.stmnt
                    ,dbms_sql.v7
                    );
            rows_processed := dbms_sql.execute (cur_name);
        END LOOP;
        dbms_sql.close_cursor (cur_name);
    EXCEPTION
        WHEN OTHERS THEN
            dbms_sql.close_cursor (cur_name);
            RAISE_APPLICATION_ERROR (
                     -20999
                    ,'Disable Trigger: '||SUBSTR(SQLERRM, 1, 100));
    END disable_triggers;
    
    PROCEDURE enable_triggers
    IS
        cur_name                INTEGER;
        rows_processed          INTEGER;
    BEGIN
        cur_name := dbms_sql.open_cursor;
        FOR c_trg IN (
            SELECT  'ALTER TRIGGER ' || trigger_name || ' ENABLE ' stmnt
            FROM    user_triggers
            )
        LOOP
            dbms_sql.parse (
                     cur_name
                    ,c_trg.stmnt
                    ,dbms_sql.v7
                    );
            rows_processed := dbms_sql.execute (cur_name);
        END LOOP;
        dbms_sql.close_cursor (cur_name);
    EXCEPTION
        WHEN OTHERS THEN
            dbms_sql.close_cursor (cur_name);
            RAISE_APPLICATION_ERROR (
                     -20999
                    ,'Enable Trigger: '||SUBSTR(SQLERRM, 1, 100)
                    );
    END enable_triggers;
    
    PROCEDURE disable_constraints
    IS
        cur_name                INTEGER;
        rows_processed          INTEGER;
    BEGIN
    
        cur_name := dbms_sql.open_cursor;
        FOR c_con IN (
            SELECT  'ALTER TABLE ' || table_name || ' DISABLE CONSTRAINT ' || constraint_name || ' ' stmnt
            FROM    user_constraints
            WHERE   constraint_type = 'R'
            )
        LOOP
            dbms_sql.parse (
                     cur_name
                    ,c_con.stmnt
                    ,dbms_sql.v7
                    );
            rows_processed := dbms_sql.execute (cur_name);
        END LOOP;
        dbms_sql.close_cursor (cur_name);
    
        cur_name := dbms_sql.open_cursor;
        FOR c_con IN (
            SELECT  'ALTER TABLE ' || table_name || ' DISABLE CONSTRAINT ' || constraint_name || ' ' stmnt
            FROM    user_constraints
            WHERE   constraint_type != 'R'
            )
        LOOP
            dbms_sql.parse (
                     cur_name
                    ,c_con.stmnt
                    ,dbms_sql.v7
                    );
            rows_processed := dbms_sql.execute (cur_name);
        END LOOP;
        dbms_sql.close_cursor (cur_name);
    
    EXCEPTION
        WHEN OTHERS THEN
            dbms_sql.close_cursor (cur_name);
            RAISE_APPLICATION_ERROR (
                     -20999
                    ,'Disable Constraints: '||
                     SUBSTR(SQLERRM, 1, 100)
                    );
    END disable_constraints;
    
    PROCEDURE enable_constraints
    IS
        cur_name                INTEGER;
        rows_processed          INTEGER;
    BEGIN
    
        cur_name := dbms_sql.open_cursor;
        FOR c_con IN (
            SELECT  'ALTER TABLE ' || table_name || ' ENABLE CONSTRAINT ' || constraint_name || ' ' stmnt
            FROM    user_constraints
            WHERE   constraint_type != 'R'
            )
        LOOP
            dbms_sql.parse (
                     cur_name
                    ,c_con.stmnt
                    ,dbms_sql.v7
                    );
            rows_processed := dbms_sql.execute (cur_name);
        END LOOP;
        dbms_sql.close_cursor (cur_name);
    
        cur_name := dbms_sql.open_cursor;
        FOR c_con IN (
            SELECT  'ALTER TABLE ' || table_name || ' ENABLE CONSTRAINT ' || constraint_name || ' ' stmnt
            FROM    user_constraints
            WHERE   constraint_type = 'R'
            )
        LOOP
            dbms_sql.parse (
                     cur_name
                    ,c_con.stmnt
                    ,dbms_sql.v7
                    );
            rows_processed := dbms_sql.execute (cur_name);
        END LOOP;
        dbms_sql.close_cursor (cur_name);
    
    EXCEPTION
        WHEN OTHERS THEN
            dbms_sql.close_cursor (cur_name);
            RAISE_APPLICATION_ERROR (
                     -20999
                    ,'Enable Constraints: '||
                     SUBSTR(SQLERRM, 1, 100)
                    );
    END enable_constraints;
    
    PROCEDURE truncate_table
        (
         p_tabelle              IN VARCHAR2
        )
    IS
        cur_name                INTEGER;
        v_statement             VARCHAR2(500);
        rows_processed          INTEGER;
    BEGIN
        v_statement     := 'TRUNCATE TABLE ' || p_tabelle || ' ';
        cur_name        := dbms_sql.open_cursor;
        dbms_sql.parse (
                 cur_name
               ,v_statement
                ,dbms_sql.v7
                );
        rows_processed  := dbms_sql.execute (cur_name);
        dbms_sql.close_cursor (cur_name);
    EXCEPTION
        WHEN OTHERS THEN
            dbms_sql.close_cursor (cur_name);
            RAISE_APPLICATION_ERROR (
                     -20999
                    ,'Truncate Table ' || p_tabelle || ': ' ||
                    SUBSTR(SQLERRM, 1, 100)
                    );
    END truncate_table;
    
    END my_trunc;
    /
    SHO ERR
    Edited by: Marwim on 18.09.2008 07:33
    Replaced lessThan greaterThan with != because using code-markup does not hinder the forum software from changing the characters.
  • 519811
    519811 Member Posts: 24
    Thank you. I can review this and maybe would revise a few statements to fit my requirements.
  • 247514
    247514 Member Posts: 10,875 Bronze Trophy
    sidkaterin wrote:
    set feedback off
    set verify off
    set echo off
    prompt Finding constraints to disable...
    set termout off
    set pages 80
    set heading off
    set linesize 120
    spool tmp_disable.sql;
    select 'spool igen_disable.log;' from dual;
    select 'ALTER TABLE '||substr(c.table_name,1,35)||
    ' DISABLE CONSTRAINT '||constraint_name||' ;'
    from user_constraints c, user_tables u
    where c.table_name = u.table_name;
    --and c.constraint_type IN ('P','R','U');
    select 'exit;' from dual;
    set termout on
    prompt Disabling constraints now...
    set termout off
    @tmp_disable.sql;
    Or run your procedure here.
    exec myprocedure ;
    exit
    /

    however, there are other procedures that shall be done after disabling the constraints. I want to put them in one package. How do I call this from a procedure? When I tried to simply enclose it in a PROCEDURE format, the spool file command is not recognized. It returned error message. Hope anyone can help me with this. Thanks in advance.
This discussion has been closed.