How to dynamically create and immediately use a sequence in PL/SQL code

I was recently approached by a developer who showed me a piece of code that raised ORA-06550 exception for “no apparent reason”. Here is a simplified version of that code:

DECLARE
    v_cnt NUMBER;
BEGIN
    SELECT COUNT(*) INTO v_cnt
    FROM user_sequences
    WHERE sequence_name='SEQ';

    IF v_cnt=0 THEN
       EXECUTE IMMEDIATE 'CREATE SEQUENCE seq START WITH 1 INCREMENT BY 1';
    END IF;

    DBMS_OUTPUT.PUT_LINE(seq.NEXTVAL);
END;

The logic behind this PL/SQL block is quite apparent: check if sequence “SEQ” exists; create it if it does not exist, and then (when it definitely exists) call its NEXTVAL attribute.

This code will only work if the sequence already exists before you run this block. If it does not exist, the code will not compile – it will not be executed at all, because the line “DBMS_OUTPUT.PUT_LINE(seq.NEXTVAL);” – references seq object that does not yet exist.

The fix is very simple – if you create the object dynamically, you can only reference it in dynamic SQL (or PL/SQL) in the same block:

DECLARE
    v_cnt NUMBER;
BEGIN
    SELECT COUNT(*) INTO v_cnt
    FROM user_sequences
    WHERE sequence_name='SEQ';

    IF v_cnt=0 THEN
       EXECUTE IMMEDIATE 'CREATE SEQUENCE seq START WITH 1 INCREMENT BY 1';
    END IF;

    EXECUTE IMMEDIATE 'BEGIN DBMS_OUTPUT.PUT_LINE(seq.NEXTVAL); END;';
END;

Note, that our dynamic PL/SQL is a block itself as it runs in its own context. If you try the following line, it will throw an exception:

EXECUTE IMMEDIATE 'DBMS_OUTPUT.PUT_LINE(seq.NEXTVAL);';
ORA-00900: invalid SQL statement ORA-06512: at line 10 ORA-06512: at "SYS.DBMS_SQL", line 1721
A lesson from this mistake is very simple and important so we shall repeat the rule:
If you create an object dynamically, you can only reference this object in dynamic SQL (or PL/SQL) in the same block.
This applies to all kinds of objects. For example, if you create a table in your procedure, you may only select from this table in dynamic SQL. If you dynamically add a column to a table, you can only update it in dynamic SQL, etc.

***

If you find this post useful, please press the LIKE button and subscribe.

My Oracle Group on Facebook:

Also, you may want to join my Oracle group on Facebook: https://www.facebook.com/groups/sqlpatterns/

Suggested Reading:

Would you like to read about many more tricks and puzzles? For more clever tricks and cool techniques check my book “Oracle SQL Tricks and Workarounds”.

Using SQL%ROWCOUNT with Dynamic PL/SQL

Using SQL%ROWCOUNT attribute when executing static or dynamic DML statement is very handy. Situation changes dramatically when you check this attribute after executing dynamic or static PL/SQL command:

Static PL/SQL

BEGIN
    NULL;
    dbms_output.put_line('Rowcount=' || SQL%ROWCOUNT);
END;
/

Result:

Rowcount=

Dynamic PL/SQL

BEGIN
    EXECUTE IMMEDIATE 'BEGIN NULL; END;';
    dbms_output.put_line('Rowcount=' || SQL%ROWCOUNT);
END;
/

Result:

Rowcount=1

Static PL/SQL “has” NULL as SQL%ROWCOUNT value while Dynamic PL/SQL – always “produces” 1, even if that dynamic PL/SQL does affect certain number of records in a table:

Dynamic SQL:

BEGIN
    EXECUTE IMMEDIATE 'DELETE FROM emp WHERE ROWNUM<=2';
    dbms_output.put_line('Rowcount=' || SQL%ROWCOUNT);
    ROLLBACK;
END;
/

Result:

Rowcount=2

Same command in Dynamic PL/SQL:

BEGIN
    EXECUTE IMMEDIATE 'BEGIN DELETE FROM emp WHERE ROWNUM<=2; END;';
    dbms_output.put_line('Rowcount=' || SQL%ROWCOUNT);
    ROLLBACK;
END;
/

Result:

Rowcount=1

Sometimes, we have to use dynamic PL/SQL so getting correct number of affected rows may be critical. Here is a simple but effective solution:

DECLARE
    v_cnt NUMBER;
BEGIN
    EXECUTE IMMEDIATE 'BEGIN 
                           DELETE FROM emp WHERE ROWNUM<=2; 
                           :0:=SQL%ROWCOUNT; 
                       END;'  USING OUT v_cnt;
    dbms_output.put_line('Rowcount=' || v_cnt);
    ROLLBACK;
END;
/

Result:

Rowcount=2

We use bind variable in the OUT mode to get the result of STATIC SQL inside of

DYNAMIC PL/SQL.

 

My Oracle Group on Facebook:

If you like this post, you may want to join my new Oracle group on Facebook: https://www.facebook.com/groups/sqlpatterns/

Would you like to read about many more tricks and puzzles?

For more tricks and cool techniques check my book “Oracle SQL Tricks and Workarounds”.

How to bind IN and OUT parameters in PL/SQL

Suppose that you need to execute dynamic PL/SQL, a stored procedure, with one in and one out parameter:

CREATE OR REPLACE PROCEDURE scott.get_emp_count(p_deptno IN NUMBER, p_count OUT NUMBER)
AS
BEGIN
    SELECT COUNT(*) INTO p_count
    FROM emp
    WHERE deptno=p_deptno;
END get_emp_count;

Now we want to call it in SQL*Plus as follows:

DECLARE
   v_sql VARCHAR2(2000);
   v_count NUMBER;
   v_deptno NUMBER:=10;
BEGIN
   v_sql:='CALL get_emp_count(:0, :1)';
   EXECUTE IMMEDIATE v_sql USING v_deptno, v_count;

   DBMS_OUTPUT.PUT_LINE(v_count);
END;
/
*
ERROR at line 1:
ORA-06536: IN bind variable bound to an OUT position
ORA-06512: at line 7

To make it work we need to use OUT keyword before v_count variable:

DECLARE
   v_sql VARCHAR2(2000);
   v_count NUMBER;
   v_deptno NUMBER:=10;
BEGIN
   v_sql:='CALL get_emp_count(:0, :1)';
   EXECUTE IMMEDIATE v_sql USING v_deptno, OUT v_count;

   DBMS_OUTPUT.PUT_LINE(v_count);
END;
/
3

PL/SQL procedure successfully completed.

Bind parameter mode is similar to a parameter mode in a stored procedure – IN is the default and we don’t have to use it, though we can:

  1  DECLARE
  2     v_sql VARCHAR2(2000);
  3     v_count NUMBER;
  4     v_deptno NUMBER:=10;
  5  BEGIN
  6     v_sql:='CALL get_emp_count(:0, :1)';
  7     EXECUTE IMMEDIATE v_sql USING IN v_deptno, OUT v_count;
  8     DBMS_OUTPUT.PUT_LINE(v_count);
  9* END;
SQL> /
3

PL/SQL procedure successfully completed.

This technique is useful when you don’t know the name of the stored procedure to be executed with EXECUTE IMMEDIATE statement in advance, though you know the parameters.

For more tricks and cool techniques check my book “Oracle SQL Tricks and Workarounds” for instructions.

Privileges needed to create spatial index in dynamic SQL

Executing DDL commands explicitly or with EXECUTE IMMEDIATE statement usually require special privileges granted directly (not as a part of a ROLE). With creating tables and indexes, things are really simple, you just need to grant CREATE TABLE privilege and that’s it.

When you need to create a special index, such as SPATIAL index, it is not obvious which privileges need to be granted.

Symptoms of the problem:

SQL> BEGIN
  2      EXECUTE IMMEDIATE 'CREATE INDEX idx_poi_geometry ON poi_geometry(geom) INDEXTYPE IS MDSYS.SPATIAL_INDEX';
  3  END;
  4  /
BEGIN
*
ERROR at line 1:
ORA-29855: error occurred in the execution of ODCIINDEXCREATE routine
ORA-13249: internal error in Spatial index: [mdidxrbd]
ORA-13249: Error in Spatial index: index build failed
ORA-13249: Error in R-tree: [mdrcrtscrt]
ORA-13231: failed to create index table [MDRT_2942E$] during R-tree creation
ORA-13249: Stmt-Execute Failure: CREATE TABLE "SCOTT".MDRT_2942E$
(NODE_ID NUMBER, NODE_LEVEL NUMBER, INFO BLOB)  LOB (INFO) STORE AS (NOCACHE)
PCTFREE 2
ORA-29400: data cartridge error
ORA-01950: no privileges on tablespace 'USERS'
ORA-06512: at "MDSYS.SDO_INDEX_METHOD_10I", line 10
ORA-06512: at line 2


Elapsed: 00:00:00.07

Note, that even though the statement failed, Oracle created an object, so before retrying you need to drop it:

SQL> DROP INDEX idx_poi_geometry;

Index dropped.

From the error message, we can conclude that there is something wrong with the tablespace privileges.
And this is not something dynamic SQL specific as the plain DDL command fails with the same error:

SQL> CREATE INDEX idx_poi_geometry ON poi_geometry(geom) INDEXTYPE IS MDSYS.SPATIAL_INDEX;
CREATE INDEX idx_poi_geometry ON poi_geometry(geom) INDEXTYPE IS MDSYS.SPATIAL_INDEX
*
ERROR at line 1:
ORA-29855: error occurred in the execution of ODCIINDEXCREATE routine
ORA-13249: internal error in Spatial index: [mdidxrbd]
ORA-13249: Error in Spatial index: index build failed
ORA-13249: Error in R-tree: [mdrcrtscrt]
ORA-13231: failed to create index table [MDRT_29430$] during R-tree creation
ORA-13249: Stmt-Execute Failure: CREATE TABLE "SCOTT".MDRT_29430$
(NODE_ID NUMBER, NODE_LEVEL NUMBER, INFO BLOB)  LOB (INFO) STORE AS (NOCACHE)
PCTFREE 2
ORA-29400: data cartridge error
ORA-01950: no privileges on tablespace 'USERS'
ORA-06512: at "MDSYS.SDO_INDEX_METHOD_10I", line 10

After granting UNLIMITED TABLESPACE privilege:

SQL> DROP INDEX idx_poi_geometry;

Index dropped.

Elapsed: 00:00:00.04
SQL> CREATE INDEX idx_poi_geometry ON poi_geometry(geom) INDEXTYPE IS MDSYS.SPATIAL_INDEX;

Index created.

Elapsed: 00:00:05.98

Dynamic SQL also works:

SQL> DROP INDEX idx_poi_geometry;

Index dropped.

Elapsed: 00:00:00.36
SQL> BEGIN
  2      EXECUTE IMMEDIATE 'CREATE INDEX idx_poi_geometry ON poi_geometry(geom) INDEXTYPE IS MDSYS.SPATIAL_INDEX';
  3  END;
  4  /

PL/SQL procedure successfully completed.

Elapsed: 00:00:06.08

A tricky part comes when you try to execute this dynamic SQL wrapped into a packaged procedure call made by a different user:

SQL> BEGIN
  2      EXECUTE IMMEDIATE 'BEGIN scott.pkg_indexes.create_spatial_index; END;';
  3  END;
  4  /
ORA-29855: error occurred in the execution of ODCIINDEXCREATE routine
ORA-13249:
internal error in Spatial index: [mdidxrbd]
ORA-13249: Error in Spatial index:
index build failed
ORA-13249: Error in R-tree: [mdrcrtscrt]
ORA-13231: failed to
create index table [MDRT_29480$] during R-tree creation
ORA-13249: Stmt-Execute
Failure: CREATE TABLE "SCOTT".MDRT_29480$ (NODE_ID NUMBER, NODE_LEVEL
NUMBER, INFO BLOB)  LOB (INFO) STORE AS (NOCACHE)  PCTFREE 2
ORA-29400:
data cartridge error
ORA-01031: in

PL/SQL procedure successfully completed.

Now it’s time to grant more privileges (as a SYSTEM USER):

SQL> GRANT CREATE TABLE, CREATE SEQUENCE TO scott
  2  /

Grant succeeded.

Now let’s execute last dynamic PL/SQL again (the packaged procedure create_spatial_index includes drop index command, so we should not worry about it):

SQL> BEGIN
  2      EXECUTE IMMEDIATE 'BEGIN scott.pkg_indexes.create_spatial_index; END;';
  3  END;
  4  /

PL/SQL procedure successfully completed.

Elapsed: 00:00:39.67

Summary:

To successfully create a spatial index in dynamic SQL (or dynamic PL/SQL), the owner of the index may need the following privileges granted explicitly:

  • UNLIMITED TABLESPACE
  • CREATE TABLE
  • CREATE SEQUENCE