Print the result of a cursor in Oracle PL/SQL

While developing Oracle PL/SQL code, sometimes one needs to debug via the old way, using DBMS_OUTPUT.PUT_LINE or inserting data into a table for a later inspection.
But when working with cursors, this is not an easy task, specially if one does not know the real output of the cursor when using dynamic SQL or simply because the cost of writing a specific output for each cursor one needs to evaluate is too high.

In order to aid this task, here’s a procedure that will print out the result of any cursor. By default, it will print the first 10 rows, but to print the entire result, just call the PRINT_CURSOR procedure with the v_maxRows = 0.

create or replace
PROCEDURE PRINT_CURSOR (
    p_refcursor IN OUT SYS_REFCURSOR, v_maxRows IN NUMBER default 10 )
AS
  v_desc DBMS_SQL.DESC_TAB;
  v_cols BINARY_INTEGER;
  v_cursor BINARY_INTEGER;
  v_varchar2 VARCHAR2(4000);
  v_number   NUMBER;
  v_date     DATE;
  v_data     VARCHAR2(32767);
  v_curRow   NUMBER;
BEGIN
  /* Convert refcursor "parameter" to DBMS_SQL cursor... */
  v_cursor := DBMS_SQL.TO_CURSOR_NUMBER(p_refcursor);
  /* Describe the cursor... */
  DBMS_SQL.DESCRIBE_COLUMNS(v_cursor, v_cols, v_desc);
  /* Define columns to be fetched. We're only using V2, NUM, DATE for example... */
  FOR i IN 1 .. v_cols
  LOOP
    IF v_desc(i).col_type = 2 THEN
      DBMS_SQL.DEFINE_COLUMN(v_cursor, i, v_number);
    ELSIF v_desc(i).col_type = 12 THEN
      DBMS_SQL.DEFINE_COLUMN(v_cursor, i, v_date);
    ELSE
      DBMS_SQL.DEFINE_COLUMN(v_cursor, i, v_varchar2, 4000);
    END IF;
  END LOOP;
  /* Now output the data, starting with header... */
  DBMS_OUTPUT.NEW_LINE;
  FOR i IN 1 .. v_cols
  LOOP
    v_data := v_data ||
    CASE v_desc(i).col_type
    WHEN 2 THEN
      LPAD(v_desc(i).col_name, v_desc(i).col_max_len+1)
    WHEN 12 THEN
      RPAD(v_desc(i).col_name, 22)
    ELSE
      RPAD(v_desc(i).col_name, v_desc(i).col_max_len+1)
    END || ' ';
  END LOOP;
  DBMS_OUTPUT.PUT_LINE(v_data);
  v_data := NULL;
  FOR i IN 1 .. v_cols
  LOOP
    v_data := v_data ||
    CASE v_desc(i).col_type
    WHEN 2 THEN
      LPAD('-', v_desc(i).col_max_len+1, '-')
    WHEN 12 THEN
      RPAD('-', 22, '-')
    ELSE
      RPAD('-', v_desc(i).col_max_len+1, '-')
    END || ' ';
  END LOOP;
  DBMS_OUTPUT.PUT_LINE(v_data);
  /* Fetch all data... */
  v_curRow := v_maxRows;
  WHILE DBMS_SQL.FETCH_ROWS(v_cursor) > 0
  LOOP
    v_data := NULL;
    FOR i IN 1 .. v_cols
    LOOP
      IF v_desc(i).col_type = 2 THEN
        DBMS_SQL.COLUMN_VALUE(v_cursor, i, v_number);
        v_data                := v_data || LPAD(v_number, v_desc(i).col_max_len+1) || ' ';
      ELSIF v_desc(i).col_type = 12 THEN
        DBMS_SQL.COLUMN_VALUE(v_cursor, i, v_date);
        v_data := v_data || RPAD(v_date, 22) || ' ';
      ELSE
        DBMS_SQL.COLUMN_VALUE(v_cursor, i, v_varchar2);
        v_data := v_data || RPAD(v_varchar2, v_desc(i).col_max_len+1) || ' ';
      END IF;
    END LOOP;
    DBMS_OUTPUT.PUT_LINE(v_data);
    if  v_maxRows <> 0 then
       v_curRow :=  v_curRow - 1;
       exit when 0 = v_curRow;
    end if;
  END LOOP;
  DBMS_SQL.CLOSE_CURSOR(v_cursor);
END;

Enable and Disable constraints and triggers in Oracle

During data migrations it’s common to have constraints disabled, usually for loading performance or testing purposes.
To aid in such task, we’re sharing two simple scripts, one for disabling and another for enabling.

To disable all enabled constraints and triggers, just execute:

BEGIN
  -- Constraints
  FOR c IN
  (SELECT c.owner, c.table_name, c.constraint_name
   FROM user_constraints c, user_tables t
   WHERE c.table_name = t.table_name
   AND c.status = 'ENABLED'
   ORDER BY c.constraint_type DESC)
  LOOP
    -- DISABLE
    execute immediate 'alter table "' || c.owner || '"."' || c.table_name || '" disable constraint ' || c.constraint_name;
  END LOOP;
 
  -- Triggers
  FOR ut IN
    (select ut.table_owner, ut.trigger_name
    from user_triggers ut
    where ut.status = 'ENABLED')
  LOOP
    -- DISABLE
    execute immediate 'ALTER TRIGGER "' || ut.table_owner || '"."' || ut.trigger_name || '" DISABLE;';
  END LOOP;
END;
/

To enable all disabled constraints and triggers, just execute:

BEGIN
  -- Constraints
  FOR c IN
  (SELECT c.owner, c.table_name, c.constraint_name
   FROM user_constraints c, user_tables t
   WHERE c.table_name = t.table_name
   AND c.status = 'DISABLE'
   ORDER BY c.constraint_type DESC)
  LOOP
    -- ENABLE
    execute immediate 'alter table "' || c.owner || '"."' || c.table_name || '" enable constraint ' || c.constraint_name;
  END LOOP;
 
  -- Triggers
  FOR ut IN
    (select ut.table_owner, ut.trigger_name
    from user_triggers ut
    where ut.status = 'DISABLE')
  LOOP
    -- ENABLE
    execute immediate 'ALTER TRIGGER "' || ut.table_owner || '"."' || ut.trigger_name || '" ENABLE;';
  END LOOP;
END;
/

For XML Path Equivalent in Oracle For String Aggregation

During a migration from SQL Server to Oracle 11g, I’ve came across with a specific functionality of T-SQL FOR XML PATH.
In the scope of the migration, the result of the select clause where this was applied was the concatenation of the values of a column per key.

Here’s an example of what I’ve found on T-SQL during the migration:

Declare @tbl1 table (
  id int,
  Col1 varchar(50),
  Col2 varchar(50)
)

INSERT INTO @tbl1
SELECT 1,'A001','Y'

INSERT INTO @tbl1
SELECT 2,'A002','N'

INSERT INTO @tbl1
SELECT 3,'A003','N'

INSERT INTO @tbl1
SELECT 4,'A004','Y'

INSERT INTO @tbl1
SELECT 5,'A005','N'

INSERT INTO @tbl1
SELECT 6,'A006','N'

INSERT INTO @tbl1
SELECT 7,'A007','N'

INSERT INTO @tbl1
SELECT 8,'A008','Y'

-- Show current values
select * from @tbl1

-- Get all values when col2 has value 'N'
SELECT c.col1 AS [text()]
FROM @tbl1 c
WHERE c.col2 = 'N'
FOR XML PATH(''),type

-- Aggregate all values from col1 using col2 as key
select c1.col2 [Yes/No],
  (SELECT c.col1 AS [text()]
   FROM @tbl1 c
   WHERE c.col2 = c1.col2
   FOR XML PATH(''),type) as Value
FROM @tbl1 c1
group by c1.col2
order by c1.col2

The execution of this T-SQL script shows how it is possible transform the result of a query into a new result where the values are aggregated by col1, and all col2 values are concatenated.

In order to achieve this kind of aggregate transformation in Oracle, one has to make use of an associative array, as Tom explains in the “String Concatenation” how one can do this. Using the examples in the AskTom web site, first we create the “STRING_AGG_TYPE” type:

CREATE OR REPLACE TYPE string_agg_type AS object
(
  total VARCHAR2(4000),

  static FUNCTION ODCIAggregateInitialize(sctx IN OUT string_agg_type) RETURN NUMBER,

  member FUNCTION ODCIAggregateIterate(self IN OUT string_agg_type, VALUE IN VARCHAR2) RETURN NUMBER,

  member FUNCTION ODCIAggregateTerminate(self IN string_agg_type, returnValue OUT VARCHAR2, flags IN NUMBER) RETURN NUMBER,

  member FUNCTION ODCIAggregateMerge(self IN OUT string_agg_type, ctx2 IN string_agg_type) RETURN NUMBER
);
/

And the correspondent body:

CREATE OR REPLACE TYPE BODY string_agg_type
IS

static FUNCTION ODCIAggregateInitialize(sctx IN OUT string_agg_type)
RETURN NUMBER
IS
BEGIN
  sctx := string_agg_type( NULL );
  RETURN ODCIConst.Success;
END;

member FUNCTION ODCIAggregateIterate(self IN OUT string_agg_type, VALUE IN VARCHAR2 )
RETURN NUMBER
IS
BEGIN
  -- NOTE: Insert a separator in the empty string if you wish
  self.total := self.total || '' || VALUE;
  RETURN ODCIConst.Success;
END;

member FUNCTION ODCIAggregateTerminate(self IN string_agg_type, returnValue OUT VARCHAR2, flags IN NUMBER)
RETURN NUMBER
IS
BEGIN
  -- NOTE: ltrim(self.total, '') if you've specified a separator in ODCIAggregateIterate
  returnValue := LTRIM(self.total);
  RETURN ODCIConst.Success;
END;

member FUNCTION ODCIAggregateMerge(self IN OUT string_agg_type, ctx2 IN string_agg_type)
RETURN NUMBER
IS
BEGIN
  self.total := self.total || ctx2.total;
  RETURN ODCIConst.Success;
END;

END;
/

Then we create the aggregated function “stragg” of the type we’ve just created:

CREATE OR REPLACE FUNCTION stragg(input VARCHAR2 ) RETURN VARCHAR2 PARALLEL_ENABLE AGGREGATE USING string_agg_type;
/

We are now able to make a similar aggregation in Oracle:

CREATE TABLE tbl1 (
  id NUMBER(10),
  Col1 VARCHAR(50),
  Col2 VARCHAR(50)
);
/

INSERT INTO tbl1 (id, col1, col2)
VALUES (1,'A001','Y');
/
INSERT INTO tbl1 (id, col1, col2)
VALUES (2,'A002','N');
/
INSERT INTO tbl1 (id, col1, col2)
VALUES (3,'A003','N');
/
INSERT INTO tbl1 (id, col1, col2)
VALUES (4,'A004','Y');
/
INSERT INTO tbl1 (id, col1, col2)
VALUES (5,'A005','N');
/
INSERT INTO tbl1 (id, col1, col2)
VALUES (6,'A006','N');
/
INSERT INTO tbl1 (id, col1, col2)
VALUES (7,'A007','N');
/
INSERT INTO tbl1 (id, col1, col2)
VALUES (8,'A008','Y');
/
COMMIT;
/

-- Show current values
SELECT * FROM tbl1;
/

-- Get all values when col2 has value 'N'
SELECT c.col2, STRAGG(c.col1)
FROM tbl1 c
WHERE c.col2 = 'N'
GROUP BY c.col2;
/

-- Aggregate all values from col1 using col2 as key
SELECT c1.col2 "Yes/No",
  (SELECT STRAGG(c.col1)
   FROM tbl1 c
   WHERE c.col2 = c1.col2
  ) AS val
FROM tbl1 c1
GROUP BY c1.col2
ORDER BY c1.col2;
/

-- drop table tbl1;

And that’s it. This will work in 9i and beyond, for 8i, check the 8i workaround in the same AskTom thread.