Monday, March 19, 2012

SQLPLUS COPY Command to copy tables across/within DB, useful for LONG data types.

Tables with LONG data type cannot be moved or copied to/from one tablespace/schema/database to another tablespace/schema/database using CTAS or even sql INSERT statement. It would fail with below error:
ORA-00997: illegal use of LONG datatype

So whats the solution. Either you could do export/import or sqlplus COPY command.It works like a charm. Here is a demonstration how I failed and how sqlplus COPY helped!!
Creating a table with LONG datatype.
SQL> create table copy_example (col1 varchar2(10), col2 long);
Table created.

SQL> insert into copy_example values ('11','10000000000000000000000000000000000000000000000000');
1 row created.

SQL> commit;
Commit complete.

Trying to CTAS:
SQL> create table copy_example_2 as select * from copy_example;
create table copy_example_2 as select * from copy_example
                                      *
ERROR at line 1:
ORA-00997: illegal use of LONG datatype

Then Tried doing INSERT to pull LONG datatype to a different table:
SQL> create table copy_example_2 (col1 varchar2(10), col2 long);
Table created.

SQL> insert into copy_example_2 select * from copy_example;
insert into copy_example_2 select * from copy_example
                                  *
ERROR at line 1:
ORA-00997: illegal use of LONG datatype

Failing too!!!
Lets see how SQLPLUS COPY command works then. You can copy tables between two databases. I’m using here same database names, you can use it for different databases as long as you have TNS entry on the source box.
Copy command support only CHAR, DATE, LONG, NUMBER andVARCHAR2 data types. It does not support any new data types.

SQL> drop table copy_example_2;
Table dropped.

SQL> copy from scott/tiger@LAB  to scott/tiger@LAB create copy_example_2 using select * from copy_example;

Array fetch/bind size is 15. (arraysize is 15)
Will commit when done. (copycommit is 0)
Maximum long size is 80. (long is 80)
Table COPY_EXAMPLE_2 created.

   1 rows selected from scott@lab
   1 rows inserted into COPY_EXAMPLE_2.
   1 rows committed into COPY_EXAMPLE_2 at lab@lab

SQL> select * from system.copy_example_2;

COL1       COL2
---------- --------------------------------------------------------------------------------
11         10000000000000000000000000000000000000000000000000

Everything copied over!!! J

Thursday, March 15, 2012

Create Oracle Directories for as-is database creation.


On several situations we need to mimick database to lab environments. And to create directories as-is of the source database; found this cool query that can generate all related directory structure creation linux command for us.

select distinct dir from (
select 'mkdir -p '||regexp_replace(fname,'(^.*)/[^/]*$','\1') dir
from (
select name fname from v$controlfile
union all
select name from v$datafile
union all
select name from v$tempfile
union all
select member from v$logfile
)
union all
select 'mkdir -p '||value dir from v$parameter where isdefault='FALSE' and type=2 and not value like '%,%' and value like '/%'
)


Monday, March 12, 2012

RESULT_CACHE parameter 11g to improve query performance

Oracle 11g allows the results of SQL queries to be cached in the SGA and reused to improve performance. Set up the following schema objects to see how the SQL query cache works.
    CREATE TABLE test_tab (
      id  NUMBER
    );

    INSERT INTO test_tab VALUES (1);
    INSERT INTO test_tab VALUES (2);
    INSERT INTO test_tab VALUES (3);
    INSERT INTO test_tab VALUES (4);
    INSERT INTO test_tab VALUES (5);

    CREATE OR REPLACE FUNCTION slow_function(p_id  IN  test_tab.id%TYPE)
      RETURN test_tab.id%TYPE DETERMINISTIC AS
    BEGIN
      DBMS_LOCK.sleep(1);
      RETURN p_id;
    END;
    /
    SET TIMING ON

The function contains a one second sleep so we can easily detect if it has been executed by checking the elapsed time of the query.

Next, we query the test table using the slow function and check out the elapsed time. Each run takes approximately five seconds, one second sleep for each row queried.

    SELECT slow_function(id) FROM test_tab;
    SLOW_FUNCTION(ID)
    -----------------
                    1
                    2
                    3
                    4
                    5
    5 rows selected.
    Elapsed: 00:00:05.15 

Adding the RESULT_CACHE hint to the query tells the server to attempt to retrieve the information from the result cache. If the information is not present, it will cache the results of the query provided there is enough room in the result cache. Since we have no cached results, we would expect the first run to take approximately five seconds, but subsequent runs to be much quicker.

    SELECT /*+ result_cache */ slow_function(id) FROM test_tab;
    SLOW_FUNCTION(ID)
    -----------------
                    1
                    2
                    3
                    4
                    5

    5 rows selected.
    Elapsed: 00:00:05.20

    SELECT /*+ result_cache */ slow_function(id) FROM test_tab;
    SLOW_FUNCTION(ID)
    -----------------
                    1
                    2
                    3
                    4
                    5

    5 rows selected.
    Elapsed: 00:00:00.15

The default action of the result cache is controlled by the RESULT_CACHE_MODE parameter. When it is set to MANUAL, the RESULT_CACHE hint must be used for a query to access the result cache.
    SHOW PARAMETER RESULT_CACHE_MODE

    NAME                                 TYPE        VALUE
    ------------------------------------ ----------- ------------------------------
    result_cache_mode                    string      MANUAL   
If we set the RESULT_CACHE_MODE parameter to FORCE, the result cache is used by default, but we can bypass it using the NO_RESULT_CACHE hint.

    ALTER SESSION SET RESULT_CACHE_MODE=FORCE;

    SELECT slow_function(id) FROM test_tab;

    SLOW_FUNCTION(ID)
    -----------------
                    1
                    2
                    3
                    4
                    5

    5 rows selected.
    Elapsed: 00:00:00.14

    SELECT /*+ no_result_cache */ slow_function(id) FROM test_tab;
    SLOW_FUNCTION(ID)
    -----------------
                    1
                    2
                    3
                    4
                    5

    5 rows selected.
    Elapsed: 00:00:05.14

ORA-01548: active rollback segment '_SYSSMU1$' found, terminate dropping tablespace


While trying to recreate undotbs to flip with a new one , ran into this unseen error.
Created a new UNDO, made it the default UNDO for the database, now while trying to drop the old undo it fails with error Ora-01548 .
SQL> drop Tablespace UNDOTBS1;
drop Tablespace UNDOTBS
*
ERROR at line 1:
ORA-01548: active rollback segment '_SYSSMU1$' found, terminate dropping
tablespace
Cause of The Problem
An attempt was made to drop a tablespace that contains active rollback segments.

Solution:
 Following steps were performed:

1.    Figure out the rollback segments still occupying UNDOTBS1
SQL> select * from v$rollname ;
USN NAME
---------- ------------------------------
0 SYSTEM
18 _SYSSMU18_650722988$
19 _SYSSMU19_176786070$
20 _SYSSMU20_2971238361$
21 _SYSSMU21_1337078425$
22 _SYSSMU22_378998127$
23 _SYSSMU23_2828850578$
24 _SYSSMU24_3342375805$
25 _SYSSMU25_1071547613$
26 _SYSSMU26_357778769$
27 _SYSSMU27_3256159541$

2.    Create pfile if you started with database with spfile.
SQL>Create PFILE from SPFILE;

3.    Edit pfile and set undo management to manual.
undo_management = manual

4.    Put the entries of the undo segments in the pfile by using the following statement in the pfile:

_offline_rollback_segments=(_SYSSMU18_650722988$,_SYSSMU19_176786070$,_SYSSMU20_2971238361$,_SYSSMU21_1337078425$,_SYSSMU22_378998127$,_SYSSMU23_2828850578$,_SYSSMU24_3342375805$,_SYSSMU25_1071547613$,_SYSSMU26_357778769$,_SYSSMU27_3256159541$)

5.    Mount the database using new pfile.
Startup mount pfile='/$ORACLE_HOME/dbs/'

6.    Drop the datafiles,
sql>Alter Database datafile '&filename' offline drop;

7.    Open the database.
sql>Alter Database Open;

8.    Drop the undo segments,

sql>Drop Rollback Segment "_SYSSMU1$";
......
9.    Drop Old undo tablespace.
sql>Drop Tablespace old_tablespace_name Including Contents;

10. Add the new undo tablespace.

11. Shutdown Immediate;

12. Change the pfile parameters back to Undo_management = AUTO and modify the parameter Undo_tablespace=new_undo_tablespace_name and remove the _offline_rollback_segments parameter.

13. Startup the Database.