Skip to Main Content
  • Questions
  • data retention from 68 table and show it

Breadcrumb

May 4th

Question and Answer

Chris Saxon

Thanks for the question.

Asked: June 06, 2017 - 12:11 pm UTC

Last updated: June 12, 2017 - 12:52 pm UTC

Version: 11g

Viewed 1000+ times

You Asked


Hi Tom

I have one requirement please let me know the solution

Requirement:
============

I have 68 table names that I get from user_tab_columns using some conditions and I achieve it easily

But the challenge is I want to show all the columns from 68 tables

how can I achieve it.


I tried to pass each table name dynamically and stored data into record. but I cant create record for 1400 columns. yes 68 table include 1400 columns. So I failed.


also I tried utl_file using cursor or bulk collect but how I use 68 table names.

waiting for your answer.


my code:
========

SET SERVEROUTPUT ON;

DECLARE

TYPE l_coll_data IS TABLE OF varchar2(32000) -- Associative array type
INDEX BY VARCHAR2(32000);

l_collection l_coll_data;

L_TAB_NAME TABLE_TYPE;

L_NAME VARCHAR2(100);

BEGIN

SELECT TABLE_NAME BULK COLLECT INTO L_TAB_NAME FROM USER_TAB_COLUMNS
WHERE COLUMN_NAME='ENQUIRY_NO';

FOR INDX IN 1..L_TAB_NAME.COUNT
LOOP

DBMS_OUTPUT.PUT_LINE(L_TAB_NAME(INDX));

L_NAME:=L_TAB_NAME(INDX);

DBMS_OUTPUT.PUT_LINE(L_NAME);

EXECUTE IMMEDIATE 'SELECT * BULK COLLECT INTO '||L_COLLECTION||' FROM '||L_NAME||'';

FOR I IN L_COLLECTION.FIRST..L_COLLECTION.LAST
LOOP
DBMS_OUTPUT.PUT_LINE(L_COLLECTION(I)); /*I have to get all table columns from here but I struggle it.*/
END LOOP;

END LOOP;
END;


in the above code I have to create l_collection recordtype but how I create record for 1400 columns



and Connor said...

First, I can't really see the sense in outputting columns in that way. If I had a SALES table and an EMPLOYEE table, then putting them like:

EMPNO  ENAME    SALES_ID
10     Connor   100
11     John     101
12     Sue      102
                103
                104
                106


That doesn't really have any sensible concept. Better to print them out table at a time.

For that, you'll need dbms_sql in order to dynamically iterate through the columns.

Here's a routine we use here to print data down the screen - you can easily customise that to meet your needs.

SQL> declare
  2      p_query varchar2(32767) := q'{select * from emp}';
  3
  4      l_theCursor     integer default dbms_sql.open_cursor;
  5      l_columnValue   varchar2(4000);
  6      l_status        integer;
  7      l_descTbl       dbms_sql.desc_tab;
  8      l_colCnt        number;
  9      n number := 0;
 10    procedure p(msg varchar2) is
 11      l varchar2(4000) := msg;
 12    begin
 13      while length(l) > 0 loop
 14        dbms_output.put_line(substr(l,1,80));
 15        l := substr(l,81);
 16      end loop;
 17    end;
 18  begin
 19      execute immediate
 20      'alter session set nls_date_format=''dd-mon-yyyy hh24:mi:ss'' ';
 21
 22      dbms_sql.parse(  l_theCursor,  p_query, dbms_sql.native );
 23      dbms_sql.describe_columns( l_theCursor, l_colCnt, l_descTbl );
 24
 25      for i in 1 .. l_colCnt loop
 26          dbms_sql.define_column(l_theCursor, i, l_columnValue, 4000);
 27      end loop;
 28
 29      l_status := dbms_sql.execute(l_theCursor);
 30
 31      while ( dbms_sql.fetch_rows(l_theCursor) > 0 ) loop
 32          for i in 1 .. l_colCnt loop
 33              dbms_sql.column_value( l_theCursor, i, l_columnValue );
 34              p( rpad( l_descTbl(i).col_name, 30 )
 35                || ': ' ||
 36                l_columnValue );
 37          end loop;
 38          dbms_output.put_line( '-----------------' );
 39          n := n + 1;
 40      end loop;
 41      if n = 0 then
 42        dbms_output.put_line( chr(10)||'No data found '||chr(10) );
 43      end if;
 44  end;
 45  /
EMPNO                         : 7369
ENAME                         : SMITH
JOB                           : CLERK
MGR                           : 7902
HIREDATE                      : 17-dec-1980 00:00:00
SAL                           : 800
COMM                          :
DEPTNO                        : 20
-----------------
EMPNO                         : 7499
ENAME                         : ALLEN
JOB                           : SALESMAN
MGR                           : 7698
HIREDATE                      : 20-feb-1981 00:00:00
SAL                           : 1600
COMM                          : 300
DEPTNO                        : 30
-----------------
EMPNO                         : 7521
ENAME                         : WARD
JOB                           : SALESMAN
MGR                           : 7698
HIREDATE                      : 22-feb-1981 00:00:00
SAL                           : 1250
COMM                          : 500
DEPTNO                        : 30
-----------------
EMPNO                         : 7566
ENAME                         : JONES
JOB                           : MANAGER
MGR                           : 7839
HIREDATE                      : 02-apr-1981 00:00:00
SAL                           : 2975
COMM                          :
DEPTNO                        : 20
-----------------
EMPNO                         : 7654
ENAME                         : MARTIN
JOB                           : SALESMAN
MGR                           : 7698
HIREDATE                      : 28-sep-1981 00:00:00
SAL                           : 1250
COMM                          : 1400
DEPTNO                        : 30
-----------------
EMPNO                         : 7698
ENAME                         : BLAKE
JOB                           : MANAGER
MGR                           : 7839
HIREDATE                      : 01-may-1981 00:00:00
SAL                           : 2850
COMM                          :
DEPTNO                        : 30
-----------------
EMPNO                         : 7782
ENAME                         : CLARK
JOB                           : MANAGER
MGR                           : 7839
HIREDATE                      : 09-jun-1981 00:00:00
SAL                           : 2450
COMM                          :
DEPTNO                        : 10
...
...


Rating

  (1 rating)

Is this answer out of date? If it is, please let us know via a Comment

Comments

A reader, June 20, 2017 - 6:19 am UTC


More to Explore

PL/SQL demos

Check out more PL/SQL tutorials on our LiveSQL tool.

PL/SQL docs

PL/SQL reference manual from the Oracle documentation library