多行轉(zhuǎn)字符串
這個比較簡單,用||或concat函數(shù)可以實現(xiàn)
SQL Code
1 2 | | select concat(id,username) str from app_user select id||username str from app_user |
字符串轉(zhuǎn)多列
實際上就是拆分字符串的問題,可以使用 substr、instr、regexp_substr函數(shù)方式
字符串轉(zhuǎn)多行
使用union all函數(shù)等方式
wm_concat函數(shù)
首先讓我們來看看這個神奇的函數(shù)wm_concat(列名),該函數(shù)可以把列值以","號分隔起來,并顯示成一行,接下來上例子,看看這個神奇的函數(shù)如何應(yīng)用準備測試數(shù)據(jù)
SQL Code
1 2 3 4 5 6 | | create table test(id number,name varchar2(20)); insert into test values(1,'a'); insert into test values(1,'b'); insert into test values(1,'c'); insert into test values(2,'d'); insert into test values(2,'e'); |
效果1 : 行轉(zhuǎn)列 ,默認逗號隔開
SQL Code
1 | | select wm_concat(name) name from test; |
效果2: 把結(jié)果里的逗號替換成"|"
SQL Code
1 | | select replace(wm_concat(name),',','|') from test; |
效果3: 按ID分組合并name
SQL Code
1 | | select id,wm_concat(name) name from test group by id; |
sql語句等同于下面的sql語句:
SQL Code
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 27 28 29 30 31 32 33 34 35 36 | | -------- 適用范圍:8i,9i,10g及以后版本 ( MAX + DECODE ) select id, max(decode(rn, 1, name, null)) || max(decode(rn, 2, ',' || name, null)) || max(decode(rn, 3, ',' || name, null)) str from (select id, name, row_number() over(partition by id order by name) as rn from test) t group by id order by 1; -------- 適用范圍:8i,9i,10g及以后版本 ( ROW_NUMBER + LEAD ) select id, str from (select id, row_number() over(partition by id order by name) as rn, name || lead(',' || name, 1) over(partition by id order by name) || lead(',' || name, 2) over(partition by id order by name) || lead(',' || name, 3) over(partition by id order by name) as str from test) where rn = 1 order by 1; -------- 適用范圍:10g及以后版本 ( MODEL ) select id, substr(str, 2) str from test model return updated rows partition by(id) dimension by(row_number() over(partition by id order by name) as rn) measures(cast(name as varchar2(20)) as str) rules upsert iterate(3) until(presentv(str [ iteration_number + 2 ], 1, 0) = 0) (str [ 0 ] = str [ 0 ] || ',' || str [ iteration_number + 1 ]) order by 1; -------- 適用范圍:8i,9i,10g及以后版本 ( MAX + DECODE ) select t.id id, max(substr(sys_connect_by_path(t.name, ','), 2)) str from (select id, name, row_number() over(partition by id order by name) rn from test) t start with rn = 1 connect by rn = prior rn + 1 and id = prior id group by t.id; |
懶人擴展用法:
案例: 我要寫一個視圖,類似"create or replace view as select 字段1,...字段50 from tablename" ,基表有50多個字段,要是靠手工寫太麻煩了,有沒有什么簡便的方法? 當然有了,看我如果應(yīng)用wm_concat來讓這個需求變簡單,假設(shè)我的APP_USER表中有(id,username,password,age)4個字段。查詢結(jié)果如下
SQL Code
1 2 3 4 5 | | /** 這里的表名默認區(qū)分大小寫 */ select 'create or replace view as select ' || wm_concat(column_name) || ' from APP_USER' sqlStr from user_tab_columns where table_name = 'APP_USER'; |
利用系統(tǒng)表方式查詢
SQL Code
1 | | select * from user_tab_columns |
Oracle 11g 行列互換 pivot 和 unpivot 說明
在Oracle 11g中,Oracle 又增加了2個查詢:pivot(行轉(zhuǎn)列) 和unpivot(列轉(zhuǎn)行)
參考:http://blog.csdn.net/tianlesoftware/article/details/7060306、http://www.oracle.com/technetwork/cn/articles/11g-pivot-101924-zhs.html
google 一下,網(wǎng)上有一篇比較詳細的文檔:http://www./display.php?id=506
pivot 列轉(zhuǎn)行
測試數(shù)據(jù) (id,類型名稱,銷售數(shù)量),案例:根據(jù)水果的類型查詢出一條數(shù)據(jù)顯示出每種類型的銷售數(shù)量。
SQL Code
1 2 3 4 5 6 7 8 9 | | create table demo(id int,name varchar(20),nums int); ---- 創(chuàng)建表 insert into demo values(1, '蘋果', 1000); insert into demo values(2, '蘋果', 2000); insert into demo values(3, '蘋果', 4000); insert into demo values(4, '橘子', 5000); insert into demo values(5, '橘子', 3000); insert into demo values(6, '葡萄', 3500); insert into demo values(7, '芒果', 4200); insert into demo values(8, '芒果', 5500); |
分組查詢 (當然這是不符合查詢一條數(shù)據(jù)的要求的)
SQL Code
1 | | select name, sum(nums) nums from demo group by name |
行轉(zhuǎn)列查詢
SQL Code
1 | | select * from (select name, nums from demo) pivot (sum(nums) for name in ('蘋果' 蘋果, '橘子', '葡萄', '芒果')); |
注意: pivot(聚合函數(shù) for 列名 in(類型)) ,其中 in('') 中可以指定別名,in中還可以指定子查詢,比如 select distinct code from customers
當然也可以不使用pivot函數(shù),等同于下列語句,只是代碼比較長,容易理解
SQL Code
1 2 3 4 5 | | select * from (select sum(nums) 蘋果 from demo where name = '蘋果'), (select sum(nums) 橘子 from demo where name = '橘子'), (select sum(nums) 葡萄 from demo where name = '葡萄'), (select sum(nums) 芒果 from demo where name = '芒果'); |
unpivot 行轉(zhuǎn)列
顧名思義就是將多列轉(zhuǎn)換成1列中去 案例:現(xiàn)在有一個水果表,記錄了4個季度的銷售數(shù)量,現(xiàn)在要將每種水果的每個季度的銷售情況用多行數(shù)據(jù)展示。
創(chuàng)建表和數(shù)據(jù)
SQL Code
1 2 3 4 5 6 | | create table Fruit(id int,name varchar(20), Q1 int, Q2 int, Q3 int, Q4 int); insert into Fruit values(1,'蘋果',1000,2000,3300,5000); insert into Fruit values(2,'橘子',3000,3000,3200,1500); insert into Fruit values(3,'香蕉',2500,3500,2200,2500); insert into Fruit values(4,'葡萄',1500,2500,1200,3500); select * from Fruit |
列轉(zhuǎn)行查詢
SQL Code
1 | | select id , name, jidu, xiaoshou from Fruit unpivot (xiaoshou for jidu in (q1, q2, q3, q4) ) |
注意: unpivot沒有聚合函數(shù),xiaoshou、jidu字段也是臨時的變量
同樣不使用unpivot也可以實現(xiàn)同樣的效果,只是sql語句會很長,而且執(zhí)行速度效率也沒有前者高
SQL Code
1 2 3 4 5 6 7 | | select id, name ,'Q1' jidu, (select q1 from fruit where id=f.id) xiaoshou from Fruit f union select id, name ,'Q2' jidu, (select q2 from fruit where id=f.id) xiaoshou from Fruit f union select id, name ,'Q3' jidu, (select q3 from fruit where id=f.id) xiaoshou from Fruit f union select id, name ,'Q4' jidu, (select q4 from fruit where id=f.id) xiaoshou from Fruit f |
XML類型
上述pivot列轉(zhuǎn)行示例中,你已經(jīng)知道了需要查詢的類型有哪些,用in()的方式包含,假設(shè)如果您不知道都有哪些值,您怎么構(gòu)建查詢呢?
pivot 操作中的另一個子句 XML 可用于解決此問題。該子句允許您以 XML 格式創(chuàng)建執(zhí)行了 pivot 操作的輸出,在此輸出中,您可以指定一個特殊的子句 ANY 而非文字值
示例如下:
SQL Code
1 2 3 4 5 6 7 | | select * from ( select name, nums as "Purchase Frequency" from demo t ) pivot xml ( sum(nums) for name in (any) ) |
如您所見,列 NAME_XML 是 XMLTYPE,其中根元素是 <PivotSet>。每個值以名稱-值元素對的形式表示。您可以使用任何 XML 分析器中的輸出生成更有用的輸出。
對于該xml文件的解析,貼代碼如下:
SQL Code
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 27 28 29 30 31 32 33 34 35 36 37 38 39 40 41 42 43 44 45 46 47 48 49 50 51
| | create or replace procedure ljz_pivot_xml_sp(pi_table_name varchar2, pi_column_name varchar2, pi_create_table varchar2) as v_column nvarchar2(50); v_count number := 0; v_i number; v_parent_node nvarchar2(4000); v_child_node nvarchar2(4000); v_over boolean := false; v_tmp nvarchar2(50); v_existsnode number; v_sql clob; v_name varchar2(30); v_name_xml xmltype; begin v_sql := 'select x.* from ' || pi_table_name || ' a, xmltable(''/PivotSet'' passing a.' || pi_column_name || ' columns '; v_parent_node := '/PivotSet'; v_child_node := 'item[1]/column[2]'; v_i := 1; execute immediate 'select ' || pi_column_name || ' from ' || pi_table_name || ' where rownum=1' into v_name_xml; select existsnode(v_name_xml, '/PivotSet/item[' || to_char(v_i) || ']/column[1]') into v_existsnode from dual; while v_existsnode = 1 loop execute immediate 'select substr(extractvalue(' || pi_column_name || ', ''/PivotSet/item[' || to_char(v_i) || ']/column[1]''),1,30) from ' || pi_table_name || ' x' into v_name; v_sql := v_sql || '"' || v_name || '" varchar2(30) path ''item[' || to_char(v_i) || ']/column[2]'','; v_i := v_i + 1; select existsnode(v_name_xml, '/PivotSet/item[' || to_char(v_i) || ']/column[1]') into v_existsnode from dual; end loop; v_sql := trim(',' from v_sql) || ') x'; commit; select count(1) into v_count from user_tab_columns where table_name = upper(pi_create_table); if v_count = 0 then execute immediate 'create table ' || pi_create_table || ' as ' || v_sql; end if; end; |
第一個參數(shù)為要解析xml文件所屬數(shù)據(jù)表,第二個參數(shù)為要解析xml所存字段,第三個參數(shù)存放解析后的數(shù)據(jù)集。
測試:
begin
ljz_pivot_xml_sp('(select * from (select deptno,sal from emp) pivot xml(sum(sal) for deptno in(any)))',
'deptno_xml',
'ljz_pivot_tmp');
end;
初學(xué)oracle xml解析,這種方法較為笨拙,一個一個循環(huán)列,原型如下:
select
extractvalue(name_xml,
'/PivotSet/item[1]/column[1]')
from
(select
*
from
(select
name,nums from demo)
pivot
xml(sum(nums)
for
name
in(any))) x
where
existsnode(name_xml,
'/PivotSet/item[1]/column[1]')
=
1;
select x.*
from
(select
*
from
(select
name, nums from demo)
pivot
xml(sum(nums)
for
name
in(any))) a,
xmltable('/PivotSet'
passing a.name_xml columns
芒果
varchar2(30)
path
'item[1]/column[2]',
蘋果
varchar2(30)
path
'item[2]/column[2]') x
不知是否存在直接進行解析的方法,這種方法還不如直接行列轉(zhuǎn)變,不通過xml轉(zhuǎn)來轉(zhuǎn)去。
select
''''
|| listagg(substr(name,
1,
30),
q'{','}')
within
group(order
by
name)
||
''''
from
(select
distinct
name
from demo);
select
*
from
(select
name, nums from demo)
pivot(sum(nums)
for
name
in('蘋果',
'橘子',
'葡萄',
'芒果'));
這樣拼接字符串反而更加方便。
結(jié)論
Pivot 為 SQL 語言增添了一個非常重要且實用的功能。您可以使用 pivot 函數(shù)針對任何關(guān)系表創(chuàng)建一個交叉表報表,而不必編寫包含大量 decode 函數(shù)的令人費解的、不直觀的代碼。同樣,您可以使用 unpivot 操作轉(zhuǎn)換任何交叉表報表,以常規(guī)關(guān)系表的形式對其進行存儲。Pivot 可以生成常規(guī)文本或 XML 格式的輸出。如果是 XML 格式的輸出,您不必指定 pivot 操作需要搜索的值域。
|