TABLE_NAME | COLUMN_LIST |
---|---|
BLOG_LABELS | BLL_BLG_ID, BLL_LABEL |
BLOG_COMMENTS | BLC_BLG_ID, BLC_IDENTIFIER, BLC_PUBLISHED_TEXT, BLC_PUBLISHED, BLC_UPDATED_TEXT, BLC_UPDATED, BLC_CONTENT, BLC_URL, BLC_AUTHOR, BLC_AUTHOR_URI |
BLOG_POSTS | BLG_ID, BLG_IDENTIFIER, BLG_TITLE, BLG_PUBLISHED_TEXT, BLG_PUBLISHED, BLG_UPDATED_TEXT, BLG_UPDATED, BLG_CONTENT, BLG_URL, BLG_BGH_ID, BLG_ENTRY |
BLOGS | BGH_ID, BGH_NAME, BGH_FEED_URL |
FEED_CACHE | CCH_URL, CCH_TIME, CCH_VALUE |
SQL> select table_name, 2 SYS_CONNECT_BY_PATH(column_name, ',') column_list 3 from user_tab_columns 4 start with column_id = 1 5 connect by table_name = prior table_name 6 and column_id = prior column_id +1 7 ;
TABLE_NAME | COLUMN_LIST |
---|---|
BLOGS | , BGH_ID |
BLOGS | , BGH_ID, BGH_NAME |
BLOGS | , BGH_ID, BGH_NAME, BGH_FEED_URL |
... | ... |
SQL> select table_name, 2 ltrim(max(SYS_CONNECT_BY_PATH(column_name, ',')), ',') column_list 3 from user_tab_columns 4 start with column_id = 1 5 connect by table_name = prior table_name 6 and column_id = prior column_id +1 7 group by table_name;
TABLE_NAME | COLUMN_LIST |
---|---|
BLOG_LABELS | BLL_BLG_ID, BLL_LABEL |
BLOG_COMMENTS | BLC_BLG_ID, BLC_IDENTIFIER, BLC_PUBLISHED_TEXT, BLC_PUBLISHED, BLC_UPDATED_TEXT, BLC_UPDATED, BLC_CONTENT, BLC_URL, BLC_AUTHOR, BLC_AUTHOR_URI |
BLOG_POSTS | BLG_ID, BLG_IDENTIFIER, BLG_TITLE, BLG_PUBLISHED_TEXT, BLG_PUBLISHED, BLG_UPDATED_TEXT, BLG_UPDATED, BLG_CONTENT, BLG_URL, BLG_BGH_ID, BLG_ENTRY |
BLOGS | BGH_ID, BGH_NAME, BGH_FEED_URL |
FEED_CACHE | CCH_URL, CCH_TIME, CCH_VALUE |
But what if we want columns to be ordered alphabetically? Than we have to use Row_Number function to calculate column position in table and make same changes to SQL:
SQL> select table_name, 2 ltrim(max(SYS_CONNECT_BY_PATH(column_name, ',')), ',') column_list 3 from (select table_name, column_name, ROW_NUMBER() OVER (partition by table_name ORDER BY column_name) AS curr from user_tab_columns) 4 start with curr = 1 5 connect by table_name = prior table_name 6 and curr = prior curr +1 7 group by table_name;
TABLE_NAME | COLUMN_LIST |
---|---|
BLOG_LABELS | BLL_BLG_ID, BLL_LABEL |
BLOG_COMMENTS | BLC_AUTHOR, BLC_AUTHOR_URI, BLC_BLG_ID, BLC_CONTENT, BLC_IDENTIFIER, BLC_PUBLISHED, BLC_PUBLISHED_TEXT, BLC_UPDATED, BLC_UPDATED_TEXT, BLC_URL |
BLOG_POSTS | BLG_BGH_ID, BLG_CONTENT, BLG_ENTRY, BLG_ID, BLG_IDENTIFIER, BLG_PUBLISHED, BLG_PUBLISHED_TEXT, BLG_TITLE, BLG_UPDATED, BLG_UPDATED_TEXT, BLG_URL |
BLOGS | BGH_FEED_URL, BGH_ID, BGH_NAME |
FEED_CACHE | CCH_TIME, CCH_URL, CCH_VALUE |
All samples where run on Oracle 10gR2 XE 10.2.0.1.
Schema used in this sample is described in Blogger Backup tool entry.
Paweł
3 comments:
Nice post... only downside with this approach is that if you have a large number of columns, you may end up with :
SQL> select table_name,
2 ltrim(max(SYS_CONNECT_BY_PATH(column_name, ',')), ',') column_list
3 from user_tab_columns
4 where table_name = 'LARGE_TABLE'
5 start with column_id = 1
6 connect by table_name = prior table_name
7 and column_id = prior column_id +1
8 group by table_name
9 /
from user_tab_columns
*
ERROR at line 3:
ORA-01489: result of string concatenation is too long
Thats right. The limit for string length in SQL is 4000 characters.
Post a Comment