how about the other way round
A reader, May 13, 2002 - 11:20 am UTC
Hi Tom
Can we use decode to convert a column into a row?. For example
ename dname
------ -------
FORD FINANCE
into
details
--------
FORD
FINANCE
this is probably a strange requirement but it has been asked :(
May 13, 2002 - 1:42 pm UTC
yes.
1 select decode( r, 1, to_char(deptno), 2, dname, 3, loc )
2 from dept, (select rownum r from all_objects where rownum <= 3 )
3* where deptno = 10
ops$tkyte@ORA817DEV.US.ORACLE.COM> /
DECODE(R,1,TO_CHAR(DEPTNO),2,DNAME,3,LOC
----------------------------------------
10
ACCOUNTING
NEW YORK
Similar Problem
Mike Wilson, May 13, 2002 - 2:16 pm UTC
I have a simlar problem to the above of pivoting tables where I don't know the domain of the pivot columns (or they fluctuate). Because of this I wrote a small domain lookup function that uses auto-binding and looks up the column values. I create a lookup table that lists the field names to be retreived and use a cartesian join to do my lookups and then exclude all of the null values. It forces auto-binding also.
CREATE OR REPLACE FUNCTION DLOOKUP (vField in varchar2,
vTable in varchar2, vWhere in varchar2 default NULL) return
varchar2
AUTHID CURRENT_USER
as
vVar varchar2(4000);
vQuery varchar2(4000);
begin
execute immediate 'alter session set cursor_sharing=force';
vQuery := 'select '||vField||' from '||vTable;
if (vWhere is not NULL) then
vQuery := vQuery ||' where '||vWhere;
end if;
execute immediate vQuery into vVar;
return vVar;
exception when others then
return null;
end;
;
This works pretty well, although the cartesian join is very expensive. With the example above though using an array, how would you get it to actually look like a table? Is there a view you can wrap around the multiset output to make it look like an actual table?
May 13, 2002 - 2:30 pm UTC
show me how this pivots? I don't get it -- seems to just do a select into of a single row/column
I don't see any cartesian products here at all?
If you have my book -- the last section of the analytic functions chapter shows how to pivot any query using a ref cursor and some simple query rewrite techniques.
theory behind pivot query
A reader, May 13, 2002 - 6:48 pm UTC
Hi Tom
I noticed you said carteasian product, the trick or theory behind pivoting a result set is by having a carteasian product the decode the columns, am I correct?
so basically from your example
select decode( r, 1, to_char(deptno), 2, dname, 3, loc )
from dept, (select rownum r from all_objects where rownum <= 3 )
where deptno = 10
we first get
1, 10, accounting, new york
2, 10, accounting, new york
3, 10, accounting, new york
then we decode 1 to deptno, 2 to accounting, 3 to new york to get
10
ACCOUNTING
NEW YORK
is my understanding correct?
cheers
May 13, 2002 - 7:01 pm UTC
Exactly, dead on.
Un-pivot example for comment ...
Mike Wilson, May 13, 2002 - 10:28 pm UTC
Sorry, for the previous incomplete post. Hit enter while incomplete in thought. You are correct, un-pivoting a table in the above case doesn't require a cartesian join.
To be brief I frequently am asked to produce un-pivots of data *and* calculate values. These calculations may also vary by department. Hard coding these views for a rather fluid calculation system and then to keep versions per department wouldn't be feasible as I would have to have a different version of the view per department and our department structures and calculation models change monthly.
I have read your examples in your excellent book on Analytic Functions (way cool) but they deal with pivoting a table (rows to columns) not columns to rows. Because of this I have resorted to writting my own domain lookup function that uses bind variables and a lookup table that allows my calculation model to vary by department.
As I so ineptly responded before, rather than hard-coding a view I wrote a small domain lookup function that allows me flexibility (at the expense of compute time). I simply wanted to share the function with the readers and see if they had any comments and to see if you might show me how to get rid of the dlookup function by hardcoding the below example into a simple view that can un-pivot the data *and* calculate values per row per deptment. At minimum I thought my small function might be useful for other readers. See below for an example of un-pivoting a table that seems more maintainable to me than using static views if your view needs to change frequently.
Pretend that I have given two departments id's 1 and 2 and that the values of a and b are important to a calculation they need. Please note that at any time a department may appear or disappear and that each department calculates their values differently.
temp table
id a b
=======================================
1 1 2
2 4 5
Per department, per column this is the calculation that each one wants.
temp_lkup table
id col calc
=======================================
1 a a
1 b b*2
2 a a+6
2 b b*3
desired output
id col orig calc val
=======================================
1 a 1 a 1
1 b 2 b*2 4
2 a 4 a+6 10
2 b 5 b*3 15
<snip>
create table temp (id integer, a integer, b integer)
/
insert into temp select 1,1,2 from dual
/
insert into temp select 2,4,5 from dual
/
commit
/
select * from temp
/
create table temp_lkup (id integer, col varchar2(16), calc varchar2(16))
/
insert into temp_lkup select 1, 'a', 'a' from dual
/
insert into temp_lkup select 1, 'b', 'b*2' from dual
/
insert into temp_lkup select 2, 'a', 'a+6' from dual
/
insert into temp_lkup select 2, 'b', 'b*3' from dual
/
commit
/
select * from temp_lkup
/
CREATE OR REPLACE FUNCTION DLOOKUP_BIND_ONE (vField in
varchar2, vTable in varchar2, vWhere in varchar2 default NULL,
vBind in varchar2) return varchar2
AUTHID CURRENT_USER
as
vVar varchar2(4000);
vQuery varchar2(4000);
begin
-- exit if field is null
if vfield is null then
return null;
end if;
-- exit if table is null
if vtable is null then
return null;
end if;
vQuery := 'select '||vField||' from '||vTable;
if (vWhere is not NULL) then
vQuery := vQuery ||' where '||vWhere;
end if;
execute immediate vQuery into vVar using vBind;
return vVar;
exception
when NO_DATA_FOUND then
return null;
when others then
raise;
end;
/
-- now to get the result set
select temp.id, temp_lkup.col, temp_lkup.calc,
to_number(nvl(dlookup_bind_one(col, 'temp', 'id=:a', temp.id),0)) orig,
to_number(nvl(dlookup_bind_one(calc, 'temp', 'id=:a', temp.id),0)) val
from temp, temp_lkup
where temp.id = temp_lkup.id
/
</snip>
ID COL CALC ORIG VAL
---------- ---------------- ---------------- ---------- ----------
1 a a 1 1
1 b b*2 2 4
2 a a+6 4 10
2 b b*3 5 15
Sagi, May 16, 2002 - 7:55 am UTC
Once again it was great tom.
I executed the below Query:
select decode( r, 1, to_char(deptno), 2, dname, 3, loc ) || chr(10) "Col2Row "
from dept, (select rownum r from all_objects where rownum <= 3)
order by deptno
Output:
=======
10
ACCOUNTING
NEW YORK
20
RESEARCH
DALLAS
30
SALES
CHICAGO
40
OPERATIONS
BOSTON
Question: How do we get say 2 empty blank lines after each deptno. I tried using CHR(10) or CHR(13). But could not get the output.
Thanx in advance.
REgards.
May 16, 2002 - 1:42 pm UTC
ops$tkyte@ORA817DEV.US.ORACLE.COM> select decode( r, 1, to_char(deptno) <b> || chr(10)</b>, 2, dname, 3, loc ) || chr(10) "Col2Row "
2 from dept, (select rownum r from all_objects where rownum <= 3)
3 order by deptno
4
ops$tkyte@ORA817DEV.US.ORACLE.COM>
ops$tkyte@ORA817DEV.US.ORACLE.COM> /
Col2Row
------------------------------------------
10
ACCOUNTING
NEW YORK
20
RESEARCH
DALLAS
30
SALES
CHICAGO
40
OPERATIONS
BOSTON
12 rows selected.
general purpose pivot function
Mikito Harakiri, May 16, 2002 - 1:53 pm UTC
Mike, could you please demonstrate what you achieve on emp table -- I don't get it.
It might be possible to write a general purpose pivot table function. The problem is the return type, which we can't declare of being any specific type. Maybe anydata/anydtaset might help...
May 17, 2002 - 7:41 am UTC
I did write a general purpose pivot function -- its in the analytic function chapter of my book. Uses a simple query rewrite to pivot and returns a dynamically opened ref cursor (works in 8i and up).
got your code, thank you
Mikito Harakiri, May 17, 2002 - 9:59 pm UTC
begin
my_pkg.pivot
(p_max_cols => 4,
p_query => 'select job, count(*) cnt, deptno,
row_number() over (partition by job order by deptno) rn
from emp
group by job, deptno',
p_anchor => my_pkg.array('JOB'),
p_pivot => my_pkg.array('DEPTNO', 'CNT'),
p_cursor => :x );
end;
This is not quite what I meant. What if pivoting is just a subquery of a larger query? Is there a way to call your function from a sql query?
May 18, 2002 - 10:04 am UTC
I cannot see how pivoting is could be a "subquery" of a larger query. That just doesn't compute with me.
good point
Mikito Harakiri, May 20, 2002 - 4:26 pm UTC
Can we have the above output using Multiset and ArrayType
Yamani, July 29, 2002 - 2:08 am UTC
Hi Tom,
Can we have the same out put generated on the above example:
JOB DEPT_10 DEPT_20 DEPT_30 DEPT_40
--------- ---------- ---------- ---------- ----------
ANALYST 2
CLERK 1 2 1
MANAGER 1 1 1
PRESIDENT 1
SALESMAN 4
But using the multiset and ArrayType.
If yes can you pleas show us how?
Thanks,
July 29, 2002 - 7:19 am UTC
they won't be columns, you would have 2 columns -- the JOB and then a single array that is the list of counts by deptno.
It would be "ugly" but it can be done. The array would have to be an array of object types that had the deptno and cnt in them (an array of records in effect).
ops$tkyte@ORA817DEV.US.ORACLE.COM> create or replace type myScalarType as object
2 ( deptno number,
3 cnt number
4 )
5 /
Type created.
ops$tkyte@ORA817DEV.US.ORACLE.COM>
ops$tkyte@ORA817DEV.US.ORACLE.COM> create or replace type myArrayType as table of MyScalarType
2 /
Type created.
ops$tkyte@ORA817DEV.US.ORACLE.COM> column data format a40
ops$tkyte@ORA817DEV.US.ORACLE.COM>
ops$tkyte@ORA817DEV.US.ORACLE.COM> select job,
2 cast( multiset( select myScalarType( deptno, count(*) )
3 from emp e2
4 where e2.job = emp.job
5 group by deptno ) as myArrayType ) data
6 from (select distinct job from emp ) emp
7 /
JOB DATA(DEPTNO, CNT)
--------- ----------------------------------------
ANALYST MYARRAYTYPE(MYSCALARTYPE(20, 2))
CLERK MYARRAYTYPE(MYSCALARTYPE(10, 1), MYSCALA
RTYPE(20, 2), MYSCALARTYPE(30, 1))
MANAGER MYARRAYTYPE(MYSCALARTYPE(10, 1), MYSCALA
RTYPE(20, 1), MYSCALARTYPE(30, 1))
PRESIDENT MYARRAYTYPE(MYSCALARTYPE(10, 1))
SALESMAN MYARRAYTYPE(MYSCALARTYPE(30, 4))
ops$tkyte@ORA817DEV.US.ORACLE.COM>
Got it !!
A reader, August 26, 2002 - 11:49 pm UTC
Pivot queries, had absolute no idea on how to write one.
Add a dash of AskTom and I have cooked up some awesome
queries that are keeping users happy and Managers off my back.
You are absolute legend Tom...
A reader, January 16, 2003 - 2:52 pm UTC
Hi Tom, please help to find out what is wrong in my query:
select dept,
max(decode(to_char(dateused,DY), MON', cnt, null)) "mon",
max(decode(to_char(dateused,DY), TUE', cnt, null)) "tue",
max(decode(to_char(dateused,DY), WED', cnt, null)) "wed",
max(decode(to_char(dateused,DY), THU', cnt, null)) "thu",
max(decode(to_char(dateused,DY), FRI', cnt, null)) "fri",
max(decode(to_char(dateused,DY), SAT', cnt, null)) "sat",
max(decode(to_char(dateused,DY), SUN', cnt, null)) "sun"
from (select dept,
decode(to_char(dateused,DY),
'MON, 'mon',
'TUE', 'tue',
'WED', 'wed',
'THU', 'thu',
'FRI', 'fri',
'SAT', 'sat',
'SUN, 'sun') t,
count(*) cnt
from visits v, users u
where v.ss = u.ss
and to_date(v.dateused, 'DD-MON-RR') > = to_date('1-AUG-02', 'DD-MON-RR')
and to_date(v.dateused, 'DD-MON-RR') < to_date('1-SEP-02', 'DD-MON-RR')
group by dept,
decode(to_char(dateused,DY),
MON,mon,
'TUE', 'tue',
'WED', 'wed',
'THU', 'thu',
'FRI', 'fri',
'SAT', 'sat',
'SUN, 'sun' ))
group by dept;
ERROR at line 8:
ORA-00904: invalid column name
SQL> desc visits
ID NOT NULL VARCHAR2(7)
LOCATION NOT NULL NUMBER(15,2)
DATEUSED NOT NULL DATE
SQL> desc users
ID NOT NULL VARCHAR2(7)
DEPT NOT NULL VARCHAR@(80)
Thanks
L.
January 16, 2003 - 7:57 pm UTC
well, you got that v.ss = u.ss in there as well -- so this is a hacked example at best.... but...
line 8 has
max(decode(to_char(dateused,'DY'), 'MON', cnt, null)) "mon",
but by the time you get there, dateused doesn't exist.
dept, t, cnt
they exist, but dateused -- long gone.
Can this pivoting apply here too?
Godwin, June 20, 2003 - 1:32 pm UTC
Hi Tom, I have this records in table A as
stno course code
---- -----------
1000 SOCI
1000 ECONS
1000 MATHS
1000 ANAT
1002 SOCI
1002 ECONS
1002 MATHS
1002 ANAT
and I want the above record to be inserted into a
table B(stno,subj1,subj2,subj3,subj4) in a row format such as :
stno subj1 subj2 stubj3 stubj4
---- ---- ----- ------ -------
1000 SOCI ECONS MATHS ANAT
How can the pivoting be performed on this?
If it is impossible, is there any way out?
Thanks for your usual co-operation.
June 20, 2003 - 5:43 pm UTC
if there is a fixed maximum number of course codes per stno, yes
select stno,
max(decode(rn,1,course_code)) s1,
...
max(decode(rn,N,course_code)) sN
from ( select stno, course_code,
row_number() over (partition by stno order by course_code )
from t )
group by stno
/
Great-the answer is right inside your book-expert-one-on-one
Godwin, June 23, 2003 - 6:36 am UTC
Hi posted the question to you before I realized the answer was in your book. I just got your book a few days ago and am now studying it.
But permit me to ask for a clarification on the answer you just posted. What if the maximum course code per stno is not known? that is if there are more than thousands course codes? In this case, I believe the selected records can't be inserted into a table since the column in the inserting table may not be known. But can the query to display the records in this case be possible? can you show with example?
Thanks.
June 23, 2003 - 8:19 am UTC
see the original answer -- you can use a COLLECTION, or you could even use a cursor variable.
select stno, CURSOR( select course_code from t t2 where t2.stno = t.stno )
from (select distinct stno from t ) T
/
like this;
scott@ORA920> select deptno, Cursor(select ename from emp e2 where e2.deptno = emp.deptno)
2 from (select distinct deptno from emp ) emp;
DEPTNO CURSOR(SELECTENAMEFR
---------- --------------------
10 CURSOR STATEMENT : 2
CURSOR STATEMENT : 2
ENAME
----------
CLARK
KING
MILLER
20 CURSOR STATEMENT : 2
CURSOR STATEMENT : 2
ENAME
----------
SMITH
JONES
SCOTT
ADAMS
FORD
30 CURSOR STATEMENT : 2
CURSOR STATEMENT : 2
ENAME
----------
ALLEN
WARD
MARTIN
BLAKE
TURNER
JAMES
Thanks Tom
Sirisha Swahari, July 15, 2003 - 6:19 pm UTC
This example simplified my work a lot.
Keep up the good work Tom.
ARC, July 25, 2003 - 3:08 am UTC
Very good explanation on pivot query.
I have info in table like this.
Table: TT
s date,
a number,
b number,
c nuber
SQL> select * from tt;
S A B C
--------- --------- --------- ---------
25-JUL-01 100 1000 2000
20-JUL-01 200 3000 4000
I would like to display info as below
25-JUL-01
1 100
2 1000
3 2000
20-JUL-01
1 200
2 3000
3 4000
No of columns are not fixed.
Please help me in regard. Thanking you in advance.
July 25, 2003 - 7:08 am UTC
the number of columns MUST be known, else you cannot write the query and to write the query is easy:
select dt, decode(r,1,a,2,b,3,c)
from t, (select rownum r from all_objects where rownum <= 3 )
/
pivot
ARC, August 01, 2003 - 3:32 am UTC
Hi Tom,
Need your help again.
I have query like below.
break on report
compute sum of deptno_10 on report
compute sum of deptno_20 on report
compute sum of deptno_30 on report
compute sum of total on report
select job,
max(decode(deptno, 10, cnt, 0)) DEPTNO_10,
max(decode(deptno, 20, cnt, 0)) DEPTNO_20,
max(decode(deptno, 30, cnt, 0)) DEPTNO_30,
max(decode(deptno, 10, cnt, 0)) +
max(decode(deptno, 20, cnt, 0)) +
max(decode(deptno, 30, cnt, 0)) TOTAL
from (select deptno deptno, job job, count(*) cnt from emp
group by deptno, job)
group by job;
JOB DEPTNO_10 DEPTNO_20 DEPTNO_30 TOTAL
--------- --------- --------- --------- ---------
ANALYST 0 2 0 2
CLERK 1 2 1 4
MANAGER 1 1 1 3
PRESIDENT 1 0 0 1
SALESMAN 0 0 5 5
--------- --------- --------- ---------
sum 3 5 7 15
1)Is it possible to display 'TOTAL' insted of 'sum' in above report?
2)If deptno column values are changing how to handle above query in more generic?
Thanks you very much.
August 01, 2003 - 7:56 am UTC
1) don't think so, plus is what it is -- very very rudimentary, simple reporting tool.
2) if you have my book "Expert one on one Oracle" -- see the chapter on analytic functions. I have a stored procedure there. In short, you need to run a query to find the domain of deptnos so you can then write a dynamic sql query to pivot based on that set of values.
for ARC: use LABEL to change sum to TOTAL
Barbara Boehmer, August 04, 2003 - 7:13 pm UTC
In response to ARC's question # 1:
Yes, you can use LABEL to change sum to TOTAL, as demonstrated below:
SQL> break on report
SQL> compute sum LABEL 'TOTAL' of deptno_10 on report
SQL> compute sum of deptno_20 on report
SQL> compute sum of deptno_30 on report
SQL> compute sum of total on report
SQL> select job,
2 max (decode (deptno, 10, cnt, 0)) deptno_10,
3 max (decode (deptno, 20, cnt, 0)) deptno_20,
4 max (decode (deptno, 30, cnt, 0)) deptno_30,
5 max (decode (deptno, 10, cnt, 0)) +
6 max (decode (deptno, 20, cnt, 0)) +
7 max (decode (deptno, 30, cnt, 0)) total
8 from (select deptno, job, count (*) cnt
9 from emp
10 group by deptno, job)
11 group by job
12 /
JOB DEPTNO_10 DEPTNO_20 DEPTNO_30 TOTAL
--------- ---------- ---------- ---------- ----------
ANALYST 0 2 0 2
CLERK 1 2 1 4
MANAGER 1 1 1 3
PRESIDENT 1 0 0 1
SALESMAN 0 0 4 4
---------- ---------- ---------- ----------
TOTAL 3 5 6 14
SQL>
August 04, 2003 - 7:41 pm UTC
awesome, thanks much!
for ARC: another generic method when deptno column values are changing
Barbara Boehmer, August 04, 2003 - 7:37 pm UTC
In response to ARC's question # 2:
The following SQL to create SQL can be used to dynamically generate the query. If you run the script below, it will create another script (query.sql) with the desired query, allowing for whatever values of deptno exist, then execute that script. Since you seem to want to do this in SQL*Plus, you may like this method.
store set saved_settings replace
set echo off feedback off heading off pages 0 verify off
spool query.sql
prompt break on report
prompt compute sum label 'TOTAL' of deptno_10 on report
prompt compute sum of deptno_20 on report
prompt compute sum of deptno_30 on report
prompt compute sum of total on report
prompt select job
select ', max (decode (deptno, ' || deptno || ', cnt, 0)) deptno_' || deptno
from (select distinct deptno from emp)
/
select ', max (decode (deptno, ' || min_deptno || ', cnt, 0))'
from (select min (deptno) min_deptno from emp)
/
select '+ max (decode (deptno, ' || other_deptnos || ', cnt, 0))'
from (select distinct deptno other_deptnos from emp where deptno >
(select min(deptno) from emp))
/
prompt as total
prompt from (select deptno, job, count (*) cnt
prompt from emp
prompt group by deptno, job)
prompt group by job
prompt /
spool off
start saved_settings
start query.sql
Pivot
ARC, August 04, 2003 - 9:33 pm UTC
Thank you very much Mr.Barbara Boehmer.
Another Pivot
A reader, August 15, 2003 - 12:59 pm UTC
I would like to turn below query into Pivot. But anything I do gives me an error [ ORA-00904: invalid column name ] pointing somewhere in main FROM clause.
Could you help?
I was trying to use example in your book but did not get far. I can't figure out what is going wrong. Error as you can see is not very descriptive and misleading.
Thank you in advance.
This:
select status,
to_char( trunc( status_date,'MM' ), 'Month') Month,
count(1)
from loanapplication a
where a.status_date > to_date('12/31/02','MM/DD/YY')
and exists (select 1
from property b
where a.rec = b.loan_rec
and b.addr_rec IN (select rec
from address
where zip >= '94101' and zip <= '94199')
)
group by status, to_char(trunc(status_date,'MM'),'Month')
order by Month
Into:
select a.status,
decode (to_char (trunc (a.status_date,'MM'),'Month'), January, cnt, null) January,
decode (to_char (trunc (a.status_date,'MM'),'Month'), February, cnt, null) February,
decode (to_char (trunc (a.status_date,'MM'),'Month'), March, cnt, null) March,
decode (to_char (trunc (a.status_date,'MM'),'Month'), April, cnt, null) April,
decode (to_char (trunc (a.status_date,'MM'),'Month'), May, cnt, null) May,
decode (to_char (trunc (a.status_date,'MM'),'Month'), June, cnt, null) June,
decode (to_char (trunc (a.status_date,'MM'),'Month'), July, cnt, null) July,
decode (to_char (trunc (a.status_date,'MM'),'Month'), August, cnt, null) August
from (select status,
status_date,
count(*) cnt
from loanapplication
group by status, status_date
) a
where a.status_date > to_date('12/31/02','MM/DD/YY')
and exists (select 1
from property b
where a.rec = b.loan_rec
and b.addr_rec IN (select rec
from address
where zip >= '94101' and zip <= '94199')
)
group by a.status, a.status_date
August 15, 2003 - 1:05 pm UTC
decode (to_char (trunc (a.status_date,'MM'),'Month'), August, cnt, null) August
*
ERROR at line 9:
ORA-00904: "AUGUST": invalid identifier
i get that myself in 9i and:
decode (to_char (trunc (a.status_date,'MM'),'Month'), August, cnt, null) August
*
ERROR at line 9:
ORA-00904: invalid column name
in 8i and before.
the * pointed me right to it. Perhaps you need quotes about the 'August', and other months?
might be easier to just
decode( to_char(a.status_date, 'mm' ), 1, cnt, null ) Jan,
?
Same Pivot problem
A reader, August 15, 2003 - 2:48 pm UTC
Thank you for your recomendation. But I am still getting the error. It points to a column that is valid.
I am running 8.1.7.4 on Solaris 2.8.
1 select a.status,
2 decode( to_char(a.status_date, 'mm' ), 01, cnt, null ) "Jan",
3 decode( to_char(a.status_date, 'mm' ), 02, cnt, null ) "Feb",
4 decode( to_char(a.status_date, 'mm' ), 03, cnt, null ) "Mar",
5 decode( to_char(a.status_date, 'mm' ), 04, cnt, null ) "Apr",
6 decode( to_char(a.status_date, 'mm' ), 05, cnt, null ) "May",
7 decode( to_char(a.status_date, 'mm' ), 06, cnt, null ) "Jun",
8 decode( to_char(a.status_date, 'mm' ), 07, cnt, null ) "Jul",
9 decode( to_char(a.status_date, 'mm' ), 08, cnt, null ) "Aug"
10 from (select status,
11 status_date,
12 count(*) cnt
13 from mm_loanapplication
14 group by status, status_date
15 ) a
16 where a.status_date > to_date('12/31/02','MM/DD/YY')
17 and exists (select 1 from mm_property b
18 where a.rec = b.loan_rec
19 and b.addr_rec IN (select rec
20 from am_address
21 where zip >= '94101' and zip <= '94199')
22 )
23* group by a.status, a.status_date
ENVPRD@PROD> /
group by a.status, a.status_date
*
ERROR at line 23:
ORA-00904: invalid column name
August 15, 2003 - 3:57 pm UTC
it won't even get that far on my machine -- since a.rec does not exist -- you grouped it out.
ops$tkyte@ORA920> select a.status,
2 decode( to_char(a.status_date, 'mm' ), 01, cnt, null ) "Jan",
3 decode( to_char(a.status_date, 'mm' ), 02, cnt, null ) "Feb",
4 decode( to_char(a.status_date, 'mm' ), 03, cnt, null ) "Mar",
5 decode( to_char(a.status_date, 'mm' ), 04, cnt, null ) "Apr",
6 decode( to_char(a.status_date, 'mm' ), 05, cnt, null ) "May",
7 decode( to_char(a.status_date, 'mm' ), 06, cnt, null ) "Jun",
8 decode( to_char(a.status_date, 'mm' ), 07, cnt, null ) "Jul",
9 decode( to_char(a.status_date, 'mm' ), 08, cnt, null ) "Aug"
10 from (select status,
11 status_date,
12 count(*) cnt
13 from loanapplication
14 group by status, status_date
15 ) a
16 where a.status_date > to_date('12/31/02','MM/DD/YY')
17 and exists (select 1
18 from property b
19 where a.rec = b.loan_rec
20 and b.addr_rec IN (select rec
21 from address
22 where zip >= '94101'
23 and zip <= '94199')
24 )
25 group by a.status, a.status_date
26 /
where a.rec = b.loan_rec
*
ERROR at line 19:
ORA-00904: "A"."REC": invalid identifier
so, it is just not possible what you have there.... look deeper.
A reader, August 16, 2003 - 7:04 pm UTC
pivot two columns
mo, September 10, 2003 - 6:28 pm UTC
Tom:
I am trying to pivot two columns and can not get it to work. Do you have any hints. The quantity for each storage is not coming out right. It is defaulting everything to the first value which is zero.
select stock_number, storage_code,qty_available,
row_number() over(partition by stock_number order by stock_number nulls last) seq
from (select a.stock_number, b.storage_code,
compute_qty_stored(b.warehouse_id,a.stock_number,b.storage_Code) qty_available
from stock_item a, physical_inventory b
where a.stock_number = b.stock_number(+)
and a.stock_number = 'AC006'
union all
select a.stock_number, b.storage_code,
compute_qty_stored(b.warehouse_id,a.stock_number,b.storage_Code) qty_available
from stock_item a, storage_receipt b
where a.stock_number = b.stock_number(+)
and a.stock_number = 'AC006'
)
group by stock_number,storage_Code,qty_available
STOCK_NUMB STORAGE_CO
---------- ----------
QTY_AVAILABLE SEQ
------------- ----------
AC006 ABC1
0 1
AC006 ABC2
50 2
AC006 ABC3
50 3
AC006 ABC4
0 4
AC006 ABC5
0 5
AC006 ABC6
250 6
AC006
0 7
7 rows selected.
Then
select stock_number,
max(decode(seq,1,storage_code,null)) Loc#1,
max(decode(seq,1,qty_Available,null)) qty#1,
max(decode(seq,2,storage_code,null)) Loc#2,
max(decode(seq,1,qty_Available,null)) qty#2,
max(decode(seq,3,storage_code,null)) loc#3,
max(decode(seq,1,qty_Available,null)) qty#3,
max(decode(seq,4,storage_code,null)) loc#4,
max(decode(seq,1,qty_Available,null)) qty#4
from (
select stock_number, storage_code,qty_available,
row_number() over(partition by stock_number order by stock_number nulls last) seq
from (select a.stock_number, b.storage_code,a.description,
compute_qty_stored(b.warehouse_id,a.stock_number,b.storage_Code) qty_available
from stock_item a, physical_inventory b
where a.stock_number = b.stock_number(+)
and a.stock_number = 'AC006'
union all
select a.stock_number, b.storage_code,a.description,
compute_qty_stored(b.warehouse_id,a.stock_number,b.storage_Code) qty_available
from stock_item a, storage_receipt b
where a.stock_number = b.stock_number(+)
and b.warehouse_id(+) like 'NLS%' and a.stock_number = 'AC006'
)
group by stock_number,storage_Code,qty_available)
where seq <=4 and stock_number='AC006'
group by stock_number
/
STOCK_NUMB LOC#1 QTY#1 LOC#2 QTY#2 LOC#3 QTY#3 LOC#4 QTY#4
---------- ---------- ---------- ---------- ---------- ---------- ---------- ---------- ----------
AC006 ABC1 0 ABC2 0 ABC3 0 ABC4 0
1 row selected.
September 10, 2003 - 8:26 pm UTC
look closely as your select list.
look at the decode on the seq.
you always use 1 for qty#
you use 1, 2, 3, 4 for the others.
pivot
mo, September 11, 2003 - 12:41 pm UTC
Tom:
You are right thanks.
1. The result set has four locations and four quantites. If quantity is zero I do not want to print the location. Since I am printing this in an HTML table, I have to check for 4x3x2=24 different possibilites so that the values will be placed starting the first cell. Is there a way easier than this? This is what I mean
If (qty1 <> 0 and qty2 <> 0 and qty3 <> 0 and qty4 <> 0) THEN
htp.p('<TD>'||loc1||</TD>');
htp.p('<TD>'||loc2||</TD>');
htp.p('<TD>'||loc3||</TD>');
htp.p('<TD>'||loc4||</TD>');
END IF;
IF (qty1 <> 0 and qty2 = 0 and ......)
2. Instead of finding all quantities and then deciding not to print the quantities with "0" I modifed the query so that it will exculde those in the result set.
Problem here is that it exculded the stock numbers from the report and I wanted to show all of them? Is there a wrokaround for this or I am stuck with option 1?
Thank you
Pivot analytic results including nulls
Robert, October 07, 2003 - 11:55 am UTC
Tom,
We need a query to calculate the sum of invoices for a particular month by customer and product as well as the sum of invoices for a year ago. This is what I have came up with so far:
create table t (month_and_year date,
customer varchar2(20),
product varchar2(30),
invoice number)
/
insert into t values (to_date('01-May-2002','DD-MON-YYYY'), 'Central', 'Dog Chow', '100');
insert into t values (to_date('01-May-2002','DD-MON-YYYY'), 'West', 'Dog Chow', '100');
insert into t values (to_date('01-May-2002','DD-MON-YYYY'), 'East', 'Dog Chow', '100');
insert into t values (to_date('01-May-2002','DD-MON-YYYY'), 'North', 'Dog Chow', '100');
insert into t values (to_date('01-May-2002','DD-MON-YYYY'), 'Central', 'Cat Chow', '50');
insert into t values (to_date('01-May-2002','DD-MON-YYYY'), 'West', 'Cat Chow', '50');
insert into t values (to_date('01-May-2002','DD-MON-YYYY'), 'East', 'Cat Chow', '50');
insert into t values (to_date('01-May-2002','DD-MON-YYYY'), 'North', 'Cat Chow', '50');
insert into t values (to_date('01-Jun-2002','DD-MON-YYYY'), 'Central', 'Dog Chow', '75');
insert into t values (to_date('01-Jun-2002','DD-MON-YYYY'), 'West', 'Dog Chow', '75');
insert into t values (to_date('01-Jun-2002','DD-MON-YYYY'), 'East', 'Dog Chow', '75');
insert into t values (to_date('01-Jun-2002','DD-MON-YYYY'), 'North', 'Dog Chow', '75');
insert into t values (to_date('01-Jul-2002','DD-MON-YYYY'), 'Central', 'Cat Chow', '25');
insert into t values (to_date('01-Jul-2002','DD-MON-YYYY'), 'West', 'Cat Chow', '25');
insert into t values (to_date('01-Jul-2002','DD-MON-YYYY'), 'East', 'Cat Chow', '25');
insert into t values (to_date('01-Jul-2002','DD-MON-YYYY'), 'North', 'Cat Chow', '25');
insert into t values (to_date('01-May-2003','DD-MON-YYYY'), 'Central', 'Dog Chow', '200');
insert into t values (to_date('01-May-2003','DD-MON-YYYY'), 'West', 'Dog Chow', '200');
insert into t values (to_date('01-May-2003','DD-MON-YYYY'), 'East', 'Dog Chow', '200');
insert into t values (to_date('01-May-2003','DD-MON-YYYY'), 'North', 'Dog Chow', '200');
insert into t values (to_date('01-May-2003','DD-MON-YYYY'), 'Central', 'Cat Chow', '150');
insert into t values (to_date('01-May-2003','DD-MON-YYYY'), 'West', 'Cat Chow', '150');
insert into t values (to_date('01-May-2003','DD-MON-YYYY'), 'East', 'Cat Chow', '150');
insert into t values (to_date('01-May-2003','DD-MON-YYYY'), 'North', 'Cat Chow', '150');
insert into t values (to_date('01-May-2003','DD-MON-YYYY'), 'Central', 'Beggin Strips','60');
insert into t values (to_date('01-May-2003','DD-MON-YYYY'), 'West', 'Beggin Strips','60');
insert into t values (to_date('01-May-2003','DD-MON-YYYY'), 'East', 'Beggin Strips','60');
insert into t values (to_date('01-May-2003','DD-MON-YYYY'), 'North', 'Beggin Strips','60');
select cy.month_and_year,
cy.customer,
cy.product,
cy.cy_invoices,
ly.ly_invoices
from (select month_and_year,
customer,
product,
SUM(invoice) over
(partition by month_and_year, customer, product
order by month_and_year) cy_invoices
from t) cy,
(select month_and_year,
customer,
product,
SUM(invoice) over
(partition by month_and_year, customer, product
order by month_and_year) ly_invoices
from t) ly
where trunc(cy.month_and_year,'MONTH') = add_months(trunc(sysdate,'MONTH'),-5)
and trunc(cy.month_and_year,'MONTH') = add_months(trunc(ly.month_and_year,'MONTH'),+12)
and (cy.customer = nvl(ly.customer,cy.customer) or ly.customer = nvl(cy.customer,ly.customer))
and (cy.product = nvl(ly.product,cy.product) or ly.product = nvl(cy.product,ly.product))
order by cy.cy_invoices desc
This returns:
MONTH_AND_YEAR CUSTOMER PRODUCT CY_INVOICES LY_INVOICES
------------------- ------------ ------------------ ----------- -----------
2003-05-01 00:00:00 Central Cat Chow 150 50
2003-05-01 00:00:00 Central Dog Chow 200 100
2003-05-01 00:00:00 East Cat Chow 150 50
2003-05-01 00:00:00 East Dog Chow 200 100
2003-05-01 00:00:00 North Cat Chow 150 50
2003-05-01 00:00:00 North Dog Chow 200 100
2003-05-01 00:00:00 West Cat Chow 150 50
2003-05-01 00:00:00 West Dog Chow 200 100
8 rows selected.
I am missing the 4 rows for beggin strips because of missing year ago data.
Can you point out what I am missing?
Thanks.
October 07, 2003 - 12:58 pm UTC
don't think you want analytics at all here -- just a simple pivot. this creates a CY column of summed invoices for the data for the year we are in, and a LY column for last year. Then, group by takes care of squishing out the extra rows by month.
If you have many years of data -- the where clause would be different -- to include a where on the years of interest of course.
ops$tkyte@ORA920> select to_char( month_and_year, 'Mon' ),
2 customer,
3 product,
4 sum( decode(to_char(month_and_year,'yyyy'), to_char(sysdate,'yyyy'), invoice, null ) ) cy,
5 sum( decode(to_char(month_and_year,'yyyy'), to_char(add_months(sysdate,-12),'yyyy'), invoice, null ) ) ly
6 from t
7 where to_char(month_and_year,'mon') = 'may'
8 group by to_char( month_and_year, 'Mon' ), customer, product
9 /
TO_ CUSTOMER PRODUCT CY LY
--- -------------------- ------------------------------ ---------- ----------
May East Cat Chow 150 50
May East Dog Chow 200 100
May East Beggin Strips 60
May West Cat Chow 150 50
May West Dog Chow 200 100
May West Beggin Strips 60
May North Cat Chow 150 50
May North Dog Chow 200 100
May North Beggin Strips 60
May Central Cat Chow 150 50
May Central Dog Chow 200 100
May Central Beggin Strips 60
12 rows selected.
Perfect
Robert Ware, October 07, 2003 - 2:23 pm UTC
Tom,
Thats exactly what we needed.
Thanks!
October 07, 2003 - 2:29 pm UTC
Oh -- one thing I wanted to add
THANK YOU
THANK YOU
THANK YOU
for giving me a create table and insert into statements !! you have no idea how much easier that is for me!
sometimes I get "nothing"
sometimes I get a describe (needs editing) and a select * from (needs LOTS of editing)
getting a ready to run script -- that's awesome.
Let's upload files....
Robert, November 07, 2003 - 2:40 pm UTC
>>THANK YOU
>for giving me a create table and insert into >statements !! you have no idea how
>much easier that is for me!
you know, maybe you should consider allowing reader file-upload and like display an icon next to the message so the page is shorter
Consecutive Numbers
Robert, November 18, 2003 - 3:23 pm UTC
SQL> select MIN(c_year), MAX(c_year)
2 from T
3 ;
MIN(C_YEAR) MAX(C_YEAR)
------------- --------------
1996 2003
There may be gaps in c_year value....How can I return
a list of c_year in CONSECUTIVE...
1996
1997
1998
1999
2000
2001
2002
2003
Thanks
November 21, 2003 - 11:06 am UTC
ops$tkyte@ORA920LAP> select min(c_year) min_c_year, max(c_year) max_c_year from t;
MIN_C_YEAR MAX_C_YEAR
---------- ----------
1996 2003
ops$tkyte@ORA920LAP>
ops$tkyte@ORA920LAP> select (select min(c_year) from t)+rownum-1
2 from all_objects
3 where rownum <= (select max(c_year)-min(c_year)+1 from t)
4 /
(SELECTMIN(C_YEAR)FROMT)+ROWNUM-1
---------------------------------
1996
1997
1998
1999
2000
2001
2002
2003
8 rows selected.
Pivoting example using ref cursor
David, December 31, 2003 - 2:47 pm UTC
Tom, in this posting above you say:
"If you have my book -- the last section of the analytic functions chapter shows how to pivot any query using a ref cursor and some simple query rewrite techniques"
I bought your book "Effective Oracle by Design" (enjoy it tremendously :D ) and looking at pages 514-534 for this example but can't see it... Did I look into the wrong book?
December 31, 2003 - 3:03 pm UTC
at the point in time of this original posting, "my book" was unambigous -- there was only one.
Now there are three.... I was refering to Expert One on One Oracle. Here is a snippet to get you interested in the rest of that book:
.....
One other thing we must know is the MAXIMUM number of rows per partition we anticipate. This will dictate the number of columns we will be generating. Without it - we cannot pivot. SQL needs to know the number of columns and there is no way around that fact. That leads us into the next more generic example of pivoting. If we do not know the number of total columns until runtime, we'll have to use dynamic SQL to deal with the fact that the SELECT list is variable. We can use PL/SQL to demonstrate how to do this - and end up with a generic routine that can be reused whenever you need a pivot. This routine will have the following specification:
scott@TKYTE816> create or replace package my_pkg
2 as
3 type refcursor is ref cursor;
4 type array is table of varchar2(30);
5
6 procedure pivot( p_max_cols in number default NULL,
7 p_max_cols_query in varchar2 default NULL,
8 p_query in varchar2,
9 p_anchor in array,
10 p_pivot in array,
11 p_cursor in out refcursor );
12 end;
13 /
Package created.
Here, you must send in either P_MAX_COLS or P_MAX_COLS_QUERY. SQL needs to know the number of columns in a query and this parameter will allow us to build a query with the proper number of columns. The value you should send in here will be the output of a query similar to:
scott@TKYTE816> select max(count(*)) from emp group by deptno, job;
That is - it is the count of the discrete values that are currently in ROWS that we will put into COLUMNS. You can either send in the query to get this number, or the number if you already know it.
The P_QUERY parameter is simply the query that gathers your data together. Using the last example from above the query would be:
10 from ( select deptno, job, ename, sal,
11 row_number() over ( partition by deptno, job
12 order by sal, ename ) rn
13 from emp
14 )
The next two inputs are arrays of column names. The P_ANCHOR tells us what columns will stay CROSS RECORD (down the page) and P_PIVOT states the columns that will go IN RECORD (across the page). In our example from above, P_ANCHOR = ( `DEPTNO', `JOB' ) and P_PIVOT = (`ENAME','SAL'). Skipping over the implementation for a moment, the entire call put together might look like this:
scott@TKYTE816> variable x refcursor
scott@TKYTE816> set autoprint on
scott@TKYTE816> begin
2 my_pkg.pivot
3 ( p_max_cols_query => 'select max(count(*)) from emp
group by deptno,job',
4 p_query => 'select deptno, job, ename, sal,
5 row_number() over ( partition by deptno, job
6 order by sal, ename ) rn
7 from emp a',
8 p_anchor => my_pkg.array( 'DEPTNO','JOB' ),
9 p_pivot => my_pkg.array( 'ENAME', 'SAL' ),
10 p_cursor => :x );
11 end;
12 /
PL/SQL procedure successfully completed.
DEPTNO JOB ENAME_ SAL_1 ENAME_2 SAL_2 ENAME_3 SAL_3 ENAME_ SAL_4
------ --------- ------ ----- ---------- ----- ---------- ----- ------ -----
10 CLERK MILLER 1300
10 MANAGER CLARK 2450
10 PRESIDENT KING 5000
20 ANALYST FORD 3000 SCOTT 3000
20 CLERK SMITH 800 ADAMS 1100
20 MANAGER JONES 2975
30 CLERK JAMES 99
30 MANAGER BLAKE 99
30 SALESMAN ALLEN 99 MARTIN 99 TURNER 99 WARD 99
9 rows selected.
As you can see - that dynamically rewrote our query using the generalized template we developed. The implementation of the package body is straightforward:
scott@TKYTE816> create or replace package body my_pkg
2 as
3
4 procedure pivot( p_max_cols in number default NULL,
5 p_max_cols_query in varchar2 default NULL,
6 p_query in varchar2,
7 p_anchor in array,
8 p_pivot in array,
9 p_cursor in out refcursor )
10 as
11 l_max_cols number;
12 l_query long;
13 l_cnames array;
14 begin
15 -- figure out the number of columns we must support
16 -- we either KNOW this or we have a query that can tell us
17 if ( p_max_cols is not null )
18 then
19 l_max_cols := p_max_cols;
20 elsif ( p_max_cols_query is not null )
21 then
22 execute immediate p_max_cols_query into l_max_cols;
23 else
24 raise_application_error(-20001, 'Cannot figure out max cols');
25 end if;
26
27
28 -- Now, construct the query that can answer the question for us...
29 -- start with the C1, C2, ... CX columns:
30
31 l_query := 'select ';
32 for i in 1 .. p_anchor.count
33 loop
34 l_query := l_query || p_anchor(i) || ',';
35 end loop;
36
37 -- Now add in the C{x+1}... CN columns to be pivoted:
38 -- the format is "max(decode(rn,1,C{X+1},null)) cx+1_1"
39
40 for i in 1 .. l_max_cols
41 loop
42 for j in 1 .. p_pivot.count
43 loop
44 l_query := l_query ||
45 'max(decode(rn,'||i||','||
46 p_pivot(j)||',null)) ' ||
47 p_pivot(j) || '_' || i || ',';
48 end loop;
49 end loop;
50
51 -- Now just add in the original query
52 l_query := rtrim(l_query,',')||' from ( '||p_query||') group by ';
53
54 -- and then the group by columns...
55
56 for i in 1 .. p_anchor.count
57 loop
58 l_query := l_query || p_anchor(i) || ',';
59 end loop;
60 l_query := rtrim(l_query,',');
61
62 -- and return it
63 execute immediate 'alter session set cursor_sharing=force';
64 open p_cursor for l_query;
65 execute immediate 'alter session set cursor_sharing=exact';
66 end;
67
68 end;
69 /
Package body created.
It only does a little string manipulation to rewrite the query and open a REF CURSOR dynamically. In the likely event the query had a predicate with constants and such in it, we set cursor sharing on and then back off for the parse of this query to facilitate bind variables (see the section on tuning for more information on that). Now we have a fully parsed query that is ready to be fetched from.
RE: Pivoting example using ref cursor
David, December 31, 2003 - 3:28 pm UTC
Thank you Tom!
I thought Expert One-on-One Oracle is mostly conceptual book vs. Effective by Design which is mostly practical, but i guess I'll have to think again :)
6 stars as always ;)
David
Dear Tom, Happy New Year !
Sami, December 31, 2003 - 7:24 pm UTC
<asktom>
at the point in time of this original posting, "my book" was unambigous -- there
was only one.
</asktom>
I thought FOUR
3)"Beginning Oracle Programming"
4)"Professional Oracle 8i Application Programming with Java, PL/SQL and XML "
December 31, 2003 - 7:37 pm UTC
I don't count 4) -- i had a single chapter in it :)
Is this pivoting?
Trevor Welch, January 09, 2004 - 6:19 pm UTC
Hi Tom,
I have a table with say stock intradata
DATE STOCK_CODE LAST_PRICE LAST_TRADE_TIME
01-JAN-2004 ABC 2.40 09:00
01-JAN-2004 ABC 2.41 09:05
01-JAN-2004 ABC 2.43 09:10
01-JAN-2004 ABC 2.39 10:00
01-JAN-2004 ABC 2.32 11:00
01-JAN-2004 ABC 2.41 11:31
01-JAN-2004 ABC 2.43 11:35
01-JAN-2004 ABC 2.40 12:00
01-JAN-2004 ABC 2.41 12:05
My requirement is for each half hour of the day to
be assigned a Character.
9:00 - 9:30 A
9:31 - 10:00 B
10:01 - 10:30 C
10:31 - 11:00 D
11:01 - 11:30 E
11:31 - 12:00 F
12:01 - 12:31 E
etc ... to 17:00
So the report required is like this
2.32 D
2.39 A
2.40 AF
2.41 AEF
2.43 F
Can you give me some pointers on how to do this please?
Thanks Trevor
January 10, 2004 - 10:43 am UTC
that is not "pivoting", that is aggregation.
questions -- why is there a 'date' and a 'last trade time'. that is really just a single column in 'real life' right.
Also, how do 2.40, 2.41, 2.43 become 2.39???? (letter A)
also, your time ranges are "strange"
9am sharp
but 10:01, 11:01 after that.
Hows about this
09:00 <= DT < 09:30 -> A
09:30 <= DT < 10:00 -> B
10:00 <= DT < 10:30 -> C
and so on...
And lastly, not getting that output in the least. AF? AEF?? huh whats up with that.
As i'll be away for a while you can start your endeavor using this technique:
ops$tkyte@ORA9IR2> select dt,
2 trunc(to_char(dt,'sssss')/(30*60)),
3 chr( ascii('A')+trunc(to_char(dt,'sssss')/(30*60))-18 )
4 from t;
DT TRUNC(TO_CHAR(DT,'SSSSS')/(30*60)) C
----------------- ---------------------------------- -
01-jan-2004 09:00 18 A
01-jan-2004 09:05 18 A
01-jan-2004 09:10 18 A
01-jan-2004 10:00 20 C
01-jan-2004 11:00 22 E
01-jan-2004 11:31 23 F
01-jan-2004 11:35 23 F
01-jan-2004 12:00 24 G
01-jan-2004 12:05 24 G
01-jan-2004 13:29 26 I
01-jan-2004 13:30 27 J
01-jan-2004 13:31 27 J
01-jan-2004 13:59 27 J
01-jan-2004 14:00 28 K
01-jan-2004 14:01 28 K
15 rows selected.
It gets your A, B, C assigned as per my method -- from there, i'm not sure what the logic is
A bit more info
Trevor Welch, January 17, 2004 - 6:38 am UTC
Tom,
Thanks for your reply.
First of sorry, I didn't quite explain my requirements and there was an error in it so I'll have another go with
and actual screen capture of "Market Profile" in action
You are quite correct the Date column and last trade time are actually the same column.
I liked your technique however what I actually need is a "graph" of when the prices occured per each half hour eg
I am basing this request of the Chicago board of trade "Market Profile" Tool.
The Market Profile day is split into half-hour time periods, A is 0800 to 0830,
B is 0830 to 0900, etc.
Soybeans open at 0930 (D). In the profile below, the opening half hour ranged from 6664 to 6690.
The next period, E, covered 6680 to 6690; and so on for the rest of the day.
SN SOYBEANS (CBOT) JUL 98 2-MAR-98
6710 F | <== Upper Extreme price
6704 F |
6700 F |
6696 FG | Upper Range Extension
6694 EFG | |
6690 DEFGH | | Initial Balance
6686 DEGH | | (6694 to 6664)
6684 DEGHIJ | Value Area |
6682 DEGHIJ | 70% of Trade | <== POC 6682
6680 DEHIJK | (6694 - 6672) |
6676 DHIJK | |
6674 DHIJK | |
6672 DHK | |
6670 DHK |
6664 DK |
6654 K |
6650 K |
6646 K |
6644 K | Lower
6630 K | Tail (single prints, 6654 - 6620)
6624 K |
6620 K | <==Lower Extreme price
You said >>Also, how do 2.40, 2.41, 2.43 become 2.39???? (letter A)
2.40 2.41 2.43 don't become 2.39 they are assigned a letter representing each half hour period they occured in.
Does the above example make it any clearer?
Regards
Trevor
January 18, 2004 - 9:03 am UTC
not really -- a little -- but not really (i don't have a set of inputs, desired outputs).
sorry -- don't think I'll be able to answer your question here in the review/followup section -- when I'm taking quesitons -- go for it there, this is bigger than a breadbox.
Pivot on columns from table
Marcio, March 16, 2004 - 2:28 pm UTC
Consider this:
create table t(
p VARCHAR2(1) constraint pk primary key,
a number(13,9),
b number(13,9),
k number(13,9)
);
insert into t values ('A', 10, 15.59040617, 5.493248938);
insert into t values ('B', 10.80674214, 16.71941596, 5.333903907);
insert into t values ('C', 10, 1516.238149, 14.64789478);
insert into t values ('D', 10, 15.59040617, 5.493248938);
insert into t values ('E', 10.80674214, 16.71941596, 5.333903907);
commit;
select 'a' p,
max(decode(p, 'A', a, null)) a,
max(decode(p, 'B', a, null)) b,
max(decode(p, 'C', a, null)) c,
max(decode(p, 'D', a, null)) d,
max(decode(p, 'E', a, null)) e
from t
union
select 'b' p,
max(decode(p, 'A', b, null)) a,
max(decode(p, 'B', b, null)) b,
max(decode(p, 'C', b, null)) c,
max(decode(p, 'D', b, null)) d,
max(decode(p, 'E', b, null)) e
from t
union
select 'k' p,
max(decode(p, 'A', k, null)) a,
max(decode(p, 'B', k, null)) b,
max(decode(p, 'C', k, null)) c,
max(decode(p, 'D', k, null)) d,
max(decode(p, 'E', k, null)) e
from t
/
The result:
~~~~~~~~~~~
P A B C D E
- ---------- ---------- ---------- ---------- ----------
a 10 10,8067421 10 10 10,8067421
b 15,5904062 16,719416 1516,23815 15,5904062 16,719416
k 5,49324894 5,33390391 14,6478948 5,49324894 5,33390391
The Question:
~~~~~~~~~~~~~
I would like know if is possible to do the query above access just once the table T.
The plan show me 3 fts.
Execution Plan
----------------------------------------------------------
0 SELECT STATEMENT Optimizer=CHOOSE
1 0 SORT (UNIQUE)
2 1 UNION-ALL
3 2 SORT (AGGREGATE)
4 3 TABLE ACCESS (FULL) OF 'T'
5 2 SORT (AGGREGATE)
6 5 TABLE ACCESS (FULL) OF 'T'
7 2 SORT (AGGREGATE)
8 7 TABLE ACCESS (FULL) OF 'T'
Thank you,
Marcio
March 16, 2004 - 2:46 pm UTC
ops$tkyte@ORA9IR2> set autotrace on explain
ops$tkyte@ORA9IR2> select decode( x, 1, 'a', 2, 'b', 3, 'k' ) pp,
2 max(decode(p,'A',decode(x,1,a,2,b,k))) a,
3 max(decode(p,'B',decode(x,1,a,2,b,k))) b,
4 max(decode(p,'C',decode(x,1,a,2,b,k))) c,
5 max(decode(p,'D',decode(x,1,a,2,b,k))) d,
6 max(decode(p,'E',decode(x,1,a,2,b,k))) e
7 from t, (select 1 x from dual union all
8 select 2 x from dual union all
9 select 3 x from dual )
10 group by decode( x, 1, 'a', 2, 'b', 3, 'k' )
11 /
P A B C D E
- ---------- ---------- ---------- ---------- ----------
a 10 10.8067421 10 10 10.8067421
b 15.5904062 16.719416 1516.23815 15.5904062 16.719416
k 5.49324894 5.33390391 14.6478948 5.49324894 5.33390391
Execution Plan
----------------------------------------------------------
0 SELECT STATEMENT Optimizer=CHOOSE
1 0 SORT (GROUP BY)
2 1 NESTED LOOPS
3 2 VIEW
4 3 UNION-ALL
5 4 TABLE ACCESS (FULL) OF 'DUAL'
6 4 TABLE ACCESS (FULL) OF 'DUAL'
7 4 TABLE ACCESS (FULL) OF 'DUAL'
8 2 TABLE ACCESS (FULL) OF 'T'
Thank you
Marcio, March 17, 2004 - 8:09 am UTC
Still Confused How to Apply it
Mary W, April 02, 2004 - 3:31 pm UTC
i have a resutls set that looks lieke this:
email qNumber letterSequence Text
m@m.com 1 a null
m@m.com 2 d null
t@t.com 1 c null
t@t.com 1 b null
t@t.com 2 a txt
t@t.com 2 d null
i need the RS to look like:
email q1a q1b q1c q2a q2b q2c q2d
m@m.com a d
t@t.com c b txt d
April 02, 2004 - 3:41 pm UTC
select email,
max( decode( qnumber, 1, decode(letterSequence,'a','a') ) ) q1a,
max( decode( qnumber, 1, decode(letterSequence,'b','b') ) ) q1b,
max( decode( qnumber, 1, decode(letterSequence,'c','c') ) ) q1c,
.... same for 2 ....
from t
group by email;
WOW! You are a the best!
A reader, April 12, 2004 - 8:53 am UTC
Thank you so very much! it works great!
--mary
How can we generate rows?
Dhrubo, April 21, 2004 - 9:46 am UTC
Hi Tom,
I have a select as given below :
SELECT START_DATE,END_DATE FROM SOME_TABLE WHERE SOME_ID = :A
Now SOME_ID being the primary key for SOME_TABLE, will return one row like
START_DATE END_DATE
---------- --------
12/06/2003 12/10/2003
Note that the difference between the start date and end date is 5 days.
So i want an output like this :
DAY DATE
--- ----
1 12/06/2003
2 12/07/2003
3 12/08/2003
4 12/09/2003
5 12/10/2003
How can i achieve this result , can you please help
Thanks in advance
April 21, 2004 - 8:43 pm UTC
ops$tkyte@ORA9IR2> select rn day, a+rn-1 dt
2 from (select a,b from t where id = 1),
3 (select rownum rn
4 from all_objects
5 where rownum <= (select ceil(b-a)+1 from t where id = 1))
6 /
DAY DT
---------- ---------
1 06-DEC-03
2 07-DEC-03
3 08-DEC-03
4 09-DEC-03
5 10-DEC-03
Collapsing null columns into 1 row using a pivot query.
ht, April 22, 2004 - 6:49 pm UTC
Tom,
Is there a way to modify the query below to produce results that look like this?
deptno isclerk ismanager ispresident
10 Miller Clark King
1 select deptno,
2 ( decode( val, 'CLERK', ename, null ) )isclerk,
3 ( decode( val, 'MANAGER', ename, null ) )ismanager,
4 ( decode( val, 'SALESMAN', ename, null ) ) issalesman,
5 ( decode( val, 'ANALYST', ename, null ) ) isanalyst,
6 ( decode( val, 'PRESIDENT', ename, null ) ) ispresident
7 from
8 (
9 select deptno,job val,ename
10 from scott.emp
11 where deptno=10
12 group by deptno,job,ename
13 )
14* group by deptno,val,ename
15 /
DEPTNO ISCLERK ISMANAGER ISSALESMAN ISANALYST ISPRESIDEN
---------- ---------- ---------- ---------- ---------- ----------
10 MILLER
10 CLARK
10 KING
3 rows selected.
>
April 23, 2004 - 10:12 am UTC
what do you want to have happen when there are 10 clerks in a single deptno?
A reader, April 22, 2004 - 8:00 pm UTC
Tom,
I figured it out:
select
max( decode( job, 'CLERK', ename ) )isclerk,
max( decode( job, 'MANAGER', ename) )ismanager,
max( decode( job, 'PRESIDENT', ename ) ) ispresident
from ( select deptno,job,ename from scott.emp where deptno=10 )
April 23, 2004 - 10:16 am UTC
i'll do the yahbut here...
change 10 to 20 -- now what sense does the "isclerk" field make.
A reader, April 23, 2004 - 1:46 pm UTC
Hi Tom,
You're correct, if more than 1 clerk exists in dept 10, this won't work. My data guarantees no duplicates - I just used the scott.emp table as an example since it would (I had hoped) be a better starting point. Sorry about that.
ht
A reader, June 07, 2004 - 12:26 pm UTC
Tom, please help, it's urgent
this pivot query works fine:
select item_code a, sum(decode(cSize,'small',cnt,0)) b,
sum(decode(cSize,'medium',cnt,0)) c,
sum(decode(cSize,'large',cnt,0)) d
from(
select item_code, decode(substr(item_code,8,3),
'S','small',
'M','medium',
'L','large' ) as cSize,
sum(NVL(BAL_ON_HAND,0)-NVL(OPEN_ORDERs,0)) as cnt
from inventory
where account_id=45
group by item_code, decode(substr(item_code,8,3),
'S','small',
'M','medium',
'L','large' )
)
group by item_code
order by a;
When I added substr to item_code I got error:
ERROR at line 17:
ORA-00904: "ITEM_CODE": invalid identifier
my query is:
select substr(item_code,1,instr(item_code,'-',1,2)-1) a, sum(decode(cSize,'small',cnt,null)) b,
sum(decode(cSize,'medium',cnt,null)) c,
sum(decode(cSize,'large',cnt,null)) d
from(
select substr(item_code,1,instr(item_code,'-',1,2)-1) , decode(substr(item_code,instr(item_code,'-',1,2)+1,3),
'S','small',
'M','medium',
'L','large' ) as cSize,
sum(NVL(BAL_ON_HAND,0)-NVL(OPEN_ORDERs,0)) as cnt
from inventory
where account_id=45
group by substr(item_code,1,instr(item_code,'-',1,2)-1),decode(substr(item_code,instr(item_code,'-',1,2)+1,3),
'S','small',
'M','medium',
'L','large' )
)
group by substr(item_code,1,instr(item_code,'-',1,2)-1)
order by a;
thank you.
June 07, 2004 - 1:34 pm UTC
rom(
select substr(item_code,1,instr(item_code,'-',1,2)-1) ITEM_CODE,
decode(substr(item_code,instr(item_code,'-',1,2)+1,3),
'S','small',
'M','medium',
'L','large' ) as cSize,
Good reminder
velvet, June 15, 2004 - 5:57 am UTC
I love this page. Just can't remember this trick and when it's needed I just type in 'pivot table' in the site search and thats it!
what is wrong in the following pivot?
A reader, June 23, 2004 - 1:35 pm UTC
I am missing something simple. Trying to pivot
columns into rows...
----
scott@ORA10G> drop table t1;
Table dropped.
scott@ORA10G> create table t1
2 (
3 x number,
4 y number,
5 z number
6 );
Table created.
scott@ORA10G>
scott@ORA10G> insert into t1 values( 1, 2, 3 );
1 row created.
scott@ORA10G> insert into t1 values( 2, 2, 10 );
1 row created.
scott@ORA10G> insert into t1 values( 2, 2, 9 );
1 row created.
scott@ORA10G> insert into t1 values( 3, 5, 5 );
1 row created.
scott@ORA10G> commit;
Commit complete.
scott@ORA10G>
scott@ORA10G> select * from t1;
X Y Z
---- ---- ----
1 2 3
2 2 10
2 2 9
3 5 5
scott@ORA10G>
scott@ORA10G> column x format 999
scott@ORA10G> column y format 999
scott@ORA10G> column z format 999
scott@ORA10G> column avg_x format 999
scott@ORA10G> column avg_y format 999
scott@ORA10G> column avg_z format 999
scott@ORA10G>
scott@ORA10G> select avg(x) avg_x, avg(y) avg_y, max(x) max_x, max(y) max_y
2 from t1;
AVG_X AVG_Y MAX_X MAX_Y
----- ----- ---------- ----------
2 3 3 5
scott@ORA10G> /* I want the output to be
scott@ORA10G> Column Average Max
scott@ORA10G> 'x' 2 3
scott@ORA10G> 'y' 3 5
scott@ORA10G> */
scott@ORA10G>
scott@ORA10G> /* First I create the select to pivot columns into rows */
scott@ORA10G>
scott@ORA10G> select avg_x, avg_y, max_x, max_y , r
2 from
3 (
4 select avg(x) avg_x, avg(y) avg_y, max(x) max_x, max(y) max_y
5 from t1
6 ) a,
7 ( select rownum r from all_objects where rownum <= 4 );
AVG_X AVG_Y MAX_X MAX_Y R
----- ----- ---------- ---------- ----------
2 3 3 5 1
2 3 3 5 2
2 3 3 5 3
2 3 3 5 4
scott@ORA10G>
scott@ORA10G> /* Next I use decode to pivot */
scott@ORA10G> select decode(r, 1, avg_x, 2, avg_y, 3, max_x, 4, max_y ) details
2 from
3 (
4 select avg_x, avg_y, max_x, max_y , r
5 from
6 (
7 select avg(x) avg_x, avg(y) avg_y, max(x) max_x, max(y) max_y
8 from t1
9 ) a,
10 ( select rownum r from all_objects where rownum <= 4 )
11 );
DETAILS
----------
2
2.75 <-----should have got avg_y = 3 here?
3
5
-----
I was expecting 3 (avg_y) above instead of 2.75?
What went wrong?
June 23, 2004 - 1:46 pm UTC
column details format 999
you formatted x,y,z avg_y and so on with a 999 mask.
you didn't do that for DETAILS
the real average is 2.75, 3 is the rounded off one.
thanx!!!
A reader, June 23, 2004 - 1:51 pm UTC
ok here is my solution for the pivot problem
A reader, June 23, 2004 - 2:13 pm UTC
This is refering back to q above where
I wanted an output as
---
col_name average max
'x' 2.00 3.00
'y' 2.75 5.00
The select at the end does it for me - but
is there a more elegant solution?
thanx!
scott@ORA10G> drop table t1;
Table dropped.
scott@ORA10G> create table t1
2 (
3 x number,
4 y number,
5 z number
6 );
Table created.
scott@ORA10G>
scott@ORA10G> insert into t1 values( 1, 2, 3 );
1 row created.
scott@ORA10G> insert into t1 values( 2, 2, 10 );
1 row created.
scott@ORA10G> insert into t1 values( 2, 2, 9 );
1 row created.
scott@ORA10G> insert into t1 values( 3, 5, 5 );
1 row created.
scott@ORA10G> commit;
Commit complete.
scott@ORA10G>
scott@ORA10G> select * from t1;
X Y Z
---- ---- ----
1 2 3
2 2 10
2 2 9
3 5 5
scott@ORA10G>
scott@ORA10G> column x format 999
scott@ORA10G> column y format 999
scott@ORA10G> column z format 999
scott@ORA10G> column avg_x format 999.99
scott@ORA10G> column avg_y format 999.99
scott@ORA10G> column avg_z format 999.99
scott@ORA10G> column average format 999.99
scott@ORA10G> column max format 999.99
scott@ORA10G> column details format 999.99
scott@ORA10G>
scott@ORA10G> select avg(x) avg_x, avg(y) avg_y, max(x) max_x, max(y) max_y
2 from t1;
AVG_X AVG_Y MAX_X MAX_Y
------- ------- ---------- ----------
2.00 2.75 3 5
scott@ORA10G> /* I want the output to be
scott@ORA10G> Column Average Max
scott@ORA10G> 'x' 2.00 3
scott@ORA10G> 'y' 2.75 5
scott@ORA10G> */
scott@ORA10G>
scott@ORA10G> /* First I create the select to pivot columns into rows */
scott@ORA10G>
scott@ORA10G> select avg_x, avg_y, max_x, max_y , r
2 from
3 (
4 select avg(x) avg_x, avg(y) avg_y, max(x) max_x, max(y) max_y
5 from t1
6 ) a,
7 ( select rownum r from all_objects where rownum <= 4 );
AVG_X AVG_Y MAX_X MAX_Y R
------- ------- ---------- ---------- ----------
2.00 2.75 3 5 1
2.00 2.75 3 5 2
2.00 2.75 3 5 3
2.00 2.75 3 5 4
scott@ORA10G>
scott@ORA10G> /* Next I use decode to pivot */
scott@ORA10G> select decode(r, 1, avg_x ) average, decode( r, 2, max_x) max,
2 decode(r, 3, avg_y) average, decode( r, 4, max_y) max
3 from
4 (
5 select avg_x, avg_y, max_x, max_y , r
6 from
7 (
8 select avg(x) avg_x, avg(y) avg_y, max(x) max_x, max(y) max_y
9 from t1
10 ) a,
11 ( select rownum r from all_objects where rownum <= 4 )
12 );
AVERAGE MAX AVERAGE MAX
------- ------- ------- -------
2.00
3.00
2.75
5.00
scott@ORA10G>
scott@ORA10G> select * from
2 (
3 with common_query as
4 (
5 select avg_x, avg_y, max_x, max_y , r
6 from
7 (
8 select avg(x) avg_x, avg(y) avg_y, max(x) max_x, max(y) max_y
9 from t1
10 ) a,
11 ( select rownum r from all_objects where rownum <= 4 )
12 )
13 select col_name, max(average) average, max(max) max
14 from
15 (
16 select case when r = 1 or r = 2 then 'x' end col_name,
17 decode(r, 1, avg_x ) average, decode( r, 2, max_x) max
18 from common_query
19 union
20 select case when r = 3 or r = 4 then 'y' end col_name,
21 decode(r, 3, avg_y) average, decode( r, 4, max_y) max
22 from common_query
23 )
24 group by col_name
25 )
26 where col_name is not null;
C AVERAGE MAX
- ------- -------
x 2.00 3.00
y 2.75 5.00
scott@ORA10G>
June 23, 2004 - 2:40 pm UTC
ops$tkyte@ORA9IR2> select decode( r, 1, 'X', 2, 'Y', 'Z' ) col,
2 decode( r, 1, avg_x, 2, avg_y, 3, avg_z ) avg,
3 decode( r, 1, max_x, 2, max_y, 3, max_z ) max
4 from ( select max(x) max_x, avg(x) avg_x,
5 max(y) max_y, avg(y) avg_y,
6 max(z) max_z, avg(z) avg_z
7 from t1
8 ),
9 (select rownum r from all_objects where rownum <= 3
10 )
11 /
C AVG MAX
- ---------- ----------
X 2 3
Y 2.75 5
Z 6.75 10
:)
A reader, June 23, 2004 - 2:49 pm UTC
my solution was almost embarrasingly complicated
compared to yours:)
thanx!
Thank you! Just what I needed
Reena, July 01, 2004 - 2:10 pm UTC
Extremely useful. Loved the explaination about the cartesian product posted by someone above.
Thank you, Tom!
From a pivot table....
mary W, July 22, 2004 - 10:04 am UTC
Tom,
I have a table with c_data
select * from c_data;
CHAN_ID CH_1 CH_4 CH_5 CH_6
---------- ---------- ---------- ---------- ----------
1 100 100 100
4 100 78 60
5 .79 30.95 100 69.05
I need to get this data in the following form:
CHAN_ID REL_CHAN_ID RANK
------------ -------------- ---------
1 1 100
1 4
1 5 100
1 6 100
4 1
4 4 100
4 5 78
4 6 60
etc.....
How can I un-pivot table c_data?
Thanks in advance.
July 23, 2004 - 7:44 am UTC
no create table...
no insert into....
so no tested answer -- just an off the cuff on, might run, might not (your review looks just like the example i use in my review page - the one that says "DON'T DO THIS, don't give me this information"):
CHAN_ID CH_1 CH_4 CH_5 CH_6
select chan_id,
decode( r, 1, 1, 2, 4, 3, 5, 4, 6 ) rel_chan,
decode( r, 1, ch_1, 2, ch_4, 3, ch_5, 4, ch_6 ) rank
from t,
(select rownum r from all_objects where rownum <= 4 )
I found one solution but is there an easier way?
mary W, July 22, 2004 - 1:42 pm UTC
Here is my solution:
select chan_id, chan_rel_id, score
from
(
select chan_id, decode(ch_1, ch_1, 1) as chan_rel_id, ch_1 as score from masha_test
union all
select chan_id, decode(ch_4, ch_4, 4), ch_4 from masha_test
union all
select chan_id, decode(ch_5, ch_5, 5), ch_5 from masha_test
union all
select chan_id, decode(ch_6, ch_6, 6), ch_6 from masha_test
)
order by chan_id
But i have a total of 68 chan_id and there fore total of 68 columns of ch_1 - ch_68 . Is there an easier way?
July 23, 2004 - 8:07 am UTC
decode.... see above.
Its increadible!
Mary W, July 23, 2004 - 9:30 am UTC
Tom,
Thank you so very much. Your solution is simple, elegant, and genious!
mary
is there a limitation in decode?
Ajeet, August 03, 2004 - 11:16 am UTC
Hi Tom,
I have a table which has 200 colums , I need to convert these columns into row -- 3 columns will not be pivot--and 107 would be --query I wrote is simply taken from your answers above --and this works fine if I give 100 or so values in decode statement below..but If use 300 values it give me an error --
ERROR at line 2:
ORA-00939: too many arguments for function --
so my question is there any limitaiton in decode or I am doing something wrong. I tried with 255 values..in that case also I got an error.If there is a limitation or sqlplus formating required please let me know.also in case of limitation is there any work around ?
Thanks again
--sorry about pasting this ugly query
as it will take lots of spac---but I think you may ask for it in order to give me an answer.
select fleet,aircraft_id,engine_id,flight_datetime,install_datetime,
decode(r,1,PIP_BLED, 2,CORETA_SMOOTHED, 3,BPENET_SMOOTHED, 4,ADJCEQ_SMOOTHED,
5,WF36,6,T5SE,7,T5,8,T49SE,9,T495SE,10,T495,11,T3SE,12,T3,13,T25SE,14,T25,15,SWF36,
16,SUMN25,17,SOL25,18,SOL2,19,SOL12,20,SHDEGT,21,SFCLPT,22,SFCLPC,23,SFCHTS,24,SFCHTR,
25,SFCHPC,26,SFCFAN,27,SCRSFC,28,PSB,29,PS25,30,PS15,31,PS13,32,PRREF,33,PIP_MPA,
34,P495,35,P48,36,P25,37,P15,38,GXN25,39,GWF36,40,GT5,41,GT49C,42,GT495C,43,GT495,
44,GT49,45,GT3,46,GT25,47,GPS3,48,GPS25,49,GPS14,50,GPS13,51,GP49,52,GP25,53,ETA,54,EGTLPT,
55,EGTLPC,56,EGTHTS,57,EGTHTR,58,EGTHPC,59,EGTFAN,60,DLPTFL,61,DLPTEF,62,DLPCFL,63,DLPCEF,
64,DHPTFL,65,DHPTEF,66,DHPCFL,67,DHPCEF,68,DFANFL,69,DFANEF,70,CORTPR,71,CORTAP,72,CORETA,
73,BPENET,74,ADJCEQ,75,CCCVPOS_D,76,WFPS3_SMOOTHED,77,WFPS3,78,OILFDP_SMOOTHED,
79,EGTDELTA_SMOOTHED,80,DELFN_SMOOTHED,81,ZVBV_D,82,LPTCPOS_D,83,HPTCPOS_D,
84,GWFR_D,85,GN2R_D,86,TIMESTAMP,87,ZPCN12_D_SMOOTHED,88,ZPCN12_D,89,ZVB2F_SMOOTHED,
90,ZVB1R_SMOOTHED,91,EDITED_IND,92,SAGE_ENG_OUTPUT_SEQ_NUM,93,MAINT_WORK_ORDER,
94,PN2ETM_DETER,95,HDEGTM_DETER,96,EGTETM_DETER,97,GPCN25_DETER,98,GWFM_DETER,
99,DEGT_DETER,100,ZWF36_D_SMOOTHED,101,ZVB2R_SMOOTHED,102,ZVB1F_SMOOTHED,
103,ZT49_D_SMOOTHED,104,ZTOIL_SMOOTHED,105,ZTNAC_D_SMOOTHED,106,ZPOIL_SMOOTHED,
107,ZPCN25_D_SMOOTHED,108,SLOATL_SMOOTHED,109,PN2MAR_SMOOTHED,
110,PN2ETM_SMOOTHED,111,GWFR_SMOOTHED,112,GWFM_D_SMOOTHED,113,GWFM_SMOOTHED,
114,EGTHDM_SMOOTHED,115,GPCN25_SMOOTHED,116,GPCN25_D_SMOOTHED,
117,GN2MC_SMOOTHED,118,GEGTMC_SMOOTHED,119,GN2R_SMOOTHED,120,EGTHDM_D_SMOOTHED,
121,ZTNAC_SMOOTHED,122,CWFPADJ2_LT_SMOOTHED,123,CADJCEQ2_LT_SMOOTHED,
124,DELN12_LT_SMOOTHED,125,DELFN2_LT_SMOOTHED,126,ZVB2R2_LT_SMOOTHED,
127,ZVB2F2_LT_SMOOTHED,128,ZVB1R2_LT_SMOOTHED,129,ZVB1F2_LT_SMOOTHED,
130,ZTOIL2_LT_SMOOTHED,131,ZPOIL2_LT_SMOOTHED,132,GWFR3_LT_SMOOTHED,
133,GWFR2_LT_SMOOTHED,134,GN2R3_LT_SMOOTHED,135,GN2R2_LT_SMOOTHED,
136,DPOIL2_LT_SMOOTHED,137,GWFM3_LT_SMOOTHED,138,GWFM2_LT_SMOOTHED,
139,CGPCN253_LT_SMOOTHED,140,CGPCN252_LT_SMOOTHED,141,CEGTHDM2_LT_SMOOTHED,
142,DEGT3_LT_SMOOTHED,143,DEGT2_LT_SMOOTHED,144,CWFPADJ2_SMOOTHED,
145,CADJCEQ2_SMOOTHED,146,DELN12_SMOOTHED,147,DELFN2_SMOOTHED,
148,ZVB2R2_SMOOTHED,149,ZVB2F2_SMOOTHED,150,ZVB1R2_SMOOTHED,
151,ZVB1F2_SMOOTHED,152,ZTOIL2_SMOOTHED,153,ZPOIL2_SMOOTHED,
154,GWFR3_SMOOTHED,155,GWFR2_SMOOTHED,156,GN2R3_SMOOTHED,157,GN2R2_SMOOTHED,
158,DPOIL2_SMOOTHED,159,GWFM3_SMOOTHED,160,GWFM2_SMOOTHED,161,CGPCN253_SMOOTHED,
162,CGPCN252_SMOOTHED,163,CEGTHDM2_SMOOTHED,164,DEGT3_SMOOTHED,165,DEGT2_SMOOTHED,
166,CWFPADJ2,167,CADJCEQ2,168,DELN12,169,DELFN2,170,GWFR3,171,GWFR2,172,GN2R3,
173,GN2R2,174,DPOIL2,175,GWFM3,176,GWFM2,177,CGPCN253,178,CGPCN252,179,CEGTHDM2,
180,DEGT3,181,DEGT2,182,DELN1_LT_SMOOTHED,183,DELFN_LT_SMOOTHED,184,WFPADJ_LT_SMOOTHED,
185,ADJCEQ_LT_SMOOTHED,186,ZVB2R_LT_SMOOTHED,187,ZVB2F_LT_SMOOTHED,188,ZVB1R_LT_SMOOTHED,
189,ZVB1F_LT_SMOOTHED,190,ZTOIL_LT_SMOOTHED,191,ZPOIL_LT_SMOOTHED,192,GWFR_LT_SMOOTHED,
193,GWFM_LT_SMOOTHED,194,EGTHDM_LT_SMOOTHED,195,GPCN25_LT_SMOOTHED,196,GN2R_LT_SMOOTHED,
197,DPOIL_LT_SMOOTHED,198,DEGT_LT_SMOOTHED,199,ZVB2RCF6_SMOOTHED,200,TAT_ENG_SMOOTHED,201,FIRELT2_SMOOTHED,
202,FIRELT1_SMOOTHED,203,EGT_TOR_SMOOTHED,204,CHIPCBC_SMOOTHED,205,T25_SMOOTHED,206,FF_DELP_SMOOTHED,
207,EGTPL_SMOOTHED,208,EGTPH_SMOOTHED,209,EGT4_SMOOTHED,210,EGT3_SMOOTHED,211,EGT2_SMOOTHED,
212,EGT1_SMOOTHED,213,CHIPBC_SMOOTHED,214,EXCLUDE_FROM_DERATE,215,WFPREF_SMOOTHED,
216,WFPREF,217,WFPADJ_SMOOTHED,218,WFPDEL_SMOOTHED,219,WFPACT_SMOOTHED,220,DEVIAT_SMOOTHED,
221,WFPADJ,222,WFPDEL,223,WFPACT,224,DEVIAT,225,PRREF_SMOOTHED,226,ETA_SMOOTHED,227,CORTPR_SMOOTHED,
228,CORTAP_SMOOTHED,229,EGTETM_SMOOTHED,230,DPOIL_SMOOTHED,231,DELVSV_SMOOTHED,
232,DEGT_D_SMOOTHED,233,DEGT_SMOOTHED,234,ZTNAC_D,235,VSVNOM,236,WBE,237,WFMP,
238,WBI,239,ZT49_D,240,SLOATL_D,241,PIP_DRAT,242,PIP_CLET,243,PIP_XN1C,244,PIP_VLTO,
245,PIP_VLCR,246,PIP_VLCL,247,PIP_SLTL,248,PIP_PEM,249,PIP_OILM,250,PIP_ETOP,
251,PIP_DVSV,252,PIP_CLDR,253,PCN1BR,254,PN2MAR_D,255,PN2MAR,256,PCN2C,257,PCN1K,
258,PN2ETM,259,PCN1AR,260,PCN12I,261,PCN12,262,IAIWG,263,IAIE,264,GWFR,265,GWFM_D,266,GWFM,
267,GPCN25_D,268,GPCN25,269,GN2R,270,GN2MC,271,GEGTMC,272,ETSI,273,ETSV,274,ETSN,275,EGTHDM_D,276,EGTHDM,
277,EGTETM,278,EGTC,279,ECSI,280,ECSV,281,ECSN,282,DPOIL,283,DIVWFE,284,DIVTLA,285,DIVNAC,286,DIVN2,287,DIVEGT,
288,DELVSV,289,DELN1,290,DELFN,291,DEGT,292,DEGT_D,293,BRAT,294,ALERT_COUNT_OTHER,295,ALERT_COUNT_VIBES,
296,ALERT_COUNT_OIL,297,ALERT_COUNT_PERFORMANCE,298,ALERT_COUNT,299,ENGINE_POSITION,300,FLIGHT_PHASE,
302,GPCN12,303,DELEPR,316,IAIE,445,SLOATL,446,ZPCN25_D,447,ZTLA_D,448,ZWF36_D ) param_value
from (select rownum r from all_objects where rownum <= 307),
flt_sage_eng_out_load
where
decode(r,1,PIP_BLED, 2,CORETA_SMOOTHED, 3,BPENET_SMOOTHED, 4,ADJCEQ_SMOOTHED,
5,WF36,6,T5SE,7,T5,8,T49SE,9,T495SE,10,T495,11,T3SE,12,T3,13,T25SE,14,T25,15,SWF36,
16,SUMN25,17,SOL25,18,SOL2,19,SOL12,20,SHDEGT,21,SFCLPT,22,SFCLPC,23,SFCHTS,24,SFCHTR,
25,SFCHPC,26,SFCFAN,27,SCRSFC,28,PSB,29,PS25,30,PS15,31,PS13,32,PRREF,33,PIP_MPA,
34,P495,35,P48,36,P25,37,P15,38,GXN25,39,GWF36,40,GT5,41,GT49C,42,GT495C,43,GT495,
44,GT49,45,GT3,46,GT25,47,GPS3,48,GPS25,49,GPS14,50,GPS13,51,GP49,52,GP25,53,ETA,54,EGTLPT,
55,EGTLPC,56,EGTHTS,57,EGTHTR,58,EGTHPC,59,EGTFAN,60,DLPTFL,61,DLPTEF,62,DLPCFL,63,DLPCEF,
64,DHPTFL,65,DHPTEF,66,DHPCFL,67,DHPCEF,68,DFANFL,69,DFANEF,70,CORTPR,71,CORTAP,72,CORETA,
73,BPENET,74,ADJCEQ,75,CCCVPOS_D,76,WFPS3_SMOOTHED,77,WFPS3,78,OILFDP_SMOOTHED,
79,EGTDELTA_SMOOTHED,80,DELFN_SMOOTHED,81,ZVBV_D,82,LPTCPOS_D,83,HPTCPOS_D,
84,GWFR_D,85,GN2R_D,86,TIMESTAMP,87,ZPCN12_D_SMOOTHED,88,ZPCN12_D,89,ZVB2F_SMOOTHED,
90,ZVB1R_SMOOTHED,91,EDITED_IND,92,SAGE_ENG_OUTPUT_SEQ_NUM,93,MAINT_WORK_ORDER,
94,PN2ETM_DETER,95,HDEGTM_DETER,96,EGTETM_DETER,97,GPCN25_DETER,98,GWFM_DETER,
99,DEGT_DETER,100,ZWF36_D_SMOOTHED,101,ZVB2R_SMOOTHED,102,ZVB1F_SMOOTHED,
103,ZT49_D_SMOOTHED,104,ZTOIL_SMOOTHED,105,ZTNAC_D_SMOOTHED,106,ZPOIL_SMOOTHED,
107,ZPCN25_D_SMOOTHED,108,SLOATL_SMOOTHED,109,PN2MAR_SMOOTHED,
110,PN2ETM_SMOOTHED,111,GWFR_SMOOTHED,112,GWFM_D_SMOOTHED,113,GWFM_SMOOTHED,
114,EGTHDM_SMOOTHED,115,GPCN25_SMOOTHED,116,GPCN25_D_SMOOTHED,
117,GN2MC_SMOOTHED,118,GEGTMC_SMOOTHED,119,GN2R_SMOOTHED,120,EGTHDM_D_SMOOTHED,
121,ZTNAC_SMOOTHED,122,CWFPADJ2_LT_SMOOTHED,123,CADJCEQ2_LT_SMOOTHED,
124,DELN12_LT_SMOOTHED,125,DELFN2_LT_SMOOTHED,126,ZVB2R2_LT_SMOOTHED,
127,ZVB2F2_LT_SMOOTHED,128,ZVB1R2_LT_SMOOTHED,129,ZVB1F2_LT_SMOOTHED,
130,ZTOIL2_LT_SMOOTHED,131,ZPOIL2_LT_SMOOTHED,132,GWFR3_LT_SMOOTHED,
133,GWFR2_LT_SMOOTHED,134,GN2R3_LT_SMOOTHED,135,GN2R2_LT_SMOOTHED,
136,DPOIL2_LT_SMOOTHED,137,GWFM3_LT_SMOOTHED,138,GWFM2_LT_SMOOTHED,
139,CGPCN253_LT_SMOOTHED,140,CGPCN252_LT_SMOOTHED,141,CEGTHDM2_LT_SMOOTHED,
142,DEGT3_LT_SMOOTHED,143,DEGT2_LT_SMOOTHED,144,CWFPADJ2_SMOOTHED,
145,CADJCEQ2_SMOOTHED,146,DELN12_SMOOTHED,147,DELFN2_SMOOTHED,
148,ZVB2R2_SMOOTHED,149,ZVB2F2_SMOOTHED,150,ZVB1R2_SMOOTHED,
151,ZVB1F2_SMOOTHED,152,ZTOIL2_SMOOTHED,153,ZPOIL2_SMOOTHED,
154,GWFR3_SMOOTHED,155,GWFR2_SMOOTHED,156,GN2R3_SMOOTHED,157,GN2R2_SMOOTHED,
158,DPOIL2_SMOOTHED,159,GWFM3_SMOOTHED,160,GWFM2_SMOOTHED,161,CGPCN253_SMOOTHED,
162,CGPCN252_SMOOTHED,163,CEGTHDM2_SMOOTHED,164,DEGT3_SMOOTHED,165,DEGT2_SMOOTHED,
166,CWFPADJ2,167,CADJCEQ2,168,DELN12,169,DELFN2,170,GWFR3,171,GWFR2,172,GN2R3,
173,GN2R2,174,DPOIL2,175,GWFM3,176,GWFM2,177,CGPCN253,178,CGPCN252,179,CEGTHDM2,
180,DEGT3,181,DEGT2,182,DELN1_LT_SMOOTHED,183,DELFN_LT_SMOOTHED,184,WFPADJ_LT_SMOOTHED,
185,ADJCEQ_LT_SMOOTHED,186,ZVB2R_LT_SMOOTHED,187,ZVB2F_LT_SMOOTHED,188,ZVB1R_LT_SMOOTHED,
189,ZVB1F_LT_SMOOTHED,190,ZTOIL_LT_SMOOTHED,191,ZPOIL_LT_SMOOTHED,192,GWFR_LT_SMOOTHED,
193,GWFM_LT_SMOOTHED,194,EGTHDM_LT_SMOOTHED,195,GPCN25_LT_SMOOTHED,196,GN2R_LT_SMOOTHED,
197,DPOIL_LT_SMOOTHED,198,DEGT_LT_SMOOTHED,199,ZVB2RCF6_SMOOTHED,200,TAT_ENG_SMOOTHED,201,FIRELT2_SMOOTHED,
202,FIRELT1_SMOOTHED,203,EGT_TOR_SMOOTHED,204,CHIPCBC_SMOOTHED,205,T25_SMOOTHED,206,FF_DELP_SMOOTHED,
207,EGTPL_SMOOTHED,208,EGTPH_SMOOTHED,209,EGT4_SMOOTHED,210,EGT3_SMOOTHED,211,EGT2_SMOOTHED,
212,EGT1_SMOOTHED,213,CHIPBC_SMOOTHED,214,EXCLUDE_FROM_DERATE,215,WFPREF_SMOOTHED,
216,WFPREF,217,WFPADJ_SMOOTHED,218,WFPDEL_SMOOTHED,219,WFPACT_SMOOTHED,220,DEVIAT_SMOOTHED,
221,WFPADJ,222,WFPDEL,223,WFPACT,224,DEVIAT,225,PRREF_SMOOTHED,226,ETA_SMOOTHED,227,CORTPR_SMOOTHED,
228,CORTAP_SMOOTHED,229,EGTETM_SMOOTHED,230,DPOIL_SMOOTHED,231,DELVSV_SMOOTHED,
232,DEGT_D_SMOOTHED,233,DEGT_SMOOTHED,234,ZTNAC_D,235,VSVNOM,236,WBE,237,WFMP,
238,WBI,239,ZT49_D,240,SLOATL_D,241,PIP_DRAT,242,PIP_CLET,243,PIP_XN1C,244,PIP_VLTO,
245,PIP_VLCR,246,PIP_VLCL,247,PIP_SLTL,248,PIP_PEM,249,PIP_OILM,250,PIP_ETOP,
251,PIP_DVSV,252,PIP_CLDR,253,PCN1BR,254,PN2MAR_D,255,PN2MAR,256,PCN2C,257,PCN1K,
258,PN2ETM,259,PCN1AR,260,PCN12I,261,PCN12,262,IAIWG,263,IAIE,264,GWFR,265,GWFM_D,266,GWFM,
267,GPCN25_D,268,GPCN25,269,GN2R,270,GN2MC,271,GEGTMC,272,ETSI,273,ETSV,274,ETSN,275,EGTHDM_D,276,EGTHDM,
277,EGTETM,278,EGTC,279,ECSI,280,ECSV,281,ECSN,282,DPOIL,283,DIVWFE,284,DIVTLA,285,DIVNAC,286,DIVN2,287,DIVEGT,
288,DELVSV,289,DELN1,290,DELFN,291,DEGT,292,DEGT_D,293,BRAT,294,ALERT_COUNT_OTHER,295,ALERT_COUNT_VIBES,
296,ALERT_COUNT_OIL,297,ALERT_COUNT_PERFORMANCE,298,ALERT_COUNT,299,ENGINE_POSITION,300,FLIGHT_PHASE,
302,GPCN12,303,DELEPR,316,IAIE,445,SLOATL,446,ZPCN25_D,447,ZTLA_D,448,ZWF36_D ) is not null
August 03, 2004 - 11:21 am UTC
The maximum number of components in the DECODE function, including expr, searches, results, and default, is 255.
Thanks --is there a woraround or any other way to solve my problem
Ajeet, August 03, 2004 - 11:43 am UTC
Tom -
Thanks -- Yes I saw it in the SQL reference manual too,soorry I should have seen it before posting it to you.
But can you please suggest a way to write the above query where I have total 600 arguments in decode.
Thanks so much
August 03, 2004 - 11:54 am UTC
looks like a union all
select *
from (select a, b, c, decode( r, 1, D, 2, E, ... ) column
from t, (select rownum r from all_objects where rownum <= 100)
)
where column is not null
UNION ALL
select *
from ( select a, b, c, decode( r, 1, DD, 2, EE, ... ) column
from t, .......
do 100 columns, then another 100, then another 100.
Or, utilize a pipelined function -- then fetches a row and calls "pipe row" n-hundred times per row.
Or perhaps just...
Padders, August 03, 2004 - 12:31 pm UTC
Can you also get around this restriction by just nesting DECODEs within eachother?
Also note that you can use in-line view to avoid repeating (and maintaining!) the DECODE in WHERE clause, e.g.
SELECT value
FROM (SELECT DECODE (value,
1, 'ONE',
2, 'TWO',
3, 'THREE',
(..snip..)
124, 'ONE HUNDRED TWENTY-FOUR',
125, 'ONE HUNDRED TWENTY-FIVE',
126, 'ONE HUNDRED TWENTY-SIX',
DECODE (value,
127, 'ONE HUNDRED TWENTY-SEVEN',
128, 'ONE HUNDRED TWENTY-EIGHT',
129, 'ONE HUNDRED TWENTY-NINE',
(..snip..)
198, 'ONE HUNDRED NINETY-EIGHT',
199, 'ONE HUNDRED NINETY-NINE',
200, 'TWO HUNDRED')) new_value
FROM (SELECT 121 value
FROM dual)
WHERE new_value IS NOT NULL;
August 03, 2004 - 12:41 pm UTC
very nice - did not think of that one.
Help
Catherine, August 19, 2004 - 8:56 am UTC
Dear Tom,
How to pivot the X values so that they appear in one single
row.
SQL> create table t(x number);
Table created.
SQL> insert into t select rownum * 10 from dictionary
2 where rownum <= 5;
5 rows created.
SQL> commit;
Commit complete.
SQL> select * from t;
X
----------
10
20
30
40
50
I would like to have the result set as
X 10 20 30 40 50
Could you please provide a way of doing it?
Thanks for your time.
Bye!
P.S :) Are there different ways to do it?
August 19, 2004 - 10:00 am UTC
you need to know the max number of columns you expect ever, then you can:
select max(decode(rownum,1,x)),
max(decode(rownum,2,x)),
....
max(decode(rownum,N,x))
from t;
Thanks
Catherine, August 20, 2004 - 4:09 am UTC
Hi Tom,
Thanks for your reply.How to draft a query for a table with data as follows
SQL> create table t(x int,y varchar2(30));
SQL> insert into t
2 select rownum,to_char(to_date(rownum,'J'),'JSP')
3 from dictionary where rownum <= 10
SQL> update t set x = 1;
SQL> select * from t;
X Y
---------- ------------------------------
1 ONE
1 TWO
1 THREE
1 FOUR
1 FIVE
1 SIX
1 SEVEN
1 EIGHT
1 NINE
1 TEN
11 rows selected.
SQL> select max(decode(x,1,y)) from t;
MAX(DECODE(X,1,Y))
------------------------------
TWO
I expect the result set to be
SQL> select x,max(decode(x,1,y)) from t
group by x;
X MAX(DECODE(X,1,Y))
---- --------------------------
1 ONE TWO THREE FOUR FIVE .....
How to achieve this?
August 20, 2004 - 11:10 am UTC
search this site for stragg
How do I avoid the pivot
Venkat, October 11, 2004 - 8:58 pm UTC
Tom,
I have a table SEG that has about 600K rows and COMMENTS table with about 1 Million rows. And about 250K of the SEG records have comments. Table COMMENTS includes multiple comments for each seg_id. My goal is to get the seg_id followed by the entire comment text.
drop table seg ;
create table seg (seg_id number primary key, comment_id number) ;
drop table comments ;
create table comments
(comment_id number, comment_seq_nbr number, comment_text varchar2(50) ) ;
alter table comments add constraint comments_pk primary key
(comment_id, comment_seq_nbr) ;
insert into comments
select object_id, 1, 'R1-'||object_name from all_objects
union all
select object_id, 2, 'R2-'||object_name from all_objects
union all
select object_id, 3, 'R3-'||object_name from all_objects
/
insert into seg
select object_id + 10000, object_id from all_objects
/
drop view seg_vw
/
create or replace view seg_vw as
select s.seg_id, c.comments
-- other <table.column> names
from
(
select comment_id,
max(decode(rn, 1, comment_text, null) ) ||
max(decode(rn, 2, comment_text, null) ) ||
max(decode(rn, 3, comment_text, null) ) comments
from
( select c.comment_id, c.comment_seq_nbr,
c.comment_text,
row_number() over
(partition by c.comment_id
order by c.comment_seq_nbr) rn
from comments c
)
where rn <= 3
group by comment_id
) c, seg s
-- other <table_names> involved in the view
where s.comment_id = c.comment_id (+)
-- and <some more joins> for other tables
/
My queries against this view will look like this:
select * from seg_vw where seg_id = 625626;
no rows selected
Execution Plan
----------------------------------------------------------
0 SELECT STATEMENT Optimizer=CHOOSE
1 0 MERGE JOIN (OUTER)
2 1 TABLE ACCESS (BY INDEX ROWID) OF 'SEG'
3 2 INDEX (UNIQUE SCAN) OF 'SYS_C0076433' (UNIQUE)
4 1 FILTER
5 4 VIEW
6 5 SORT (GROUP BY)
7 6 VIEW
8 7 WINDOW (SORT PUSHED RANK)
9 8 TABLE ACCESS (FULL) OF 'COMMENTS'
Statistics
----------------------------------------------------------
7 recursive calls
0 db block gets
5 consistent gets
0 physical reads
60 redo size
131 bytes sent via SQL*Net to client
214 bytes received via SQL*Net from client
1 SQL*Net roundtrips to/from client
0 sorts (memory)
0 sorts (disk)
0 rows processed
There are other tables (4 more) and columns that all join to the SEG table in the creation of the view but the join involving only these 2 tables is shown in this example.
1. Every time I query from this view, it does a full-table scan on COMMENTS table (whether there is a match or not). Is there a way I can rewrite the view such that the pivoting steps to fetch the concatenated comments are avoided unless there is a match to the COMMENT_ID in SEG table?
2. Can I alter the view definition to make it do an index scan on the COMMENT_ID column since it is a PK? Is it possible?
3. Is there a different/better way of concatenating the comment rows to get the entire comment text?
Thanks,
Venkat
October 12, 2004 - 7:39 am UTC
the group by and where on rn in the inline view is going to preclude view merging...
So, lets lose the outer join, use another view that we can merge into and a scalar subquery:
ops$tkyte@ORA9IR2> create or replace view comment_view
2 as
3 select c.comment_id, c.comment_seq_nbr, c.comment_text,
4 row_number() over (partition by c.comment_id order by c.comment_seq_nbr) rn
5 from comments c
6 /
View created.
<b>that can be merged into when we use a where clause on COMMENT_ID easily..</b>
ops$tkyte@ORA9IR2> create or replace view seg_vw_2
2 as
3 select s.seg_id,
4 (select max( decode(rn,1,comment_text) ) || ' ' ||
5 max( decode(rn,2,comment_text) ) || ' ' ||
6 max( decode(rn,3,comment_text) )
7 from comment_view
8 where comment_id = s.comment_id) comments
9 from seg s
10 /
View created.
<b>the scalar subquery can replace the outer join and it'll just get the comment text for the one comment we are interested in..</b>
ops$tkyte@ORA9IR2> set autotrace on
ops$tkyte@ORA9IR2> select * from seg_vw_2 where seg_id = 33430;
SEG_ID COMMENTS
---------- --------------------
33430 R1-/4c9c51bf_XSLForE
ach R2-/4c9c51bf_XSL
ForEach R3-/4c9c51bf
_XSLForEach
Execution Plan
----------------------------------------------------------
0 SELECT STATEMENT Optimizer=CHOOSE
1 0 SORT (AGGREGATE)
2 1 VIEW OF 'COMMENT_VIEW'
3 2 WINDOW (BUFFER)
4 3 TABLE ACCESS (BY INDEX ROWID) OF 'COMMENTS'
5 4 INDEX (RANGE SCAN) OF 'COMMENTS_PK' (UNIQUE)
6 0 TABLE ACCESS (BY INDEX ROWID) OF 'SEG'
7 6 INDEX (UNIQUE SCAN) OF 'SYS_C003362' (UNIQUE)
Statistics
----------------------------------------------------------
0 recursive calls
0 db block gets
8 consistent gets
0 physical reads
0 redo size
507 bytes sent via SQL*Net to client
499 bytes received via SQL*Net from client
2 SQL*Net roundtrips to/from client
1 sorts (memory)
0 sorts (disk)
1 rows processed
ops$tkyte@ORA9IR2> set autotrace off
Can The Following Pivot be Perfomed
A reader, October 15, 2004 - 10:18 am UTC
Hi Tom
Apoligies in advance if the formatting does not come out right on this one but:
Say for example I have a query that returns a result set like:
Date Job Pay Bonus Tax
------------------------------------------------
07/2004 Mgr 80000 5000 32000
07/2004 Clk 20000 200 1000
08/2004 Clk 25000 850 1300
08/2004 Cl 12000 0 500
What I would like to achieve is to perform a pivot on this result set so that the query returns the figures in the following way:
Job Pay(J) Bonus(J) Tax(J) Pay(A) Bonus(A) Tax(A)
--------------------------------------------------------Mgr 80000 5000 32000 0 0 0
Clk 20000 200 1000 25000 850 1300
Cl 0 0 0 12000 0 500
The number of values allowed in the pay, bonus and tax columns are not finite but the job titles are (300) at most.
If it is not possible to perform a pivot on my result to produce the desired output, what would you recommend?
Regards
Jimmy
October 15, 2004 - 11:58 am UTC
j? a?
what are those?
but you can use the technique above to pivot whatever you like -- did you follow the example? does it make sense how the TECHNIQUE works?
July/August pivot query
Bob Shepard, October 15, 2004 - 3:19 pm UTC
Based on the dates in the table under the question "Can The Following Pivot Be Performed", I'm assuming that "J" means "July" and "A" means "August".
One possible way of generating the desired "pivot" query is as follows:
SELECT "Job",
SUM("Pay(J)") As "Pay(J)",
SUM("Bonus(J)") As "Bonus(J)",
SUM("Tax(J)") As "Tax(J)",
SUM("Pay(A)") As "Pay(A)",
SUM("Bonus(A)") As "Bonus(A)",
SUM("Tax(A)") As "Tax(A)"
FROM (
SELECT "Job",
DECODE("Date",'07/2004',"Pay",0) AS "Pay(J)",
DECODE("Date",'07/2004',"Bonus",0) AS "Bonus(J)",
DECODE("Date",'07/2004',"Tax",0) AS "Tax(J)",
DECODE("Date",'08/2004',"Pay",0) AS "Pay(A)",
DECODE("Date",'08/2004',"Bonus",0) AS "Bonus(A)",
DECODE("Date",'08/2004',"Tax",0) AS "Tax(A)"
FROM
(
SELECT '07/2004' AS "Date", 'Mgr' AS "Job", 80000 AS "Pay",
5000 AS "Bonus", 32000 AS "Tax"
FROM dual
UNION
SELECT '07/2004' AS "Date", 'Clk' AS "Job", 20000 AS "Pay",
200 AS "Bonus", 1000 AS "Tax"
FROM dual
UNION
SELECT '08/2004' AS "Date", 'Clk' AS "Job", 25000 AS "Pay",
850 AS "Bonus", 1300 AS "Tax"
FROM dual
UNION
SELECT '08/2004' AS "Date", 'Cl' AS "Job", 12000 AS "Pay",
0 AS "Bonus", 500 AS "Tax"
FROM dual
)
)
GROUP BY "Job"
ORDER BY "Job" DESC;
Of course, in real life the innermost query would be replaced by an actual table, but a "union" query will suffice here.
I hope this is helpful to the reader who posed the question. If nothing else, it was a good exercise for me.
Pivot Query !
RK, November 09, 2004 - 6:56 pm UTC
I have a table
CREATE TABLE test(id varchar2(10),
att varchar2(10), start_date date, value varchar2(20),
constraint test_pk primary key (id, att, start_date))
/
The data in the table would be:
INSERT INTO TEST VALUES ('A', 'SECTIND', '27-OCT-2004', 'ALL')
/
INSERT INTO TEST VALUES ('A','LB', '27-OCT-2004', 'b-.005')
/
INSERT INTO TEST VALUES ('A','UB', '27-OCT-2004', 'b+.005')
/
INSERT INTO TEST VALUES ('A','SIFLAG', '27-OCT-2004', 'S')
/
INSERT INTO TEST VALUES ('A','SIFLAG', '26-OCT-2004', 'I')
/
INSERT INTO TEST VALUES ('B', 'SECTIND', '27-OCT-2004', 'ALL')
/
INSERT INTO TEST VALUES ('B','LB', '27-OCT-2004', 'b-.005')
/
INSERT INTO TEST VALUES ('B','UB', '27-OCT-2004', 'b+.005')
/
INSERT INTO TEST VALUES ('B','SIFLAG', '27-OCT-2004', 'S')
/
COMMIT
/
SELECT * FROM TEST
/
ID ATT START_DATE VALUE
A SECTIND 27-OCT-04 ALL
A LB 27-OCT-04 b-.005
A UB 27-OCT-04 b+.005
A SIFLAG 27-OCT-04 S
A SIFLAG 26-OCT-04 I
B SECTIND 27-OCT-04 ALL
B LB 27-OCT-04 b-.005
B UB 27-OCT-04 b+.005
B SIFLAG 27-OCT-04 S
I would need the following output:
When queried for ID A:
SECTIND LB UB SIFLAG
ALL b-.005 b+.005 S
ALL b-.005 b+.005 I
When queried for ID B:
SECTIND LB UB SIFLAG
ALL b-.005 b+.005 S
Can you Please help me with a query with this, if it is possible with a query ?
November 09, 2004 - 7:52 pm UTC
need more info. I see SIFLAG can have "more than one entry" per ID
is it "0, 1, or more"
and are the others "only 0 or 1" per id
Pivot Query !
A reader, November 10, 2004 - 10:31 am UTC
SIFLAG can have "0,1,or more" values, and for all others, it would be 0 or 1 per ID.
Please let me know if have any further questions.
November 10, 2004 - 12:17 pm UTC
ops$tkyte@ORA9IR2> variable x varchar2(5)
ops$tkyte@ORA9IR2> exec :x := 'A'
PL/SQL procedure successfully completed.
ops$tkyte@ORA9IR2> select *
2 from (select value siflag
3 from test
4 where id = :x
5 and att = 'SIFLAG' ),
6 (select max(decode(att,'LB',value)) lb,
7 max(decode(att,'UB',value)) ub,
8 max(decode(att,'SECTIND',value)) SECTIND
9 from test
10 where id = :x )
11 /
SIFLAG LB UB SECTIND
-------------------- -------------------- -------------- --------------------
I b-.005 b+.005 ALL
S b-.005 b+.005 ALL
ops$tkyte@ORA9IR2> exec :x := 'B'
PL/SQL procedure successfully completed.
ops$tkyte@ORA9IR2> /
SIFLAG LB UB SECTIND
-------------------- -------------------- --------------- --------------------
S b-.005 b+.005 ALL
Pivot Query !
rk, November 10, 2004 - 3:53 pm UTC
My apologies, for missing this point. If 'SLFLAG' is not defined then the output must be
LB UB SECTIND
-------------------- -------------------- ------
b-.05 b+.05 ALL
INSERT INTO TEST VALUES ('C','SECTIND','27-OCT-2004', 'ALL')
/
INSERT INTO TEST VALUES ('C','LB','27-OCT-2004', 'b-.05')
/
INSERT INTO TEST VALUES ('C','UB','27-OCT-2004', 'b+.05')
/
COMMIT
/
SELECT * FROM TEST
/
ID ATT START_DATE VALUE
----------------------------------------
A SECTIND 27-OCT-04 ALL
A LB 27-OCT-04 b-.005
A UB 27-OCT-04 b+.005
A SIFLAG 27-OCT-04 S
A SIFLAG 26-OCT-04 I
B SECTIND 27-OCT-04 ALL
B LB 27-OCT-04 b-.005
B UB 27-OCT-04 b+.005
B SIFLAG 27-OCT-04 S
C SECTIND 27-OCT-04 ALL
C LB 27-OCT-04 b-.05
C UB 27-OCT-04 b+.05
The query works fine, but when id "C" is used, doesnot return any data back. Please help.
November 10, 2004 - 8:24 pm UTC
ops$tkyte@ORA9IR2> delete from test where att = 'SIFLAG';
3 rows deleted.
ops$tkyte@ORA9IR2> /
0 rows deleted.
ops$tkyte@ORA9IR2>
ops$tkyte@ORA9IR2> select siflag, lb, ub, sectind
2 from (select 1 x, value siflag
3 from test
4 where id = :x
5 and att = 'SIFLAG' ) a,
6 (select 1 x,
7 max(decode(att,'LB',value)) lb,
8 max(decode(att,'UB',value)) ub,
9 max(decode(att,'SECTIND',value)) SECTIND
10 from test
11 where id = :x ) b
12 where b.x = a.x(+)
13 /
SIFLAG LB UB SECTIND
-------- -------------------- -------------------- --------
b-.005 b+.005 ALL
Thanks
Bill Coulam, November 12, 2004 - 11:59 am UTC
This reply to response feature is great for posting questions, but lousy for being able to refer to an individual response.
I wanted to say thanks for your original follow-up to this thread. I'd never once in 10 years had to create a pivot table, but when I needed to, it was 15 seconds on your site for the answer.
Thanks! Just right.
PIVOT ON DATES
john steinbeck, December 03, 2004 - 12:49 pm UTC
Hi,
Begginer here... I noticed on previous ?'s about columns on the TO_CHAR... I figured that part out... in the DECODE, the TO_CHAR needs to be an Alias!!!
Problem... anything I do with dates never, never, never returns all the sum values???? why, why, why...lol
Please look below
John
SQL> break on report
SQL> compute sum LABEL 'TOTAL' of 'JAN' on report
SQL> compute sum of 'FEB' on report
SQL> compute sum of 'MAR' on report
SQL> compute sum of 'APR' on report
SQL> compute sum of 'MAY' on report
SQL> compute sum of 'JUNE' on report
SQL> compute sum of 'JULY' on report
SQL> compute sum of 'AUG' on report
SQL> compute sum of 'SEPT' on report
SQL> compute sum of 'OCT' on report
SQL> compute sum of 'NOV' on report
SQL> compute sum of 'DEC' on report
SQL> compute sum of total on report
SQL>
SQL> select job,
2 max( decode(MONTH, 'JANUARY', SPENT, 0 ) ) JAN,
3 max( decode(MONTH, 'FEBRUARY', SPENT, 0 ) ) FEB,
4 max (decode(MONTH, 'MARCH', SPENT, 0)) MAR,
5 max( decode(MONTH, 'APRIL', SPENT, 0 ) ) APR,
6 max( decode(MONTH, 'MAY', SPENT, 0 ) ) MAY,
7 max (decode(MONTH, 'JUNE', SPENT, 0)) JUNE,
8 max( decode(MONTH, 'JULY', SPENT, 0 ) ) JULY,
9 max( decode(MONTH, 'AUGUST', SPENT, 0 ) ) AUG,
10 max (decode(MONTH, 'SEPTEMBER', SPENT, 0)) SEPT,
11 max( decode(MONTH, 'OCTOBER', SPENT, 0 ) ) OCT,
12 max( decode(MONTH, 'NOVEMMBER', SPENT, 0 ) ) NOV,
13 max (decode(MONTH, 'DECEMBER', SPENT, 0)) DEC,
14 max( decode(MONTH, 'JANUARY', SPENT, 0 ) ) +
15 max( decode(MONTH, 'FEBRUARY', SPENT, 0 ) ) +
16 max (decode(MONTH, 'MARCH', SPENT, 0)) +
17 max( decode(MONTH, 'APRIL', SPENT, 0 ) ) +
18 max( decode(MONTH, 'MAY', SPENT, 0 ) ) +
19 max (decode(MONTH, 'JUNE', SPENT, 0)) +
20 max( decode(MONTH, 'JULY', SPENT, 0 ) ) +
21 max( decode(MONTH, 'AUGUST', SPENT, 0 ) ) +
22 max (decode(MONTH, 'SEPTEMBER', SPENT, 0)) +
23 max( decode(MONTH, 'OCTOBER', SPENT, 0 ) ) +
24 max( decode(MONTH, 'NOVEMMBER', SPENT, 0 ) ) +
25 max (decode(MONTH, 'DECEMBER', SPENT, 0)) TOTAL
26 from (select job, to_char(hiredate, 'MONTH') MONTH, sum(nvl(sal,0)) spent
27 from emp
28 group by job, to_char(hiredate, 'MONTH'))
29 GROUP BY job;
JOB JAN FEB MAR APR MAY JUNE JULY AUG SEPT OCT NOV DEC TOTAL
--------- ---------- ---------- ---------- ---------- ---------- ---------- ---------- ---------- ---------- ---------- ---------- ---------- ----------
ANALYST 0 0 0 0 0 0 0 0 0 0 0 0 0
CLERK 0 0 0 0 0 0 0 0 0 0 0 0 0
MANAGER 0 0 0 0 0 0 0 0 0 0 0 0 0
PRESIDENT 0 0 0 0 0 0 0 0 0 0 0 0 0
SALESMAN 0 0 0 0 0 0 0 0 2750 0 0 0 2750
---------- ---------- ---------- ---------- ---------- ---------- ---------- ---------- ---------- ---------- ---------- ---------- ----------
TOTAL 0 0 0 0 0 0 0 0 2750 0 0 0 2750
SQL> select job, to_char(hiredate, 'MONTH') MONTH, sum(nvl(sal,0)) spent
2 from emp
3 group by job, to_char(hiredate, 'MONTH')
4 ;
JOB MONTH SPENT
--------- --------- ----------
CLERK DECEMBER 1750
CLERK JANUARY 1300
CLERK MAY 1100
ANALYST APRIL 3000
ANALYST DECEMBER 3000
MANAGER APRIL 2975
MANAGER JUNE 2450
MANAGER MAY 2850
SALESMAN FEBRUARY 2850
SALESMAN SEPTEMBER 2750
PRESIDENT NOVEMBER 5000
11 rows selected.
SQL>
December 03, 2004 - 1:37 pm UTC
ops$tkyte@ORA9IR2> select '"' || to_char( sysdate, 'MONTH' ) || '"' from dual;
'"'||TO_CHA
-----------
"DECEMBER "
see the trailing blank.... MONTH format is a fixed width field.
fmMONTH would be blank trimmed.
MM would be easier (just a number, less typos)
PIVOT ON DATES
john steinbeck, December 03, 2004 - 2:00 pm UTC
YOU ROCK!!!!! You are quick to reply... thought I would wait days...
I tried the 'fmMONTH' and see what you mean compared to just 'MONTH' wow!!!
I did mm you are right much easier...
you are awesome... I hope your proud of me and my little discovery with the alias...lol
John
December 03, 2004 - 2:21 pm UTC
I know this--a man got to do what he got to do.
PIVOT
John Steinbeck, December 03, 2004 - 5:57 pm UTC
oh, is there a good book to learn more about all the extra's of SQL you show??
And is there a guy like you for FORMS on here like askmrforms.oracle.com???
Thanks again,
John
December 04, 2004 - 10:46 am UTC
otn.oracle.com has discussion forums covering many topics.
the SQL Reference, coupled with experience and "thinking in sets" is what I used to learn. I'm afraid a book of "tricks" would be so myoptic -- you'd learn 5 'tricks' and never really be able to take advantage of all that sql has to offer.
pivot question
vivek saxena, December 07, 2004 - 7:05 am UTC
tom,
I have a table having price groups data (upto fifteen columns) for various code on different dates.
and data is like
date code PG1 PG2 PG3 PG4 ....PG15
----------------------------------------
01-01-04 600 10 20 30 40
08-01-04 600 100 200 300 400
15-01-04 600 1000 2000 3000 4000
01-01-04 601 500 600 700 800
15-08-04 602 5000 6000 7000 8000
22-01-04 603 10 20 30 40
29-01-04 603 100 200 300 400
_______________________________________________
I want to have an output from this single table in the following form using
PL/SQL. (oracle version 8.1.7)
code | CODE
-----------------------------------
date PG1 PG2 | PG1 PG2 PG3
i.e.
600 | 601 | 602 | 603
01-01-04 pg1 pg2.. | pg1 pg2.. |
08-01-04 pg1 pg2.. | pg1 pg2..
15-01-04 pg1 pg2.. pg1 pg2...
22-01-04 pg1 pg2..
290104 pg1 pg2 pg3..
I tried by example discussed on this site but not able to achieve it.
Tom, is it possible to get this result through PL/SQL.
If yes, please advise, as you have always done.
Regards
Vivek
December 07, 2004 - 10:28 am UTC
new question.... ask it when I'm taking questions.
How to get ouput thru SQL ?
Parag Jayant Patankar, January 06, 2005 - 4:11 am UTC
Hi Tom,
suppose I am having table parag having following details
SQL> desc parag
Name Null? Type
----------------------------------------- -------- ------
A NUMBER
B NUMBER
C NUMBER
D NUMBER
E NUMBER
I want ouput in following way by sql ( 2 values per row only ) for COBOL programs
a, b,
c, d,
e
How can I do this ? ( Can I avoid to have comma [","] at last field in this case column is e ? )
regards & thanks
pjp
January 06, 2005 - 10:51 am UTC
i think we went through this before (not this problem, but this request)
hey, where is the simple create table, insert into.....
select decode( r, 1, a, 3, c, 5, e ),
decode( r, 2, b, 4, d )
from t, ( select 1 r from dual union all select 2 from dual
union all select 3 from dual union all select 4 from dual
union all select 5 from dual );
How can I get output thru SQL ?
Parag Jayant Patankar, January 06, 2005 - 10:21 am UTC
Hi Tom,
suppose I am having table parag having following details
SQL> desc parag
Name Null? Type
----------------------------------------- -------- ------
A NUMBER
B NUMBER
C NUMBER
D NUMBER
E NUMBER
I want ouput in following way by sql ( 2 values per row only ) for COBOL
programs
a, b,
c, d,
e
How can I do this ? ( Can I avoid to have comma [","] at last field in this case
column is e ? )
for example I have described small table, there are few tables having more than 100 columns
regards & thanks
pjp
January 06, 2005 - 11:16 am UTC
you would either have to do what I did for a hundred times...
or write a program to print the data out in the fashion you wanted.
no magic.
output for pro-cobol programs
Parag Jayant Patankar, January 06, 2005 - 11:20 am UTC
Hi Tom,
thanks for your answer to my query. But for e.g I have shown parag table having only few columns which you can decode and get result. which you have explained to me.
I want to generat output for PRO-COBOL "copy/include" files such as cursors, fetchs and inserts for various oracle tables. So for this reason I want ouput from user_tab_columns having only 2 values per row ( otherwise in COBOL it may exceed 72 columns ). There are many tables having nearly 100 columns. So I want to write general purpose SQL for this. For e.g if I want to generate ouput for pro-cobol for table "user_indexes" then I want details as follows
INDEX_NAME, INDEX_TYPE
TABLE_OWNER, TABLE_NAME,
TABLE_TYPE, UNIQUENESS,
COMPRESSION, PREFIX_LENGTH,
TABLESPACE_NAME, INI_TRANS,
MAX_TRANS, INITIAL_EXTENT,
NEXT_EXTENT, MIN_EXTENTS,
MAX_EXTENTS, PCT_INCREASE,
PCT_THRESHOLD, INCLUDE_COLUMN
FREELISTS, FREELIST_GROUPS,
PCT_FREE, LOGGING,
BLEVEL, LEAF_BLOCKS,
DISTINCT_KEYS, AVG_LEAF_BLOCKS_PER_KEY,
AVG_DATA_BLOCKS_PER_KEY, CLUSTERING_FACTOR,
STATUS, NUM_ROWS,
SAMPLE_SIZE,LAST_ANALYZED,
DEGREE, INSTANCES,
PARTITIONED, TEMPORARY
GENERATED, SECONDARY
BUFFER_POOL, USER_STATS,
DURATION, PCT_DIRECT_ACCESS
ITYP_OWNER, ITYP_NAME
PARAMETERS, GLOBAL_STATS,
DOMIDX_STATUS, DOMIDX_OPSTATUS,
FUNCIDX_STATUS <= last value without comma "," attached to it !!!
As this output to be generated from user_tab_columns so in my earlier example I have not attached create table script.
I have seen examples on this site for various mulitcolumn pivot tables using cartesian product with rownumbers but I was unable to trace question where it has been asked for single column and only for specified values in a row i.e here I requrie 2 values in each row maximum.
I think analytical will again come for rescue but not sure.
Kindly help.
regards & thanks
pjp
January 06, 2005 - 11:33 am UTC
you are going to write code for this OR you will use the decode example taken out to this extreme.
One way of generating output
Parag Jayant Patankar, January 07, 2005 - 7:42 am UTC
Hi Tom,
With ref to my question in this thread for having 2 values per column in AIX, following SQL developed
SQL> create table parag
2 (
3 a number, b number, c number, d number, e number, f number, g number, h number, i number, j number, k number,
4 l number, m number
5 );
Table created.
select substr(z,1,50) a3
from
(
select a.column_name c1, b.column_name c2, cnt,
case when rownum = cnt then
decode(b.column_name, null, a.column_name, a.column_name||','||b.column_name )
else
a.column_name||','||b.column_name||','
end z
from user_tab_columns a, user_tab_columns b,
(SELECT round(COUNT(*)/2,0) CNT
FROM USER_TAB_COLUMNS
WHERE TABLE_NAME = 'PARAG') C
where a.column_id + 1 = b.column_id (+)
and a.table_name = upper('PARAG')
and b.table_name (+) = upper('PARAG')
and mod(a.column_id,2) = 1
order by a.column_id
)
/
A,B,
C,D,
E,F,
G,H,
I,J,
K,L,
M
regards & thanks
pjp
Need advice on this query
Mike, January 25, 2005 - 7:42 am UTC
Tom,
I need your advice on how to write this query.
I have the table PA_BUDGET_LINES.
There is the composite unique key on (RESOURCE_ASSIGNMENT_ID, START_DATE). I want to find out how many rows for count(start_date) >240.
APPS@DN01> desc pa_budget_lines
Name Null? Type
----------------------------------------------------- -------- ---------------
RESOURCE_ASSIGNMENT_ID NOT NULL NUMBER(15)
START_DATE NOT NULL DATE
LAST_UPDATE_DATE NOT NULL DATE
LAST_UPDATED_BY NOT NULL NUMBER
CREATION_DATE NOT NULL DATE
CREATED_BY NOT NULL NUMBER
LAST_UPDATE_LOGIN NOT NULL NUMBER
END_DATE NOT NULL DATE
PERIOD_NAME VARCHAR2(30)
QUANTITY NUMBER
RAW_COST NUMBER
BURDENED_COST NUMBER
REVENUE NUMBER
CHANGE_REASON_CODE VARCHAR2(30)
DESCRIPTION VARCHAR2(255)
ATTRIBUTE_CATEGORY VARCHAR2(30)
ATTRIBUTE1 VARCHAR2(150)
ATTRIBUTE2 VARCHAR2(150)
ATTRIBUTE3 VARCHAR2(150)
ATTRIBUTE4
January 25, 2005 - 9:34 am UTC
I want to find out how many rows for count(start_date) >240.
it is not clear to me what you mean by that.
Pivoting a pre-ordered hierarchy
Jim, February 11, 2005 - 5:34 pm UTC
Hello Tom.
I have a stubborn hierarchy/pivot/analytic puzzle.
=============================================
-- detail table with "type" flags
create table rd
(r_id number,
t_flag char(1),
r_flag char(1),
s_flag char(1),
f_flag char(1),
l_flag char(1));
insert into rd values(1, 'Y','N','N','N','N');
insert into rd values(2, 'N','Y','Y','N','N');
insert into rd values(3, 'N','N','N','Y','N');
insert into rd values(4, 'N','N','N','N','Y');
insert into rd values(5, 'N','N','N','N','Y');
insert into rd values(6, 'Y','N','N','N','N');
insert into rd values(7, 'N','Y','Y','N','N');
insert into rd values(8, 'N','N','N','Y','N');
insert into rd values(9, 'N','N','N','N','Y');
insert into rd values(10,'N','Y','Y','Y','N');
insert into rd values(11,'N','N','N','N','Y');
insert into rd values(12,'N','Y','Y','Y','N');
insert into rd values(13,'N','N','N','N','Y');
insert into rd values(14,'N','N','N','N','Y');
-- hierarchy table:
-- p_order is the order in which to process
-- rows that share a level (underneath a single parent)
create table rc
(parent_id number,
child_id number,
p_order number);
insert into rc values(1,2,1);
insert into rc values(2,3,1);
insert into rc values(3,4,2);
insert into rc values(3,5,1);
insert into rc values(6,7,2);
insert into rc values(7,8,1);
insert into rc values(8,9,1);
insert into rc values(6,10,1);
insert into rc values(10,11,1);
insert into rc values(6,12,3);
insert into rc values(12,13,2);
insert into rc values(12,14,1);
=============================================
So what I want to get is an intermediate structure
in the proper order...
T R S F L
--- --- --- --- ---
1
2 2
3
4
6
10 10 10
11
7 7
8
9
12 12 12
14
13
that can be flattened out to the final structure:
T R S F L
--- --- --- --- ---
1 2 2 3 4
6 10 10 10 11
6 7 7 8 9
6 12 12 12 14
6 12 12 12 13
=============================================
Tried some things like the following embarrassing
code, but I can't get the p_order right, and also
stall when collapsing and pivoting (as shown,
tried row_number(),but flubbed that too...)
=o(
=============================================
select decode(tf,'Y',parent_id) T,
decode(rf,'Y',child_id) R,
decode(sf,'Y',child_id) S,
decode(ff,'Y',child_id) F,
decode(lf,'Y',child_id) L,
row_number() over
(partition by tf,rf,sf,ff
order by o desc) rn
from
(
select rc.parent_id,
rc.child_id,
rd.t_flag tf,
rd.r_flag rf,
rd.s_flag sf,
rd.f_flag ff,
rd.l_flag lf,
rc.p_order o
from
rd,
(select parent_id,
child_id,
p_order
from rc
start with parent_id in
(select r_id
from rd
where t_flag = 'Y')
connect by prior child_id = parent_id
order by p_order) rc
where rd.r_id = rc.child_id
or rd.t_flag = 'Y'
)
Any thoughts or advice would be most apprciated.
Thanks for your consideration!
February 12, 2005 - 12:14 pm UTC
can you verbablly explain what rd and rc are and how they relate to eachother.
problem is when looking at a query that doesn't work with data I don't understand -- it's really hard to figure out "what needs be done"
RC and RD explained...
Jim, February 14, 2005 - 11:30 am UTC
Hi.
RD contains (in real life) row details about a hierarchy. A given RD row can serve multiple purposes (hence all the "flag" columns).
In a perfect world, the hierachy rows would follow this pattern:
* "T" - root row
** "R" - next level row(s)
*** "S" - next level row(s)
**** "F" - next level row(s)
***** "L" - leaf level row(s)
... but the multiplicity of flags often collapses the non-T and non-L rows into a single row that performs double or triple duty (strangeness up here in the pacific northwest). So that many hierarchies look like this:
* "T" - root row
** "R + S + F" - next level row(s)
*** "L" - leaf level row(s)
The RC table is the hierarchy structure that shows how the RD's fit together in a "connect by prior" fashon. The twist here is that there's an "order by" column which states "at this level within a given "T" root hierarchy, process that given level in this particular order". For example: We have a single "T" root parent, with three underlying "R" childen. So process child-1 hierarchy first, then the child-2 hierarchy, etc. This logic pattern repeats itself within the scope of each underlying hierarchical parent-child module.
So what I'm thinking (apologies - probably all wet here) is to 1) create the hierarchy, 2) collapse the structure, and 3) pivot around the "root" levels so that each "parent"-level data is flattened out down to the "leaf" level in a denormalized fashon.
Hope this helps - and thanks again for your advice.
February 14, 2005 - 2:38 pm UTC
what happened to row "5"
why is 5 not there but 13 and 14 are
Hello. Row "5" is missing because...
Jim, February 14, 2005 - 3:29 pm UTC
... well, I, uh messed up, coach. =o)
Here's where I am:
select *
from
(select rc.*
from rc
start with parent_id in
(select r_id from rd where t_flag = 'Y')
connect by parent_id = prior child_id
order by p_order)
start with parent_id in
(select r_id from rd where t_flag = 'Y')
connect by parent_id = prior child_id;
PARENT_ID CHILD_ID P_ORDER
---------- --------- --------
1 2 1
2 3 1
3 5 1
3 4 2
6 10 1
10 11 1
6 7 2
7 8 1
8 9 1
6 12 3
12 14 1
12 13 2
... which is all properly ordered. So now I've got to figure out how to incorporate the flags into the query and pivot around the roots (#1 and #6).
Thanks again!
Use Pivot to update null records?
Warren McCall, February 21, 2005 - 6:21 pm UTC
Tom,
I am trying to solve a problem, and it seems that the pivot my resolve my issue, but I haven't been able to make it do that yet! Here is the situation:
I have data in a table that has null values in the Site_ID field. The reason this happened is that the data is loaded regularly from Excel (truncate and load) and the Site_ID values are removed in Excel for "viewing pleasure." The records below each Site_ID are logically related:
ID SITE ID REGIONAL OFFICE COMMON NAME
--- ------- --------------- -----------
1 9 Region 1 NEW YORK WHARVES LTD
2 AE SHIPPERS
3 10 Region 2 ESSO BULK PLANT
4 SHELL BULK PLANT
5 Region 2 STATION A
6 STATION B
7 STATION C
8 STATION D
9 STATION E
10 STATION F
11 11 Region 3 RAIL RIGHT-OF-WAY
12 STORAGE SHED
13 FUELING DE
14 EMERGENCY SHELTER
15 13 Region 4 CANRON
I would like to update the data so that it looks like:
ID SITE ID REGIONAL OFFICE COMMON NAME
--- ------- --------------- -----------
1 9 Region 1 NEW YORK WHARVES LTD
2 9 Region 1 AE SHIPPERS
3 10 Region 2 ESSO BULK PLANT
4 10 Region 2 SHELL BULK PLANT
5 10 Region 2 STATION A
6 10 Region 2 STATION B
7 10 Region 2 STATION C
8 10 Region 2 STATION D
9 10 Region 2 STATION E
10 10 Region 2 STATION F
11 11 Region 3 RAIL RIGHT-OF-WAY
12 11 Region 3 STORAGE SHED
13 11 Region 3 FUELING DE
14 11 Region 3 EMERGENCY SHELTER
15 13 Region 4 CANRON
What do you think is the best method for this?
February 22, 2005 - 8:09 am UTC
time for HTML/DB to erradicate excel! keep the data in the database and let them access it via the web. excel as a database, ugh.
if you were to give me a create table, insert intos -- I'd be glad to show you how merge can do this in 9i and even easier in 10g with a new analytic feature.
analytics and merge will be the answer here. (how big is the table, cannot be too big if it fits in little excel spreadsheets)
How to write this query?
Raja, February 22, 2005 - 9:04 am UTC
I want to get the second latest row from the table for grouped columns col1 and col2,where count(parno) > 1. Data for this query is:
create table anl (col1 varchar2(10),col2 varchar2(10),parno number);
insert into anl values('R1C1','R1C2',1);
insert into anl values('R1C1','R1C2',2);
insert into anl values('R1C1','R1C2',3);
insert into anl values('R2C1','R2C2',1);
insert into anl values('R2C1','R2C2',2);
insert into anl values('R3C1','R3C2',1);
insert into anl values('R3C1','R3C2',2);
insert into anl values('R3C1','R3C2',3);
insert into anl values('R4C1','R4C2',1);
And I want the output to be:
R1C1,R1C2,2
R2C1,R2C2,1
R3C1,R3C2,2
The row "R4C1,R4C2,1" will not be output because the count for the grouped columns is not > 1.
Please can you tell me how to go about writing this query.
Thanks
February 22, 2005 - 9:33 am UTC
define "latest" for us here -- I don't see a timestamp, I don't see what you would order by (i'm assuming parno is like a part number or something)
so, what is the "latest record"
answer
Raja, February 22, 2005 - 9:42 am UTC
Sorry, latest means ...latest by parno. I wish to see the second latest by parno. No, the table doesn't have any timestamp but the requirement is to get the second latest of the given parno.
I hope this is clear now.
Many thanks
February 22, 2005 - 9:58 am UTC
I keep hoping these analytics will catch on -- they are extremely powerful and I demo them all of the time........
you want the second row from a group after ordering by parno from big to small.
row_number()
ops$tkyte@ORA9IR2> select *
2 from (
3 select col1, col2, parno,
4 row_number() over (partition by col1, col2 order by parno desc nulls last) rn
5 from anl
6 )
7 where rn = 2
8 /
COL1 COL2 PARNO RN
---------- ---------- ---------- ----------
R1C1 R1C2 2 2
R2C1 R2C2 1 2
R3C1 R3C2 2 2
Thanks
Raja, February 22, 2005 - 10:02 am UTC
That's what I want! Thanks Tom! You are a STAR!
Some more tip...
Tamilselvan, February 22, 2005 - 4:16 pm UTC
This is for Warren McCall, Victoria, Canada
SQL> desc t1
Name Null? Type
-------------------------------- -------- -----------------------
ID NUMBER(38)
SITE_ID NUMBER(38)
REGIONAL_OFFICE VARCHAR2(30)
COMM_NAME VARCHAR2(30)
insert into t1 values(1 , 9, 'Region 1', 'NEW YORK WHARVES LTD');
insert into t1 values(2, null, null, 'AE SHIPPERS');
insert into t1 values(3, 10,'Region 2', 'ESSO BULK PLANT');
insert into t1 values(4, null, null, 'SHELL BULK PLANT');
insert into t1 values(5, null,'Region 2', 'STATION A');
insert into t1 values(6, null, null, 'STATION B');
insert into t1 values(7, null, null, 'STATION C');
insert into t1 values(8, null, null, 'STATION D');
insert into t1 values(9, null, null, 'STATION E');
insert into t1 values(10, null, null, 'STATION F');
insert into t1 values(11, 11 , 'Region 3','RAIL RIGHT-OF-WAY');
insert into t1 values(12, null, null, 'STORAGE SHED');
insert into t1 values(13, null, null , 'FUELING DE');
insert into t1 values(14, null, null, 'EMERGENCY SHELTER');
insert into t1 values(15, 13 , 'Region 4', 'CANRON');
commit;
SQL> select * from t1 ;
ID SITE_ID REGIONAL_OFF COMM_NAME
---------- ---------- ------------ ------------------------------
1 9 Region 1 NEW YORK WHARVES LTD
2 AE SHIPPERS
3 10 Region 2 ESSO BULK PLANT
4 SHELL BULK PLANT
5 Region 2 STATION A
6 STATION B
7 STATION C
8 STATION D
9 STATION E
10 STATION F
11 11 Region 3 RAIL RIGHT-OF-WAY
12 STORAGE SHED
13 FUELING DE
14 EMERGENCY SHELTER
15 13 Region 4 CANRON
15 rows selected.
SQL> get warren.sql
1 select Y.id,
2 (case
3 when y.site_id is not null then y.site_id
4 else (select site_id
5 from T1
6 where T1.id = prev_site_id)
7 end ) NSITE_ID,
8 ( case
9 when y.regional_office is not null then y.regional_office
10 else ( select regional_office
11 from T1
12 where T1.id = prev_reg_id)
13 end ) NRegional_office,
14 y.comm_name
15 FROM
16 (select a.id as id , a.site_id as site_id,
17 (select max(id)
18 from (select distinct id, site_id
19 from t1 where site_id is not null) b
20 where b.id < a.id ) prev_site_id,
21 regional_office regional_office,
22 (select max(id)
23 from (select distinct id , regional_office
24 from t1 where regional_office is not null) c
25 where c.id < a.id ) prev_reg_id
26 from t1 a ) X,
27 T1 Y
28* where x.id = Y.id
SQL> /
ID NSITE_ID NREGIONAL_OFF COMM_NAME
---------- ---------- ------------- ------------------------------
1 9 Region 1 NEW YORK WHARVES LTD
2 9 Region 1 AE SHIPPERS
3 10 Region 2 ESSO BULK PLANT
4 10 Region 2 SHELL BULK PLANT
5 10 Region 2 STATION A
6 10 Region 2 STATION B
7 10 Region 2 STATION C
8 10 Region 2 STATION D
9 10 Region 2 STATION E
10 10 Region 2 STATION F
11 11 Region 3 RAIL RIGHT-OF-WAY
12 11 Region 3 STORAGE SHED
13 11 Region 3 FUELING DE
14 11 Region 3 EMERGENCY SHELTER
15 13 Region 4 CANRON
15 rows selected.
Tom, I tried lead/lag function. I am getting previous site for the subsequent row, but for all the rows.
I am sure, Tom will come up with "ANALYTIC FUNCTION".
Thanks
Tami
How to write this query
Sujit, February 23, 2005 - 12:51 am UTC
Hi,
if a table TAB has the following entries :
Column1
-------
Ant
Ball
Deck
Eight
Xing
Yes
Zen
and I want to find if there is anything missing from the table TAB from the list
('Ant', 'Ball', 'Cat', 'Deck', 'Eight', 'Fix')
then the query should return :
Cat
Fix
In general i want to built a table (or may be view) from a list of given values.
Thanks in advance!
February 23, 2005 - 2:08 am UTC
then you do not want a list, you want a table.
search this site for str2tbl, then you can:
ops$tkyte@ORA9IR2> variable x varchar2(50);
ops$tkyte@ORA9IR2>
ops$tkyte@ORA9IR2> exec :x := 'Ant, Ball, Cat, Deck, Eight, Fix'
PL/SQL procedure successfully completed.
ops$tkyte@ORA9IR2>
ops$tkyte@ORA9IR2> select * from table( cast( str2tbl(:x) as str2tblType ) );
COLUMN_VALUE
------------------------------
Ant
Ball
Cat
Deck
Eight
Fix
6 rows selected.
and the rest should be easy.
Great techniques, but how effecient
B F, March 01, 2005 - 11:59 am UTC
Tom
It seems that this tequnique is very cool and has many applications:
1) creating a non-repeating view of the "first" record among repeating records in a repeating table by some key column
2) creating a view of the source code for a view (using system tables and finctions that grab a line of source from the long given a line number, and the rownum from all_object where rownum <= f_lines_in_long(dba_views_rowid)
3) creating a view with behavior like your printtable() function.
(Views are handy for giving MS Access users their own reporting views to save too many phone calls to the DBA).
I have often seen the same thing done using PL_SQL functions that use cursors to select the "first" of something by a key column (a column that is the unique identifier on a different table), and only getting one of them, and returning either a data column or the rowid.
Would a view like the one below (untested) be more effecient than the function approach?
create or replace view t_nonrepeating
AS
SELECT t.*
FROM (
select stno stno,
max(decode(rn,1,t_rowid)) s1
from ( select rowid t_rowid,
stno,
course_code,
row_number() over (
partition by stno
order by course_code
) rn
from t
)
group by stno
)u,
t
where t.stno = u.stno
/
March 01, 2005 - 12:34 pm UTC
sounds like first_value() over (partition by x order by y) or min() over (partition by x order by y), i don't know that I'd pivot for that.
Inverse resultset possible?
Dan Loomis, March 01, 2005 - 3:32 pm UTC
Tom - I'm not sure if this falls under the pivot query category, but what I want to do is transform a 1 row, 10 column resultset to it's inverse - 1 column and 10 rows.
For example:
SQL> select
2 min(id) b0,
3 percentile_disc(.1) within group (order by id) b1,
4 percentile_disc(.20) within group (order by id) b2,
5 percentile_disc(.30) within group (order by id) b3,
6 percentile_disc(.40) within group (order by id) b4,
7 percentile_disc(.50) within group (order by id) b5,
8 percentile_disc(.60) within group (order by id) b6,
9 percentile_disc(.70) within group (order by id) b7,
10 percentile_disc(.80) within group (order by id) b8,
11 percentile_disc(.90) within group (order by id) b9,
12 percentile_disc(1) within group (order by id) b10
13 from xxcts_ent_okc_k_lines_b_stg
14 where process_flag = 'U' and operation_code = 'I';
B0 B1 B2 B3 B4 B5 B6 B7 B8 B9 B10
---------- ---------- ---------- ---------- ---------- ---------- ---------- ---------- ---------- ---------- ----------
1279698913 1279813242 1280004250 1280110131 1280225989 1280345832 1280474377 1280581043 1280711711 1280837723 1280978292
1 rows selected.
Switched to something like this:
B
----------
1279698913
1279813242
1280004250
1280110131
1280225989
1280345832
1280474377
1280581043
1280711711
1280837723
1280978292
10 rows selected.
How can the original SQL statement be rewritten to accomplish this? As you can guess this query was taken from your new book to generate id ranges for DIY parallelism...many thanks for that idea.
March 01, 2005 - 3:38 pm UTC
cartesian product with a 10 row table.
here is a 3 column example:
ops$tkyte@ORA9IR2> with three
2 as
3 (select level r from dual connect by 1=1 and level <= 3)
4 select decode(r,1,'ename',2,'empno',3,'sal') tag,
5 decode(r,1,ename,2,empno,3,sal) data
6 from scott.emp, three
7 /
Re: Inverse Resultset Possible
Dan Loomis, March 01, 2005 - 5:05 pm UTC
At risk at being marked as inept, I don't really follow your solution. Maybe I can give you a query against scott.emp to better explain my question:
Initial query:
apps@CTSDEV> select
2 min(empno) b0,
3 percentile_disc(.25) within group (order by empno) b1,
4 percentile_disc(.50) within group (order by empno) b2,
5 percentile_disc(.75) within group (order by empno) b3,
6 percentile_disc(1) within group (order by empno) b4
7 from scott.emp;
B0 B1 B2 B3 B4
---------- ---------- ---------- ---------- ----------
7499 7654 7788 7876 7934
1 row selected.
I want to pivot the result to look like the following, but obviously I want to avoid the 4 full index scans, which would be devastating on a large table:
apps@CTSDEV> select min(empno) b from scott.emp
2 union all
3 select percentile_disc(.25) within group (order by empno) b from scott.emp
4 union all
5 select percentile_disc(.50) within group (order by empno) b from scott.emp
6 union all
7 select percentile_disc(.75) within group (order by empno) b from scott.emp
8 union all
9 select percentile_disc(1) within group (order by empno) b from scott.emp
10 /
B
----------
7499
7654
7788
7876
7934
5 rows selected.
Better yet, this would fit my needs perfectly, as I'm really trying to generate N sets of id ranges:
apps@CTSDEV> select
2 min(empno) low_id,
3 percentile_disc(.25) within group (order by empno) high_id
4 from scott.emp
5 union all
6 select
7 percentile_disc(.25) within group (order by empno) low_id,
8 percentile_disc(.50) within group (order by empno) high_id
9 from scott.emp
10 union all
11 select
12 percentile_disc(.50) within group (order by empno) low_id,
13 percentile_disc(.75) within group (order by empno) high_id
14 from scott.emp
15 union all
16 select
17 percentile_disc(.75) within group (order by empno) low_id,
18 percentile_disc(1) within group (order by empno) high_id
19 from scott.emp;
LOW_ID HIGH_ID
---------- ----------
7499 7654
7654 7788
7788 7876
7876 7934
4 rows selected.
March 01, 2005 - 5:20 pm UTC
what you would like is for each row to be output 5 times.
each time it is output, output the i'th column.
To get a row 5 times, we cartesian product your set with a set of 5 rows.
If these 5 rows have the numbers 1, 2, 3, 4, 5 -- we can use decode to output the i'th column:
ops$tkyte@ORA9IR2> with five
2 as
3 (select level r from dual connect by 1=1 and level <= 5)
4 select * from five;
R
----------
1
2
3
4
5
ops$tkyte@ORA9IR2>
ops$tkyte@ORA9IR2>
ops$tkyte@ORA9IR2> select
2 min(empno) b0,
3 percentile_disc(.25) within group (order by empno) b1,
4 percentile_disc(.50) within group (order by empno) b2,
5 percentile_disc(.75) within group (order by empno) b3,
6 percentile_disc(1) within group (order by empno) b4
7 from scott.emp ;
B0 B1 B2 B3 B4
---------- ---------- ---------- ---------- ----------
7369 7566 7782 7876 7934
ops$tkyte@ORA9IR2>
ops$tkyte@ORA9IR2>
ops$tkyte@ORA9IR2> with five
2 as
3 (
4 select level r
5 from dual
6 connect by 1=1
7 and level <= 5
8 ),
9 data
10 as
11 (
12 select min(empno) b0,
13 percentile_disc(.25) within group (order by empno) b1,
14 percentile_disc(.50) within group (order by empno) b2,
15 percentile_disc(.75) within group (order by empno) b3,
16 percentile_disc(1) within group (order by empno) b4
17 from scott.emp)
18 select decode( r, 1, b0, 2, b1, 3, b2, 4, b3, 5, b4 )
19 from five,
20 data
21 /
DECODE(R,1,B0,2,B1,3,B2,4,B3,5,B4)
----------------------------------
7369
7566
7782
7876
7934
ops$tkyte@ORA9IR2>
ops$tkyte@ORA9IR2> with five
2 as
3 (
4 select level r
5 from dual
6 connect by 1=1
7 and level <= 5
8 ),
9 data
10 as
11 (
12 select min(empno) b0,
13 percentile_disc(.25) within group (order by empno) b1,
14 percentile_disc(.50) within group (order by empno) b2,
15 percentile_disc(.75) within group (order by empno) b3,
16 percentile_disc(1) within group (order by empno) b4
17 from scott.emp)
18 select decode( r, 1, 'min', 2, '.25', 3, '.50', 4, '.75', 5, '1.0' ),
19 decode( r, 1, b0, 2, b1, 3, b2, 4, b3, 5, b4 )
20 from five,
21 data
22 /
DEC DECODE(R,1,B0,2,B1,3,B2,4,B3,5,B4)
--- ----------------------------------
min 7369
.25 7566
.50 7782
.75 7876
1.0 7934
(note: if you are using 8i, just use INLINE views instead of the with)
PERFECT
Dan Loomis, March 01, 2005 - 10:54 pm UTC
Thanks for spending an extra few minutes explaining your approach, which by the way is exactly what I was looking for. I don't know what I would do without this website and the service you provide.
Good - very good
Tim B, March 26, 2005 - 9:07 pm UTC
Pivot Table in Oracle very useful. Customers want it. Thanks for the time/trouble to produce this.
column to row
Pushpendra Singh, April 13, 2005 - 12:48 am UTC
Hi Tom,
I have one query:
SELECT id, glCode, name,
(select name from chartofaccounts where parentid = cOfAcc.id)
From chartofaccounts cOfAcc;
here this inside query
(select name from chartofaccounts where parentid = cOfAcc.id)
should retun all the names in a comma separated list. the names I want are those names whose parentId equals ID in outer table. means for ID's there may be 1, 2, ..... unknown names (or children) at the time of firing query, and I want all children of a parent to be in a column in same row in comma separated list.
So my output will be like this:
ID GLCODE NAME CHILDREN
1 GL001 P1 C1, C2, C3
2 GL002 P1 C4, C5
3 GL003 P1 C6, C7, C8, C9
... ..... .. ..,..,..,...........
...
...
... ..... .. ..,..,..,...........
please help me.
Thanks
April 13, 2005 - 9:03 am UTC
search this site for stragg
A Reader, April 19, 2005 - 4:54 pm UTC
Hi Tom,
I am trying to convert rows in to columns using pivot query solution. I would appreciate any help.
I have table a table test1, where results of different queries are being inserted along with the query number assigned to it.
When qry_no = 0, then its a base query, with all the values of x and y.
Counts for all other values of qry_no needs to be mapped for x and y. There in total 10 queries.
create table test1
(
qry_no char(1)
,x char(2)
,y char(2)
,cnt number(2)
);
insert into test1 values('0', 'A1','B1',null);
insert into test1 values('0', 'A2','B2',null);
insert into test1 values('0', 'A3','B3',null);
insert into test1 values('0', 'A4','B4',null);
insert into test1 values('0', 'A5','B5',null);
insert into test1 values('1', 'A1','B1',4);
insert into test1 values('1', 'A2','B2',6);
insert into test1 values('1', 'A3','B3',1);
insert into test1 values('2', 'A3','B3',8);
insert into test1 values('2', 'A4','B4',5);
insert into test1 values('2', 'A5','B5',3);
select * from test1;
Q X Y CNT
- -- -- ----------
0 A1 B1
0 A2 B2
0 A3 B3
0 A4 B4
0 A5 B5
1 A1 B1 4
1 A2 B2 6
1 A3 B3 1
2 A3 B3 8
2 A4 B4 5
2 A5 B5 3
Result
X Y qry1_cnt qry2_cnt qry10_cnt
-- -- -------- -------- .......---------
A1 B1 4
A2 B2 6
A3 B3 1 8
A4 B4 5
A5 B5 3
April 19, 2005 - 7:48 pm UTC
ops$tkyte@ORA9IR2> select x, y,
2 max(decode( qry_no, 1, cnt) ) c2,
3 max(decode( qry_no, 2, cnt) ) c3
4 from test1
5 group by x,y;
X Y C2 C3
-- -- ---------- ----------
A1 B1 4
A2 B2 6
A3 B3 1 8
A4 B4 5
A5 B5 3
Thank you very much Tom.
A Reader, April 20, 2005 - 4:06 pm UTC
Regarding old comment
Mikito Harakiri, May 18, 2005 - 12:30 pm UTC
<quote>
I cannot see how pivoting is could be a "subquery" of a larger query. That just doesn't compute with me.
</quote>
It could easily be an inner view. If a table is in EAV "format" you have to pivot the data in order to perform any nontrivial query (eg. aggregate with group by, etc). Pure EAV table is unqueriable otherwise.
How does Oracle Calculate it
Yousef, June 26, 2005 - 2:35 am UTC
Dear Tom:
How does oracle calculate the result of this query
SQL> select job,
2 max( decode( deptno, 10, cnt, null ) ) dept_10,
3 max( decode( deptno, 20, cnt, null ) ) dept_20,
4 max( decode( deptno, 30, cnt, null ) ) dept_30,
5 max( decode( deptno, 40, cnt, null ) ) dept_40
6 from ( select job, deptno, count(*) cnt
7 from emp
8 group by job, deptno )
9 group by job
10 /
As I understand, first the subquery is executed first, and it will return the following result
SQL>select job, deptno, count(*) cnt
2 from emp
3 group by job,deptno;
JOB DEPTNO CNT
--------- ---------- ----------
CLERK 10 1
CLERK 30 1
MANAGER 10 1
MANAGER 30 1
SALESMAN 30 4
PRESIDENT 10 1
6 rows selected.
But then how it's calcualting the result, and why do we use max, if I change it sum i still can get the same result.
Best Regards,
June 26, 2005 - 9:43 am UTC
It'll take this data:
scott@ORA9IR2> select job, deptno, count(*) cnt
2 from emp
3 group by job,deptno;
JOB DEPTNO CNT
--------- ---------- ----------
CLERK 10 1
CLERK 20 2
CLERK 30 1
ANALYST 20 2
MANAGER 10 1
MANAGER 20 1
MANAGER 30 1
SALESMAN 30 4
PRESIDENT 10 1
9 rows selected.
Use decode to put it into a sparse matrix -- with the same number of rows but putting the single DEPTNO count into separate columns:
scott@ORA9IR2>
scott@ORA9IR2> select job,
2 decode( deptno, 10, cnt, null ) c1,
3 decode( deptno, 20, cnt, null ) c2,
4 decode( deptno, 30, cnt, null ) c3,
5 decode( deptno, 40, cnt, null ) c4
6 from (
7 select job, deptno, count(*) cnt
8 from emp
9 group by job,deptno
10 )
11 /
JOB C1 C2 C3 C4
--------- ---------- ---------- ---------- ----------
CLERK 1
CLERK 2
CLERK 1
ANALYST 2
MANAGER 1
MANAGER 1
MANAGER 1
SALESMAN 4
PRESIDENT 1
9 rows selected.
and then we use aggregation to "squish out" the white space. Max makes the most sense since we just want the non-null value to appear, there is nothing to "sum" since there is only one observation.
Another way to have written THIS PARTICULAR query would have been:
scott@ORA9IR2> select job,
2 sum(decode( deptno, 10, 1, null )) c1,
3 sum(decode( deptno, 20, 1, null )) c2,
4 sum(decode( deptno, 30, 1, null )) c3,
5 sum(decode( deptno, 40, 1, null )) c4
6 from emp
7 group by job
8 /
JOB C1 C2 C3 C4
--------- ---------- ---------- ---------- ----------
ANALYST 2
CLERK 1 2 1
MANAGER 1 1 1
PRESIDENT 1
SALESMAN 4
scott@ORA9IR2>
but in general, the pivot is done via the max(decode(....)) trick
Thanks
A reader, June 26, 2005 - 9:51 am UTC
Thank you alot
Very Helpful
Hema, June 27, 2005 - 1:08 am UTC
Hi Tom,
This is very helpful in accomplishing some of my reports.
Can you provide me the link where I can submit question directly on your site www.asktom.oracle.com ?
I really need your expert help in a pivot report.
I have a table data like below ..
SELECT rmonth,calls,qa,hold FROM TRATINGS WHERE uid='ab12345678' AND ryear =2005;
------------------------------------------
rmonth calls qa hold
------------------------------------------
1 10 15 20
2 20 25 30
3 30 35 40
4 40 45 50
5 50 55 60
-------------------------------------------
I want to output like below ..
----------------------------------------
Item Jan Feb Mar Apr May ..so on.. upto December
---------------------------------------
Calls 10 20 30 40 50
qa 15 25 35 45 55
hold 20 30 40 50 60
---------------------------------------
Is it possible with a single SQL ?
Thanks
Hema
June 27, 2005 - 7:11 am UTC
when I'm taking new questions, there is a link on the home page.
this pivot is not very different from the examples above, just requires two steps.
ops$tkyte@ORA9IR2> create table t
2 as
3 select rownum rmonth, rownum*10 calls, 5+(rownum*10) qa, 10+rownum*10 hold
4 from all_users
5 where rownum <= 5;
Table created.
ops$tkyte@ORA9IR2>
ops$tkyte@ORA9IR2>
ops$tkyte@ORA9IR2> select decode(r,1,'Calls',2,'QA',3,'Hold') tag,
2 max(decode(rmonth,1,data)) jan,
3 max(decode(rmonth,2,data)) feb,
4 max(decode(rmonth,3,data)) mar,
5 max(decode(rmonth,4,data)) apr,
6 max(decode(rmonth,5,data)) may
7 from (
8 select decode(r,1,calls,2,qa,3,hold) data, rmonth, r
9 from t, (select level r from dual connect by level<=3)
10 )
11 group by decode(r,1,'Calls',2,'QA',3,'Hold')
12 /
TAG JAN FEB MAR APR MAY
----- ---------- ---------- ---------- ---------- ----------
Calls 10 20 30 40 50
Hold 20 30 40 50 60
QA 15 25 35 45 55
Excellent
Hema, June 28, 2005 - 8:48 pm UTC
Tom, Thanks for a nice solution.
Pivot table
Ron, July 18, 2005 - 11:26 am UTC
Tom,
please Give me the simple example for changing from rows to columns
select * from emp;
10
20
30
40
50
60
70
80
90
100
-----------------
No i want
No
--
10,20,30,40,50,60,70,80,90,100
Thanks
Ron
July 18, 2005 - 11:35 am UTC
search this site for stragg
that isn't columns you are showing, that is a string with commas between fields.
Pivot
ron, July 19, 2005 - 2:41 am UTC
Tom,
Ya, the column is varchar2 and i want the rows in columns with the comma.
like
select * from text
Name
--------
A
B
C
D
then i want to show
Name
------
A,B,C,D
please end me the query for the same.
July 19, 2005 - 7:32 am UTC
please read the above again??? I told you what to search for on this site.
N number of rows with cartision
Jignesh, September 09, 2005 - 6:56 am UTC
I am looking for producing weekdays of two years in pivot table. I am able to produce the same using following query :
select weekend_date nv_date, to_char(weekend_date,'DAY') nv_day
from (
select trunc(sysdate,'YY')+rownum-1 weekend_date from all_tab_columns
WHERE ROWNUM <= (366*2))
WHERE trim(to_char(weekend_date,'DAY')) in ('SATURDAY','SUNDAY')
However, this uses all_tab_columns which I want to avoid.
I tried using with clause
At the very first step of developing query :
select level dummy from dual connect by 1=1 and level <= (365*2)
I only got 25 rows returned whereas I need two years calendar in first place.
Any better way of resolving this issue?
I want to avoid temporary tables.
Thanks
Before actually you pick it up.... Got the solution
Jignesh, September 09, 2005 - 7:26 am UTC
(select trunc(sysdate,'YY')+rownum-1 weekend_date from
(select level dummy from dual connect by 1=1 and level <= (366*2))
connect by 1=1
and LEVEL = 1)
Months of a year
Reader, October 12, 2005 - 6:24 am UTC
How can I use something like this to get the months in a year .
ie
Jan
Feb
Mar
...
..
Dec
Thanks
October 12, 2005 - 7:32 am UTC
1 with x
2 as
3 (select level-1 l from dual connect by level <= 12)
4 select to_char(add_months(to_date('0101','ddmm'),l),'mon')
5* from x
ops$tkyte@ORA10GR1> /
TO_
---
jan
feb
mar
apr
may
jun
jul
aug
sep
oct
nov
dec
12 rows selected.
I got it ..
Reader, October 12, 2005 - 6:37 am UTC
I got it ...
(select decode(rownum,1,'Jan',2,'Feb',3,'Mar',4,'Apr',5,'May',6,'Jun',7,'Jul',8,'Aug',9,'Sep',10,'Oct',11,'Nov',12,'Dec') Month from (select level dummy from dual connect by 1=1 and level <=(12))
connect by 1=1
and level=1 )
BUT ,How can I use this to do an outer join with my table so that even if I do not have data for a particular month I can display 0.0 for that month.
I can construct some sample data if I am not clear about my question .
October 12, 2005 - 7:38 am UTC
ops$tkyte@ORA10GR1> with x
2 as
3 (select add_months(to_date('0101','ddmm'),level-1) dt
4 from dual
5 connect by level <= 12)
6 select x.dt, count(all_objects.object_id)
7 from x left outer join all_objects on ( x.dt = trunc(all_objects.created,'mm') )
8 group by x.dt;
DT COUNT(ALL_OBJECTS.OBJECT_ID)
--------- ----------------------------
01-JAN-05 243
01-FEB-05 0
01-MAR-05 13
01-APR-05 10
01-MAY-05 7
01-JUN-05 3
01-JUL-05 14
01-AUG-05 46
01-SEP-05 0
01-OCT-05 27
01-NOV-05 0
01-DEC-05 0
12 rows selected.
Complex query
Venkateswara Reddy, December 26, 2005 - 4:47 am UTC
Hi Tom
I have a requirement that, I need to pivot some columns data from a singe table.
for ex: my table has 3 columns and has data like this.
Col A, Col B Col B
301 110 Company A
301 110 Company A
301 ABC Company A
301 ABC Company A
301 CDE Company A
so, here col B data might change sometime back or it may change over the period. I want data like, the movement change COL B to ( here after 110 then ABC) it should appear new column like this
Col A OLD Column A Old Col B New Col A New Col B
301 110 Company A ABC Col A
301 110 Company A CDE Col A
How can I achieve this with singe SQL Query. I am trying to generate data like above format. My database version is 9i.
Appriciate your help.
December 26, 2005 - 10:53 am UTC
no create table
no inserts
not even going to look....
well, I did peek - I see no logical way to get from your input to the output - you would need to define that a tad better too.
Query
Madhukar, January 18, 2006 - 4:41 am UTC
Hi Tom,
I have a requirement as follows:
1. The table say Dept has the columns like 'Deptno','Job',... and the data looks like this
Table Dept:
Deptno Job
10 Manager
10 Clerk
10 Analyst
20 Attender
20 Engineer
20 Team Lead
20 Project Leader
and etc.
I want an output like as shown below.
10 Manager Clerk Analyst
20 Attender Engineer Team Lead Project Leader
and etc....
Please help me in this regards.
Madhukar.
January 18, 2006 - 8:18 am UTC
search this site for stragg for one possible approach.
Using over (... partition ..) in a PL/SQL block
Jose, January 18, 2006 - 11:29 am UTC
Hello Tom:
I am trying to use ...over ( ... partition .. ) in an UPDATE sentence into a PL/SQL block and i get an error message, but the same SQL sentence in a SQL*Plus session works correctly.
I am using oracle 8.1.7.4 over hp-ux. In the docs i have seen that the word OVER is not a reserved word of PL/SQL.
Does it mean that i can't use ... over ( ... partition ...) in PL/SQL?
Using over (... partition ..) in a PL/SQL block
Michel Cadot, January 18, 2006 - 12:20 pm UTC
Jose,
This is because direct SQL engine and PL/SQL SQL engine are not at the same level in 8i. PL/SQL engine is a little late and does not support some SQL syntax.
In 9i and up, SQL and PL/SQL use the same SQL engine, so what works in SQL works in PL/SQL block.
Regards
Michel
Thanks Michel
Jose, January 18, 2006 - 12:30 pm UTC
Thanks Michel for your clarification.
Convert column having NULL value to rows
Narendra, February 02, 2006 - 6:35 am UTC
Hi Tom,
Following is my table definition
CREATE TABLE LND_CHT
(
ID VARCHAR2(14 BYTE) NOT NULL,
P_NAME VARCHAR2(30 BYTE),
P_OWNER VARCHAR2(30 BYTE)
)
Here is data:
INSERT INTO LND_CHT ( INTERCHANGE_ID, PROJECT_NAME, OWNER ) VALUES (
'A1', 'P1', 'O1');
INSERT INTO LND_CHT ( INTERCHANGE_ID, PROJECT_NAME, OWNER ) VALUES (
'A2', 'P2', NULL);
INSERT INTO LND_CHT ( INTERCHANGE_ID, PROJECT_NAME, OWNER ) VALUES (
'A3', NULL, 'O3');
INSERT INTO LND_CHT ( INTERCHANGE_ID, PROJECT_NAME, OWNER ) VALUES (
'A4', NULL, NULL);
COMMIT;
I need following output:
A3 Project Name
A4 Project Name
A2 Owner
A4 Owner
I have used following query:
SELECT interchange_id, Nvl(project_name, 'Project Name')
FROM LND_CHT
WHERE project_name IS NULL
UNION ALL
SELECT interchange_id, Nvl(owner, 'Owner')
FROM LND_CHT
WHERE owner IS NULL
However, it requires 2 full table scans. Is there any better way to achieve the same?
Thanks
February 02, 2006 - 12:01 pm UTC
that query does not give that output.
Not that I could really run the example - since the column names don't match up.
Not sure why you want
A4 Owner
and not
A4 Project Name
using pipelining for pivoting
A reader, February 02, 2006 - 12:46 pm UTC
You suggested using pipelining above. When testing, I found the foll. for pipelined functions.
Can you provide some insight???
Why are consistent gets and recursive calls more when using the pipelined function
I run 2 sql's , one is a select * from emp
and the other as select * from table(test_ppln.f1()) (the pipelined fn code is below).
Please see the results . Why are there more consistent and recursive calls gets when using pipelining?
I understand that there is overhead in piping the row but why does that impact the consistent gets??
CREATE package test_ppln
as
type tab1 is table of emp%rowtype ;
function f1 return tab1 pipelined;
end ;
/
CREATE package body test_ppln
as
function f1 return tab1 pipelined
as
l_rec emp%rowtype ;
cursor c1
is
select * from emp;
begin
open c1 ;
loop
fetch c1 into l_rec ;
exit when c1%notfound ;
pipe row (l_rec) ;
end loop ;
close c1 ;
return ;
end ;
end ;
/
SQL> select * from emp;
14 rows selected.
Statistics
----------------------------------------------------------
490 recursive calls
0 db block gets
96 consistent gets
23 physical reads
0 redo size
1346 bytes sent via SQL*Net to client
500 bytes received via SQL*Net from client
2 SQL*Net roundtrips to/from client
5 sorts (memory)
0 sorts (disk)
14 rows processed
SQL> select * from table(test_ppln_1.f1());
14 rows selected.
Statistics
----------------------------------------------------------
8575 recursive calls
0 db block gets
2038 consistent gets
223 physical reads
0 redo size
1340 bytes sent via SQL*Net to client
500 bytes received via SQL*Net from client
2 SQL*Net roundtrips to/from client
134 sorts (memory)
0 sorts (disk)
14 rows processed
February 02, 2006 - 2:28 pm UTC
couple of things....
run things "twice" - your select * from emp for example - it should have zero recursive calls, maybe 4 or 5 IOs. Not
Statistics
----------------------------------------------------------
490 recursive calls
0 db block gets
96 consistent gets
23 physical reads
hard parsing, cold system - lots of "extra one time stuff"
another thing - sqlplus array fetches 15 rows at a time - select * from emp - did maybe 1 or 2 fetches (sqlplus fetches 1 row and then fetches the rest 15 at a time). In the plsql routine, you fetched a single row at a time - sure way to increase IO.
Just like this:
ops$tkyte@ORA9IR2> set autotrace traceonly statistics;
ops$tkyte@ORA9IR2> set arraysize 2
ops$tkyte@ORA9IR2> select * from emp;
14 rows selected.
Statistics
----------------------------------------------------------
0 recursive calls
0 db block gets
10 consistent gets
0 physical reads
0 redo size
2060 bytes sent via SQL*Net to client
569 bytes received via SQL*Net from client
8 SQL*Net roundtrips to/from client
0 sorts (memory)
0 sorts (disk)
14 rows processed
ops$tkyte@ORA9IR2> set arraysize 15
ops$tkyte@ORA9IR2> select * from emp;
14 rows selected.
Statistics
----------------------------------------------------------
0 recursive calls
0 db block gets
4 consistent gets
0 physical reads
0 redo size
1307 bytes sent via SQL*Net to client
503 bytes received via SQL*Net from client
2 SQL*Net roundtrips to/from client
0 sorts (memory)
0 sorts (disk)
14 rows processed
Correction
Narendra, February 02, 2006 - 11:27 pm UTC
Hi Tom,
Sorry for my incorrect input.
Here are corrected details:
CREATE TABLE LND_CHT
(
ID VARCHAR2(14 BYTE) NOT NULL,
P_NAME VARCHAR2(30 BYTE),
P_OWNER VARCHAR2(30 BYTE)
)
INSERT INTO LND_CHT ( ID, P_NAME, P_OWNER ) VALUES (
'A1', 'P1', 'O1');
INSERT INTO LND_CHT ( ID, P_NAME, P_OWNER ) VALUES (
'A2', 'P2', NULL);
INSERT INTO LND_CHT ( ID, P_NAME, P_OWNER ) VALUES (
'A3', NULL, 'O3');
INSERT INTO LND_CHT ( ID, P_NAME, P_OWNER ) VALUES (
'A4', NULL, NULL);
COMMIT;
I need following output:
A3 Project Name => Because row with ID "A3" has P_NAME with NULL value
A4 Project Name => Because row with ID "A4" has P_NAME with NULL value
A2 Owner => Because row with ID "A2" has P_OWNER with NULL value
A4 Owner => Because row with ID "A4" has P_OWNER with NULL value
I have used following query:
SELECT id, 'Project Name')
FROM LND_CHT
WHERE p_name IS NULL
UNION ALL
SELECT id, 'Owner'
FROM LND_CHT
WHERE p_owner IS NULL
Would appreciate your help.
February 03, 2006 - 2:04 pm UTC
you would need to cartesian join this table with a table that has as many rows as columns you want to check.
ops$tkyte@ORA10GR2> with data as (select level r from dual connect by level <= 2)
2 select id,
3 case when r=1 and p_owner is null then 'owner'
4 when r=2 and p_name is null then 'project'
5 end tag
6 from lnd_cht, data
7 where (r=1 and p_owner is null)
8 or (r=2 and p_name is null);
ID TAG
-------------- -------
A2 owner
A4 owner
A3 project
A4 project
Correction
Narendra, February 02, 2006 - 11:31 pm UTC
Tom,
Sorry for one more mistake.
The SELECT that generates results will be:
SELECT id, 'Project Name'
FROM LND_CHT
WHERE p_name IS NULL
UNION ALL
SELECT id, 'Owner'
FROM LND_CHT
WHERE p_owner IS NULL
Regards
Transpose
Ratan, February 09, 2006 - 10:15 am UTC
Hi Tom,
I need your help in formulating my query to transpose the records.
Query:
SELECT A.CAT_NBR,
C.ITEM_NOTES
FROM TB_007CAT_MSTR A,
TB_084INVNT_STATUS B,
TB_OST06459_FCT_ITEM_NOTES C
WHERE A.CAT_NBR= B.CAT_NBR
AND A.CAT_NBR = C.CAT_NUM(+)
AND A.CAT_NBR IN (SELECT DISTINCT B.CAT_NBR FROM TB_001INVCE_SUMRY A, TB_002INVCE_DET B WHERE
A.INVCE_NBR = B.INVCE_NBR
AND A.INVCE_DATE = B.INVCE_DATE
AND A.INVCE_WRHSE = B.INVCE_WRHSE
AND A.CHG_TO_CUST = B.CHG_TO_CUST
AND B.PROCESS_DATE >= '20030101'
AND A.DIST_APRCH = 'X')
Output:
CAT# INOTES
---------------------------------------------------------
DC300 KIT KIT IS TO BE SENT OUT USING "EXCHAN
DC300 KIT GE" FUNCTION FOR ENGINEERS USE ONLY
DC300 KIT !!!
DC300 KIT SEE NELDA OR CHARLIE - WEIGHT 46.0
DC300 KIT LBS
DC300 KIT 02/01/01
I need to modify the query to transpose the data such that for 1 Cat# should display 1 record by concatinating all INOTES values.
Ex:
CAT# INOTES
---------------------------------------------------------
DC300 KIT KIT IS TO BE SENT OUT USING "EXCHANGE" FUNCTION FOR ENGINEERS USE ONLY !!! SEE NELDA OR CHARLIE - WEIGHT 46.0
Please help me to formulate query. Will it be possible in single SQL statement?
Thanks in advance.
Ratan
February 10, 2006 - 11:13 am UTC
I don't see any way to order this data, there is no order by? what sorts it - else data comes out any old way it feels like it wants to.
do you have a maximum number of "lines" of inotes?
will the concatenation of inotes exceed 4000 bytes?
To Ratan
Michel Cadot, February 09, 2006 - 2:59 pm UTC
Related HTML crosstab
ottar soerland, April 05, 2006 - 9:55 am UTC
I find the following little utility useful sometimes to create a HTML crosstab report from a query:
create type pivot_output_t as table of varchar2(1000);
/
CREATE OR REPLACE FUNCTION pivot_output(p_col1_heading IN VARCHAR2,
p_col2_heading IN VARCHAR2,
p_col1 IN VARCHAR2,
p_col2 IN VARCHAR2,
p_col3 IN VARCHAR2,
p_from IN VARCHAR2)
RETURN pivot_output_t pipelined IS
TYPE t_curRef IS REF CURSOR;
l_curRef t_curRef;
col1 varchar2(30);
col2 varchar2(30);
col3 varchar2(30);
l_from varchar2(1000);
l_cur_txt VARCHAR2(32000);
l_line_cnt NUMBER:=0;
l_col1_vals NUMBER;
l_col2_vals NUMBER;
l_desc VARCHAR2(300);
TYPE t_num IS TABLE OF NUMBER INDEX BY VARCHAR2(100);
TYPE t_num2 IS TABLE OF t_num INDEX BY VARCHAR2(100);
TYPE t_char IS TABLE OF VARCHAR2(100) INDEX BY BINARY_INTEGER;
l_x_head t_char;
l_y_head t_char;
l_x_ind NUMBER:=0;
l_y_ind NUMBER:=0;
l_tab t_num2;
l_x t_num;
l_y t_num;
l_colx_head VARCHAR2(40);
l_coly_head VARCHAR2(40);
l_g_tot NUMBER:=0;
BEGIN
pipe row('</tr>');
pipe row('</table> <br>');
pipe row('<br>');
pipe row('<br>');
EXECUTE IMMEDIATE 'select COUNT(DISTINCT '||p_col1||') '||p_from
INTO l_col1_vals;
EXECUTE IMMEDIATE 'select COUNT(DISTINCT '||p_col2||') '||p_from
INTO l_col2_vals;
IF l_col1_vals < l_col2_vals THEN
l_colx_head:=p_col2_heading;
l_coly_head:=p_col1_heading;
l_cur_txt:='SELECT '||p_col2||' source_x,
'||p_col1||' source_y,
'||p_col3||' prn_col3_val '||p_from;
ELSE
l_colx_head:=p_col1_heading;
l_coly_head:=p_col2_heading;
l_cur_txt:='SELECT '||p_col1||' source_x,
'||p_col2||' source_y,
'||p_col3||' prn_col3_val '||p_from;
END IF;
OPEN l_curRef FOR l_cur_txt;
LOOP
FETCH l_curRef INTO col1, col2, col3;
EXIT WHEN l_curRef%NOTFOUND;
l_tab (col1) (col2) := col3;
IF l_x.EXISTS(col1) THEN
l_x(col1):= l_x(col1) + col3;
ELSE
l_x(col1):= col3;
l_x_ind:=l_x_ind+1;
l_x_head(l_x_ind):=col1;
END IF;
IF l_y.EXISTS(col2) THEN
l_y(col2):= l_y(col2) + col3;
ELSE
l_y(col2):= col3;
l_y_ind:=l_y_ind+1;
l_y_head(l_y_ind):=col2;
END IF;
END LOOP;
CLOSE l_curRef;
pipe row('<table border=1 cellpadding="3" cellspacing="0" bgcolor=#FFFFFF> <tr>');
pipe row('<td align=center style=''background:99CCCC;font-size:10.0pt''> '||
l_coly_head||'</td>');
FOR c IN l_y_head.FIRST..l_y_head.LAST LOOP
pipe row('<td rowspan=2 align=center style=''background:99CCCC;font-size:10.0pt''> '||
l_y_head(c)||'</td>');
END LOOP;
pipe row('<td rowspan=2 align=center style=''background:CCCCCC;font-size:10.0pt''> SUM </td>');
pipe row('<tr><td align=center style=''background:99CCCC;font-size:10.0pt''> '||
l_colx_head||'</td>');
FOR x IN l_x_head.FIRST..l_x_head.LAST LOOP
pipe row('</tr><tr>');
pipe row('<td align=right style=''background:99CCCC;font-size:10.0pt''>'||
l_x_head(x)||'</td>');
FOR y IN l_y_head.FIRST..l_y_head.LAST LOOP
IF l_tab(l_x_head(x)).EXISTS(l_y_head(y)) THEN
pipe row('<td align=right style=''font-size:10.0pt''>'||
to_char(l_tab(l_x_head(x)) (l_y_head(y)),'999,999,999,999')||'</td>' );
ELSE
pipe row('<td align=right style=''font-size:10.0pt''>0</td>' );
END IF;
END LOOP;
pipe row('<td align=right style=''background:CCCCCC;font-size:10.0pt''>'||
to_char(l_x(l_x_head(x)),'999,999,999,999')||'</td>');
END LOOP;
pipe row('</tr><tr><td align=center style=''background:CCCCCC;font-size:10.0pt''> SUM</td>');
FOR y IN l_y_head.FIRST..l_y_head.LAST LOOP
pipe row('<td align=right style=''background:CCCCCC;font-size:10.0pt''> '||
to_char(l_y(l_y_head(y)),'999,999,999,999')||'</td>');
l_g_tot:=l_g_tot+l_y(l_y_head(y));
END LOOP;
pipe row('<td align=right style=''background:CCCCCC;font-size:10.0pt''> '||
to_char(l_g_tot,'999,999,999,999')||'</td>');
END;
/
CREATE TABLE CFL (season varchar2(100),team varchar2(100),points number);
INSERT INTO CFL (season, team, points) VALUES (2005, 'Argonauts', 22);
INSERT INTO CFL (season, team, points) VALUES (2005, 'Alouettes', 20);
INSERT INTO CFL (season, team, points) VALUES (2005, 'Renegades', 14);
INSERT INTO CFL (season, team, points) VALUES (2005, 'Tiger-Cats', 10);
INSERT INTO CFL (season, team, points) VALUES (2005, 'Team 1', 12);
INSERT INTO CFL (season, team, points) VALUES (2005, 'Team 2', 12);
INSERT INTO CFL (season, team, points) VALUES (2004, 'Argonauts', 22);
INSERT INTO CFL (season, team, points) VALUES (2004, 'Alouettes', 20);
INSERT INTO CFL (season, team, points) VALUES (2004, 'Renegades', 14);
INSERT INTO CFL (season, team, points) VALUES (2004, 'Tiger-Cats', 10);
INSERT INTO CFL (season, team, points) VALUES (2004, 'Team 1', 12);
INSERT INTO CFL (season, team, points) VALUES (2004, 'Team 2', 12);
INSERT INTO CFL (season, team, points) VALUES (2003, 'Argonauts', 22);
INSERT INTO CFL (season, team, points) VALUES (2003, 'Alouettes', 20);
INSERT INTO CFL (season, team, points) VALUES (2003, 'Renegades', 14);
INSERT INTO CFL (season, team, points) VALUES (2003, 'Tiger-Cats', 10);
INSERT INTO CFL (season, team, points) VALUES (2003, 'Team 2', 12);
SET NEWPAGE 0
SET SPACE 0
SET LINESIZE 200
SET PAGESIZE 0
select * from
table(pivot_output('SEASONS','TEAMS','season','team','points','from cfl'));
Pivot query
Reader, April 11, 2006 - 12:00 pm UTC
Hi,
The cross tab query was very useful, but what if I have to display 3 values under one group and one column?? for eg:
customer mth1 mth2 mth3 ......
cust1 1000 (Rent1) 2000(rent1) ...
1200(Rent2) 1000(rent2) ...
1300(Rent3) 1200(rent3) ...
cust2 5000(rent1) 4000(rent1) ...
3000(rent2) 2000(rent2) ...
1400(rent3) 3500(rent3) ....
... and so on
the table contains data like this
customer | mths | rent1 |rent2 | rent3 ...
cust1 04/2006 1000 1200 1300
cust1 05/2006 5000 3000 1400
cust2 04/2006 2000 1000 1200 ..
cust2 05/2006 4000 2000 3500
the 'mths' column is fixed.. please respond as soon as you can..
Thanks,
April 11, 2006 - 6:01 pm UTC
so you need to turn each row into N rows (where N is the number of month columns - gotta wonder what the person modeling this data was thinking...)
no create table
no insert intos
no look.
reverse pivoting a data result
A reader, April 27, 2006 - 5:03 pm UTC
Tom:
I got a file ( or Oracle table ) like a spreadsheet, not I need to construct it back to relational structure, an example would like this:
I have a report
Name Day1 Day2 Day3 Day4 Day5
Ad 10 9 10 8 9
Tom 8 8 7 6 7
Jack 5 6 6 7 8
Now I need to show like:
Name Day Hours
Ad day1 10
Ad day2 9
.
Please advice
Thanks
April 28, 2006 - 1:45 am UTC
with data
as
(select level l from dual connect by level <= 5)
select name,
'day' || l day,
decode(l,1,day1,2,day2,3,day3,4,day4,5,day5) hours
from T, data;
reverse pivoting a data result
A reader, April 27, 2006 - 5:55 pm UTC
I came up a with solution, maybe there is a better to do it,
select name, 'day1' as day, day1 as hours from thistable
union
select name, 'day2' as day, day2 as hours from thistable
union
.
.
pretty simple, sorry for asking dumb questions.
April 28, 2006 - 1:53 am UTC
you would never want to use union for that, "union all" maybe - but not union.
But see above for an alternative.
reverse pivoting a data result
A reader, April 28, 2006 - 10:13 am UTC
Thanks a lot
Marcel, May 04, 2006 - 6:16 am UTC
Hi Tom,
I hvae a problem with creating a pivot query.
Below is a case like my, with dummy data.
I don't know how much courses are booked , when I run the query, so the columns displayed is not always the same.
he're I have no idea how I could calculate the number of rows and then replacing them with the heading cols.
Can you please give me a tip how I could resolve this.
Regards
Marcel
create table training ( user_id_pk int, course_user varchar2(25) );
create table traing_query (id_pk int ,user_id_fk int ,id_fk int , planed int);
create table traing_course (id_pk int, course_desc varchar2(50) );
insert into training values (1,'User_1');
insert into training values (2,'User_2');
insert into training values (3,'User_3');
insert into training values (4,'User_4');
insert into traing_query values (1,1,1,0);
insert into traing_query values (2,1,2,0);
insert into traing_query values (3,1,3,0);
insert into traing_query values (4,1,4,0);
insert into traing_query values (5,2,1,0);
insert into traing_query values (6,2,2,0);
insert into traing_query values (7,3,3,0);
insert into traing_query values (8,3,4,0);
insert into traing_query values (9,4,1,0);
insert into traing_query values (10,4,2,0);
insert into traing_course values (1,'SQL');
insert into traing_course values (2,'Enterprise Manager');
insert into traing_course values (3,'SQL Pivot');
insert into traing_course values (4,'SQL Functions');
insert into traing_course values (5,'dbms_sql');
insert into traing_course values (6,'APEX');
insert into traing_course values (7,'DBMS_STAT');
insert into traing_course values (8,'SQLPLUS');
SQL Enterprise Manager SQL Pivot Learn SQL Functions dbms_sql APEX DBMS_STATS SQLPLUS
user_1 0 0 0 0
user_2 0 0 0
user_3 0 0
user_4 0 0
May 04, 2006 - 7:40 am UTC
take a query that selects username, whatever-count-you-need, course_desc (I assume you can get that one)
Then, you will query the traing_course table to figure out what columns you'll have and use the output of the query against traing_course to dynamically constraint a query in the form:
select username,
max( decode(course_desc,'Enterprise Manager',cnt) ) "Enterprise Manager",
...
max( decode(course_desc,'APEX',cnt) ) "APEX"
from (your_first_query)
group by username;
but basically you would have to
a) query traing_course to discover the columns
b) dynamically constraint the above query based on that.
Pivot Query
PRS, May 17, 2006 - 8:14 pm UTC
Tom,
I have table X which has two columns.
Data is following
Id Desc
1 My Test
1 My Test1
1 My Test2
2 My Test
2 My Test
I need output as shown below a Pivot.
Id Desc
1 My Test - My Test1 - My Test2
2 My Test - My Test
Number of rows can be dynamic for a given id.
I want to achive through SQL without writing an ORACLE function. Is there any way we can achive this?
We are using oracle 9.2.0.6 - 64 bit on Solaris-8.
Thanks in advance,
PRS
May 18, 2006 - 10:45 am UTC
search for stragg - people have demonstrated how you can do this with connect by and sys_connect_by_path()
What is the reason ?
A reader, May 18, 2006 - 10:47 am UTC
what is the technical reason behing
"Sort key too long" Error ?
I know why it happens I don't know why oracle has to do it in one block ?
May 19, 2006 - 9:49 am UTC
implementation restriction.
I'm sure your code has some here and there as well.
A reader, June 12, 2006 - 7:55 pm UTC
A simple way to create Excel like Pivot Table
Ahmed Saber, June 20, 2006 - 12:40 am UTC
select 1 as gr, 'EmpID/->State ' as Row_Col_Head,
max(decode (ColNo, 1, state, 0)) C1,
max(decode (ColNo, 2, state, 0)) C2,
max(decode (ColNo, 3, state, 0)) C3,
max(decode (ColNo, 4, state, 0)) C4,
max(decode (ColNo, 5, state, 0)) C5
from
(
select state, count(*) n, row_number()
over (partition by 1 order by 1) as ColNo
from sales group by state
)
union all
select 2 as gr, empid,
to_char(max(decode (ColNo, 1, n, 0))),
to_char(max(decode (ColNo, 2, n, 0))),
to_char(max(decode (ColNo, 3, n, 0))),
to_char(max(decode (ColNo, 4, n, 0))),
to_char(max(decode (ColNo, 5, n, 0)))
from
(
select a.empid, a.state, b.ColNo, a.n from
(select empid, state, count(*) n
from sales
group by empid, state) a,
(
select state, count(*) c1, row_number()
over (partition by 1 order by 1) as ColNo
from sales group by state
) b
where a.state = b.state
) group by empid
union all
select 3 as gr, 'Total ',
to_char(max(decode (ColNo, 1, n, 0))),
to_char(max(decode (ColNo, 2, n, 0))),
to_char(max(decode (ColNo, 3, n, 0))),
to_char(max(decode (ColNo, 4, n, 0))),
to_char(max(decode (ColNo, 5, n, 0)))
from
(
select state, count(*) n, row_number()
over (partition by 1 order by 1) as ColNo
from sales group by state
)
A Simple way to create Excel like Pivot Table
Ahmed Saber, June 20, 2006 - 1:10 am UTC
Two questions for Tom :
1. How to eliminate the repetition (please see the code below)?
2. How to replace C1, C2,... (column names) by actual "State" code?
Thanks for maintaining this wonderful site!!!!!
to_char(max(decode (ColNo, 1, n, 0))),
to_char(max(decode (ColNo, 2, n, 0))),
to_char(max(decode (ColNo, 3, n, 0))),
to_char(max(decode (ColNo, 4, n, 0))),
to_char(max(decode (ColNo, 5, n, 0)))
June 20, 2006 - 9:44 am UTC
you give no context whatsoever.
Pivoting my Query
suren, June 22, 2006 - 4:03 am UTC
Tom,
I have two tables
Tab1
Lookup Code
Lookup Type
Description
Tab 2
Bureau code
member code
partner code
x
y
z
My requirment is a bit typical (i guess)
Tab1
---------------------------------------------
lookupcode lookup type desc
----------------------------------------------
TRA Bureau code Sample Desc1
CCHK Membder Code Sample Desc2
CMSI Partner Code Sample Desc3
TAB2
---------------------------------------------------------------
Bureau Code Member Code Partner Code x y z
----------------------------------------------------------------
TRA CCHK CMSI 1 2 3
i want the data to be fetched in this fashion
---------------------------------------------------------------
x y z DESC1 DESC2 DESC3
---------------------------------------------------------------
1 2 3 Sample Desc1 Sample Desc2 Sample Desc3
How can i get the description of respective Lookup codes from tab1
while querying tab2.
I fell pivoting the query can resolve this, but unable to frame the query
I have refered to lot examples but to be frank some how i dont get the concept of Pivoting the Query can you explain for all of us to learn and master this concept .... would be great if explaination can be with above example.
Thanks on behalf of all who may read this.. i know its going to help each one of us out there.
June 22, 2006 - 12:20 pm UTC
hmm. deja-vu.
go to other place you put this same exact text.
Awesome
Paul, June 28, 2006 - 4:22 am UTC
I finally got it. I have been able to do the rows to columns for a while but not the columns to rows. This will go a long way to solve the queries i see which are like this.
select a,b,c,count(*)
from t
group by a,b,c
union
select d,e,c,count(*)
from t
group by d,e,c
generic query for transpose
RRM, July 03, 2006 - 9:47 pm UTC
Hi Tom,
Can we transform a table like following
A1 B1 C1 D1
A2 B2 C2 D2
A3 B3 C3 D3
into
A1 A2 A3
B1 B2 B3
C1 C2 C3
D1 D2 D3
So, the no. of rows in first table simply becomes no. of cols in second table.
I mean just a matrix transpose of any table? I wanted to do it using cursor to build dynamic query, but couldn't do it.
July 07, 2006 - 8:02 pm UTC
well, if you KNOW the number of columns....
ops$tkyte@ORA10GR2> select * from t;
C1 C2 C3
-- -- --
A1 A2 A3
B1 B2 B3
C1 C2 C3
D1 D2 D3
ops$tkyte@ORA10GR2> with data
2 as
3 (select rownum rnum, t.*
4 from (select * from t order by c1) t
5 ),
6 rows_to_have
7 as
8 (select level rr
9 from dual
10 connect by level <= 3 -- number of columns in T
11 )
12 select rnum,
13 max( decode( rr, 1, c1 ) ),
14 max( decode( rr, 2, c2 ) ),
15 max( decode( rr, 3, c3 ) )
16 from data, rows_to_have
17 group by rnum
18 /
RNUM MA MA MA
---------- -- -- --
1 A1 A2 A3
2 B1 B2 B3
4 D1 D2 D3
3 C1 C2 C3
Dynamically write date as column name in pivot query
Kubilay, July 04, 2006 - 10:40 am UTC
Hi Tom
I have a question today:
I have two tables as follows:
CREATE TABLE "TA"
( "A_ID" NUMBER,
"A_TXT" CHAR(10 BYTE)
) ;
Insert into "TA" ("A_ID","A_TXT") values (1,'Tazan ');
Insert into "TA" ("A_ID","A_TXT") values (2,'Hercules ');
Insert into "TA" ("A_ID","A_TXT") values (3,'Ulysses ');
Insert into "TA" ("A_ID","A_TXT") values (4,'Spiderman ');
CREATE TABLE "TB"
( "B_ID" NUMBER,
"A_ID" NUMBER,
"B_DAT" DATE
) ;
Insert into "TB" ("B_ID","A_ID","B_DAT") values (30,3,to_date('04-JUL-06','DD-MON-RR'));
Insert into "TB" ("B_ID","A_ID","B_DAT") values (10,1,to_date('04-JUL-06','DD-MON-RR'));
Insert into "TB" ("B_ID","A_ID","B_DAT") values (20,2,to_date('04-MAY-06','DD-MON-RR'));
Insert into "TB" ("B_ID","A_ID","B_DAT") values (50,3,to_date('18-MAY-06','DD-MON-RR'));
Insert into "TB" ("B_ID","A_ID","B_DAT") values (60,3,to_date('21-JUL-06','DD-MON-RR'));
Insert into "TB" ("B_ID","A_ID","B_DAT") values (70,2,to_date('04-MAY-06','DD-MON-RR'));
Insert into "TB" ("B_ID","A_ID","B_DAT") values (80,2,to_date('04-MAY-06','DD-MON-RR'));
Insert into "TB" ("B_ID","A_ID","B_DAT") values (85,1,to_date('11-JUL-06','DD-MON-RR'));
Insert into "TB" ("B_ID","A_ID","B_DAT") values (40,3,to_date('27-JUN-06','DD-MON-RR'));
I want to do an analytical query on them as follows:
SELECT person,
MAX(decode(cdate, to_char(add_months(last_day(sysdate), -1), 'mm-yy'), cnt, 0)) jun06,
MAX(decode(cdate, to_char(add_months(last_day(sysdate), -2), 'mm-yy'), cnt, 0)) may06
from
(SELECT ta.a_txt person, to_char(tb.b_dat, 'mm-yy') cdate, count(*) cnt
FROM ta, tb
WHERE
ta.a_id=tb.a_id
GROUP BY ta.a_txt, tb.b_dat)
GROUP BY person
PERSON JUN06 MAY06
---------- ---------------------- ----------------------
Hercules 0 3
Ulysses 1 1
Tazan 0 0
Which is excellent, exactly what I need, but I have to provide the column names 'jun06' and 'may06'
how can I get them writen down dynamically from the query as this
is a datawarehouse and I don't want to go and add a line to the sql every end of the month. Is there an analytical
function to do this?
Many thanks for all your help!
Kubilay
Kubilay...
A reader, July 07, 2006 - 10:58 am UTC
I've built a package to dynamically build the statement and then hand it back to an application. This is the only way that I know how to create the column names on the fly. I'm pretty sure that Tom has an example in his book (I probably "borrowed" code from it).
Column headers
Michel Cadot, July 08, 2006 - 2:33 am UTC
Kubilay,
If your client is SQL*Plus and you use a SQL script, you can use something like:
-- Build the column headers you want in SQL*Plus variables
col v1 new_value h1
col v2 new_value h2
select to_char(add_months(last_day(sysdate), -1), 'mm-yy') v1,
to_char(add_months(last_day(sysdate), -2), 'mm-yy') v2
from dual;
-- Dynamically set your headings for fixed column names
col c1 heading &h1
col c2 heading &h2
-- Then your query, renaming your column names to c1 and c2
SELECT person,
MAX(decode(cdate, to_char(add_months(last_day(sysdate), -1), 'mm-yy'),
cnt, 0)) c1,
MAX(decode(cdate, to_char(add_months(last_day(sysdate), -2), 'mm-yy'),
cnt, 0)) c2
from
( SELECT ta.a_txt person,
to_char(tb.b_dat, 'mm-yy') cdate,
count(*) cnt
FROM ta, tb
WHERE ta.a_id=tb.a_id
GROUP BY ta.a_txt, tb.b_dat )
GROUP BY person
/
You can do something like that with any client application but if you want only one query I posted some solutions at:
</code>
http://asktom.oracle.com/pls/asktom/f?p=100:11:::::P11_QUESTION_ID:124812348063#51542758465483 http://asktom.oracle.com/pls/asktom/f?p=100:11:::::P11_QUESTION_ID:52266643928180#52284733269998 <code>
Regards
Michel
Reader & Michel
Kubilay, July 10, 2006 - 4:59 am UTC
Thank you very much for your response, great!
Now my 6 months data window, will be self-defining! :-))
Have a great day.
Is it possible through sql?
A reader, July 25, 2006 - 7:01 am UTC
Hi Tom,
Can this be done through single sql?
create table product (cust number(10) NOT NULL, prod_cat varchar2(10) NOT NULL, product varchar2(10) NOT NULL);
insert into product values (1,'A1','P1');
insert into product values (1,'A1','P2');
insert into product values (1,'A2','P1');
insert into product values (2,'A1','P1');
SQL> select * from product;
CUST PROD_CAT PRODUCT
---------- ---------- ----------
1 A1 P1
1 A1 P2
1 A2 P1
2 A1 P1
______________
O/p required
There are three combinations as below:-
prod_cat p1_flag p2_flag distinct_cust_count
A1 Y Y 1 -- for record 1 and 2
A1 Y N 1 -- for record 4
A2 Y N 1 -- for record 3
Regards,
July 25, 2006 - 11:33 am UTC
sorry, but that output really doesn't quite "make sense". I cannot figure out why A1 would appear twice - why do records 1 and 2 go together and 4 is by itself (I mean, if you are breaking up by cust - WHY bother having distinct cust count - that would, well, always be one wouldn't it??????? And how do you KNOW that the first A1 output record is for 1 and 2 and then next for 4 - what point would it be having this output if you cannot tell??)
can I get the output? sure, but not sure if it is useful:
ops$tkyte%ORA10GR2> select prod_cat,
2 decode( count(case when product = 'P1' then 1 end), 0, 'N', 'Y' ) p1_flag,
3 decode( count(case when product = 'P2' then 1 end), 0, 'N', 'Y' ) p2_flag,
4 count(distinct cust)
5 from product
6 group by prod_cat, cust
7 order by prod_cat
8 /
PROD_CAT P P COUNT(DISTINCTCUST)
---------- - - -------------------
A1 Y Y 1
A1 Y N 1
A2 Y N 1
Yes it is possible
Michel Cadot, July 25, 2006 - 7:37 am UTC
SQL> with
2 data as (
3 select cust, prod_cat,
4 max(decode(product,'P1','Y','N')) p1_flag,
5 max(decode(product,'P2','Y','N')) p2_flag
6 from product
7 group by cust, prod_cat
8 )
9 select prod_cat, p1_flag, p2_flag, count(*)
10 from data
11 group by prod_cat, p1_flag, p2_flag
12 order by prod_cat, p1_flag, p2_flag
13 /
PROD_CAT P P COUNT(*)
---------- - - ----------
A1 Y N 1
A1 Y Y 1
A2 Y N 1
Michel
Reason
A reader, July 25, 2006 - 5:36 pm UTC
Tom,
Thanks for your help. The reason for this is:-
How many customers own products p1 and p2 together/individually of specific category? This will help business to bundle products. Like your book, sometimes sold with other books?
Regards,
Tarun
July 25, 2006 - 5:48 pm UTC
but that is not what your sample output shows!
you have it broken out by customer!!! should your output not really have just TWO ROWS
Can row be treated as Column
Rai, August 14, 2006 - 7:09 am UTC
Hi Tom,
I have a query :->
Table Name : T1
Name Role
A SD
B JD
C QE
D SD
E JD
F QE
Output I need :
SD JD QE
A B C
D E F
Note : Roles are Fixed.Only.Three - SD(Senior Developer),JD(Junior Developer),QE(Quality Engineer).
I tried this :->
SQL> Select (Decode(Role,'SD',Name)) SD,
(Decode(Role,'JD',Name)) JD,
(Decode(Role,'QE',Name)) QE
from t1
/
Out put is :->
SD JD QE
----- ----- -----
A
B
C
D
E
F
But I want output as followos :->
SD JD QE
A B C
D E F
August 14, 2006 - 11:25 am UTC
this can quite easily be done.
scott%ORA10GR2> select rn,
2 max( decode( job, 'CLERK', ename ) ),
3 max( decode( job, 'MANAGER', ename ) ),
4 max( decode( job, 'ANALYST', ename ))
5 from (
6 select job, ename, row_number() over (partition by job order by ename) rn
7 from emp
8 where job in ( 'CLERK', 'MANAGER', 'ANALYST' )
9 )
10 group by rn
11 order by rn
12 /
RN MAX(DECODE MAX(DECODE MAX(DECODE
---------- ---------- ---------- ----------
1 ADAMS BLAKE FORD
2 JAMES CLARK SCOTT
3 MILLER JONES
4 SMITH
(hint, my job = your role, my ename = your name)
I need To Solve..
DRA, August 15, 2006 - 8:31 am UTC
Hi Tom,
tab1
ID, NAME, VERSION
1 a 1.1
2 b 2.1
3 c 3.1
4 d 1.1
5 e 2.0
6 f 3.0
tab2
ID LOCATION
1 L1
1 L2
1 L3
1 L4
2 L1
2 L5
2 L6
3 L7
3 L8
3 L9
4 L10
4 L11
4 L12
I want result
ID, NAME, VERSION, WHERE_USED_COUNT, L1,L2,L3,L4.....Ln(all location)
1 A 1.1 4 ,X,X,X,X, , ,
WHERE_USED_COUNT: It count number of LOCATION used the same ID
L1,L2...LN: If the LOCATION is used for a particular ID then mark it as "X"
Please give me sql query to generete the result.
NOTE: I need the location columns should come in dyanamically as column in the result.
August 15, 2006 - 8:39 am UTC
and I want create tables, insert intos (sort of requested on the page you used to add this?)
actually, just read this:
</code>
http://asktom.oracle.com/Misc/evolution.html <code>
that is the technique I would have used - you can just apply it to this problem
I Need Oracle Query..
DRA, August 16, 2006 - 4:15 am UTC
Hi Tom...
I have MS - Access Query but i need it in Oracle(SQL)..pls help..i didn't get proper solution..
This is MS-Access Query:
TRANSFORM First(IIf(tab1.ID Is Not Null, X)) AS Check
SELECT
tab2.ID,
tab2.NAME,
tab2.DEP,
Sum(IIf(Check=X, 1)) AS TotalWhereUsed
FROM
tab2 LEFT JOIN tab1 ON tab2.ID = tab1.ID
GROUP BY
tab2.ID,
tab2.NAME,
tab2.DEP,
ORDER BY
tab2.ID,
tab1.LOC
PIVOT
tab1.LOC
Mainly am facing "tab1.loc" it contains more then 50 values. How we can make it column values.
Pls help me.
Regards,
DRA
August 16, 2006 - 8:34 am UTC
but this page shows how to pivot a result set.
query
mal, August 16, 2006 - 11:01 pm UTC
Hi Tom,
Please help me to write one query or comment which one of the followin query is right? It is a part of debate :-)
CUSTOMER (CustomerSK, Name, Phone, EmailAddress)
STOVE (SerialNumber, Type, Version, DateofManufacture)
REGISTRATION (CustomerSK, SerialNumber, Date)
STOVE_REPAIR (RepairInvoiceNumber, SerialNumber, Date, Description, Cost, CustomerSK)
List all the versions of stoves that are of a type "Maytag" and they have not spent any money on repairs.
SQL> select stve.version from stove stve,stove_repair str where stve.serialnumber=str.serialnumber and stve.type='MayTag' and str.cost>0;
VERSION
------------------------------
1
1
select STOVE.Version
From STOVE
Where STOVE.Type = 'Maytag'
and STOVE.SerialNumber not in
(Select STOVE_REPAIR.SerialNumber
From STOVE_REPAIR
WHERE STOVE_REPAIR.Cost > 0)
no rows selected
August 17, 2006 - 8:52 am UTC
no primary keys
no foreign keys
no create table
no insert intos
no look. but this sounds like homework - not material for a "debate"?
query
mal, August 17, 2006 - 10:12 pm UTC
:-) it was a home work and debate got started with class mate when she mentioned that my query is wrong
Please Correct this Query in SQL
DRA, August 24, 2006 - 5:12 am UTC
Hi Tom,
Table T1 and 4 column: ID, name, value, date
ID, name, value, date
1, A, A1, 1/1/2006
1, B, B1, 1/1/2006
1, C, C1, 1/1/2006
2, A, A2, 1/1/2006
2, B, A2, 1/1/2006
2, C, A2, 1/1/2006
3, A, A3, 1/1/2006
3, B, A3, 1/1/2006
3, C, A3, 1/1/2006
4, A, A4, 1/1/2006
4, B, A4, 1/1/2006
4, C, A4, 1/1/2006
1, A, A1, 2/1/2006
1, B, B1, 2/1/2006
1, C, C1, 2/1/2006
2, A, A2, 2/1/2006
2, B, A2, 2/1/2006
2, C, A2, 2/1/2006
3, A, A3, 2/1/2006
3, B, A3, 2/1/2006
3, C, A3, 2/1/2006
4, A, A4, 2/1/2006
4, B, A4, 2/1/2006
4, C, A4, 2/1/2006
1, A, A1, 3/1/2006
1, B, B1, 3/1/2006
1, C, C1, 3/1/2006
2, A, A2, 3/1/2006
2, B, A2, 3/1/2006
2, C, A2, 3/1/2006
3, A, A3, 3/1/2006
3, B, A3, 3/1/2006
3, C, A3, 3/1/2006
4, A, A4, 3/1/2006
4, B, A4, 3/1/2006
4, C, A4, 3/1/2006
I need result like :
ID, A_JAN, B_JAN , C_JAN, A_FEB, B_FEB, C_FEB, A_MAR, B_MAR, C_MAR
1, A1, B1, C1, A1, B1, C1, A1, B1, C1
2, A2, B2, C2, A2, B2, C2, A2, B2, C2
3, A3, B3, C3, A3, B3, C3, A3, B3, C3
Cretiria:
I need retrive data based MONTH
if "DATE" is JAN then if "NAME" is A then display the corresponding "VALUE" in A_JAN Column.
I wrote the query...but some where am wrong..please correct it & send me any shotest query.
SELECT ID, A_JAN, B_JAN , C_JAN, A_FEB, B_FEB, C_FEB, A_MAR, B_MAR, C_MAR FROM
(SELECT id ID,
CASE WHEN ( DATE = TO_DATE('1/1/2006','mm/dd/YYYY') )
THEN DECODE(NAME, 'A',VALUE)
ELSE '0'
END AS A_JAN ,
CASE WHEN ( DATE = TO_DATE('1/1/2006','mm/dd/YYYY') )
THEN DECODE(NAME, 'B',VALUE)
ELSE '0'
END AS B_JAN ,
CASE WHEN ( DATE = TO_DATE('1/1/2006','mm/dd/YYYY') )
THEN DECODE(NAME, 'C',VALUE)
ELSE '0'
END AS C_JAN ,
CASE WHEN ( DATE = TO_DATE('2/1/2006','mm/dd/YYYY') )
THEN DECODE(NAME, 'A',VALUE)
ELSE '0'
END AS A_FEB ,
CASE WHEN ( DATE = TO_DATE('2/1/2006','mm/dd/YYYY') )
THEN DECODE(NAME, 'B',VALUE)
ELSE '0'
END AS B_FEB ,
CASE WHEN ( DATE = TO_DATE('2/1/2006','mm/dd/YYYY') )
THEN DECODE(NAME, 'C',VALUE)
ELSE '0'
END AS C_FEB ,
CASE WHEN ( DATE = TO_DATE('3/1/2006','mm/dd/YYYY') )
THEN DECODE(NAME, 'A',VALUE)
ELSE '0'
END AS A_MAR ,
CASE WHEN ( DATE = TO_DATE('3/1/2006','mm/dd/YYYY') )
THEN DECODE(NAME, 'B',VALUE)
ELSE '0'
END AS B_MAR ,
CASE WHEN ( DATE = TO_DATE('3/1/2006','mm/dd/YYYY') )
THEN DECODE(NAME, 'C',VALUE)
ELSE '0'
END AS C_MAR
FROM
T1) t
WHERE
A_JAN!='0' AND B_JAN!='0' AND C_JAN!='0' AND A_FEB!='0' AND B_FEB!='0' AND C_FEB!='0' AND A_MAR!='0' AND B_MAR!='0' AND C_MAR!='0'
ORDER BY t.id
Thanks in Advance.
DRA
August 27, 2006 - 7:44 pm UTC
no create table
no insert into table
no look
Almost works for my sitiuation
Jay Kiefer, September 06, 2006 - 5:27 pm UTC
I am trying to use your example but I am not able to adjust for the columns. Mine too has a set cardinality (12). However I want the columns to pivot to rows. In your example it pivots on Jobs.
The union gives me the exact answer I want. The reason I'm asking the question is that there must be a better way since I expect there is a limit to how many union alls I can do. There is one union for each color (column).
I've tried using all_tab_columns to help me pivot but I can't seem to make that work.
SELECT column_name, COLUMN_ID
FROM all_tab_columns atc
WHERE table_name = 'JK_DEMO_DATA'
CREATE TABLE JK_DEMO_DATA
(calendar_year VARCHAR2(4)
, month_number VARCHAR2(2)
, month_mon VARCHAR2(3)
, red NUMBER
, orange NUMBER
, yellow NUMBER
, blue NUMBER
, green NUMBER);
BEGIN
INSERT INTO JK_DEMO_DATA VALUES('2005','1','JAN',1,2,3,4,5);
INSERT INTO JK_DEMO_DATA VALUES('2005','2','FEB',4,5,6,7,8);
INSERT INTO JK_DEMO_DATA VALUES('2005','3','MAR',7,8,9,10,11);
INSERT INTO JK_DEMO_DATA VALUES('2005','4','APR',1,2,3,4,5);
INSERT INTO JK_DEMO_DATA VALUES('2005','5','MAY',4,5,6,7,8);
INSERT INTO JK_DEMO_DATA VALUES('2005','6','JUN',7,8,9,10,11);
INSERT INTO JK_DEMO_DATA VALUES('2005','7','JUL',1,2,3,4,5);
INSERT INTO JK_DEMO_DATA VALUES('2005','8','AUG',4,5,6,7,8);
INSERT INTO JK_DEMO_DATA VALUES('2005','9','SEP',7,8,9,10,11);
INSERT INTO JK_DEMO_DATA VALUES('2005','10','OCT',1,2,3,4,5);
INSERT INTO JK_DEMO_DATA VALUES('2005','11','NOV',4,5,6,7,8);
INSERT INTO JK_DEMO_DATA VALUES('2005','12','DEC',7,8,9,10,11);
INSERT INTO JK_DEMO_DATA VALUES('2006','1','JAN',4,5,6,7,8);
INSERT INTO JK_DEMO_DATA VALUES('2006','2','FEB',7,8,9,10,11);
INSERT INTO JK_DEMO_DATA VALUES('2006','3','MAR',10,11,12,13,14);
INSERT INTO JK_DEMO_DATA VALUES('2006','4','APR',4,5,6,7,8);
INSERT INTO JK_DEMO_DATA VALUES('2006','5','MAY',7,8,9,10,11);
INSERT INTO JK_DEMO_DATA VALUES('2006','6','JUN',10,11,12,13,14);
INSERT INTO JK_DEMO_DATA VALUES('2006','7','JUL',4,5,6,7,8);
INSERT INTO JK_DEMO_DATA VALUES('2006','8','AUG',7,8,9,10,11);
INSERT INTO JK_DEMO_DATA VALUES('2006','9','SEP',10,11,12,13,14);
INSERT INTO JK_DEMO_DATA VALUES('2006','10','OCT',4,5,6,7,8);
INSERT INTO JK_DEMO_DATA VALUES('2006','11','NOV',7,8,9,10,11);
INSERT INTO JK_DEMO_DATA VALUES('2006','12','DEC',10,11,12,13,14);
END;
SELECT CALENDAR_YEAR, DESCR
, SUM(JAN) JAN
, SUM(FEB) FEB
, SUM(MAR) MAR
, SUM(APR) APR
, SUM(MAY) MAY
, SUM(JUN) JUN
, SUM(JUL) JUL
, SUM(AUG) AUG
, SUM(SEP) SEP
, SUM(OCT) OCT
, SUM(NOV) NOV
, SUM(DEC) DEC
FROM (
SELECT CALENDAR_YEAR, 'red' DESCR, 1 PLACEHOLDER
, ( CASE WHEN jk.month_number ='1' THEN jk.red ELSE NULL END) JAN
, ( CASE WHEN jk.month_number ='2' THEN jk.red ELSE NULL END) FEB
, ( CASE WHEN jk.month_number ='3' THEN jk.red ELSE NULL END) MAR
, ( CASE WHEN jk.month_number ='4' THEN jk.red ELSE NULL END) APR
, ( CASE WHEN jk.month_number ='5' THEN jk.red ELSE NULL END) MAY
, ( CASE WHEN jk.month_number ='6' THEN jk.red ELSE NULL END) JUN
, ( CASE WHEN jk.month_number ='7' THEN jk.red ELSE NULL END) JUL
, ( CASE WHEN jk.month_number ='8' THEN jk.red ELSE NULL END) AUG
, ( CASE WHEN jk.month_number ='9' THEN jk.red ELSE NULL END) SEP
, ( CASE WHEN jk.month_number ='10' THEN jk.red ELSE NULL END) OCT
, ( CASE WHEN jk.month_number ='11' THEN jk.red ELSE NULL END) NOV
, ( CASE WHEN jk.month_number ='12' THEN jk.red ELSE NULL END) DEC
FROM JK_DEMO_DATA jk
UNION ALL
SELECT CALENDAR_YEAR, 'orange' DESCR, 2 PLACEHOLDER
, ( CASE WHEN jk.month_number ='1' THEN jk.orange ELSE NULL END) JAN
, ( CASE WHEN jk.month_number ='2' THEN jk.orange ELSE NULL END) FEB
, ( CASE WHEN jk.month_number ='3' THEN jk.orange ELSE NULL END) MAR
, ( CASE WHEN jk.month_number ='4' THEN jk.orange ELSE NULL END) APR
, ( CASE WHEN jk.month_number ='5' THEN jk.orange ELSE NULL END) MAY
, ( CASE WHEN jk.month_number ='6' THEN jk.orange ELSE NULL END) JUN
, ( CASE WHEN jk.month_number ='7' THEN jk.orange ELSE NULL END) JUL
, ( CASE WHEN jk.month_number ='8' THEN jk.orange ELSE NULL END) AUG
, ( CASE WHEN jk.month_number ='9' THEN jk.orange ELSE NULL END) SEP
, ( CASE WHEN jk.month_number ='10' THEN jk.orange ELSE NULL END) OCT
, ( CASE WHEN jk.month_number ='11' THEN jk.orange ELSE NULL END) NOV
, ( CASE WHEN jk.month_number ='12' THEN jk.orange ELSE NULL END) DEC
FROM JK_DEMO_DATA jk
UNION ALL
SELECT CALENDAR_YEAR, 'yellow' DESCR, 3 PLACEHOLDER
, ( CASE WHEN jk.month_number ='1' THEN jk.yellow ELSE NULL END) JAN
, ( CASE WHEN jk.month_number ='2' THEN jk.yellow ELSE NULL END) FEB
, ( CASE WHEN jk.month_number ='3' THEN jk.yellow ELSE NULL END) MAR
, ( CASE WHEN jk.month_number ='4' THEN jk.yellow ELSE NULL END) APR
, ( CASE WHEN jk.month_number ='5' THEN jk.yellow ELSE NULL END) MAY
, ( CASE WHEN jk.month_number ='6' THEN jk.yellow ELSE NULL END) JUN
, ( CASE WHEN jk.month_number ='7' THEN jk.yellow ELSE NULL END) JUL
, ( CASE WHEN jk.month_number ='8' THEN jk.yellow ELSE NULL END) AUG
, ( CASE WHEN jk.month_number ='9' THEN jk.yellow ELSE NULL END) SEP
, ( CASE WHEN jk.month_number ='10' THEN jk.yellow ELSE NULL END) OCT
, ( CASE WHEN jk.month_number ='11' THEN jk.yellow ELSE NULL END) NOV
, ( CASE WHEN jk.month_number ='12' THEN jk.yellow ELSE NULL END) DEC
FROM JK_DEMO_DATA jk
UNION ALL
SELECT CALENDAR_YEAR, 'green' DESCR, 4 PLACEHOLDER
, ( CASE WHEN jk.month_number ='1' THEN jk.green ELSE NULL END) JAN
, ( CASE WHEN jk.month_number ='2' THEN jk.green ELSE NULL END) FEB
, ( CASE WHEN jk.month_number ='3' THEN jk.green ELSE NULL END) MAR
, ( CASE WHEN jk.month_number ='4' THEN jk.green ELSE NULL END) APR
, ( CASE WHEN jk.month_number ='5' THEN jk.green ELSE NULL END) MAY
, ( CASE WHEN jk.month_number ='6' THEN jk.green ELSE NULL END) JUN
, ( CASE WHEN jk.month_number ='7' THEN jk.green ELSE NULL END) JUL
, ( CASE WHEN jk.month_number ='8' THEN jk.green ELSE NULL END) AUG
, ( CASE WHEN jk.month_number ='9' THEN jk.green ELSE NULL END) SEP
, ( CASE WHEN jk.month_number ='10' THEN jk.green ELSE NULL END) OCT
, ( CASE WHEN jk.month_number ='11' THEN jk.green ELSE NULL END) NOV
, ( CASE WHEN jk.month_number ='12' THEN jk.green ELSE NULL END) DEC
FROM JK_DEMO_DATA jk
)
--WHERE calendar_year = '2006'
GROUP BY CALENDAR_YEAR, DESCR, placeholder
ORDER BY CALENDAR_YEAR, placeholder
September 07, 2006 - 7:00 am UTC
turn the columns into the rows (they should have been from day one apparently, your data model is not 'good' that way) by cartesian joining to a set that has as many rows as you have columns to "unpivot" (any 5 row table will do, I made up one on the fly here)
then a simple pivot against that fixed up data set:
ops$tkyte%ORA10GR2> with data
2 as
3 (select level l from dual connect by level <= 5)
4 SELECT CALENDAR_YEAR, DESCR, PLACEHOLDER
5 , sum( CASE WHEN month_number ='1' THEN val ELSE NULL END) JAN
6 , sum( CASE WHEN month_number ='2' THEN val ELSE NULL END) FEB
7 , sum( CASE WHEN month_number ='3' THEN val ELSE NULL END) MAR
8 , sum( CASE WHEN month_number ='4' THEN val ELSE NULL END) APR
9 , sum( CASE WHEN month_number ='5' THEN val ELSE NULL END) MAY
10 , sum( CASE WHEN month_number ='6' THEN val ELSE NULL END) JUN
11 , sum( CASE WHEN month_number ='7' THEN val ELSE NULL END) JUL
12 , sum( CASE WHEN month_number ='8' THEN val ELSE NULL END) AUG
13 , sum( CASE WHEN month_number ='9' THEN val ELSE NULL END) SEP
14 , sum( CASE WHEN month_number ='10' THEN val ELSE NULL END) OCT
15 , sum( CASE WHEN month_number ='11' THEN val ELSE NULL END) NOV
16 , sum( CASE WHEN month_number ='12' THEN val ELSE NULL END) DEC
17 from (
18 select calendar_year,
19 month_number,
20 l placeholder,
21 decode( l, 1, 'red',
22 2, 'orange',
23 3, 'yellow',
24 4, 'green',
25 5, 'blue' ) descr,
26 decode( l, 1, red,
27 2, orange,
28 3, yellow,
29 4, green,
30 5, blue ) val
31 from t, data
32 )
33 group by calendar_year, descr, placeholder
34 order by calendar_year, placeholder
35 /
Perfect; Thank you!
Jay Kiefer, September 07, 2006 - 10:26 am UTC
I appreciate your response and your commitment to this site!
Simple question
Alex, September 07, 2006 - 6:01 pm UTC
If I understand correctly, there is no way to convert all or some of the rows from one table, to columns in some sql query?
Thanks,
Alex
September 08, 2006 - 4:08 pm UTC
I'm not even sure what that would look like, using SCOTT.DEPT table - tell us what that "means" by way of an example (eg: this is what I expect as output)
Example
Alex, September 07, 2006 - 6:10 pm UTC
For example:
col1 col2
a 1
b 2
c 3
...etc
is it possible to create something like this, without hardcoding every column, only with pure sql? (i don't have permissions to create new tables, views or packages)
=>
a b c
1 2 3
Thanks,
Alex
September 08, 2006 - 4:18 pm UTC
you would have to use SQL to write SQL here.
You would have to query to find the number of rows in the table.
You would have to query to find the number of columns in the table.
then you could write a query to pivot it all and open that result set with dynamic sql.
line 3: number of columns is what drives the level <= 3
lines 5-8 - determined by number of rows in the table
lines 10-11 - built based on number of columns
ops$tkyte%ORA10GR2> with data
2 as
3 (select level line from dual connect by level <= 3)
4 select cname,
5 max( decode( r, 1, val ) ) c1,
6 max( decode( r, 2, val ) ) c2,
7 max( decode( r, 3, val ) ) c3,
8 max( decode( r, 4, val ) ) c4
9 from (
10 select decode( line, 1, 'deptno', 2, 'dname', 3, 'loc' ) cname,
11 decode( line, 1, to_char(deptno), 2, dname, 3, loc ) val,
12 r, line
13 from ( select dept.*, rownum r
14 from dept ),
15 data
16 )
17 group by cname, line
18 order by line
19 /
CNAME C1 C2 C3 C4
------ ---------- ---------- ---------- ----------
deptno 10 20 30 40
dname ACCOUNTING RESEARCH SALES OPERATIONS
loc NEW YORK DALLAS CHICAGO BOSTON
execlent examples easy to follow
A reader, September 14, 2006 - 11:38 am UTC
Thanks to Tom et Al.
execlent examples - easy to follow
Dave, September 14, 2006 - 12:09 pm UTC
Thanks to Tom et Al.
very interesting discussion
A reader, September 14, 2006 - 4:12 pm UTC
Tom,
I was wondering if there is a better way to re write this query. I want to be able to elimiate the union all and therefore you not doing a double pass on the data. I was
thinking maybe using a pivot but the query is in a way pivoted Any ideas??
SELECT R.FINALIZED_DATE FINALIZE_DATE, R.RAIL_LINE_CODE RAILLINE_CODE,
DECODE(R.DIRECTION,1,DECODE(R.STATUS_CODE,'E',0,
DECODE(UPPER(R.EDI_W4_STATE),'AB',1,'BC',1,'MB',1,'NB',1,'NF',1,'NT',1,'NS',1,'ON',1,
'PE',1,'PQ',1,'SK',1,'YT',1,0)),0)EASTBOUND_CANADIAN_FULL,
DECODE(R.DIRECTION,1,DECODE(R.STATUS_CODE,'E',
DECODE(UPPER(R.EDI_W4_STATE),'AB',1,'BC',1,'MB',1,'NB',1,'NF',1,'NT',1,
'NS',1,'ON',1,'PE',1,'PQ',1,'SK',1,'YT',1,0),0),0)EASTBOUND_CANADIAN_EMPTY,
DECODE(R.DIRECTION,1,DECODE(R.STATUS_CODE,'E',0,
DECODE(UPPER(R.EDI_W4_STATE),'AB',0,'BC',0,'MB',0,'NB',0,'NF',0,'NT',0,
'NS',0,'ON',0,'PE',0,'PQ',0,'SK',0,'YT',0,1)),0)EASTBOUND_MIDWEST_FULL,
DECODE(R.DIRECTION,1,DECODE(R.STATUS_CODE,'E',
DECODE(UPPER(R.EDI_W4_STATE),'AB',0,'BC',0,'MB',0,'NB',0,'NF',0,'NT',0,
'NS',0,'ON',0,'PE',0,'PQ',0,'SK',0,'YT',0,1),0),0)EASTBOUND_MIDWEST_EMPTY,
DECODE(R.DIRECTION,0,1,0)WESTBOUND,
DECODE(R.DIRECTION,0,DECODE(R.STATUS_CODE,'E',0,
DECODE(SUBSTR(R.COUNTRY,1,4),'CANA',1,0)),0)WESTBOUND_CANADIAN_FULL,
DECODE(R.DIRECTION,0,DECODE(R.STATUS_CODE,'E',
DECODE(SUBSTR(R.COUNTRY,1,4),'CANA',1,0),0),0)WESTBOUND_CANADIAN_EMPTY,
DECODE(R.DIRECTION,0,DECODE(R.STATUS_CODE,'E',0,
DECODE(SUBSTR(R.COUNTRY,1,4),'CANA',0,1)),0)WESTBOUND_MIDWEST_FULL,
DECODE(R.DIRECTION,0,DECODE(R.STATUS_CODE,'E',
DECODE(SUBSTR(R.COUNTRY,1,4),'CANA',0,1),0),0)WESTBOUND_MIDWEST_EMPTY
FROM new_table R
UNION ALL
SELECT RA.FINALIZED_DATE FINALIZE_DATE,
RA.RAIL_LINE_CODE RAILLINE_CODE,
DECODE(RA.DIRECTION,1,DECODE(RA.STATUS_CODE,'E',0,
DECODE(UPPER(RA.EDI_W4_STATE),'AB',1,'BC',1,'MB',1,'NB',1,'NF',1,'NT',1,'NS',1,'ON',1,
'PE',1,'PQ',1,'SK',1,'YT',1,0)),0)EASTBOUND_CANADIAN_FULL,
DECODE(RA.DIRECTION,1,DECODE(RA.STATUS_CODE,'E',
DECODE(UPPER(RA.EDI_W4_STATE),'AB',1,'BC',1,'MB',1,'NB',1,'NF',1,'NT',1,
'NS',1,'ON',1,'PE',1,'PQ',1,'SK',1,'YT',1,0),0),0)EASTBOUND_CANADIAN_EMPTY,
DECODE(RA.DIRECTION,1,DECODE(RA.STATUS_CODE,'E',0,
DECODE(UPPER(RA.EDI_W4_STATE),'AB',0,'BC',0,'MB',0,'NB',0,'NF',0,'NT',0,
'NS',0,'ON',0,'PE',0,'PQ',0,'SK',0,'YT',0,1)),0)EASTBOUND_MIDWEST_FULL,
DECODE(RA.DIRECTION,1,DECODE(RA.STATUS_CODE,'E',
DECODE(UPPER(RA.EDI_W4_STATE),'AB',0,'BC',0,'MB',0,'NB',0,'NF',0,'NT',0,
'NS',0,'ON',0,'PE',0,'PQ',0,'SK',0,'YT',0,1),0),0)EASTBOUND_MIDWEST_EMPTY,
DECODE(RA.DIRECTION,0,1,0)WESTBOUND,
DECODE(RA.DIRECTION,0,DECODE(RA.STATUS_CODE,'E',0,
DECODE(SUBSTR(RA.COUNTRY,1,4),'CANA',1,0)),0)WESTBOUND_CANADIAN_FULL,
DECODE(RA.DIRECTION,0,DECODE(RA.STATUS_CODE,'E',
DECODE(SUBSTR(RA.COUNTRY,1,4),'CANA',1,0),0),0)WESTBOUND_CANADIAN_EMPTY,
DECODE(RA.DIRECTION,0,DECODE(RA.STATUS_CODE,'E',0,
DECODE(SUBSTR(RA.COUNTRY,1,4),'CANA',0,1)),0)WESTBOUND_MIDWEST_FULL,
DECODE(RA.DIRECTION,0,DECODE(RA.STATUS_CODE,'E',
DECODE(SUBSTR(RA.COUNTRY,1,4),'CANA',0,1),0),0)WESTBOUND_MIDWEST_EMPTY
FROM new_table RA
September 14, 2006 - 4:52 pm UTC
looks like you want each row output "twice"
select FINALIZED_DATE FINALIZE_DATE,
RAIL_LINE_CODE RAILLINE_CODE,
case when r = 1
then DECODE-FROM-FIRST-QUERY
else DECODE-FROM-SECOND-QUERY
end EASTBOUND_CANADIAN_FULL,
case when r = 1
then ..
else ...
end ....
from new_table, (select 1 r from dual union all select 2 r from dual)
GREAT!!!
A reader, September 15, 2006 - 10:09 am UTC
Tom,
The approach was great. I forgot to mention that
the reason why I have the second union is that it is
from different table let's table b in the last
query.
September 15, 2006 - 10:31 am UTC
eh? if you have two separate tables then you are not making a "double pass".
now you've confused me entirely.
Row values in single column
Jonty, September 21, 2006 - 2:36 pm UTC
Hi,
Dept, Emp columns in a table.
I want to get results like
Dept1, 'emp1, emp2, emp3'
Dept2, 'emp11, emp22'
Dept3, 'emp9'
How can I get this ?
Response will be highly appreciated.
Thanks
Jonty
September 22, 2006 - 2:40 am UTC
search this site for stragg
ok
Ravikumar, September 26, 2006 - 6:47 am UTC
Hi Tom,
I am not sure why the sum(decode(... function returns the same values as that
of original column values.I thought there would be a change in column values after
applying the sum(decode(... function.
what can be the use of sum(decode(.. function?
SQL> create table t (x number);
Table Created.
SQL> insert into t values(10);
1 row created.
SQL> insert into t values(20);
1 row created.
SQL> insert into t values(50);
1 row created.
SQL> insert into t values(100);
1 row created.
SQL> select * from t
2 /
X
----------
10
20
50
100
4 rows selected.
SQL> select x,sum(decode(sign(x),1,x,-x)) as val
2 from t
3 group by x
4 /
X VAL
---------- ----------
10 10
20 20
50 50
100 100
4 rows selected.
Please do reply.
September 26, 2006 - 3:49 pm UTC
I don't know why you would thing "values would change". so you'll have to explain what you thought should happen - and WHY.
You have 4 rows in the input set
they all have unique X= values
group by returns unique group by values
you group by X
hence 4 rows in the output... and the sum of x, given they are all positive, would be X in this case...
Pivoting
hari bhaskar gupta, October 04, 2006 - 4:59 pm UTC
It is very very good for it helpfull
performance issue on pivot query
Franco Ropelato, October 10, 2006 - 11:05 am UTC
Hi Tom,
Thanks a lot for the site!
I noticed that the execution time of the pivot query is highly dependent on the number of the columns of the pivot.
i.e., this query:
SELECT
code,
max(decode(fld0,1,fld1,NULL)) AS x1,
max(decode(fld0,2,fld1,NULL)) AS x2
FROM
t_fv
GROUP BY code;
takes 5 sec on my system, while this:
SELECT
code,
max(decode(fld0,1,fld1,NULL)) AS x1,
max(decode(fld0,2,fld1,NULL)) AS x2,
max(decode(fld0,3,fld1,NULL)) AS x3,
max(decode(fld0,4,fld1,NULL)) AS x4,
max(decode(fld0,5,fld1,NULL)) AS x5,
max(decode(fld0,6,fld1,NULL)) AS x6
FROM
t_fv
GROUP BY code;
takes 150 seconds!
Why this is happening? The execution plans, obviously, are the same; it seems to me that the only difference is a matter of numbers of "if"s in the execution code.
The run_stats package tells that in the 2nd query there are a lot more physical reads and writes, why that?
Should I investigate on poor values of some parameter of my db instance?
Investigating further, these are the figures for a growing number of result columns:
columns time in seconds
1 4
2 5
3 64
4 101
5 121
6 150
The strange thing: the big bump from 3rd...
There is the "build code" for this analysis:
CREATE TABLE t_fv (
code NUMBER(10,0),
fld0 NUMBER(10,0),
fld1 VARCHAR2(250));
INSERT INTO t_fv
SELECT rownum, 1, object_name FROM all_objects;
COMMIT;
INSERT INTO t_fv
SELECT rownum, 2, object_name FROM all_objects;
COMMIT;
INSERT INTO t_fv
SELECT rownum, 3, object_name FROM all_objects;
COMMIT;
INSERT INTO t_fv
SELECT rownum, 4, object_name FROM all_objects;
COMMIT;
INSERT INTO t_fv
SELECT rownum, 5, object_name FROM all_objects;
COMMIT;
INSERT INTO t_fv
SELECT rownum, 6, object_name FROM all_objects;
COMMIT;
SELECT
code,
max(decode(fld0,1,fld1,NULL)) AS x1
FROM
t_fv
GROUP BY code;
SELECT
code,
max(decode(fld0,1,fld1,NULL)) AS x1,
max(decode(fld0,2,fld1,NULL)) AS x2
FROM
t_fv
GROUP BY code;
SELECT
code,
max(decode(fld0,1,fld1,NULL)) AS x1,
max(decode(fld0,2,fld1,NULL)) AS x2,
max(decode(fld0,3,fld1,NULL)) AS x3
FROM
t_fv
GROUP BY code;
SELECT
code,
max(decode(fld0,1,fld1,NULL)) AS x1,
max(decode(fld0,2,fld1,NULL)) AS x2,
max(decode(fld0,3,fld1,NULL)) AS x3,
max(decode(fld0,4,fld1,NULL)) AS x4
FROM
t_fv
GROUP BY code;
SELECT
code,
max(decode(fld0,1,fld1,NULL)) AS x1,
max(decode(fld0,2,fld1,NULL)) AS x2,
max(decode(fld0,3,fld1,NULL)) AS x3,
max(decode(fld0,4,fld1,NULL)) AS x4,
max(decode(fld0,5,fld1,NULL)) AS x5
FROM
t_fv
GROUP BY code;
SELECT
code,
max(decode(fld0,1,fld1,NULL)) AS x1,
max(decode(fld0,2,fld1,NULL)) AS x2,
max(decode(fld0,3,fld1,NULL)) AS x3,
max(decode(fld0,4,fld1,NULL)) AS x4,
max(decode(fld0,5,fld1,NULL)) AS x5,
max(decode(fld0,6,fld1,NULL)) AS x6
FROM
t_fv
GROUP BY code;
October 10, 2006 - 12:23 pm UTC
tkprof it, what does that show....
performance issue on pivot query
Franco Ropelato, October 10, 2006 - 1:29 pm UTC
If I understand your request correctly, this is the tkprof output:
CREATE TABLE t_zz1 AS
SELECT
code,
max(decode(fld0,1,fld1,NULL)) AS x1
, CAST('xxx' as varchar2(250)) AS x2
, CAST('xxx' as varchar2(250)) AS x3
, CAST('xxx' as varchar2(250)) AS x4
, CAST('xxx' as varchar2(250)) AS x5
, CAST('xxx' as varchar2(250)) AS x6
FROM
t_fv
GROUP BY code
call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 1 0.00 0.00 0 1 0 0
Execute 1 1.83 1.95 1512 1616 224 25425
Fetch 0 0.00 0.00 0 0 0 0
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 2 1.83 1.95 1512 1617 224 25425
Misses in library cache during parse: 1
Optimizer goal: FIRST_ROWS
Parsing user id: 107 (ASST_SVIL2)
Rows Execution Plan
------- ---------------------------------------------------
0 CREATE TABLE STATEMENT GOAL: FIRST_ROWS
0 LOAD AS SELECT
0 SORT (GROUP BY)
0 TABLE ACCESS (FULL) OF 'T_FV'
********************************************************************************
CREATE TABLE t_zz6 AS
SELECT
code,
max(decode(fld0,1,fld1,NULL)) AS x1,
max(decode(fld0,2,fld1,NULL)) AS x2,
max(decode(fld0,3,fld1,NULL)) AS x3,
max(decode(fld0,4,fld1,NULL)) AS x4,
max(decode(fld0,5,fld1,NULL)) AS x5,
max(decode(fld0,6,fld1,NULL)) AS x6
FROM
t_fv
GROUP BY code
call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 1 0.00 0.00 0 1 0 0
Execute 1 21.69 33.85 77788 1622 270 25425
Fetch 0 0.00 0.00 0 0 0 0
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 2 21.69 33.85 77788 1623 270 25425
Misses in library cache during parse: 1
Optimizer goal: FIRST_ROWS
Parsing user id: 107 (ASST_SVIL2)
Rows Execution Plan
------- ---------------------------------------------------
0 CREATE TABLE STATEMENT GOAL: FIRST_ROWS
0 LOAD AS SELECT
0 SORT (GROUP BY)
0 TABLE ACCESS (FULL) OF 'T_FV'
********************************************************************************
October 10, 2006 - 8:12 pm UTC
I don't trust explain plan, can you
a) log into sqlplus
b) enable trace
c) run the sql statements
d) EXIT sqlplus (to close all cursors)
e) then tkprof.
Single Column into row
A reader, October 12, 2006 - 9:04 am UTC
How should I best turn a query that will always return a single row, e.g. select 1,2,3 from dual;
which returns:
1 2 3
into one which returns separate rows, e.g.
1
2
3
?
October 12, 2006 - 11:34 am UTC
ops$tkyte%ORA10GR2> with data as (select level l from dual connect by level <= 3)
2 select decode( l, 1, c1, 2, c2, 3, c3 )
3 from (
4 select 1 c1, 2 c2, 3 c3, l
5 from dual, data
6 )
7 /
DECODE(L,1,C1,2,C2,3,C3)
------------------------
1
2
3
Pivot filtering by single column value
Mike Thomas, October 12, 2006 - 4:01 pm UTC
Take your first example:
scott@DEV816>
scott@DEV816> select job,
2 max( decode( deptno, 10, cnt, null ) ) dept_10,
3 max( decode( deptno, 20, cnt, null ) ) dept_20,
4 max( decode( deptno, 30, cnt, null ) ) dept_30,
5 max( decode( deptno, 40, cnt, null ) ) dept_40
6 from ( select job, deptno, count(*) cnt
7 from emp
8 group by job, deptno )
9 group by job
10 /
JOB DEPT_10 DEPT_20 DEPT_30 DEPT_40
--------- ---------- ---------- ---------- ----------
ANALYST 2
CLERK 1 2 1
MANAGER 1 1 1
PRESIDENT 1
SALESMAN 4
I need only the column sets of pivoted data for where DEPT_10 = 1. E.g. DEPT_10 through DEPT_40 for CLERK, MANAGER, and PRESIDENT. I am only trying to filter by one column, e.g. DEPT_10.
I could not think of WHERE clause syntax for the outer query that would return DEPT_10 = 1 data sets for CLERK, MANAGER, PRESIDENT. E.g. "WHERE max( decode( deptno, 10, cnt, null ) ) = 1" gives an syntax error.
If possible, I do _not_ want to wrap the statement, e.g.
select *
from (<all above>)
where DEPT_10 = 1;
I suspect its possible to use analytical or group in sub-query to test for one column's dataset DEPT_10 = 1. Then, I might then be able to filter just the set of sub-query values that contribute to the pivot DEPT_10 = 1.
I hope there might be a performance difference between wrapping with SELECT * FROM () WHERE DEPT_10 = 1 and the analytical/group of sub-query technique.
Is this possible?
October 13, 2006 - 6:59 am UTC
sorry, you do want to wrap that statement in the manner you say you do not want to.
why _dont_ you want to???????????? you don't want to get the answer??
Pivot filtering by single column value (followup)
Mike Thomas, October 12, 2006 - 6:10 pm UTC
I got something working. I'm not sure if it improves or worsens performance as compared to a simple wrapper like SELECT * FROM (<ORIG SQL>) WHERE dept_10 = 1. But, it works without a wrapper which implies it might not need to return values for dept_20 through dept_40 and might save LIO.
--
select job,
max ( decode( deptno, 10, cnt, null ) ) dept_10,
max ( decode( deptno, 20, cnt, null ) ) dept_20,
max ( decode( deptno, 30, cnt, null ) ) dept_30,
max ( decode( deptno, 40, cnt, null ) ) dept_40
from ( select job, deptno, count(*) cnt,
count( decode( deptno, 10, 1, null ) ) over ( partition by job order by job ) deptno_x
from emp
group by job, deptno )
where deptno_x = 1
and cnt = 1
group by job
order by job;
--
Note: Two parts.
First "deptno_x = 1" determines pivotset for deptno = 10.
Second "cnt = 1" determines pivot value.
--
I'll have to test performance with a larger dataset, like my big pivot queries at work.
October 13, 2006 - 7:01 am UTC
(hint: the inline view is, well, better - you have to materialize the set anyway, the inline view is much easier to digest in this case don't you think)
minor SQL correction, sorry
Mike Thomas, October 12, 2006 - 7:19 pm UTC
--
select job,
max ( decode( deptno, 10, cnt, null ) ) dept_10,
max ( decode( deptno, 20, cnt, null ) ) dept_20,
max ( decode( deptno, 30, cnt, null ) ) dept_30,
max ( decode( deptno, 40, cnt, null ) ) dept_40
from ( select job, deptno, count(*) cnt,
sum( decode( deptno, 10, count(*), null ) )
over ( partition by job order by job ) deptno_value
from emp
group by job, deptno )
where deptno_value = 1
group by job
order by job;
--
Note: deptno_value = 1, using count(*) for depno = 10
--
agree
Mike Thomas, October 13, 2006 - 12:14 pm UTC
<QUOTE>
(hint: the inline view is, well, better - you have to materialize the set anyway, the inline view is much easier to digest in this case don't you think)
</QUOTE>
I agree with you about being easier to digest, and that we have to materialize the set anyway. I'm not sure the temp space requirements are the same with both, so I'm checking with performance tests.
The reason for _not_ doing, as I requested above, is there are existing stored procedures generating dynamic sql, and the pivot max/decodes are dynamically generated as a wrapper to a user generated sub-query. First, plsql determines how many and what rows/columns to pivot, and second dynamically generates the SQL. This extends the features in your book by allowing dynamic numbers of columns based on sub-query data.
So, basically, I'm using the "harder to understand" technique, but without any stored procedure code changes - some business benefit. And, I'm testing both SQL to deterimine if there is possibly any LIO/Sort differences between the two SQL. I suspect only TEMP space benefit, but won't know till I see tkprof on my larger datasets.
Thanks for your site, and help. This is an awesome website - I would never have gotten this far without your help!
Pivot table oracle with unknown number of rows to be pivot
Prince, October 31, 2006 - 6:32 pm UTC
Tom
I read each line on this page but couldn't find sol. I tried
several methods before could not succed. My Problem is
DATE_RT CODE QTY
27-SEP-2006 1444 .01
27-SEP-2006 2924 .9
27-SEP-2006 2924 .45
26-JUL-2006 2372 .05
26-JUL-2006 1444 .01
26-JUL-2006 2966 .025
26-JUL-2006 2074 1
26-JUL-2006 2810 .01
26-JUL-2006 3270 .015
26-JUL-2006 2372 .05
26-JUL-2006 1444 .01
26-JUL-2006 2966 .025
26-JUL-2006 2074 1
26-JUL-2006 2810 .01
26-JUL-2006 3270 .015
26-JUL-2006 3426 .5
26-JUL-2006 3426 1
26-JUL-2006 3426 4.5
26-JUL-2006 3426 1
29-AUG-2006 2074 .1
29-AUG-2006 1444 .01
29-AUG-2006 2372 .005
09-OCT-2006 3270 .055
07-OCT-2006 2924 4
07-OCT-2006 3426 2
07-OCT-2006 2810 .01
07-OCT-2006 1444 .02
07-OCT-2006 3426 .5
07-OCT-2006 2924 .45
07-OCT-2006 2924 .45
07-OCT-2006 3426 1
07-OCT-2006 3426 2
07-OCT-2006 2372 .05
07-OCT-2006 3426 2.5
07-OCT-2006 2966 .025
07-OCT-2006 1444 1
07-OCT-2006 2810 2
29-AUG-2006 2074 5
Desired Result should be like :
DATE 1444 2074 2372 2810 2924 2966 3426 ......
07-OCT-2006 1.02 .05 2.01 4.90 .............
...
29-AUG-2006 .01 5.1 .005 ..........
my p_anchor is date
my pivot col is (code) And Qty which is sum of QTY of same code on the same date as displayed above.
The number off code varies so i am not sure how many cols they can.
I tried
variable x refcursor
set autoprint on
begin
my_pkg.pivot
( p_max_cols_query => 'select count (distinct (code)) from TT',
p_query => 'select DATE_RT, code, sum(QTY) SUMQTY, row_number() over ( partition by
DATE_RT order by CODE) rn from TT group by DATE_RT, code',
p_anchor => my_pkg.array( 'DATE_RT','SUMQTY'),
p_pivot => my_pkg.array( 'code'),
p_cursor => :x );
end;
with tried ur my_pivot package but not successful.
please suggest where the package needs to be changed.
l_query := l_query ||
'max(decode(rn,'||i||','||
p_pivot(j)||',null)) ' ||
p_pivot(j) || '_' || i || ',';
October 31, 2006 - 6:49 pm UTC
you would have to
a) run a query to determine the number of columns
b) use that information to build a dynamic sql query that does that.
pivot table oracle using ref cursor
prince, October 31, 2006 - 8:07 pm UTC
CREATE TABLE DEMO_DATA
(DATE_RT DATE
, code NUMBER
, qty NUMBER (10,4)
);
INSERT INTO DEMO_DATA VALUES ('27-SEP-2006',1444,.01);
INSERT INTO DEMO_DATA VALUES ('27-SEP-2006',2924,9);
INSERT INTO DEMO_DATA VALUES ('27-SEP-2006',2924,.45);
INSERT INTO DEMO_DATA VALUES ('26-JUL-2006',2372,.05);
INSERT INTO DEMO_DATA VALUES ('26-JUL-2006',1444,.01);
INSERT INTO DEMO_DATA VALUES ('26-JUL-2006',2966,.025);
INSERT INTO DEMO_DATA VALUES ('26-JUL-2006',2074,1);
INSERT INTO DEMO_DATA VALUES ('26-JUL-2006',2810,.01);
INSERT INTO DEMO_DATA VALUES ('26-JUL-2006',3270,.015);
INSERT INTO DEMO_DATA VALUES ('26-JUL-2006',2372,.05);
INSERT INTO DEMO_DATA VALUES ('26-JUL-2006',1444,.01);
INSERT INTO DEMO_DATA VALUES ('26-JUL-2006',2966,.025);
INSERT INTO DEMO_DATA VALUES ('26-JUL-2006',2074,1);
INSERT INTO DEMO_DATA VALUES ('26-JUL-2006',2810,.01);
INSERT INTO DEMO_DATA VALUES ('26-JUL-2006',3270,.015);
INSERT INTO DEMO_DATA VALUES ('26-JUL-2006',3426,.5);
INSERT INTO DEMO_DATA VALUES ('26-JUL-2006',3426,1);
INSERT INTO DEMO_DATA VALUES ('26-JUL-2006',3426,4.5);
INSERT INTO DEMO_DATA VALUES ('26-JUL-2006',3426,1);
INSERT INTO DEMO_DATA VALUES ('29-AUG-2006',2074,.1);
INSERT INTO DEMO_DATA VALUES ('29-AUG-2006',1444,.01);
INSERT INTO DEMO_DATA VALUES ('29-AUG-2006',2372,.005);
INSERT INTO DEMO_DATA VALUES ('09-OCT-2006',3270,.055);
INSERT INTO DEMO_DATA VALUES ('07-OCT-2006',2924,4);
INSERT INTO DEMO_DATA VALUES ('07-OCT-2006',3426,2);
INSERT INTO DEMO_DATA VALUES ('07-OCT-2006',2810,.01);
INSERT INTO DEMO_DATA VALUES ('07-OCT-2006',1444,.02);
INSERT INTO DEMO_DATA VALUES ('07-OCT-2006',3426,.5);
INSERT INTO DEMO_DATA VALUES ('07-OCT-2006',2924,.45);
INSERT INTO DEMO_DATA VALUES ('07-OCT-2006',2924,.45);
INSERT INTO DEMO_DATA VALUES ('07-OCT-2006',3426,1);
INSERT INTO DEMO_DATA VALUES ('07-OCT-2006',3426,2);
INSERT INTO DEMO_DATA VALUES ('07-OCT-2006',3372,.05);
INSERT INTO DEMO_DATA VALUES ('07-OCT-2006',3426,2.5);
INSERT INTO DEMO_DATA VALUES ('07-OCT-2006',2966,.025);
INSERT INTO DEMO_DATA VALUES ('07-OCT-2006',1444,1);
INSERT INTO DEMO_DATA VALUES ('07-OCT-2006',2810,2);
INSERT INTO DEMO_DATA VALUES ('29-AUG-2006',2074,5);
Here is the table and values for the pivot problem
October 31, 2006 - 8:10 pm UTC
go for it, if you have access to "expert one on one oracle" I actually provide in there the stored procedure that
a) queries a table to find the columns
b) writes a query based on a)
c) opens it
but you get the concept - you know how to pivot, you just need to dynamically figure out the columns...
pivot table oracle
prince, October 31, 2006 - 8:34 pm UTC
I did something like this:create or replace package my_pkg
as
type refcursor is ref cursor;
type array is table of varchar2(30);
procedure pivot( p_max_cols in number default NULL,
p_max_cols_query in varchar2 default NULL,
p_query in varchar2,
p_anchor in array,
p_pivot in array,
p_cursor in out refcursor );
end;
/
create or replace package body my_pkg
as
procedure pivot( p_max_cols in number default NULL,
p_max_cols_query in varchar2 default NULL,
p_query in varchar2,
p_anchor in array,
p_pivot in array,
p_cursor in out refcursor )
as
l_max_cols number;
l_query long;
l_cnames array;
begin
-- figure out the number of columns we must support
-- we either KNOW this or we have a query that can tell us
if ( p_max_cols is not null )
then
l_max_cols := p_max_cols;
elsif ( p_max_cols_query is not null )
then
execute immediate p_max_cols_query into l_max_cols;
else
raise_application_error(-20001, 'Cannot figure out max cols');
end if;
-- Now, construct the query that can answer the question for us...
-- start with the C1, C2, ... CX columns:
l_query := 'select ';
for i in 1 .. p_anchor.count
loop
l_query := l_query || p_anchor(i) || ',';
end loop;
-- Now add in the C{x+1}... CN columns to be pivoted:
-- the format is "max(decode(rn,1,C{X+1},null)) cx+1_1"
for i in 1 .. l_max_cols
loop
for j in 1 .. p_pivot.count
loop
l_query := l_query ||
'max(decode(rn,'||i||','||
p_pivot(j)||',null)) ' ||
p_pivot(j) || '_' || i || ',';
end loop;
end loop;
-- Now just add in the original query
l_query := rtrim(l_query,',')||' from ( '||p_query||') group by ';
-- and then the group by columns...
for i in 1 .. p_anchor.count
loop
l_query := l_query || p_anchor(i) || ',';
end loop;
l_query := rtrim(l_query,',');
-- and return it
execute immediate 'alter session set cursor_sharing=force';
open p_cursor for l_query;
execute immediate 'alter session set cursor_sharing=exact';
end;
end;
/
=========================================================================
variable x refcursor
set autoprint on
begin
my_pkg.pivot
( p_max_cols_query => 'select count (distinct (CODE)) from demo _data',
p_query => 'select DATE_RT, code, sum(QTY) SUMQTY, row_number() over ( partition by DATE_RT order by CODE) rn from demo_data group by DATE_RT, ',
p_anchor => my_pkg.array( 'DATE_RT' ),
p_pivot => my_pkg.array( 'CODE', 'SUMQTY'),
p_cursor => :x );
end;
but i am not getting the desire result.
November 01, 2006 - 8:35 am UTC
"sorry"? I mean - what else can we say?
why are you not getting the desired result? If you state that, you might be able to figure out how to debug your code?
pivot table oracle
prince, October 31, 2006 - 8:57 pm UTC
but i am not getting the desire result.
I need to get something
DATE 1444 2074 2372 2373 2810 2924 2966 3270 3426
07-OCT-2006 1.02 .05 2.01 4.90
29-AUG-2006 .01 5.1 .005
09-OCT-2006 .055
26-JUL-2006 .02 1 .05 .02 .025 .015 7
.
.
.
.
something like this.
so my pivot col is code and i need the sum of qty displayed like on the top.
Thanks
November 01, 2006 - 8:39 am UTC
so fix your code? it is what you do for a living right? develop code to specification. You have the specs, you need to debug your code.
If you like SQL :)
Michel Cadot, November 01, 2006 - 3:45 am UTC
SQL> def colWidth=7
SQL> def f1=999990
SQL> def f2=90D000
SQL> col nop noprint
SQL> set heading off
SQL> with
2 cols as (
3 select to_char(code,'&f1') code, rownum rn, count(*) over () nb
4 from (select distinct code from demo_data)
5 ),
6 dates as ( select distinct date_rt from demo_data ),
7 data as (
8 select date_rt, to_char(code,'&f1') code, sum(qty) qty
9 from demo_data
10 group by date_rt, code
11 )
12 select to_date('01/01/0001','DD/MM/YYYY') nop,
13 'DATE '||replace(sys_connect_by_path(code,'/'),'/',' ')
14 from cols
15 where level = nb
16 connect by prior rn = rn-1
17 start with rn = 1
18 union all
19 select to_date('02/01/0001','DD/MM/YYYY') nop,
20 '-----------'||sys_connect_by_path(lpad('-',&colWidth,'-'),' ')
21 from cols
22 where level = nb
23 connect by prior rn = rn-1
24 start with rn = 1
25 union all
26 select c.date_rt nop,
27 c.date_rt||
28 replace(sys_connect_by_path(nvl(to_char(d.qty,'&f2'),rpad(' ',&colWidth)),'/'),'/',' ')
29 from ( select code, rn, nb, date_rt from cols, dates ) c,
30 data d
31 where d.code (+) = c.code
32 and d.date_rt (+) = c.date_rt
33 and level = c.nb
34 connect by prior c.rn = c.rn-1 and prior c.date_rt = c.date_rt
35 start with c.rn = 1
36 order by nop
37 /
DATE 1444 2074 2372 2810 2924 3270 3372 3426
----------- ------- ------- ------- ------- ------- ------- ------- -------
26-JUL-2006 0.020 2.000 0.100 0.020 0.030 7.000
29-AUG-2006 0.010 5.100 0.005
27-SEP-2006 0.010 9.450
07-OCT-2006 1.020 2.010 4.900 0.050 8.000
09-OCT-2006 0.055
(I remove code 2966 data to prevent from line fold in report but this does not change anything.)
(This query can be compacted to avoid some repetitions but it is difficult enough to read like this.)
Michel
stuck with slightly differen scenario ..need help
Umesh, November 14, 2006 - 11:47 pm UTC
Hi Tom ,
as always , this post has been very informational ,especially the use of Analytical function .
However , i have slightly different need for pivot table
my scenario
i have a table
CREATE TABLE PRICETYPE_PRICELIST
(
PRICE_TYPE VARCHAR2(100 BYTE),
PRICE NUMBER(15,2),
ITEM_ID VARCHAR2(40 BYTE)
)
INSERT INTO PRICETYPE_PRICELIST ( PRICE_TYPE, PRICE, ITEM_ID ) VALUES (
'WSH', 10, '1');
INSERT INTO PRICETYPE_PRICELIST ( PRICE_TYPE, PRICE, ITEM_ID ) VALUES (
'WSH', 5, '2');
INSERT INTO PRICETYPE_PRICELIST ( PRICE_TYPE, PRICE, ITEM_ID ) VALUES (
'DI', 10, '1');
INSERT INTO PRICETYPE_PRICELIST ( PRICE_TYPE, PRICE, ITEM_ID ) VALUES (
'DI', 20, '2');
INSERT INTO PRICETYPE_PRICELIST ( PRICE_TYPE, PRICE, ITEM_ID ) VALUES (
'PPD', 2, '1');
INSERT INTO PRICETYPE_PRICELIST ( PRICE_TYPE, PRICE, ITEM_ID ) VALUES (
'PPD', 4, '2');
COMMIT;
basically the Price type values need to be dynamic .
For now i have only inserted 3 different type valeus .. but the list can group based on future requirements
now i have a requirment where in i need this data in following format
Item Id WSH DI PPD (add on cols )->X Y Z ...
1 10 20 2
2 5 20 4
i ran following query to get above output
select item_id
,max(decode(price_type,'WSH',price)) wsh
,max(decode(price_type,'DI',price)) DI
,max(decode(price_type,'PPD',price)) PPD
from PriceType_PriceList p1
group by item_id
however , this restricts me from getting the colums dynamically , ie i would end up hard coding
any suggestions .. help will really be appreciated
November 15, 2006 - 7:04 am UTC
reread the page, there is a solution provided (hint: it takes two steps, one to discover the number of columns and then we build a dynamic query and then we use that newly built query)
to: Umesh
Michel Cadot, November 15, 2006 - 8:02 am UTC
Maybe I'm wrong but I don't see any difference with "prince" problem apart from table and column names.
Michel
with slight difference..
Umesh, November 15, 2006 - 12:49 pm UTC
Michael ,
u r right as for as the output format is concernd ,however , if you look at the contents or the values ..my query doesnt run any aggregating functions . All i want is data which is based on Price_type stored in rows , in columns format .
And the problem i am into is that i cant be sure of how many different types of Price Types ,which translates to having flexibility of n # of cols based on Price Type .
hope this explains ..
Said that ..I am still looking for scalable solution :(
Tom ?
will appreciate it .
to: Umesh
Michel Cadot, November 15, 2006 - 2:47 pm UTC
Try:
%s/demo_data/PRICETYPE_PRICELIST/
%s/date_rt/ITEM_ID/g
%s/code/PRICE_TYPE/g
%s/qty/PRICE/g
%s:to_date('01/01/0001','DD/MM/YYYY'):-2:
%s:to_date('02/01/0001','DD/MM/YYYY'):-1:
and if you don't need to sum then don't sum and group by.
And if you don't want a single query then apply Tom's algorithm.
Michel
Follow-up Question
Juan, January 02, 2007 - 10:57 pm UTC
Tom, on April 21, 2004 you provided the following query solution:
select rn day, a + rn - 1 dt
from (select a, b from t where id = 1),
(select rownum rn
from all_objects
where rownum <= (select ceil(b - a) + 1 from t where id = 1))
What is I needed to run the query for IDs 1 through 1500? Is there a way to rewrite this query for a range of IDs, each ID being unique in the table?
Thanks.
January 05, 2007 - 7:53 am UTC
we can do that, and if you prepare a small create table, insert into with just one or two values for ID and different date ranges - I'll show you how.
Follow-up Question
Juan, January 05, 2007 - 6:02 am UTC
Hi Tom.
I'd appreciate any feedback on the above question.
Thanks.
Follow-up Question
Juan, January 05, 2007 - 9:07 am UTC
Here is the information you requested:
create table t
( id number,
start_datetm date,
end_datetm date)
/
insert into t values (1, '01-JAN-2006', '17-JAN-2006');
insert into t values (2, '02-FEB-2006', '11-FEB-2007');
insert into t values (3, '01-FEB-2005', '10-FEB-2005');
insert into t values (4, '01-JUL-2006', '12-JUL-2006');
insert into t values (5, '01-JAN-2007', '5-JAN-2007');
insert into t values (6, '01-JAN-2006', '7-JAN-2006');
I am trying to the following query do the same for a range of ids.
select id, rn day, start_datetm + rn - 1 dt
from (select id, start_datetm, end_datetm from t where id = 1),
(select rownum rn
from all_objects
where rownum <= (select ceil(end_datetm - start_datetm) + 1 from t where id = 1))
/
January 05, 2007 - 10:07 am UTC
variable x number
variable y number
exec :x := 1; :y := 10
with
max_spread
as
(select max(ceil(end_datetm - start_datetm) + 1) spread
from t
where id between :x and :y),
data
as
(select level l
from dual
connect by level <= (select spread from max_spread))
select t.id, data.l day, t.start_datetm+data.l-1 dt
from t, data
where l <= ceil(end_datetm - start_datetm) + 1
order by id, l
/
Thanks for the query
Juan, January 05, 2007 - 10:29 am UTC
Slight clarification
Vinay Pai, January 06, 2007 - 9:23 am UTC
Hi Tom,
Would this fragment need to be changed from:
where l <= ceil(end_datetm - start_datetm) + 1
order by id, l
to:
where l <= ceil(end_datetm - start_datetm) + 1
and id between :x and :y
order by id, l
Perhaps its not evident in this example because the bind values are for the complete range rather than a subset ?
Anyways, quite a wonderful example of using the with clause !.
Thanks
Vinay
January 07, 2007 - 7:59 pm UTC
yes indeed, i missed that predicate in the second select on T, thanks!
Pivot on this requirement
Arindam Mukherjee, January 09, 2007 - 1:35 am UTC
create table daily_sales
( daily date,
amount number,
net_profit number,
gross_profit number
)
/
insert into daily_sales values (sysdate-4,100,20,30)
/
insert into daily_sales values (sysdate-3,110,21,31)
/
insert into daily_sales values (sysdate-2,120,22,32)
/
insert into daily_sales values (sysdate-1,130,23,33)
/
insert into daily_sales values (sysdate,140,24,34)
/
SQL> select * from daily_sales;
DAILY AMOUNT NET_PROFIT GROSS_PROFIT
--------- ---------- ---------- ------------
06-JAN-07 110 21 31
07-JAN-07 120 22 32
08-JAN-07 130 23 33
09-JAN-07 140 24 34
Now I want an output like below.
DAILY -> 06-JAN-07 07-JAN-07 08-JAN-07 09-JAN-07
Amount 110 120 130 140
NET_PROFIT 21 22 23 24
GROSS_PROFIT 31 32 33 34
I could not find any way to write SQL to get this output. My database is Oracle 10g
Please help me.
January 11, 2007 - 9:15 am UTC
we need to make amount, net_profit, gross_profit "cross record" first:
ops$tkyte%ORA10GR2> with data
2 as
3 (select level l
4 from dual
5 connect by level <= 3)
6 select daily,
7 decode(l,1,'Amount',2,'Net_Profit',3,'Gross_Profit'),
8 decode(l,1, Amount ,2, Net_Profit ,3, Gross_Profit )
9 from daily_sales, data
10 /
DAILY DECODE(L,1,' DECODE(L,1,AMOUNT,2,NET_PROFIT,3,GROSS_PROFIT)
--------- ------------ ----------------------------------------------
07-JAN-07 Amount 100
08-JAN-07 Amount 110
09-JAN-07 Amount 120
10-JAN-07 Amount 130
11-JAN-07 Amount 140
07-JAN-07 Net_Profit 20
08-JAN-07 Net_Profit 21
09-JAN-07 Net_Profit 22
10-JAN-07 Net_Profit 23
11-JAN-07 Net_Profit 24
07-JAN-07 Gross_Profit 30
08-JAN-07 Gross_Profit 31
09-JAN-07 Gross_Profit 32
10-JAN-07 Gross_Profit 33
11-JAN-07 Gross_Profit 34
15 rows selected.
and then pivoting is straightforward:
ops$tkyte%ORA10GR2>
ops$tkyte%ORA10GR2> with data
2 as
3 (select level l
4 from dual
5 connect by level <= 3)
6 select tag,
7 sum( decode( trunc(daily), trunc(sysdate-3), val ) ) "3 days ago",
8 sum( decode( trunc(daily), trunc(sysdate-2), val ) ) "2 days ago",
9 sum( decode( trunc(daily), trunc(sysdate-1), val ) ) "1 day ago",
10 sum( decode( trunc(daily), trunc(sysdate), val ) ) "today"
11 from (
12 select daily,
13 decode(l,1,'Amount',2,'Net_Profit',3,'Gross_Profit') tag,
14 decode(l,1, Amount ,2, Net_Profit ,3, Gross_Profit ) val
15 from daily_sales, data
16 )
17 group by tag
18 order by tag
19 /
TAG 3 days ago 2 days ago 1 day ago today
------------ ---------- ---------- ---------- ----------
Amount 110 120 130 140
Gross_Profit 31 32 33 34
Net_Profit 21 22 23 24
Excellent!! Really sterling skill in writing SQL
Arindam Mukherjee, January 12, 2007 - 8:01 am UTC
TRANSPOSE function for date datatype or fixed length datat
Senthil, January 23, 2007 - 3:27 pm UTC
TRANSPOSE function for date datatype or fixed length data
select decode(zx.dt, zx.dt, decode(rownum, 1, substr(zx.dt, rownum, rownum + 9),
substr(zx.dt, (((ROWNUM-1)*10)+ROWNUM),10)),
null) val
from (select '01/01/2006,01/31/2006,08/01/2006,08/10/2006,08/11/2006,01/01/2007' dt
from dual
group by cube(1,2,3)
) zx
where rownum <= 6
Is there a dynamic transpose function from row to column
Biju C, January 26, 2007 - 5:40 pm UTC
Tom
Did you ever get a chance to write a dynamic transpose function from row to column? Or is it something impossible
I have lot of reports which has to be transposed (convert from row to column) based on one of the dimensions (say Product). I know the product category is fixed and want reports with that as Column Headings.
Thanks for your help as always
Pivot on this requirement
Alf, January 27, 2007 - 12:45 am UTC
Hi Tom,
The objective of the statement below is to return rows with the values column separated and to trim out the coma character out.
This is what I have so far....
SELECT Y_MUTATIONS.ORDER_ID,
CLARITY_COMPONENT.NAME,
substr(ORDER_RES_COMMENT.RESULTS_CMT ||',',1,
instr(ORDER_RES_COMMENT.RESULTS_CMT ||',',',')-1) ORDER_RESULT2,
substr(ORDER_RES_COMMENT.RESULTS_CMT ||',,',
instr(ORDER_RES_COMMENT.RESULTS_CMT ||',,',',') +1,
instr(ORDER_RES_COMMENT.RESULTS_CMT ||',,',',', 1, 2) -
instr(ORDER_RES_COMMENT.RESULTS_CMT ||',,',',')-1) ORD_RS3,
substr(ORDER_RES_COMMENT.RESULTS_CMT ||',',
instr(ORDER_RES_COMMENT.RESULTS_CMT ||',',',',1,2)+1,
instr(ORDER_RES_COMMENT.RESULTS_CMT ||',',',', 1, 2) -
instr(ORDER_RES_COMMENT.RESULTS_CMT ||',',',')-1) ORD_RS4,
substr(ORDER_RES_COMMENT.RESULTS_CMT ||',',
instr(ORDER_RES_COMMENT.RESULTS_CMT ||',',',',2,3)+1,
instr(ORDER_RES_COMMENT.RESULTS_CMT ||',',',', 1, 2) -
instr(ORDER_RES_COMMENT.RESULTS_CMT ||',',',')-1) ORD_RS5,
substr(ORDER_RES_COMMENT.RESULTS_CMT ||',',
instr(ORDER_RES_COMMENT.RESULTS_CMT ||',',',',3,4)+1,
instr(ORDER_RES_COMMENT.RESULTS_CMT ||',',',', 1, 2) -
instr(ORDER_RES_COMMENT.RESULTS_CMT ||',',',')-1) ORD_RS6,
rtrim(substr(ORDER_RES_COMMENT.RESULTS_CMT ||',,',
instr(ORDER_RES_COMMENT.RESULTS_CMT ||',,',',',1,2)+1),',') Full_instr_of_values
FROM ("CLARITY"."Y_MUTATIONS" "Y_MUTATIONS" INNER JOIN
"CLARITY"."CLARITY_COMPONENT" "CLARITY_COMPONENT" ON
"Y_MUTATIONS"."COMPONENT_ID"="CLARITY_COMPONENT"."COMPONENT_ID")
LEFT OUTER JOIN "CLARITY"."ORDER_RES_COMMENT" "ORDER_RES_COMMENT" ON
"Y_MUTATIONS"."ORDER_ID"="ORDER_RES_COMMENT"."ORDER_ID"
WHERE "Y_MUTATIONS"."ORDER_ID"=1435844 AND
ORDER_RES_COMMENT.Line >= Y_MUTATIONS.RESULT_VAL_START_L and
ORDER_RES_COMMENT.Line <=Y_MUTATIONS.RESULT_VAL_END_LN and
Y_MUTATIONS.COMPONENT_ID ='6017' and
"Y_MUTATIONS"."RESULT_VAL_START_L" IS NOT NULL
Ord_ID Result_name Value1 Value2 value3 value4 value5 Full_instr_of_values
------- ------------ ----- ------ ----- ----- ----- ---------------------------------------------------------
1435844 RT MUTATIONS M41L K46K/R V60I, D67N, K70R, V60I, D67N, K70R, Q102K, K122E, C162S, Y188L, G196E,
1435844 RT MUTATIONS L210W R211K T215Y K219E L228H T215Y, K219E, L228H, V245K, A272P, R277K, K281K/R, V293I,
1435844 RT MUTATIONS E297K
The problem with this is that the Full_instr_of_values column doesn't have a fixed numbers of values nor the numbers of commas
so the way I've done so far is not really efficient.
Would please guide me how to wrap this in inside a select case statement?
How would I group this as?
Ord_ID Result_Name Values
------- ------------ ------
1435844 RT MUTATIONS M41L
K46K/R
V60I,
D67N,
...
...
Ord_ID Result_Name Values
------- ------------ ------
1435844 RT MUTATIONS L210W
R211K
T215Y
K219E
L228H
...
...
Ord_ID Result_Name Values
------- ------------ ------
1435844 RT MUTATIONS E297K
If I can take my question back
Biju C, February 05, 2007 - 11:07 am UTC
If I can take my question back, I would take it out. The answer to my question was right above my question. Just didn't read it properly.
Student Data
Tony Cillo, February 19, 2007 - 9:28 am UTC
Great info!
I am trying to follow your example you gave godwin on june, 20 2003. I have a simular problem. We have students that can have up to 8 courses and I would like to pivot the data so that we have one row for each student. When I run the following query most of the columns are NULL and the ones that have data list the courses more than once.
select StudentID,
max(decode(rownum,1,Course_number)) c1,
max(decode(rownum,2,Course_number)) c2,
max(decode(rownum,3,Course_number)) c3,
max(decode(rownum,4,Course_number)) c4,
max(decode(rownum,5,Course_number)) c5,
max(decode(rownum,6,Course_number)) c6,
max(decode(rownum,7,Course_number)) c7,
max(decode(rownum,8,Course_number)) c8
from ( select StudentID, Course_number,
row_number() over (partition by studentid order by course_number )
from MF_ST_ATTENDANCE )
group by studentID
Thanks for all the help!
February 19, 2007 - 9:37 am UTC
do not use rownum - alias the row_number() column to be "RN" or something and use that.
Thanks!
Tony C, February 20, 2007 - 7:44 am UTC
That worked like a charm.
Thanks for all the help and all your hard work Tom!!!
How do you reference the output
Scott, February 22, 2007 - 12:39 am UTC
G'day Tom,
Back to the original response, where you use cast multiset to get the output:
DEPTNO X(JOB, CNT)
---------- ----------------------------------------
10 MYARRAYTYPE(MYSCALARTYPE('CLERK', 1),
MYSCALARTYPE('MANAGER', 1),
MYSCALARTYPE('PRESIDENT', 1))
How do we reference this output so it's "useable"?
ie - what sort of dot notation or function do we use to get the literal 'CLERK' and count of "1", instead of seeing output that includes the type name.
Or is it only relevant in an application, would we be selecting this into a type, ready for use?
eg:
v_array myArrayType;
...
dbms_output.put_line(v_array(1).job);
Make sense?
February 22, 2007 - 8:45 am UTC
you have an array, sqlplus is going to format it as such.
Unless you unnest it (turn it back into rows and columns - but wait, we just took rows and columns and nested them into a collection!!!!)
sqlplus is just a generic data dumping tool - in a "real application" there would be no type names - unless and until you yourself printed them.
model clause
Adam, February 23, 2007 - 6:49 pm UTC
if you have the luxury of 10g.
select job
,dept_10
,dept_20
,dept_30
from emp
model
return updated rows
partition by ( job )
dimension by ( deptno )
measures (cnt, 0 dept_10, 0 dept_20, 0 dept_30 )
rules
(
dept_10[0] = cnt[deptno=10]
,dept_20[0] = cnt[deptno=20]
,dept_30[0] = cnt[deptno=30]
)
order by job
/
Another Variation of Your Pivot Example
Fred, April 18, 2007 - 2:15 pm UTC
Hi Tom,
In your first thread above, you offered this suggestion:
scott@DEV816> select job,
2 max( decode( deptno, 10, cnt, null ) ) dept_10,
3 max( decode( deptno, 20, cnt, null ) ) dept_20,
4 max( decode( deptno, 30, cnt, null ) ) dept_30,
5 max( decode( deptno, 40, cnt, null ) ) dept_40
6 from ( select job, deptno, count(*) cnt
7 from emp
8 group by job, deptno )
9 group by job
10 /
I have seen others come up with a similar statement:
select job,
sum( decode( deptno, 10, 1, 0 ) ) dept_10,
sum( decode( deptno, 20, 1, 0 ) ) dept_20,
sum( decode( deptno, 30, 1, 0 ) ) dept_30,
sum( decode( deptno, 40, 1, 0 ) ) dept_40
from emp
group by job
/
Is there any performance difference between your example and this example? Take for instance if we are talking about a lot of data.
April 18, 2007 - 2:25 pm UTC
for this, probably "six one way, half dozen the other" - would depend on the number of columns to be generated.
SQL Query to do flattening of a joined column
A reader, April 20, 2007 - 11:45 pm UTC
Hi Tom
I have a SQL Qn
-- one row per company
creare table company
(com_id varchar2(10),
stock_symbol varchar2(10),
...
exec_name varchar2(100))
-- contains various names for the company
creare table company_alias
(com_id varchar2(10),
alias varchar2(100))
user types in the name with wildcard on the web-page - we have to match it to the Alias and give One record per company with all the matching aliases - something like
com_id stock_symbol Exec_name Aliases
1 ABCD John Doe FORD, Ford Motor,X FORD
2 XYZ Jane Doe IBM, IBM INDIA, IBM BLU
etc
The Aliases are flattened out and only the Aliases that metch the search have to be included, so For com_id 1 there may be 20 aliases - but if teh search is on the word FORD and only 3 alises match (FORD, Ford Motor,X FORD) then only those should be in the Aliases Column.
The result set needs to paginated for the web application.
Will greatly appreciate some pointers.
April 21, 2007 - 9:03 am UTC
Dynamic Transpose Listing
Naveen, May 03, 2007 - 3:57 am UTC
Table1: (15 columns)
--------
REC_ID DESC MODIFIED_BY MODIFY_DT
101 XYZ hspi2 12-Aug-06
101 XYZ1 hspi6 14-Jan-07
101 XY Z hspi12 12-Feb-07
Output Reqd:
REC_ID DESC1 DESC2 DESC3 DESC4 .........DESC{n}
101 XYZ XYZ1 XY Z
Here {n} is dynamically determined by the number of changes made to DESC columns
Using Oracle 8.1.7, so (With {alias} as ) clause will not work here.
May 03, 2007 - 5:38 pm UTC
not going to happen "dynamically" since the number of columns sort of (not sort of, does) has to be known at query parse time.
Finding Relationship
sibghat, July 30, 2007 - 8:16 am UTC
Hi,
A Table contains two columns, column1 and column2 respectively, where these columns represent some relationship which shows a > c , b > d, a >d, c >d. basically column1 > column2
column1 column2
a c
d b
a d
c d
I want the output to be greatest,next greatest, next next greatest like (n,n-1,n-2 etc) like
a -> c -> d - > b
It would be of great help if you could help in doing this.
Thanks in advance
Regards,
Sibghat
July 30, 2007 - 5:31 pm UTC
simple connect by, lots of examples.
I'd have given you one with this data, but no create, no inserts, no look
CHANGE ROWS TO COLUMN NAMES
writeraj, July 31, 2007 - 8:53 am UTC
Hi Tom,
is there any way to transpose the data in a row to field name in a query ?
i.e suppose I have the following
Select * from Table1
field_name
--------------
NAME
TITLE
select * from table2
NAME TITLE
------------ ------------
PITER MR
KNOCK MR
BRAFMAN MJ
I WANT THE field value in querying TABLE2 only if the column name is listed in table1, otherwise, it should return null. Is there anyway to achieve this ?? your quick response is much appreciated.
August 02, 2007 - 9:34 am UTC
you would have to
a) read the values from table1
b) construct a sql query dynamically
c) then execute it
that is the only way.
Bermuxa, August 01, 2007 - 4:33 pm UTC
Hi Writeraj,
SELECT
(select t2.name
from table1 t1
where t1.field_name='NAME') as name,
(select t2.title
from table1 t1
where t1.field_name='TITLE') as title
FROM table2 t2
/
NAME TITLE
-------------------- --------------------
PITER MR
KNOCK MR
BRAFMAN MJ
3 row(s) retrieved
delete from table1 where field_name='NAME'
/
1 row(s) deleted
SELECT
(select t2.name
from table1 t1
where t1.field_name='NAME') as name,
(select t2.title
from table1 t1
where t1.field_name='TITLE') as title
FROM table2 t2
/
NAME TITLE
-------------------- --------------------
MR
MR
MJ
3 row(s) retrieved
rollback
/
delete from table1 where field_name='TITLE'
/
1 row(s) deleted
SELECT
(select t2.name
from table1 t1
where t1.field_name='NAME') as name,
(select t2.title
from table1 t1
where t1.field_name='TITLE') as title
FROM table2 t2
/
NAME TITLE
-------------------- --------------------
PITER
KNOCK
BRAFMAN
3 row(s) retrieved
I hope it helps
Why dynamic SQL?
Bermuxa, August 03, 2007 - 7:04 pm UTC
Hello Tom,
Your answer to previous question said :
b) construct a sql query dynamically
My question is: why do we need to construct dynamic sql?
Columns of requested query is known at the moment of writing the query and are same as Table2 table columns.
Only content of column is evaluated at runtime. Witch either is the same as in Table2 or is null if name of this column is not in Table1's field_name column.
As Writeraj's question said:
I want the field value in querying TABLE2 only if the column name is listed in Table1, otherwise,
it should return null.
August 05, 2007 - 1:51 pm UTC
because you don't know
a) how many columns
b) their datatypes
c) their names
until runtime
a SQL query always
a) knows how many columns
b) and their types
c) and their names
You do not have a sql statement until you have a, b, and c.
So, you have to
1) query table2 to get their names
2) build a query that references them by name
A reader, August 13, 2007 - 2:24 pm UTC
Tom,
But in this case we know number of columns in query - 2.
Types varchars and names are "NAME" and "TITLE".
August 15, 2007 - 11:11 am UTC
no, you said they are in a table, anything can be in that table.
obviously, if you KNOW THEIR NAMES, you can code the query, you are wanting to do things "from a table", you don't know their names and their names can change.
Title of the book
Tilak, August 13, 2007 - 9:29 pm UTC
hi
Can i know the title of the book where pivoting was discussed by Tom, pl help
August 20, 2007 - 10:58 am UTC
well, pretty much anything I would have to say about it is actually above. it is a very short topic
Expert One-On-One Oracle
Harrison Picot, August 19, 2007 - 11:15 pm UTC
The first book page 576. When Tom does not say which book, it is usually the first.
And 11g time now :)
TongucY, August 20, 2007 - 10:01 am UTC
Fernando
Fernando, October 12, 2007 - 1:53 pm UTC
Tengo en una tabla estos datos
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
Y necesito mostrar de esta manera
1 6 11
2 7 12
3 8 13
4 9 14
5 10 15
Pivoting Millions of Rows - Dynamically
A reader, October 25, 2007 - 4:09 pm UTC
We have created a schema design that has been often derided as being impractical, and have made it practical, useful, and throught he power of pivots, have made it very efficient and fast.
We are using a cousin of what has been called EAV or Value Pair. We have all of our data values stored vertically. Each has an element name stored as an ID. Each ID is stored with a set which contains all of the necessary meta-data. We also store column sequence.
With those intact, we are able to write a single query, stored in a proc, that will never need to be changed since it will pick up any new columns in the form of a row in the EAV-like table.
Once the analyze is run (less than 1 second), we are able to dynamically pivot the query based on the Max(decode... and the column sequence that is added on new column insert.
An analyze is run after each insert of a virtual row, which can be hundreds of physical rows.
As it stands we have over 3 million phycial rows of data, an number of which can be pulled in < 1 second, pivoted and returned to the user as normal, horizontal data. Thank you for your explanations of pivoting. And, although I know many dislike the idea of the table design described, we are not only using it efficiently, but we are able to perform operations on tables that we normally would not be able to.
October 25, 2007 - 6:37 pm UTC
example please - your text description does not do this justice (since I didn't follow it)
Pivoting a Big Table
Dav, October 27, 2007 - 12:10 pm UTC
Hi,
We've Oracle Financial application running on 9.2.8 version databae.
There is a table called GL_BALANCES which has balance information for each code_combination_id,currency_code, set_of_books_id, period. The structure looks like something like this.
CODE_COMBINATION_ID NUMBER ( for ex. 1201212)
PERIOD_NAME VARCHAR2(30) ( for ex. SEP-07)
PERIOD_YEAR NUMBER ( for ex. 2007)
CURRENCY_CODE VARCHAR2(30) ( for ex. USD or EUR..)
SET_OF_BOOKS_ID NUMBER ( for ex. 1001, 1002.. )
ACTUAL_FLAG VARCHAR2(1) ( A (actual), B (budget))
PERIOD_NET_CR number ( for ex. 100.01)
PERIOD_NET_DR number ( for ex. 200.01)
BEGIN_BALANCE_CR number ( for ex. 200.00)
BEGIN_BALANCE_DR number ( for ex. 400.00)
from this table , we pivot the data in the following format
code_combination_id,period_year, currency_code,actual_flag, Jan_begin_balance_dr, jan_begin_balance_cr,..12 month buckets..
We've 7 mil code combinations and depends on the calendar month we need to fill the monthly bucket from Jan to current period. So when we run it this month Oct.07 , We need to look up 70 million records( 7 million records/per month for 10 months) and do the pivot. The query takes too long. Even though the data may be changing for current period and previous period ( oct.07 and sep.07), we still need to fill up buckets from Jan to Oct.
I tried Materalized view ., it's not accepting FAST REFRESH mode, because of complex query. ( pivot query has max(decode..) clause.
Any Idea to make this process faster?
Thank you in advance.
Pivoting Millions of Rows - Dynamically -follow up
A reader, October 30, 2007 - 1:09 pm UTC
I apologize if these two tables to not give the big picture. The total solution is too large to fully paste. However,the data_string_txt is where the data is stored. it is pivoted based on the col_pos_seq in the xx_tmplt table. The pivot is built dynamically by looping through our possible values and building the statement in a clob and executing. As long as we do an analyze after large amounts of data are inserted, we have no problem with scale. we currently pivot data within sets that are > 3 mil.
CREATE TABLE XX_ELMNT
(
LVL1_ID NUMBER,
ELMNT_ID NUMBER,
DATA_STRING_TXT VARCHAR2(200 BYTE),
TXN_ID NUMBER,
SHEET_ID NUMBER
);
Insert into XX_ELMNT
(LVL1_ID, ELMNT_ID, DATA_STRING_TXT, TXN_ID, SHEET_ID)
Values
(258150, 1, 'ADD', 6012, 3);
Insert into XX_ELMNT
(LVL1_ID, ELMNT_ID, DATA_STRING_TXT, TXN_ID, SHEET_ID)
Values
(258151, 126, '400000968', 6012, 3);
Insert into XX_ELMNT
(LVL1_ID, ELMNT_ID, DATA_STRING_TXT, TXN_ID, SHEET_ID)
Values
(258152, 454, '0', 6012, 3);
Insert into XX_ELMNT
(LVL1_ID, ELMNT_ID, DATA_STRING_TXT, TXN_ID, SHEET_ID)
Values
(258153, 371, 'SB', 6012, 3);
Insert into XX_ELMNT
(LVL1_ID, ELMNT_ID, DATA_STRING_TXT, TXN_ID, SHEET_ID)
Values
(258154, 311, 'HYLHG', 6012, 3);
Insert into XX_ELMNT
(LVL1_ID, ELMNT_ID, DATA_STRING_TXT, TXN_ID, SHEET_ID)
Values
(258155, 129, '10KM-021852', 6012, 3);
Insert into XX_ELMNT
(LVL1_ID, ELMNT_ID, DATA_STRING_TXT, TXN_ID, SHEET_ID)
Values
(258156, 112, '19671024', 6012, 3);
Insert into XX_ELMNT
(LVL1_ID, ELMNT_ID, DATA_STRING_TXT, TXN_ID, SHEET_ID)
Values
(258157, 131, 'F', 6012, 3);
Insert into XX_ELMNT
(LVL1_ID, ELMNT_ID, DATA_STRING_TXT, TXN_ID, SHEET_ID)
Values
(258158, 304, '7368 RUGBY STREET', 6012, 3);
Insert into XX_ELMNT
(LVL1_ID, ELMNT_ID, DATA_STRING_TXT, TXN_ID, SHEET_ID)
Values
(258159, 306, 'PHILADELPHIA', 6012, 3);
Insert into XX_ELMNT
(LVL1_ID, ELMNT_ID, DATA_STRING_TXT, TXN_ID, SHEET_ID)
Values
(258160, 309, 'PA', 6012, 3);
Insert into XX_ELMNT
(LVL1_ID, ELMNT_ID, DATA_STRING_TXT, TXN_ID, SHEET_ID)
Values
(258161, 310, '191380000', 6012, 3);
Insert into XX_ELMNT
(LVL1_ID, ELMNT_ID, DATA_STRING_TXT, TXN_ID, SHEET_ID)
Values
(258162, 446, '521031854', 6012, 3);
Insert into XX_ELMNT
(LVL1_ID, ELMNT_ID, DATA_STRING_TXT, TXN_ID, SHEET_ID)
Values
(258163, 122, '20070701', 6012, 3);
Insert into XX_ELMNT
(LVL1_ID, ELMNT_ID, DATA_STRING_TXT, TXN_ID, SHEET_ID)
Values
(258164, 450, '0001', 6012, 3);
Insert into XX_ELMNT
(LVL1_ID, ELMNT_ID, DATA_STRING_TXT, TXN_ID, SHEET_ID)
Values
(258165, 449, '20070701', 6012, 3);
Insert into XX_ELMNT
(LVL1_ID, ELMNT_ID, DATA_STRING_TXT, TXN_ID, SHEET_ID)
Values
(258166, 67, 'A001', 6012, 3);
Insert into XX_ELMNT
(LVL1_ID, ELMNT_ID, DATA_STRING_TXT, TXN_ID, SHEET_ID)
Values
(258167, 66, '20070701', 6012, 3);
Insert into XX_ELMNT
(LVL1_ID, ELMNT_ID, DATA_STRING_TXT, TXN_ID, SHEET_ID)
Values
(258168, 71, 'MCAP0002', 6012, 3);
Insert into XX_ELMNT
(LVL1_ID, ELMNT_ID, DATA_STRING_TXT, TXN_ID, SHEET_ID)
Values
(258169, 70, 'SELECT', 6012, 3);
Insert into XX_ELMNT
(LVL1_ID, ELMNT_ID, DATA_STRING_TXT, TXN_ID, SHEET_ID)
Values
(258170, 68, '20060101', 6012, 3);
COMMIT;
CREATE TABLE XX_TMPLT
(
DTL_ID NUMBER,
TMPLT_ID NUMBER,
COL_POS_SEQ NUMBER,
COLTYPE_ID NUMBER,
SHEET_ID NUMBER,
COL_HDG_NM VARCHAR2(50 BYTE),
REQD_IND VARCHAR2(1 BYTE),
MIN_VALUE_TXT VARCHAR2(30 BYTE),
MAX_VALUE_TXT VARCHAR2(30 BYTE),
MIN_FLD_SZ_NBR NUMBER,
MAX_FLD_SZ_NBR NUMBER,
DEFAULT_VALUE_TXT VARCHAR2(50 BYTE),
ELMNT_ID NUMBER,
BULK_CHG_IND CHAR(1 BYTE),
VAL_PARNT_ID NUMBER,
TMPLT_NOTES VARCHAR2(2000 BYTE),
COL_START NUMBER,
ADDL_EDITS_IND CHAR(1 BYTE)
)
Insert into XX_TMPLT
(DTL_ID, TMPLT_ID, COL_POS_SEQ, COLTYPE_ID, SHEET_ID,
COL_HDG_NM, REQD_IND, MIN_VALUE_TXT, MAX_VALUE_TXT, MIN_FLD_SZ_NBR,
MAX_FLD_SZ_NBR, DEFAULT_VALUE_TXT, ELMNT_ID, BULK_CHG_IND, VAL_PARNT_ID,
TMPLT_NOTES, COL_START, ADDL_EDITS_IND)
Values
(472, 3, 1, 1, 3,
'ACTION', 'Y', NULL, NULL, 3,
3, 'ADD', 1, 'N', NULL,
NULL, NULL, NULL);
Insert into XX_TMPLT
(DTL_ID, TMPLT_ID, COL_POS_SEQ, COLTYPE_ID, SHEET_ID,
COL_HDG_NM, REQD_IND, MIN_VALUE_TXT, MAX_VALUE_TXT, MIN_FLD_SZ_NBR,
MAX_FLD_SZ_NBR, DEFAULT_VALUE_TXT, ELMNT_ID, BULK_CHG_IND, VAL_PARNT_ID,
TMPLT_NOTES, COL_START, ADDL_EDITS_IND)
Values
(473, 3, 2, 1, 3,
'FAMILY_LINK_ID', 'Y', NULL, NULL, 0,
0, NULL, 126, 'Y', NULL,
NULL, NULL, NULL);
Insert into XX_TMPLT
(DTL_ID, TMPLT_ID, COL_POS_SEQ, COLTYPE_ID, SHEET_ID,
COL_HDG_NM, REQD_IND, MIN_VALUE_TXT, MAX_VALUE_TXT, MIN_FLD_SZ_NBR,
MAX_FLD_SZ_NBR, DEFAULT_VALUE_TXT, ELMNT_ID, BULK_CHG_IND, VAL_PARNT_ID,
TMPLT_NOTES, COL_START, ADDL_EDITS_IND)
Values
(474, 3, 3, 1, 3,
'SUFFIX', 'Y', NULL, NULL, 1,
2, NULL, 454, 'Y', NULL,
NULL, NULL, NULL);
Insert into XX_TMPLT
(DTL_ID, TMPLT_ID, COL_POS_SEQ, COLTYPE_ID, SHEET_ID,
COL_HDG_NM, REQD_IND, MIN_VALUE_TXT, MAX_VALUE_TXT, MIN_FLD_SZ_NBR,
MAX_FLD_SZ_NBR, DEFAULT_VALUE_TXT, ELMNT_ID, BULK_CHG_IND, VAL_PARNT_ID,
TMPLT_NOTES, COL_START, ADDL_EDITS_IND)
Values
(475, 3, 4, 1, 3,
'RELATIONSHIP', 'Y', NULL, NULL, 2,
2, NULL, 371, 'Y', 11,
NULL, NULL, NULL);
Insert into XX_TMPLT
(DTL_ID, TMPLT_ID, COL_POS_SEQ, COLTYPE_ID, SHEET_ID,
COL_HDG_NM, REQD_IND, MIN_VALUE_TXT, MAX_VALUE_TXT, MIN_FLD_SZ_NBR,
MAX_FLD_SZ_NBR, DEFAULT_VALUE_TXT, ELMNT_ID, BULK_CHG_IND, VAL_PARNT_ID,
TMPLT_NOTES, COL_START, ADDL_EDITS_IND)
Values
(476, 3, 5, 1, 3,
'LAST_NAME', 'Y', NULL, NULL, 1,
30, NULL, 311, 'N', NULL,
NULL, NULL, NULL);
Insert into XX_TMPLT
(DTL_ID, TMPLT_ID, COL_POS_SEQ, COLTYPE_ID, SHEET_ID,
COL_HDG_NM, REQD_IND, MIN_VALUE_TXT, MAX_VALUE_TXT, MIN_FLD_SZ_NBR,
MAX_FLD_SZ_NBR, DEFAULT_VALUE_TXT, ELMNT_ID, BULK_CHG_IND, VAL_PARNT_ID,
TMPLT_NOTES, COL_START, ADDL_EDITS_IND)
Values
(477, 3, 6, 1, 3,
'FIRST_NAME', 'Y', NULL, NULL, 1,
30, NULL, 129, 'N', NULL,
NULL, NULL, NULL);
Insert into XX_TMPLT
(DTL_ID, TMPLT_ID, COL_POS_SEQ, COLTYPE_ID, SHEET_ID,
COL_HDG_NM, REQD_IND, MIN_VALUE_TXT, MAX_VALUE_TXT, MIN_FLD_SZ_NBR,
MAX_FLD_SZ_NBR, DEFAULT_VALUE_TXT, ELMNT_ID, BULK_CHG_IND, VAL_PARNT_ID,
TMPLT_NOTES, COL_START, ADDL_EDITS_IND)
Values
(480, 3, 9, 1, 3,
'DATE_OF_BIRTH', 'Y', NULL, NULL, 8,
8, NULL, 112, 'N', NULL,
NULL, NULL, NULL);
Insert into XX_TMPLT
(DTL_ID, TMPLT_ID, COL_POS_SEQ, COLTYPE_ID, SHEET_ID,
COL_HDG_NM, REQD_IND, MIN_VALUE_TXT, MAX_VALUE_TXT, MIN_FLD_SZ_NBR,
MAX_FLD_SZ_NBR, DEFAULT_VALUE_TXT, ELMNT_ID, BULK_CHG_IND, VAL_PARNT_ID,
TMPLT_NOTES, COL_START, ADDL_EDITS_IND)
Values
(481, 3, 10, 1, 3,
'GENDER', 'Y', NULL, NULL, 1,
1, NULL, 131, 'N', 2,
NULL, NULL, NULL);
Insert into XX_TMPLT
(DTL_ID, TMPLT_ID, COL_POS_SEQ, COLTYPE_ID, SHEET_ID,
COL_HDG_NM, REQD_IND, MIN_VALUE_TXT, MAX_VALUE_TXT, MIN_FLD_SZ_NBR,
MAX_FLD_SZ_NBR, DEFAULT_VALUE_TXT, ELMNT_ID, BULK_CHG_IND, VAL_PARNT_ID,
TMPLT_NOTES, COL_START, ADDL_EDITS_IND)
Values
(482, 3, 11, 1, 3,
'HOME_ADDRESS1', 'Y', NULL, NULL, 1,
40, NULL, 304, 'N', NULL,
NULL, NULL, NULL);
Insert into XX_TMPLT
(DTL_ID, TMPLT_ID, COL_POS_SEQ, COLTYPE_ID, SHEET_ID,
COL_HDG_NM, REQD_IND, MIN_VALUE_TXT, MAX_VALUE_TXT, MIN_FLD_SZ_NBR,
MAX_FLD_SZ_NBR, DEFAULT_VALUE_TXT, ELMNT_ID, BULK_CHG_IND, VAL_PARNT_ID,
TMPLT_NOTES, COL_START, ADDL_EDITS_IND)
Values
(484, 3, 13, 1, 3,
'HOME_CITY', 'Y', NULL, NULL, 1,
40, NULL, 306, 'N', NULL,
NULL, NULL, NULL);
Insert into XX_TMPLT
(DTL_ID, TMPLT_ID, COL_POS_SEQ, COLTYPE_ID, SHEET_ID,
COL_HDG_NM, REQD_IND, MIN_VALUE_TXT, MAX_VALUE_TXT, MIN_FLD_SZ_NBR,
MAX_FLD_SZ_NBR, DEFAULT_VALUE_TXT, ELMNT_ID, BULK_CHG_IND, VAL_PARNT_ID,
TMPLT_NOTES, COL_START, ADDL_EDITS_IND)
Values
(485, 3, 14, 1, 3,
'HOME_STATE', 'Y', NULL, NULL, 2,
2, NULL, 309, 'N', 30,
NULL, NULL, NULL);
Insert into XX_TMPLT
(DTL_ID, TMPLT_ID, COL_POS_SEQ, COLTYPE_ID, SHEET_ID,
COL_HDG_NM, REQD_IND, MIN_VALUE_TXT, MAX_VALUE_TXT, MIN_FLD_SZ_NBR,
MAX_FLD_SZ_NBR, DEFAULT_VALUE_TXT, ELMNT_ID, BULK_CHG_IND, VAL_PARNT_ID,
TMPLT_NOTES, COL_START, ADDL_EDITS_IND)
Values
(486, 3, 15, 1, 3,
'HOME_ZIP', 'Y', NULL, NULL, 5,
9, NULL, 310, 'N', NULL,
NULL, NULL, NULL);
Insert into XX_TMPLT
(DTL_ID, TMPLT_ID, COL_POS_SEQ, COLTYPE_ID, SHEET_ID,
COL_HDG_NM, REQD_IND, MIN_VALUE_TXT, MAX_VALUE_TXT, MIN_FLD_SZ_NBR,
MAX_FLD_SZ_NBR, DEFAULT_VALUE_TXT, ELMNT_ID, BULK_CHG_IND, VAL_PARNT_ID,
TMPLT_NOTES, COL_START, ADDL_EDITS_IND)
Values
(487, 3, 16, 1, 3,
'SSN', 'Y', NULL, NULL, 9,
9, NULL, 446, 'N', NULL,
NULL, NULL, NULL);
Insert into XX_TMPLT
(DTL_ID, TMPLT_ID, COL_POS_SEQ, COLTYPE_ID, SHEET_ID,
COL_HDG_NM, REQD_IND, MIN_VALUE_TXT, MAX_VALUE_TXT, MIN_FLD_SZ_NBR,
MAX_FLD_SZ_NBR, DEFAULT_VALUE_TXT, ELMNT_ID, BULK_CHG_IND, VAL_PARNT_ID,
TMPLT_NOTES, COL_START, ADDL_EDITS_IND)
Values
(495, 3, 24, 1, 3,
'EFFECTIVE_DATE', 'Y', NULL, NULL, 8,
8, NULL, 122, 'N', NULL,
NULL, NULL, NULL);
Insert into XX_TMPLT
(DTL_ID, TMPLT_ID, COL_POS_SEQ, COLTYPE_ID, SHEET_ID,
COL_HDG_NM, REQD_IND, MIN_VALUE_TXT, MAX_VALUE_TXT, MIN_FLD_SZ_NBR,
MAX_FLD_SZ_NBR, DEFAULT_VALUE_TXT, ELMNT_ID, BULK_CHG_IND, VAL_PARNT_ID,
TMPLT_NOTES, COL_START, ADDL_EDITS_IND)
Values
(510, 3, 39, 1, 3,
'SUBGROUP_ID', 'Y', NULL, NULL, 4,
4, NULL, 450, 'N', NULL,
NULL, NULL, NULL);
Insert into XX_TMPLT
(DTL_ID, TMPLT_ID, COL_POS_SEQ, COLTYPE_ID, SHEET_ID,
COL_HDG_NM, REQD_IND, MIN_VALUE_TXT, MAX_VALUE_TXT, MIN_FLD_SZ_NBR,
MAX_FLD_SZ_NBR, DEFAULT_VALUE_TXT, ELMNT_ID, BULK_CHG_IND, VAL_PARNT_ID,
TMPLT_NOTES, COL_START, ADDL_EDITS_IND)
Values
(511, 3, 40, 1, 3,
'SUBGROUP_EFFECTIVE_DATE', 'Y', NULL, NULL, 8,
8, NULL, 449, 'N', NULL,
NULL, NULL, NULL);
Insert into XX_TMPLT
(DTL_ID, TMPLT_ID, COL_POS_SEQ, COLTYPE_ID, SHEET_ID,
COL_HDG_NM, REQD_IND, MIN_VALUE_TXT, MAX_VALUE_TXT, MIN_FLD_SZ_NBR,
MAX_FLD_SZ_NBR, DEFAULT_VALUE_TXT, ELMNT_ID, BULK_CHG_IND, VAL_PARNT_ID,
TMPLT_NOTES, COL_START, ADDL_EDITS_IND)
Values
(517, 3, 46, 1, 3,
'CLASS_ID', 'Y', NULL, NULL, 4,
4, NULL, 67, 'N', NULL,
NULL, NULL, NULL);
Insert into XX_TMPLT
(DTL_ID, TMPLT_ID, COL_POS_SEQ, COLTYPE_ID, SHEET_ID,
COL_HDG_NM, REQD_IND, MIN_VALUE_TXT, MAX_VALUE_TXT, MIN_FLD_SZ_NBR,
MAX_FLD_SZ_NBR, DEFAULT_VALUE_TXT, ELMNT_ID, BULK_CHG_IND, VAL_PARNT_ID,
TMPLT_NOTES, COL_START, ADDL_EDITS_IND)
Values
(518, 3, 47, 1, 3,
'CLASS_EFF_DATE', 'Y', NULL, NULL, 8,
8, NULL, 66, 'N', NULL,
NULL, NULL, NULL);
Insert into XX_TMPLT
(DTL_ID, TMPLT_ID, COL_POS_SEQ, COLTYPE_ID, SHEET_ID,
COL_HDG_NM, REQD_IND, MIN_VALUE_TXT, MAX_VALUE_TXT, MIN_FLD_SZ_NBR,
MAX_FLD_SZ_NBR, DEFAULT_VALUE_TXT, ELMNT_ID, BULK_CHG_IND, VAL_PARNT_ID,
TMPLT_NOTES, COL_START, ADDL_EDITS_IND)
Values
(520, 3, 49, 1, 3,
'CLASS_PLAN_ID1', 'Y', NULL, NULL, 1,
8, NULL, 71, 'N', NULL,
NULL, NULL, NULL);
Insert into XX_TMPLT
(DTL_ID, TMPLT_ID, COL_POS_SEQ, COLTYPE_ID, SHEET_ID,
COL_HDG_NM, REQD_IND, MIN_VALUE_TXT, MAX_VALUE_TXT, MIN_FLD_SZ_NBR,
MAX_FLD_SZ_NBR, DEFAULT_VALUE_TXT, ELMNT_ID, BULK_CHG_IND, VAL_PARNT_ID,
TMPLT_NOTES, COL_START, ADDL_EDITS_IND)
Values
(521, 3, 50, 1, 3,
'CLASS_PLAN_EVENT1', 'Y', NULL, NULL, 1,
8, NULL, 70, 'N', 5,
NULL, NULL, NULL);
Insert into XX_TMPLT
(DTL_ID, TMPLT_ID, COL_POS_SEQ, COLTYPE_ID, SHEET_ID,
COL_HDG_NM, REQD_IND, MIN_VALUE_TXT, MAX_VALUE_TXT, MIN_FLD_SZ_NBR,
MAX_FLD_SZ_NBR, DEFAULT_VALUE_TXT, ELMNT_ID, BULK_CHG_IND, VAL_PARNT_ID,
TMPLT_NOTES, COL_START, ADDL_EDITS_IND)
Values
(522, 3, 51, 1, 3,
'CLASS_PLAN_EFF_DATE1', 'Y', NULL, NULL, 8,
8, NULL, 68, 'N', NULL,
NULL, NULL, NULL);
COMMIT;
PROCEDURE pivot_lvl1 (
p_tmplt_id IN xx_tmplt.tmplt_id%TYPE,
p_sheet_id IN xx_sheet.sheet_id%TYPE,
p_set_id IN xx_set.set_id%TYPE,
p_lvl IN NUMBER,
c_pivot1 OUT pivot1_cur
)
IS
v_q1 CLOB := 'SELECT';
v_suff VARCHAR2 (500);
n_tmplt_cnt NUMBER;
n_tmplt_id xx_tmplt.tmplt_id%TYPE := p_tmplt_id;
n_sheet_id xx_sheet.sheet_id%TYPE := p_sheet_id;
n_set_id xx_set.set_id%TYPE := p_set_id;
CURSOR tmplt_cur
IS
SELECT col_pos_seq, col_hdg_nm
FROM ta_val_tmplt_dtl
WHERE sheet_id = p_sheet_id AND tmplt_id = p_tmplt_id;
BEGIN
--loop through each heading name and column position sequence pair and attach
--the code that will pivot the column to a row.
<<tmplt_loop>>
FOR c_row IN tmplt_cur
LOOP
v_q1 :=
v_q1
|| ' MAX (DECODE (rn,'
|| c_row.col_pos_seq
|| ', txt, NULL))'
|| '"'
|| SUBSTR (c_row.col_hdg_nm, 1, 30)
|| '"'
|| ',';
END LOOP tmplt_loop;
--remove the trailing comma from the loop.
v_q1 := RTRIM (v_q1, ',');
--attach the correct suffix depending on the level of the elements
CASE p_lvl
WHEN 1
THEN
v_suff :=
' FROM (SELECT c.col_pos_seq rn, data_string_txt txt, a.txn_id, c.col_hdg_nm'
|| ' FROM xx_lvl1 a, xx_tmplt c'
|| ' WHERE a.elmnt_id = c.elmnt_id'
|| ' AND a.sheet_id = :a'
|| ' AND txn_id IN (SELECT txn_id'
|| ' FROM xx_tran'
|| ' WHERE tmplt_id = :b'
|| ' AND set_id = :c'
|| '))'
|| ' GROUP BY txn_id ORDER BY txn_id';
WHEN 2
THEN
v_suff :=
' FROM (SELECT c.col_pos_seq rn, data_string_txt txt, a.txn_id, a.lvl2_seq, c.col_hdg_nm'
|| ' FROM xx_lvl2 a, xx_tmplt c'
|| ' WHERE a.elmnt_id = c.elmnt_id'
|| ' AND a.sheet_id = :a'
|| ' AND txn_id IN (SELECT txn_id'
|| ' FROM xx_tran'
|| ' WHERE tmplt_id = :b'
|| ' AND set_id = :c'
|| '))'
|| ' GROUP BY txn_id, lvl2_seq ORDER BY txn_id,lvl2_seq';
WHEN 3
THEN
v_suff :=
' FROM (SELECT c.col_pos_seq rn, data_string_txt txt, a.txn_id, a.lvl3_seq, c.col_hdg_nm'
|| ' FROM xx_lvl3 a, xx_tmplt c'
|| ' WHERE a.elmnt_id = c.elmnt_id'
|| ' AND a.sheet_id = :a'
|| ' AND txn_id IN (SELECT txn_id'
|| ' FROM xx_tran'
|| ' WHERE tmplt_id = :b'
|| ' AND set_id = :c'
|| '))'
|| ' GROUP BY txn_id, lvl3_seq ORDER BY txn_id,lvl3_seq';
END CASE;
v_q1 := v_q1 || v_suff;
/*UNITTESTUNITTESTUNITTEST*/
INSERT INTO clobhold
VALUES (v_q1 || ';');
/*UNITTESTUNITTESTUNITTEST*/
OPEN c_pivot1 FOR TO_CHAR (v_q1) USING n_sheet_id, n_tmplt_id, n_set_id;
END;
October 30, 2007 - 1:52 pm UTC
... As long as we do an analyze
after large amounts of data are inserted, we have no problem with scale. ...
so, now I don't know what you are asking for?
Data pivot
A reader, October 30, 2007 - 3:51 pm UTC
Im not asking for anything. Per the intent of "Write a Review" I was providing feedback on Pivoting. And how we have successfully used it for large amounts of data dynamically.
Thank you for the informative discussion and here's an example of pratcial application. That's all.
feedback on "providing feedback on Pivoting"
another reader ... or writer?, October 31, 2007 - 4:56 pm UTC
To "A Reader":
an example of pratcial application
It is indeed practical in the sense that it is doable, a concrete application of the technique.
It is otherwise impractical in the sense that it is not sensible, not rational to do something for no reason what-so-ever. Well, you alluded to "we are able to perform operations on tables that we normally would not be able to" but have otherwise provided not one shred of evidence that the cousin of EAV is "practical, useful [snip] efficient and fast". On the fast portion, remember you should be proving faster than not just fast enough.
Your consumer needs a result set equivalent to: "Select A, B, C from T where P"
One could have a table T with columns A, B, C and execute the above SQL by supplying input for the predicate P.
You don't have a table T. You have an EAV model forcing you into pivoting in order the supply the consumer with the result set. You have relatively small amounts of data and pivoting is fast enough. So what? What is the advantage of not having T implemented as a table?
Out of curiosity:
1. Why do you ORDER BY your generated SQL?
2. If your consumer really needs a predicate like "where DATE_OF_BIRTH = :d" (DATE_OF_BIRTH being your DTL_ID=480), when does that happen? Is the consumer pivoting and retrieving the entire, ordered, content of your virtual table T and then applying the predicate?
Logical Leaps
A reader, November 07, 2007 - 9:29 am UTC
I don't understand how you would know that we did this for no reason what-so-ever. (we did do it for no reason what-so-ever, but how would YOU know that? We just did it for slaps and giggles and to waste company money ;-) ) Seriously, we had a problem to solve and this was the only way to solve it. So does that make you revise your impracticality claim?
I don't really have to prove "faster than" anything because I wasn't writing to show anybody up. i was writing to demonstrate that using pivot with EAV-like schema can be used practically and with speed and efficiency. Also, "faster-than" what? i'm not sure what you want me to be faster than.
" What is the advantage of not having T implemented as a table? " - The advantage is it solved the problem we were given that we needed to be able to add columns to tables without changing code. Do you have another way to do that using standard tables?
Out of curiosity:
1. Why do you ORDER BY your generated SQL? --because the result set needs to be ordered.
2. If your consumer really needs a predicate like "where DATE_OF_BIRTH = :d" -our consumer doesn't need a predicate like "where date_of_birth = :d" so the question is moot. Secondly, if that were the case, we have contrived key's that take care of indexing and finding particular data based on keys and foreign keys.
Help, pls..
Mich, November 26, 2007 - 4:04 pm UTC
Hi, i need help. I have a table named, 'Attendance'
with the following fields and data(prob more),
---------------------------------------
StdID SubjID ADate StdAttend
=======================================
1001 2001 2007-11-19 present
1002 2001 2007-11-19 absent
1003 2001 2007-11-19 present
1001 2001 2007-11-26 absent
1002 2001 2007-11-26 present
1003 2001 2007-11-26 present
1001 2001 2007-12-03 present
1002 2001 2007-11-03 present
1003 2001 2007-11-03 absent
========================================
And would like to create a query/report from it that would look like this:
---------------------------------------------------
StdId 2007-11-19 2007-11-26 2007-12-03
===================================================
1001 present absent present
1002 absent present present
1003 present present absent
===================================================
I found a way of doing this by:
select StdID,
sum(case when ADate='2007-11-19' then 1 else 0 end) as "2007-11-19",
sum(case when ADate='2007-11-26' then 1 else 0 end) as "2007-11-26",
sum(case when ADate='2007-12-03' then 1 else 0 end) as "2007-12-03"
from Attendance
group by StdID, SubjID
But, what if i don't know the exact value of 'ADate' and still want to add it into the ff. columns?
P.S.
Is it also possible to add a last column like this, after all the dates have been listed? Sorry, I'm very new to this.
-----------------------------------------------------------
StdId 2007-11-19 2007-11-26 2007-12-03 Total
===========================================================
1001 present absent present 2/3
1002 absent present present 2/3
1003 present present absent 2/3
===========================================================
Thanks a bunch,
Mich
November 27, 2007 - 3:05 pm UTC
ff columns? what the heck is an ff column.
and if you do not know adate - is adate an INPUT to the query or what? what if there are thousands of adates in the table?
also, next time you hit the review button, please take a second to read the text I put at the top of the page - if you don't, I'll just be ignoring the post altogether - you know the bit that says:
If your followup requires a response that might include a query, you had better supply very very simple create tables and insert statements. I cannot create a table and populate it for each and every question. The SMALLEST create table possible (no tablespaces, no schema names, just like I do in my examples for you)
PQ on cartesian result set
Marc, November 27, 2007 - 2:44 am UTC
Dear Tom,
is there a chance to have the result set of the cartesian product processed in parallel ?
as soon as the data comes back from a query like :
select *
from tableA, tableB
;
there is only 1 CPU doing the rest and the "rest" easily could be a result set of 500 mio rows which I want some
heavy case-when expressions run at.
thanks a lot
regards
Marc
November 27, 2007 - 3:37 pm UTC
sure, yes, just alter the tables to be parallel (or use parallel hints)
cartesian product in parallel
Marc, November 28, 2007 - 7:48 am UTC
I hadn't written this if I didn't do so.
tablescans are done in parallel indeed , but the result is processed by 1 CPU as mentioned...
pretty easy to reproduce
10.2.0.3
--------
alter table X parallel 20;
alter table Y parallel 20;
select *
from X,Y
;
launch prstat simultaneously
wait until data comes back in the sqlplus session
from that moment onwards 1 CPU is working only
the problem is that I got something like
select * from
(
select case when huge ...expression ..
from T_20_mio_rows , T_200_rows
)
where shrink_back_restriction_based_upon_huge_case ...
;
and u can imagine that processing the result set of 20 Mio x 200 rows in serial is really slow
November 28, 2007 - 11:02 pm UTC
20,000,000 x 200 should give me rows back almost instantly in serial - take first row of 20,000,000 and join to first row of 200 - bamm
I'm not sure what you are looking for here from parallel. the case isn't going to be a huge bottleneck, not compared to shipping 4,000,000,000 (4 BILLION) records anyway.
pivot with model
rc, December 01, 2007 - 10:25 am UTC
Adam from st. louis, MO gave a select statement with model but that doesn't work.
select job
,dept_10
,dept_20
,dept_30
from emp
model
return updated rows
partition by ( job )
dimension by ( deptno )
measures (cnt, 0 dept_10, 0 dept_20, 0 dept_30 )
rules
(
dept_10[0] = cnt[deptno=10]
,dept_20[0] = cnt[deptno=20]
,dept_30[0] = cnt[deptno=30]
)
order by job
/
Probably emp is not the emp table but a view??
I use this select statement:
select distinct job, deptno_10, deptno_20, deptno_30, deptno_40
from (select job,deptno,count(*) cnt
from emp
group by job,deptno ) empv
model
partition by (job)
dimension by (deptno)
measures (cnt ,0 deptno_10 ,0 deptno_20 ,0 deptno_30, 0 deptno_40 )
rules
(
deptno_10[any] = cnt [deptno = 10]
, deptno_20[any] = cnt [deptno = 20]
, deptno_30[any] = cnt [deptno = 30]
, deptno_40[any] = cnt [deptno = 40]
)
order by job
;
JOB DEPTNO_10 DEPTNO_20 DEPTNO_30 DEPTNO_40
--------- ---------- ---------- ---------- ----------
ANALYST 2
CLERK 1 2 1
MANAGER 1 1 1
PRESIDENT 1
SALESMAN 4
This works because the combination of job and deptno is unique for inline view empv.
The column deptno_40 is not necessary because there are no employees with deptno = 40.
select ... model ... works only in Oracle 10 and Oracle 11 .
when I run this query, I get an ORA-00932 inconsistent datatypes error ???
A reader, December 06, 2007 - 3:16 pm UTC
When I tried to run Tami's proposed solution for Warren, I get an ORA-00932 inconsistent datatypes error. Tom, can you please tell me why I receive and/or how to get around the ORA error.
SQL> get warren.sql
1 select Y.id,
2 (case
3 when y.site_id is not null then y.site_id
4 else (select site_id
5 from T1
6 where T1.id = prev_site_id)
7 end ) NSITE_ID,
8 ( case
9 when y.regional_office is not null then y.regional_office
10 else ( select regional_office
11 from T1
12 where T1.id = prev_reg_id)
13 end ) NRegional_office,
14 y.comm_name
15 FROM
16 (select a.id as id , a.site_id as site_id,
17 (select max(id)
18 from (select distinct id, site_id
19 from t1 where site_id is not null) b
20 where b.id < a.id ) prev_site_id,
21 regional_office regional_office,
22 (select max(id)
23 from (select distinct id , regional_office
24 from t1 where regional_office is not null) c
25 where c.id < a.id ) prev_reg_id
26 from t1 a ) X,
27 T1 Y
28* where x.id = Y.id
SQL> /
ID NSITE_ID NREGIONAL_OFF COMM_NAME
---------- ---------- ------------- ------------------------------
1 9 Region 1 NEW YORK WHARVES LTD
2 9 Region 1 AE SHIPPERS
3 10 Region 2 ESSO BULK PLANT
4 10 Region 2 SHELL BULK PLANT
5 10 Region 2 STATION A
6 10 Region 2 STATION B
7 10 Region 2 STATION C
8 10 Region 2 STATION D
9 10 Region 2 STATION E
10 10 Region 2 STATION F
11 11 Region 3 RAIL RIGHT-OF-WAY
12 11 Region 3 STORAGE SHED
13 11 Region 3 FUELING DE
14 11 Region 3 EMERGENCY SHELTER
15 13 Region 4 CANRON
15 rows selected.
Tom, I tried lead/lag function. I am getting previous site for the subsequent row, but for all the
rows.
I am sure, Tom will come up with "ANALYTIC FUNCTION".
replacing dept_10 with corresponding deptno
Bhaskar, June 12, 2008 - 5:09 am UTC
Hi Tom your o/p is like this
JOB DEPT_10 DEPT_20 DEPT_30 DEPT_40
--------- ---------- ---------- ---------- ----------
ANALYST 2
CLERK 1 2 1
MANAGER 1 1 1
PRESIDENT 1
SALESMAN 4
but how i can repalce the headings like DEPT_10 with it's corresponding deptno like in a single sql query?
JOB 10 20 30 40
--------- ---------- ---------- ---------- ----------
ANALYST 2
CLERK 1 2 1
MANAGER 1 1 1
PRESIDENT 1
SALESMAN 4
June 12, 2008 - 8:07 am UTC
scott@DEV816> select job,
2 max( decode( deptno, 10, cnt, null ) ) "10",
3 max( decode( deptno, 20, cnt, null ) ) "20",
4 max( decode( deptno, 30, cnt, null ) ) "30",
5 max( decode( deptno, 40, cnt, null ) ) "40"
6 from ( select job, deptno, count(*) cnt
7 from emp
8 group by job, deptno )
9 group by job
10 /
Row vs Column Comparison
Radhika, July 07, 2008 - 2:30 pm UTC
I have two tables like tableA,tableB
The row in tableA is exactly instered into tableB as Columns
For eg:
tableA
------
Num Name Sal
=== ==== ===
1 XXX 12000
tableB
-------
Col1
====
1
XXX
12000
Now how to do a comparision between tableA and tableB to make sure whether the values in the source (Row) is same as in the targets (column values).
July 07, 2008 - 3:09 pm UTC
you are missing stuff here. tableB is entirely incomplete in it's design. It is missing at least two columns that would a) comprise the primary key, b) provide a way to order the rows
Actually, just please drop tableB, it is a really bad idea.
oh, and no create, no inserts, no look
Row Vs Column comparision
Radhika, July 08, 2008 - 2:58 pm UTC
The requirement is like that.Need to insert a row in one table as column in another table. The target table column is of Varchar type. I want a query to compare the source and the target thats row vs column.
July 08, 2008 - 5:15 pm UTC
what is driving this requirement
because this requirement is a really bad idea
let us backup and get to the crux of the problem "how can we help you defeat this really bad idea and make you look better"
Unknown column number and name
John, July 16, 2008 - 10:04 am UTC
Hi, I have split my data in 3 tables: LOG, MESSAGEFIELDS, AND LOGMESSAGEDETTAILS. The tables look as follows:
LOG
-----------------------------------------------------------------------------------------------
ID DATETIME MESSAGE
-----------------------------------------------------------------------------------------------
1 2008-04-02 11:45:01 attr_01=val_01 attr_02=val_02 <otherdata>
2 2008-04-04 10:12:05 attr_02=val_01 attr_03=val_02 attr_04=val_03
3 2008-04-01 09:01:24 attr_04=val_01 <otherdata>
4 2008-04-11 23:45:17 attr_01=val_01 attr_02=val_02 attr_03=val_03 attr03=val_04
...
MESSAGEFIELDS
----------------
ID FIELD
----------------
1 attr_01
2 attr_02
3 attr_03
4 attr_04
...
LOGMESSAGEDETTAILS
---------------------------------------
ID LOGID FIELDID FVALUE
---------------------------------------
1 1 1 val_01
1 1 2 val_02
1 2 2 val_01
1 2 3 val_02
1 2 4 val_03
1 3 4 val_01
1 4 1 val_01
1 4 2 val_02
1 4 3 val_03
1 4 4 val_04
...
The LOG.MESSAGE field is composed of valued attributes and other types of data. The valued attributes are programmatically extracted and inserted into a dettails table.
The result I want to obtain is:
DETTAILEDLOGVIEW
---------------------------------------------------------------------------------------------------
ID DATETIME genericData attr_01 attr_02 attr_03 attr_04 ...
---------------------------------------------------------------------------------------------------
1 2008-04-02 11:45:01 <otherdata> val_01 val_02
2 2008-04-04 10:12:05 val_01 val_02 val_03
3 2008-04-01 09:01:24 <otherdata> val_01
4 2008-04-11 23:45:17 val_01 val_02 val_03 val_04
...
Could you give a hint on the best way to do this please?
pivot
A reader, March 02, 2009 - 12:28 am UTC
Tom:
is this done using a pivot query.
I want to get a 5 column result (one per video) based on the following table/data and queries.
When i do those as subqueries it takes a long time "select a.vidno,(sub1),(sub2),(sub3) from table a".
Also, would you consider creating a trigger and storing those values instead of calculating every time for better performance.
vidno, date_assign, curr_assigned, prev_asigned, last_assigned
Date Assigned = select max(date_assigned) from assign c where vidno=a.vidno
Current Assigned = select assigned_to from assign d where (vidno,date_assigned) in
(select vidno,max(date_assigned) from assign where vidno=a.vidno
and status_code='A' group by vidno)
and d.date_assigned >= a.recdt
Previous Assigned = select assigned_to from assign c where (vidno,created_date) in
(select vidno,max(date_assigned) from assign where vidno=a.vidno
and status_code='T' group by vidno)
Last Assigned = select assigned_to from assign t where (vidno,created_date) in
(select vidno,max(created_date) from assign where vidno=a.vidno
group by vidno
create table assign (
assign_no number(10), --PK
vidno number(10),
media varchar2(3),
assigned_to varchar2(10),
date_assigned date,
status_code varchar2(1),
created_Date date)
insert into assign values (1,1001,'CA','mike','01-JAN-2009','A',sysdate)
/
insert into assign values (2,1002,'CA','sam','02-JAN-2009','T',sysdate)
/
insert into assign values (3,1002,'CA','john','03-JAN-2009','A',sysdate)
/
insert into assign values (4,1003,'CA','trish','04-JAN-2009','T',sysdate)
/
insert into assign values (5,1003,'CA','suzan','05-JAN-2009','T',sysdate)
/
insert into assign values (6,1003,'CA','wiley','06-JAN-2009','A',sysdate)
/
insert into assign values (7,1004,'CA','jenn','07-JAN-2009','T',sysdate)
/
insert into assign values (8,1004,'CA','wesl','08-JAN-2009','T',sysdate)
/
insert into assign values (9,1004,'CA','eric','09-JAN-2009','T',sysdate)
/
insert into assign values (10,1004,'CA','magic','10-JAN-2009','A',sysdate)
/
insert into assign values (11,1005,'CA','tese','11-JAN-2009','T',sysdate)
/
insert into assign values (12,1005,'CA','dera','12-JAN-2009','A',sysdate)
/
insert into assign values (13,1005,'CA','simon','13-JAN-2009','T',sysdate)
/
insert into assign values (14,1005,'CA','liz','14-JAN-2009','A',sysdate)
/
March 03, 2009 - 3:07 pm UTC
... Also, would you consider creating a trigger and storing those values instead of
calculating every time for better performance.
....
absolutely NOT.
It is not at all clear what you want there, instead of giving me snippets of code (that do not work standalone) - how about you either give us a FUNCTIONING query to look at and try to understand what you want or even better - explain it in specification like form.
pvt query
A reader, March 03, 2009 - 8:02 pm UTC
Tom:
thanks, here is the query and specs for tables/data. This one will run fast. However, the QSTAGES table i have has about 200,000 records and ASSIGN table is 1000.
It takes 1.5 minutes for user to see records on screen.
I did troubleshooting and found that the congestions is when the sub-query on ASSIGN table multiple time to figure out current and previous reviewer. The main query where i use RANK() runs pretty fast.
SELECT "MEDIA","VIDNO","STAGE","STATUS","RECDT","CREATED_DATE","PREV_REVIEWER","CURR_REVIEWER","MINDATE1","MINDATE2" FROM ( select g.*,min(mindate1) over () MINDATE2 from (
select e.media,e.vidno,e.stage,e.status,e.recdt,e.created_date,
(case when recdt > date_assigned then last_assigned else old_prev_reviewer end) prev_reviewer,
curr_reviewer,
(case when curr_reviewer is null then recdt else null end) mindate1
FROM
(
select a.media,a.vidno,a.stage,a.status,a.recdt,a.created_date,
(select assigned_to from assign c where (vidno,date_assigned) in
(select vidno,max(date_assigned) from assign where vidno=a.vidno and status_code='T'
group by vidno) ) old_prev_reviewer,
(select max(date_assigned) from assign c where vidno =a.vidno) date_assigned,
(select assigned_to from assign t where (vidno,date_assigned) in
(select vidno,max(date_assigned) from assign where vidno=a.vidno
group by vidno) ) last_assigned,
(select assigned_to from assign d where (vidno,date_assigned) in
(select vidno,max(date_assigned) from assign where vidno=a.vidno and status_code='A'
group by vidno)
and d.date_assigned >= a.recdt) Curr_reviewer
FROM
(
SELECT * FROM
(
select a.*, dense_rank() over (partition by vidno order by seq_no desc) as rnk
FROM qstages a where status <> 'I')
WHERE stage = 0 and status = 'A' and rnk = 1 order by recdt
) A
where rownum <= (select to_Number(parameter_value) from ref_sys_parameters where lower(parameter_name)='no_rows') order by recdt,vidno
) E
) G
)
where recdt <= nvl(mindate2+(select to_Number(parameter_value) from ref_sys_parameters where lower(parameter_name)='assign_days'),recdt)
/
create table ref_sys_parameters (
parameter_name varchar2(20),
parameter_value varchar2(15) );
insert into ref_sys_parameters values ('assign_days','150')
/
insert into ref_sys_parameters values ('no_rows','100')
/
create table qstages (
seq_no number(10),
vidno number(10) ,
media varchar2(3),
stage number(1),
recdt date,
compdt date,
status varchar2(1),
created_Date date )
/
insert into qstages values (1,1000,'CA',0,'10-NOV-2008','10-NOV-2008','A',sysdate)
/
insert into qstages values (2,1001,'CA',0,'10-NOV-2008','10-NOV-2008','R',sysdate)
/
insert into qstages values (3,1002,'CA',0,'10-NOV-2008','10-NOV-2008','A',sysdate)
/
insert into qstages values (4,1002,'CA',0,'10-NOV-2008','10-NOV-2008','R',sysdate)
/
insert into qstages values (5,1003,'CA',0,'10-NOV-2008','10-NOV-2008','R',sysdate)
/
insert into qstages values (6,1003,'CA',0,'12-NOV-2008','12-NOV-2008','A',sysdate)
/
insert into qstages values (7,1004,'CA',0,'10-NOV-2008','10-NOV-2008','A',sysdate)
/
insert into qstages values (8,1004,'CA',1,'12-NOV-2008','12-NOV-2008','A',sysdate)
/
insert into qstages values (9,1005,'CA',0,'10-NOV-2008','10-NOV-2008','A',sysdate)
/
insert into qstages values (10,1005,'CA',1,'10-NOV-2008','10-NOV-2008','A',sysdate)
/
insert into qstages values (11,1005,'CA',5,'12-NOV-2008','12-NOV-2008','A',sysdate)
/
insert into qstages values (12,1006,'CA',0,'10-NOV-2008','10-NOV-2008','A',sysdate)
/
insert into qstages values (13,1006,'CA',1,'10-NOV-2008','10-NOV-2008','A',sysdate)
/
insert into qstages values (14,1006,'CA',5,'10-NOV-2008','10-NOV-2008','R',sysdate)
/
insert into qstages values (15,1007,'CA',0,'10-NOV-2008','10-NOV-2008','A',sysdate)
/
insert into qstages values (16,1007,'CA',1,'10-NOV-2008','10-NOV-2008','A',sysdate)
/
insert into qstages values (17,1007,'CA',5,'10-NOV-2008','10-NOV-2008','A',sysdate)
/
insert into qstages values (18,1007,'CA',2,'12-NOV-2008','12-NOV-2008','A',sysdate)
/
insert into qstages values (19,1008,'CA',0,'10-NOV-2008','10-NOV-2008','A',sysdate)
/
insert into qstages values (20,1008,'CA',1,'10-NOV-2008','10-NOV-2008','A',sysdate)
/
insert into qstages values (21,1008,'CA',5,'10-NOV-2008','10-NOV-2008','A',sysdate)
/
insert into qstages values (22,1008,'CA',2,'12-NOV-2008','12-NOV-2008','R',sysdate)
/
insert into qstages values (23,1008,'CA',0,'12-NOV-2008','12-NOV-2008','A',sysdate)
/
insert into qstages values (24,1009,'CA',0,'10-NOV-2008','10-NOV-2008','A',sysdate)
/
insert into qstages values (25,1009,'CA',1,'10-NOV-2008','10-NOV-2008','A',sysdate)
/
insert into qstages values (26,1009,'CA',5,'10-NOV-2008','10-NOV-2008','A',sysdate)
/
insert into qstages values (27,1009,'CA',2,'12-NOV-2008','12-NOV-2008','R',sysdate)
/
insert into qstages values (28,1009,'CA',0,'12-NOV-2008','12-NOV-2008','R',sysdate)
/
March 04, 2009 - 12:55 pm UTC
oh
my
gosh
Ok, now I hate scalar subqueries. They are nice for very few things. This is NOT one of them.
so, I reformat your query so we have a *chance* of getting it - by the way, when one asks for "specifications",
.... thanks, here is the query and specs for tables/data. ...
that isn't what they are asking for. They are asking for a textual, step by step description of the problem (the QUESTION). You know, that material YOU had when YOU developed this thing in the first place.
and it would have been nice to have, well, all of the tables - don't you think - that assign table seems rather "relevant" no?I think the ability to phrase a question is the most important attribute one can have in our profession. I see it rarely.
SELECT "MEDIA","VIDNO","STAGE","STATUS","RECDT","CREATED_DATE",
"PREV_REVIEWER","CURR_RE VIEWER","MINDATE1","MINDATE2"
FROM ( select g.*,min(mindate1) over () MINDATE2
from ( select e.media,e.vidno,e.stage,e.status,e.recdt,e.created_date,
(case when recdt > date_assigned
then last_assigned
else old_prev_reviewer
end ) prev_reviewer,
curr_reviewer,
(case when curr_reviewer is null
then recdt
else null
end ) mindate1
FROM ( select a.media,a.vidno,a.stage,a.status,a.recdt,a.created_date,
(select assigned_to
from assign c
where (vidno,date_assigned) in
(select vidno,max(date_assigned)
from assign
where vidno=a.vidno
and status_code='T'
group by vidno) ) old_prev_reviewer,
(select max(date_assigned)
from assign c
where vidno =a.vidno) date_assigned,
(select assigned_to
from assign t
where (vidno,date_assigned) in
(select vidno,max(date_assigned)
from assign
where vidno=a.vidno
group by vidno) ) last_assigned,
(select assigned_to
from assign d
where (vidno,date_assigned) in
(select vidno,max(date_assigned)
from assign
where vidno=a.vidno
and status_code='A'
group by vidno)
and d.date_assigned >= a.recdt) Curr_reviewer
FROM ( SELECT *
FROM ( select a.*,
dense_rank() over
(partition by vidno
order by seq_no desc) as rnk
FROM qstages a
where status <> 'I')
WHERE stage = 0
and status = 'A'
and rnk = 1
order by recdt) A
where rownum <= (select to_Number(parameter_value)
from ref_sys_parameters
where lower(parameter_name)='no_rows')
order by recdt,vidno
) E
) G
)
where recdt <= nvl(mindate2+(select to_Number(parameter_value)
from ref_sys_parameters
where lower(parameter_name)='assign_days'), recdt )
Ok, so you get the set of records for each vidno after sorting by seq_no from big to small. You don't say of seq_no is UNIQUE or anything and since you use dense_rank, that could be more than one record PER vidno
(do you see why
specifications are necessary, I'm pretty sure that seq_no is unique - but you don't say - I don't know - I cannot assume so I have to live with the ASSUMPTION that it isn't - I have to live with ALL of the assumptions one can derive from your query - which isn't performing well - which means I am shackled by all of the hidden assumptions. If we had a well formed DATA MODEL (constraints and all) and a well formed QUESTION - "this is the data I need...." sort of question - we'd be much better off...)but you do it in sort of a strange fashion:
FROM ( SELECT *
FROM ( select a.*,
dense_rank() over
(partition by vidno
order by seq_no desc) as rnk
FROM qstages a
where status <> 'I')
WHERE stage = 0
and status = 'A'
and rnk = 1
order by recdt) A
did you really mean to assign rank BEFORE filtering on stage and status? We'll assume so...
Then you keep only rownum <= value of them...
Now, for each of thos vidno's, you want
a) assigned_to for the status_code = 'T' with the max(date_assigned)
b) max(date_assigned)
c) assigned_to
d) assigned_to for the status_code = 'A' if the date_assigned is > recdt
Assume for a moment that the set described above is called "data", then we want:
select vidno,
substr( max( case when status_code = 'T' and date_assigned is not null then to_char(date_assigned,'yyyymmddhh24miss') || assigned_to end), 15 ) old_prev_reviewer,
max(date_assigned) max_date_assigned,
substr( max( case when date_assigned is not null then to_char(date_assigned,'yyyymmddhh24miss') || assigned_to end), 15 ) last_assigned,
substr( max( case when status_code = 'A' and date_assigned is not null then to_char(date_assigned,'yyyymmddhh24miss') || assigned_to end), 15 ) curr_reviewer,
to_date(substr( max( case when status_code = 'A' and date_assigned is not null then to_char(date_assigned,'yyyymmddhh24miss') || to_char(recdt,'yyyymmddhh24miss') end), 15 ),'yyyymmddhh24miss') curr_reviewer_recdt
from assign
where vidno in (select vidno from data)
group by vidno;
(probably, I cannot really test anything with this "specification". If we call that assign_data, then what we want is:
select data.media,data.vidno,data.stage,data.status,data.recdt,data.created_date,
assign_data.old_prev_reviewer, assign_data.max_date_assigned, assign_data.last_assigned,
case when assign_data.curr_reviewer_recdt >= data.recdt then assign_data.Curr_reviewer end Curr_reviewer
from data, assign_data
where data.vidno = assign_data.vidno(+)
order by data.recdt, data.vidno
that gives the result set that is meaningfully named "E" above. If we have E, then
SELECT "MEDIA","VIDNO","STAGE","STATUS","RECDT","CREATED_DATE",
"PREV_REVIEWER","CURR_REVIEWER","MINDATE1","MINDATE2"
from (
select e.media,e.vidno,e.stage,e.status,e.recdt,e.created_date,
(case when recdt > max_date_assigned then last_assigned else old_prev_reviewer end) prev_reviewer,
curr_reviewer,
(case when curr_reviewer is null then recdt else null end) mindate1,
min( (case when curr_reviewer is null then recdt else null end) ) over () mindate2,
(select to_Number(parameter_value) from ref_sys_parameters where lower(parameter_name)='assign_days') assign_days
from e
)
where recdt <= nvl( mindate2+assign_days, recdt )
order by recdt, vidno
does it.
put it all together:
with data
as
( select *
from
( SELECT *
FROM
( select a.*,
dense_rank() over (partition by vidno
order by seq_no desc) as rnk
FROM qstages a
where status <> 'I'
)
WHERE stage = 0
and status = 'A'
and rnk = 1
order by recdt
)
where rownum <= (select to_Number(parameter_value)
from ref_sys_parameters
where lower(parameter_name)='no_rows')
),
assign_data
as
(
select vidno,
substr( max( case when status_code = 'T' and date_assigned is not null then to_char(date_assigned,'yyyymmddhh24miss') || assigned_to end), 15 ) old_prev_reviewer,
max(date_assigned) max_date_assigned,
substr( max( case when date_assigned is not null then to_char(date_assigned,'yyyymmddhh24miss') || assigned_to end), 15 ) last_assigned,
substr( max( case when status_code = 'A' and date_assigned is not null then to_char(date_assigned,'yyyymmddhh24miss') || assigned_to end), 15 ) curr_reviewer,
to_date(substr( max( case when status_code = 'A' and date_assigned is not null then to_char(date_assigned,'yyyymmddhh24miss') || to_char(recdt,'yyyymmddhh24miss') end), 15 ),'yyyymmddhh24miss') curr_reviewer_recdt
from assign
where vidno in (select vidno from data)
group by vidno
),
E
as
(
select data.media,data.vidno,data.stage,data.status,data.recdt,data.created_date,
assign_data.old_prev_reviewer, assign_data.max_date_assigned, assign_data.last_assigned,
case when assign_data.curr_reviewer_recdt >= data.recdt then assign_data.Curr_reviewer end Curr_reviewer
from data, assign_data
where data.vidno = assign_data.vidno(+)
)
SELECT "MEDIA","VIDNO","STAGE","STATUS","RECDT","CREATED_DATE",
"PREV_REVIEWER","CURR_REVIEWER","MINDATE1","MINDATE2"
from (
select e.media,e.vidno,e.stage,e.status,e.recdt,e.created_date,
(case when recdt > max_date_assigned then last_assigned else old_prev_reviewer end) prev_reviewer,
curr_reviewer,
(case when curr_reviewer is null then recdt else null end) mindate1,
min( (case when curr_reviewer is null then recdt else null end) ) over () mindate2,
(select to_Number(parameter_value) from ref_sys_parameters where lower(parameter_name)='assign_days') assign_days
from e
)
where recdt <= nvl( mindate2+assign_days, recdt )
order by recdt, vidno
/
think in sets....
query
A reader, March 04, 2009 - 9:01 am UTC
Tom:
I forgot to describe what i am trying to get that helps you understand the query
MY main query (the one with rank ()) is based on the "QSTAGES" tables. THat finds each video that has a last stage of 0 approved. works fine.
Then i want to find the current assigned reviewer and previous assigned reviewer for that video.
The data is in "ASSIGN" table. This is where things slow down.
To determine that I check the highest assignment date "DATE_ASSIGNED" and compare it to the stage date "RECDT" i get from the main query because the assignment could have taken place BEFORE the new stage was added. This means there is NO current reviewer. If the assignment date was less than stage date then I pick the current reviewer and then the previous one (if exists) based on the logic i showed you.
There are also other filters I use in the view to freeze the list of records displayed if the first RECDT of the record was within 150 days of the last one. Also there is a filter on number of rows that can be displayed.
query
A reader, March 04, 2009 - 1:19 pm UTC
Tom:
yes, seq_no is primary key.
I should replace DENSE_RANK with ROW_NUMBER() but since seq_no is unique it will be the same but i will replace it anyhow.
I will test this out. But still do not you think an AFTER INSERT trigger on the "assign" table that would simply update two columns in the MASTER VIDEO table (prev_reviewer, cur_reviewer) would be easier.
My idea is that every time they make an assignment I update the VIDEO.PREV_REVIEWER with data in VIDEO.CURR_REVIEWER and then VIDEO.CURR_REVIEWER with the new person assigned.
Then another AI trigger on QSTAGES would do the same after a new stage is addded (reset the current reviewer).
That would make it much easier for querying. Sometimes storing derived data makes some sense would it here.
thanks for your help
March 04, 2009 - 2:03 pm UTC
... But still do not you think an AFTER INSERT trigger on the
....
NO, I already said "no"
https://www.oracle.com/technetwork/issue-archive/2008/08-sep/o58asktom-101055.html I have no problem with 'derived' data in general. Triggers = big trouble.
If you want to store the 'derived' data - do so by revoking INSERT on the tables from everyone, create a transactional API (stored procedure) to interact with these objects (not a TABLE api, a transctional interface, a series of stored procedures that do the transaction processing in it's entirety) and making it part of that.
query
A reader, March 04, 2009 - 2:25 pm UTC
Tom:
I read your article. it seems you had very bad experiences with triggers that got you to this point.
So you are suggesting to populate the derived data fields in the client code that does the INSERT into assign table (instead of using AI oracle trigger). correct?
Another small thing i was thinking of. That main query where i scan the whole QSTAGES table and check any video that has last stage of "0" approved. I can also instead have create a FLAG in the master VIDEO table that I can set to imply that this video is to show up in the result set. When a new stage is added i reset this flag.
Do you like this approach. I guess the downpart if you keep using flags instead of queries the database will be have lots of FLAGS. but the advantage is you will get better performance and there would be no need to write complex SQL that a few people can write.
March 04, 2009 - 4:16 pm UTC
.. it seems you had very bad experiences with triggers that
got you to this point. ..
had? That would be past tense, this is an ongoing situation.
I did not say CLIENT code, I said "transactional api - the ONLY way to modify the data is via a transactional api that knows what it is doing, is well documented, easy to understand, straight-forward, and forgoes all MAGIC (triggers being of the black magic variety).
... but the advantage is you
will get better performance and there would be no need to write complex SQL
that a few people can write.
....
hah, and you want to write triggers? If you cannot master sql, you shouldn't be touching triggers at all.
I'm not a fan of your "flag" concept, no. I cannot really comment on your design, since - well - frankly - I don't understand or have your entire schema with me. You talk of a master video table - and I have no idea what you mean by that.
beware of maintaining this derived data, there are race conditions and multi-user situations you just haven't thought of - it is tricky stuff (and triggers would only make it harder to do correctly)
query
A reader, March 04, 2009 - 6:33 pm UTC
Tom:
I almost got this working, but i was not sure about why you used "RECDT" below.
this is not in the assign table. can be it a typo.
When i join "DATA" with "ASSIGN_DATA" it still can;t see RECDT because it is part of the join.
Also, I was using DATE_ASSIGNED but would not be faster to use the primary key "assign_no"
to find the max instead of to_char (dates) and then substring and checking id date_assigned is not null.
select vidno,
substr( max( case when status_code = 'T' and date_assigned is not null then
to_char(date_assigned,'yyyymmddhh24miss') || assigned_to end), 15 ) old_prev_reviewer,
max(date_assigned) max_date_assigned,
substr( max( case when date_assigned is not null then
to_char(date_assigned,'yyyymmddhh24miss') || assigned_to end), 15 ) last_assigned,
substr( max( case when status_code = 'A' and date_assigned is not null then
to_char(date_assigned,'yyyymmddhh24miss') || assigned_to end), 15 ) curr_reviewer,
to_date(substr( max( case when status_code = 'A' and date_assigned is not null then
to_char(date_assigned,'yyyymmddhh24miss') || to_char(recdt,'yyyymmddhh24miss') end), 15
),'yyyymmddhh24miss') curr_reviewer_recdt
from assign
where vidno in (select vidno from data)
group by vidno;
March 04, 2009 - 8:46 pm UTC
... I almost got this working, but i was not sure about why you used "RECDT" below.
this is not in the assign table. can be it a typo.
...
well, you know what, I had NO CLUE, NO IDEA what was in or not in the assign table. You never *shared it* with me - did you.
when you figure out the approach I was taking, you'll know exactly what to put in there. And if you cannot, please do not use this query.
query
A reader, March 04, 2009 - 10:30 pm UTC
sure i did, i put it in the first comment above. I did not want to copy it again.
you are telling me you figured all of thsi out without seeing the table too.
create table assign (
assign_no number(10), --PK
vidno number(10),
media varchar2(3),
assigned_to varchar2(10),
date_assigned date,
status_code varchar2(1),
created_Date date)
Anyway, I understood your approach and followed it and you are truly amazing.
The old query was timing at 1:30 (one min 30 seconds).
With your way it ran in 4 seconds - with exactly same result
you are simply the best and the only mentor i ever had.
thanks a million
i guess no more scalar subqueries or triggers- use SETs and joins like you had it
the new thing to me was how you did the SUBSTR/MAX on the dates and assigned userid for the assign table. I never saw that in any book or column. just wondering if using ASSIGN_NO would be more efficient. I think i would need an index on (VIDNO, DATE_ASSIGNED).
March 05, 2009 - 1:34 pm UTC
I look at one thing, you cannot expect me to page up and down and try to reassemble everything. I look at the current review, and that is about it.
scalar subqueries are good for certain things. If you are calling plsql from sql, ALWAYS use a scalar subquery.
Eg: do not:
select f(x)
from t
where g(y) = 42;
do:
select (select f(x) from dual)
from t
where (select g(y) from dual) = 42;
search for scalar subquery caching on this site to read why.
another case is for pagination queries where by we could remove a lot of work form the inner query - and just do a quick scalar subquery for the resulting (few) rows.
for example, say you have a small table "owners" (few rows, or easily retrieved in sorted order via an index) and you have a big table of "owner objects"
In my example - big_table_owners is my "owners" (copy of all_users)
big_table is my "owner objects" (hundreds of thousands of rows or more, copy all_objects over and over)
You want to report on owners and the number of tables they have, even if it is ZERO (outer join). You are paging or doing a top-n - sorting by username in "owners"
You could code:
select *
from (
select a.owner, count(b.owner)
from big_table.big_table_owners a left join big_table.big_table b
on (a.owner = b.owner and b.object_type = 'TABLE' )
group by a.owner
order by a.owner
)
where rownum <= 2
/
Or you could recognize that this is the same as:
select a.*,
(select count(*)
from big_table.big_table b
where b.owner = a.owner and b.object_type = 'TABLE' ) cnt
from (
select a.owner
from big_table.big_table_owners a
order by a.owner
) a
where rownum <= 2
/
the inner query goes very fast, gets a small number of rows and then does (an index range scan, you'll have indexed owner and object_type obviously) to get the count
... I never saw that in any book or column. ...There are thousands of techniques, if you know sql, if you think in sets, they just happen.
Look in Effective Oracle by Design, it has been written :) Chapter on Effective SQL - I demonstrate the exact 'technique' there.
Rownum vs where 1=2
DK, March 06, 2009 - 2:34 am UTC
Tom,
We have a process where we are referring a table T and pulling the records.
Due to some reasons we want the table not to fecth the records from this table,while it does some other processings.
There are 2 options.
1.Use Select * from T where rownum <1
2.Use Select * from T where 1=2.
Which one of the 2 options will give better performance and why?
Thanks,
Dheeraj
March 06, 2009 - 10:24 am UTC
I prefer 1=2, but they should do the same amount of work (stage is copy of all objects)
ops$tkyte%ORA11GR1> select * from stage where rownum < 1;
no rows selected
Execution Plan
----------------------------------------------------------
Plan hash value: 3766266605
------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time
------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 1 | 158 | 3 (34)| 00:00:
|* 1 | COUNT STOPKEY | | | | |
| 2 | TABLE ACCESS FULL| STAGE | 68392 | 10M| 3 (34)| 00:00:
------------------------------------------------------------------------
Predicate Information (identified by operation id):
---------------------------------------------------
1 - filter(ROWNUM<1)
Note
-----
- dynamic sampling used for this statement
Statistics
----------------------------------------------------------
0 recursive calls
0 db block gets
0 consistent gets
0 physical reads
0 redo size
1123 bytes sent via SQL*Net to client
409 bytes received via SQL*Net from client
1 SQL*Net roundtrips to/from client
0 sorts (memory)
0 sorts (disk)
0 rows processed
ops$tkyte%ORA11GR1> select * from stage where 1=2;
no rows selected
Execution Plan
----------------------------------------------------------
Plan hash value: 1343009456
------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time
------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 1 | 158 | 0 (0)|
|* 1 | FILTER | | | | |
| 2 | TABLE ACCESS FULL| STAGE | 68392 | 10M| 284 (1)| 00:00:
------------------------------------------------------------------------
Predicate Information (identified by operation id):
---------------------------------------------------
1 - filter(NULL IS NOT NULL)
Note
-----
- dynamic sampling used for this statement
Statistics
----------------------------------------------------------
0 recursive calls
0 db block gets
0 consistent gets
0 physical reads
0 redo size
1123 bytes sent via SQL*Net to client
409 bytes received via SQL*Net from client
1 SQL*Net roundtrips to/from client
0 sorts (memory)
0 sorts (disk)
0 rows processed
I like 1=2 because of the filter it puts there, it is so obvious "this will not happen" since "null is not null" is "not true"
query
A reader, March 07, 2009 - 10:45 am UTC
<<I'm not a fan of your "flag" concept, no. I cannot really comment on your design, since - well - frankly - I don't understand or have your entire schema with me. You talk of a master video table - and I have no idea what you mean by that. >>
Basically, you have a master video table. When a video arrives in, it is tested and the test result is stored in VIDEO_TEST. A record is also entered into QSTAGES table as stage "0", approved.
Now, it is ready for a human to review it.
I have a screen that requires to list every video that is ready for that review (any vide with last record is stage 0 ,approved) That is the SQL query i listed - which is basically sorting/ranking the records in QSTAGES table and then checking if the last record is stage 0 and approved. When the reviewer enters a new stage number the video dissapears from screen.
My idea is that you can also have an ASSIGN_READY_FLAG in VIDEO table so that everytime a test is done you check that flag. Then the SQL query would not scan/sort the BIG QSTAGES table but rather the VIDEO table which has one record per video. Then every time a reviewer enters a new stage (other than 0) i will reset that flag procedurally or via a trigger.
Would this make sense or you would still go with SQL? How do you usually decide on whether to create a FLAG (Y/N) versus writing somehow complex SQL to derive the result. I know you always like to write SQL. One disadvantage also is that ad-hoc users can only write very simple SQL so they can't get the derived result (unless i write a view for them). But then they come and start criticizing the db design as being very complex to deal with. How do you deal with those situations and explain to non-technical users that the design is correct and that is how they can get the result.
VIDEO
-------
vidno NUMBER(10) (PK)
other_columns_details (70 columns)
assign_ready_flag??
VIDEO_TEST
------------
vidno
test_date
test_no
other_test_details
QSTAGES
-----------
seq_no number(10),
vidno number(10) ,
media varchar2(3),
stage number(1),
recdt date,
compdt date,
status varchar2(1),
created_Date date
Cost Comparison
DK, March 09, 2009 - 10:08 am UTC
Tom,
You said that you prefer "where 1=2" over "rownum <1"
1.When I see the plan generated by you
Plan hash value: 1343009456(where 1=2)
The cost of Full table scan is 248
Plan hash value: 3766266605(where rownum <10
The cost of Full table scan is 0
2. I would expect the Cost of where 1=2 as 0 and Cost of where rownum < 1 to some value.
Please suggest.
Thanks,
Dheeraj
March 09, 2009 - 1:07 pm UTC
do you see the amount of work each did. forget the cost, you cannot compare the cost of two different queries really, cost is just a number.
they both did 0 IO's.
so, which one is more expensive? They did the *same exact thing*.
I like "1=2", it is "very obvious" what you are trying to do.
Pivot Query : Avoiding TABLE FULL ACCESS
Surajit chakraborty, March 10, 2009 - 3:40 am UTC
how can we avoid TABLE FULL ACCESS in case of a pivot query.
March 11, 2009 - 2:25 am UTC
do something that uses an index?
no example
no context
no nothing
probably, your full scan is not only warranted - but the best possible plan for you, but, you fail to give any example
drop "in case of a pivot query" from your question, there is nothing special about a pivot query that would cause a full scan - your query is causing the full scan (and that might not be BAD at all, it might be the BEST way to process your query)
Avoiding TABLE FULL ACCESS in case of a pivot query
Surajit Chakraborty, March 12, 2009 - 2:45 am UTC
Hi,
1) The following is the pivot query :
select
t3.ppv_policy_master_id policy_no,
max(decode(t3.ppv_policy_param_id,
(select t2.pp_policy_param_id from iims_config.t_policy_parameters t2 where t2.pp_parameter_name='agency-code'),
nvl(t3.ppv_policy_param_value,null),null)) agent_code_1,
max(decode(t3.ppv_policy_param_id,
(select t2.pp_policy_param_id from iims_config.t_policy_parameters t2 where t2.pp_parameter_name='instalment-premium'),
to_number(nvl(t3.ppv_policy_param_value,0)),0)) ins_prem
from iims_uwr.t_policy_parameter_values t3
group by t3.ppv_policy_master_id
having
max(decode(t3.ppv_policy_param_id,
(select t2.pp_policy_param_id from iims_config.t_policy_parameters t2 where t2.pp_parameter_name='dev-officer'),
nvl(t3.ppv_policy_param_value,null),null))= '0006993' and
max(decode(t3.ppv_policy_param_id,
(select t2.pp_policy_param_id from iims_config.t_policy_parameters t2 where t2.pp_parameter_name='date-of-commencement'),
nvl(t3.ppv_policy_param_value,null),null)) between '20090304' and '20090304' and
max(decode(t3.ppv_policy_param_id,
(select t2.pp_policy_param_id from iims_config.t_policy_parameters t2 where t2.pp_parameter_name='plan'),
to_number(nvl(t3.ppv_policy_param_value,0)),0))= 14 and
-- eliminate policies without agency code
max(decode(t3.ppv_policy_param_id,
(select t2.pp_policy_param_id from iims_config.t_policy_parameters t2 where t2.pp_parameter_name='agency-code'),
nvl(t3.ppv_policy_param_value,null),null)) is not null;
/
2) The following is the table structure :
-- Create table
create table T_POLICY_PARAMETER_VALUES
(
PPV_POLICY_PARAM_ID NUMBER(4) not null,
PPV_POLICY_MASTER_ID NUMBER(38) not null,
PPV_POLICY_PARAM_VALUE VARCHAR2(100)
)
tablespace TS_IIMS_UWR_DAT_01
pctfree 20
initrans 1
maxtrans 255
storage
(
initial 12544K
minextents 1
maxextents unlimited
);
-- Create/Recreate primary, unique and foreign key constraints
alter table T_POLICY_PARAMETER_VALUES
add constraint POLVALUES_PK primary key (PPV_POLICY_PARAM_ID,PPV_POLICY_MASTER_ID)
using index
tablespace TS_IIMS_UWR_DAT_01
pctfree 20
initrans 2
maxtrans 255
storage
(
initial 12544K
minextents 1
maxextents unlimited
);
alter table T_POLICY_PARAMETER_VALUES
add constraint PPV_FK1 foreign key (PPV_POLICY_MASTER_ID)
references T_POLICY_MASTER (POL_POLICY_MASTER_ID);
alter table T_POLICY_PARAMETER_VALUES
add constraint PPV_FK2 foreign key (PPV_POLICY_PARAM_ID)
references IIMS_CONFIG.T_POLICY_PARAMETERS (PP_POLICY_PARAM_ID);
-- Grant/Revoke object privileges
grant select, insert, update, delete, references, alter, index on T_POLICY_PARAMETER_VALUES to PUBLIC;
3) The following is the plan :
Execution Plan
----------------------------------------------------------
--------------------------------------------------------------------------------
------
| Id | Operation | Name | Rows | Bytes | Cost (
%CPU)|
--------------------------------------------------------------------------------
------
| 0 | SELECT STATEMENT | | 1 | 19 | 1084
(19)|
| 1 | TABLE ACCESS FULL | T_POLICY_PARAMETERS | 1 | 19 | 15
(0)|
| 2 | TABLE ACCESS FULL | T_POLICY_PARAMETERS | 1 | 19 | 15
(0)|
| 3 | FILTER | | | |
|
| 4 | SORT GROUP BY | | 1 | 19 | 1084
(19)|
| 5 | TABLE ACCESS FULL| T_POLICY_PARAMETER_VALUES | 1039K| 18M| 922
(5)|
| 6 | TABLE ACCESS FULL | T_POLICY_PARAMETERS | 1 | 19 | 15
(0)|
| 7 | TABLE ACCESS FULL | T_POLICY_PARAMETERS | 1 | 19 | 15
(0)|
| 8 | TABLE ACCESS FULL | T_POLICY_PARAMETERS | 1 | 19 | 15
(0)|
| 9 | TABLE ACCESS FULL | T_POLICY_PARAMETERS | 1 | 19 | 15
(0)|
--------------------------------------------------------------------------------
------
Note
-----
- 'PLAN_TABLE' is old version
Statistics
----------------------------------------------------------
5 recursive calls
3 db block gets
4162 consistent gets
583 physical reads
0 redo size
551 bytes sent via SQL*Net to client
385 bytes received via SQL*Net from client
2 SQL*Net roundtrips to/from client
0 sorts (memory)
1 sorts (disk)
1 rows processed
I did even create an index on the column: PPV_POLICY_PARAM_VALUE of the table : table T_POLICY_PARAMETER_VALUES , but still couldnot avoid TABLE FULL ACCESS.
Thanks
Surajit
March 12, 2009 - 12:47 pm UTC
from iims_uwr.t_policy_parameter_values t3
group by t3.ppv_policy_master_id
having
tell me how you would see that avoiding a full scan - given you want EVERY row from it? Forget the pivot, how would that avoid a full scan?
...I did even create an index on the column: PPV_POLICY_PARAM_VALUE of
the table : table T_POLICY_PARAMETER_VALUES ....
so, you do not use that column in a where clause anywhere? so what about the index?
pivot query
ravi, April 27, 2009 - 9:22 am UTC
i have data in table like this
id parent_id
1 2
2 3
3 4
4 5
5 6
6 7
i need a query out put as below.
in where condition if i pass id=6
i have to get parent_id column as
7
6
5
4
3
2
please help me
April 27, 2009 - 2:23 pm UTC
no create table
no inserts
no sql from me.
But - before you just do that (add create and inserts) be sure to explain your output in a manner that someone other than you can actually determine what is happening.
If you pass in id=6, I can see you getting one row - parent_id=7
The rest of the output, no clue as to where/how/why it is there.
not sure but may be..
Hashmi, April 28, 2009 - 3:44 am UTC
If you want the parent_id corresponding to id then the query is as simple as
select parent_id from <yourtable> where id=5;
But most likely this is not your requirement.As per the output provided,may be this you want:
select distinct b.parent_id from(select parent_id,id from tbl
where parent_id<=(select max(parent_id)from tbl where id=5)
)b
order by b.parent_id desc
/
April 28, 2009 - 10:06 am UTC
it is best to not guess, you and I would just be wasting our time.
Unless and until there is a specification and a test case to work with, the person asking the question hasn't done their due diligence.
pivot using clob getting ora-932
Matt, June 18, 2009 - 6:06 pm UTC
Hi Tom
I have data in a clob that I want to show after pivoting
Connected to:
Oracle Database 10g Enterprise Edition Release 10.2.0.3.0 - 64bit Production
With the Partitioning, OLAP and Data Mining options
create table interaction
(id number);
create table message
(id number,
interaction_id number,
is_request number);
create table data
(message_id number,
data clob);
insert into interaction values (1);
insert into interaction values (2);
insert into message values (1,1,1);
insert into message values (2,1,0);
insert into message values (3,2,1);
insert into message values (4,2,0);
insert into data values (1,'this is request 1');
insert into data values (2,'this is reply 1');
insert into data values (3,'this is request 2');
insert into data values (2,'this is reply 2');
select i.id,
max(decode(m.is_request,1,d.data,null)) request_data,
max(decode(m.is_request,0,d.data,null)) reply_data
from interaction i, message m, data d
where m.interaction_id = i.id and d.message_id = m.id
group by i.id;
max(decode(m.is_request,0,d.data,null)) reply_data
*
ERROR at line 3:
ORA-00932: inconsistent datatypes: expected - got CLOB
Should be:
ID request_data reply_data
----------------------------------------
1 this is request 1 this is reply 1
2 this is request 2 this is reply 2
Thanks in advance
June 19, 2009 - 3:35 pm UTC
you cannot do that to a clob, it will not work with aggregates, not possible.
you can use dbms_lob.substr to get the first 4000 bytes if you want, if that suffices - otherwise you will not be pivoting this data.
Partial conditional Pivot
Sanjay Jha, June 19, 2009 - 3:42 am UTC
I have a requirement like this:
Table has each row having 3 separate boolean type columns which need to be picked up while extraction and broken into separate rows, only if it is 'Y'. If all three are 'N', then one record needs to be generated. Any thoughts? I came out with this:
select distinct id_sess,featr_type_code from
(select id_sess,(case when featr_type.rowno=1 then DECODE(C_PORTOVERAGE_DISCOUNTABLE,'Y',3,0)
when featr_type.rowno=2 then DECODE(C_MINIMUM_DISCOUNTABLE,'Y',2,0)
when featr_type.rowno=3 then DECODE(C_NOSHOW_DISCOUNTABLE,'Y',1,0) end) featr_type_code
from temp,(
select rownum rowno
from dual
connect by level <= 3
) featr_type)
June 19, 2009 - 3:52 pm UTC
no create table
no inserts
no lookie
and this doesn't sound like a pivot. more like an un-pivot (turn columns into rows)
sounds like:
with data
as
(select level l from dual where level <= 3)
select *
from t, data
where (t.bool1 = 'N' and t.bool2 = 'N' and t.bool3 = 'N' and data.l = 1)
OR (t.bool1 <> 'N' or t.bool2 <> 'N' or t.bool3 <> 'N')
/
to get 1 or 3 rows from each row
Reader, July 08, 2009 - 5:24 pm UTC
create table tst
(subj varchar2(100),student varchar2(100), grade number);
insert into tst values('MATH', 'A',1);
insert into tst values('MATH', 'B',2);
insert into tst values('MATH', 'C',3);
insert into tst values('MATH', 'D',4);
insert into tst values('ENG', 'A',1);
insert into tst values('ENG', 'B',2);
insert into tst values('ENG', 'C',3);
insert into tst values('ENG', 'D',4);
commit;
select * from tst
SUBJ STU GRADE
----- --- ----------
MATH A 1
MATH B 2
MATH C 3
MATH D 4
ENG A 1
ENG B 2
ENG C 3
ENG D 4
select subj,
max(decode(student,'A',grade,null)) as student_a,
max(decode(student,'B',grade,null)) as student_b,
max(decode(student,'C',grade,null)) as student_c,
max(decode(student,'D',grade,null)) as student_d
from tst
group by subj
I used the max-decode to get the the results as
SUBJ STUDENT_A STUDENT_B STUDENT_C STUDENT_D
----- ---------- ---------- ---------- ----------
MATH 1 2 3 4
ENG 1 2 3 4
I am trying to understand the logic used in the pivot.
Question 1)Please tell why we need max in to get this
Question 2)If there are 1000's of students in the table, I have to use 1000's of max-decode. Is there anyway to generalize this?
July 08, 2009 - 7:36 pm UTC
1) you could use min, you could use sum. you could use any aggregate that makes sense.
look at what you have without the group by/aggregate:
ops$tkyte%ORA10GR2> l
1 select subj,
2 (decode(student,'A',grade,null)) as student_a,
3 (decode(student,'B',grade,null)) as student_b,
4 (decode(student,'C',grade,null)) as student_c,
5 (decode(student,'D',grade,null)) as student_d
6* from tst
ops$tkyte%ORA10GR2> /
SUBJ STUDENT_A STUDENT_B STUDENT_C STUDENT_D
---- ---------- ---------- ---------- ----------
MATH 1
MATH 2
MATH 3
MATH 4
ENG 1
ENG 2
ENG 3
ENG 4
8 rows selected.
since student is unique inside of a given subject, you can see what looks like a sparse matrix, we want to squish out the "null" cells. For student_a in subj math - only ONE row will have a value, same with student_b and so on.
So, if you group by subj - you get one row per subject and if you select the max(decode()), you get that single value for student a, b, c, d.
2) ... Is there anyway to generalize this? ...
no, a sql statement has a know number of columns - known at PARSE TIME.
Reader, July 09, 2009 - 12:06 pm UTC
Tom,
Are you mentioning that in Oracle SQL query, there will be a maximum number of columns and after that we cannot have any more columns?
July 14, 2009 - 3:08 pm UTC
there is a very very very reasonable limit of 1000 columns in a table or view.
a query however, can have many more than that
But that is not even close to what I said (I said nothing regarding any limit on the number of columns)
what I said was "AT PARSE TIME, SQL demands to know how many columns you are interested in, it is not possible to run a query that returns N columns an then to run the same query and get N+M columns later (where M is any integer other than zero)
Great job Tom
AC, October 08, 2009 - 7:28 am UTC
Hi Tom,
I have a typical requirement.
My table looks like
FBILL_NO PCODE AMT
------------------------- ---------- ----------
09-10/00000042 46 67
09-10/00000042 17 6715
09-10/00000043 46 39
09-10/00000043 38 15742.77
09-10/00000043 17 3896
Now the rquirement is to show the data as
FBILL_NO 46 17 38
------------------------- ---------- ---------- ----------
09-10/00000042 67 6715 0
09-10/00000043 39 3896 15742.77
Here the number of records in PCODE column per FBILL_NO is dynamic.
Can you please help.
Regards,AC
Performance
Sudeep, April 26, 2010 - 4:19 am UTC
Hi Tom,
First of all, Kudos to you for doing such a great service to the Oracle Community!
I needed to pivot all parents of a given child in columns. I searched through and WOW lots of info on pivoting.
One think I am still worried though, how about performance? In my case the tables contain more than a million records and with all the aggregate functions, group by etc, will it be the most efficient one..
I ran it against my table and it is talking more than 40mins.......
Adding..
m_nasef, May 06, 2010 - 1:24 am UTC
* the first example( job_deptno_pivot ) :-
the difference with totals ...===================================================================
SQL> with pvt_emp as
(select job,
max( decode( deptno, 10, cnt, null ) ) dept_10,
max( decode( deptno, 20, cnt, null ) ) dept_20,
max( decode( deptno, 30, cnt, null ) ) dept_30,
max( decode( deptno, 40, cnt, null ) ) dept_40,
cnt total
from ( select job, deptno, count(*) cnt
from emp
group by job, deptno )
group by job,cnt)
select job,dept_10,dept_20,dept_30,dept_40,total from pvt_emp
union all
select 'Total',
sum(nvl(dept_10,0)),sum(nvl(dept_20,0)),
sum(nvl(dept_30,0)),sum(nvl(dept_40,0)),
sum(nvl(total,0))
from pvt_emp
JOB DEPT_10 DEPT_20 DEPT_30 DEPT_40 TOTAL
--------- ---------- ---------- ---------- ---------- ----------
CLERK 1 1 1
CLERK 2 2
SALESMAN 4 4
ANALYST 2 2
MANAGER 1 1 1 1
PRESIDENT 1 1
Total 3 5 6 0 11
7 rows selected.
* the other example (converting the columns to rows) :-
the difference with using user_tab_columns in the inline view
(select rownum r from user_tab_columns where table_name = 'DEPT') ... ===================================================================
SQL> select decode( r, 1, to_char(deptno), 2, dname, 3, loc )
from dept, (select rownum r from user_tab_columns where table_name = 'DEPT')
where deptno = 10
DECODE(R,1,TO_CHAR(DEPTNO),2,DNAME,3,LOC
----------------------------------------
10
ACCOUNTING
NEW YORK
Regards,
m_nasef, May 06, 2010 - 4:08 am UTC
* selecting range of columns numbers (5 to 10) from a table
SQL> select 'select '||max(decode(column_id,5,column_name))||','||max(decode(column_id,6,column_name))||','||
max(decode(column_id,7,column_name))||','||max(decode(column_id,8,column_name))||','||
max(decode(column_id,9,column_name))||','||max(decode(column_id,10,column_name))||' from EMPLOYEES;' as query
from (select *
from user_tab_columns
where table_name = 'EMPLOYEES'
and column_id between 5 and 10)
QUERY
----------------------------------------------------------------------------------------------
select PHONE_NUMBER,HIRE_DATE,JOB_ID,SALARY,COMMISSION_PCT,MANAGER_ID from EMPLOYEES;
m_nasef, May 12, 2010 - 7:52 pm UTC
converting the last row to the first row and so on ...
SQL> select * from emp
/
EMPNO ENAME JOB MGR HIREDATE SAL COMM DEPTNO
---------- ---------- --------- ---------- --------- ---------- ---------- ----------
7369 SMITH CLERK 7902 17-DEC-80 800 20
7499 ALLEN SALESMAN 7698 20-FEB-81 1600 300 30
7521 WARD SALESMAN 7698 22-FEB-81 1250 500 30
7566 JONES MANAGER 7839 02-APR-81 2975 20
7654 MARTIN SALESMAN 7698 28-SEP-81 1250 1400 30
7698 BLAKE MANAGER 7839 01-MAY-81 2850 30
7782 CLARK MANAGER 7839 09-JUN-81 2450 10
7788 SCOTT ANALYST 7566 09-DEC-82 3000 20
7839 KING PRESIDENT 17-NOV-81 5000 10
7844 TURNER SALESMAN 7698 08-SEP-81 1500 0 30
7876 ADAMS CLERK 7788 12-JAN-83 1100 20
EMPNO ENAME JOB MGR HIREDATE SAL COMM DEPTNO
---------- ---------- --------- ---------- --------- ---------- ---------- ----------
7900 JAMES CLERK 7698 03-DEC-81 950 30
7902 FORD ANALYST 7566 03-DEC-81 3000 20
7934 MILLER CLERK 7782 23-JAN-82 1300 10
14 rows selected.
then,
SQL> select *
from (select *
from emp
order by rowid desc)
EMPNO ENAME JOB MGR HIREDATE SAL COMM DEPTNO
---------- ---------- --------- ---------- --------- ---------- ---------- ----------
7934 MILLER CLERK 7782 23-JAN-82 1300 10
7902 FORD ANALYST 7566 03-DEC-81 3000 20
7900 JAMES CLERK 7698 03-DEC-81 950 30
7876 ADAMS CLERK 7788 12-JAN-83 1100 20
7844 TURNER SALESMAN 7698 08-SEP-81 1500 0 30
7839 KING PRESIDENT 17-NOV-81 5000 10
7788 SCOTT ANALYST 7566 09-DEC-82 3000 20
7782 CLARK MANAGER 7839 09-JUN-81 2450 10
7698 BLAKE MANAGER 7839 01-MAY-81 2850 30
7654 MARTIN SALESMAN 7698 28-SEP-81 1250 1400 30
7566 JONES MANAGER 7839 02-APR-81 2975 20
EMPNO ENAME JOB MGR HIREDATE SAL COMM DEPTNO
---------- ---------- --------- ---------- --------- ---------- ---------- ----------
7521 WARD SALESMAN 7698 22-FEB-81 1250 500 30
7499 ALLEN SALESMAN 7698 20-FEB-81 1600 300 30
7369 SMITH CLERK 7902 17-DEC-80 800 20
look at ename column ..... (SMITH) replaced by (MILLER)
and (MILLER) replaced by (SMITH)
....
A reader, May 15, 2010 - 4:34 am UTC
what a great site, it's *really* most helpful..
A reader, May 16, 2010 - 1:47 am UTC
I used Ex. job_dept_pivot in hr schema, and the query will be ...
SQL> set pages 80
SQL> set lines 80
SQL> column d10,d20,d30,d40,d50,d60,d70,d80,d90,d100,d110 format a4
SQL> with pvt_emp as
(select job_id,
max( decode( department_id, 10, cnt, null ) ) d10,
max( decode( department_id, 20, cnt, null ) ) d20,
max( decode( department_id, 30, cnt, null ) ) d30,
max( decode( department_id, 40, cnt, null ) ) d40,
max( decode( department_id, 50, cnt, null ) ) d50,
max( decode( department_id, 60, cnt, null ) ) d60,
max( decode( department_id, 70, cnt, null ) ) d70,
max( decode( department_id, 80, cnt, null ) ) d80,
max( decode( department_id, 90, cnt, null ) ) d90,
max( decode( department_id, 100, cnt, null ) ) d100,
max( decode( department_id, 110, cnt, null ) ) d110,
cnt total
from ( select job_id, department_id, count(*) cnt
from employees
group by job_id, department_id )
group by job_id,cnt)
select job_id,d10,d20,d30,d40,d50,d60,d70,d80,d90,d100,d110, total
from pvt_emp
union all
select 'Total',
sum(nvl(d10,0)),sum(nvl(d20,0)),sum(nvl(d30,0)),sum(nvl(d40,0)),
sum(nvl(d50,0)),sum(nvl(d60,0)),sum(nvl(d70,0)),sum(nvl(d80,0)),
sum(nvl(d90,0)),sum(nvl(d100,0)),sum(nvl(d110,0)),sum(nvl(total,0))
from pvt_emp
JOB_ID D10 D20 D30 D40 D50 D60 D70 D80 D90 D100 D110 TOTAL
---------- ---------- ---------- ---------- ---------- ---------- ---------- ---------- ---------- ---------- ---------- ---------- ----------
AD_VP 2 2
SA_MAN 5 5
AC_ACCOUNT 1 1
HR_REP 1 1
SA_REP 1
SA_REP 29 29
MK_MAN 1 1
IT_PROG 5 5
SH_CLERK 20 20
ST_CLERK 20 20
FI_ACCOUNT 5 5
AC_MGR 1 1
AD_ASST 1 1
FI_MGR 1 1
PR_REP 1 1
PU_MAN 1 1
ST_MAN 5 5
AD_PRES 1 1
PU_CLERK 5 5
MK_REP 1 1
Total 1 2 6 1 45 5 1 34 3 6 2 107
but i want to format the query in better form such as
* The columns (d10,d20,d30,d40,d50,d60,d70,d80,d90,d100,d110) displayed in only 4 characters width ..
i typed (
SQL> column d10,d20,d30,d40,d50,d60,d70,d80,d90,d100,d110 format a4
but it doesn't effect..
* second, when I spool the query file , the spooled file is fulled with padding spaces and it doesn't displayed with the same form in SQLPLUS....
May 24, 2010 - 7:23 am UTC
column d10 format a4
column d20 format a4
...
etc
SQL> set trimspool on
will trim lines in the spool file.
A reader, May 17, 2010 - 1:35 am UTC
what do you say,Tom?
May 24, 2010 - 7:31 am UTC
I say - Good Morning to you!
Sorry, I do not monitor the site 24x7, I travel 100% of the time every other week - not always possible to update.
(however, the documentation on sqlplus never ever sleeps!!!
http://www.oracle.com/pls/db112/homepage all of these things are fully documented too - you don't have to be told sometimes, you can find out yourself...)
pivot without max-decode
A reader, June 02, 2010 - 11:15 pm UTC
in an interview, iwas asked to pivot a table without max - decode /case . and acoording to interviewer, it was fairly easy.
so, I have to know how to do it. ora version <=10g
any suggestions!
June 08, 2010 - 11:30 am UTC
Well, you could join over and over. But that would be dumb. You'd have to full outer join as well (since any one of deptno = 10, 20, 30, 40 might be missing).
you could distinct the "down the page values" and then just outer join to the across the page stuff - but that would be not smart as well.
You could use scalar subqueries, but that would be dumb. You'd end up doing many orders of magnitude more work in the database than necessary.
I mean, there are lots of dumb ways to do this.
ops$tkyte%ORA10GR2> select job,
2 max( decode( deptno, 10, cnt, null ) ) dept_10,
3 max( decode( deptno, 20, cnt, null ) ) dept_20,
4 max( decode( deptno, 30, cnt, null ) ) dept_30,
5 max( decode( deptno, 40, cnt, null ) ) dept_40
6 from ( select job, deptno, count(*) cnt
7 from scott.emp
8 group by job, deptno )
9 group by job
10 order by job
11 /
JOB DEPT_10 DEPT_20 DEPT_30 DEPT_40
--------- ---------- ---------- ---------- ----------
ANALYST 2
CLERK 1 2 1
MANAGER 1 1 1
PRESIDENT 1
SALESMAN 4
ops$tkyte%ORA10GR2>
ops$tkyte%ORA10GR2>
ops$tkyte%ORA10GR2> select job,
2 (select count(*) from scott.emp where deptno = 10 and job = x.job) dept_10,
3 (select count(*) from scott.emp where deptno = 20 and job = x.job) dept_20,
4 (select count(*) from scott.emp where deptno = 30 and job = x.job) dept_30,
5 (select count(*) from scott.emp where deptno = 40 and job = x.job) dept_40
6 from (select distinct job from scott.emp) x
7 order by job
8 /
JOB DEPT_10 DEPT_20 DEPT_30 DEPT_40
--------- ---------- ---------- ---------- ----------
ANALYST 0 2 0 0
CLERK 1 2 1 0
MANAGER 1 1 1 0
PRESIDENT 1 0 0 0
SALESMAN 0 0 4 0
ops$tkyte%ORA10GR2>
ops$tkyte%ORA10GR2> select x.job, a.cnt, b.cnt, c.cnt, d.cnt
2 from (select distinct job from scott.emp) X,
3 (select job, count(*) cnt from scott.emp where deptno = 10 group by job) a ,
4 (select job, count(*) cnt from scott.emp where deptno = 20 group by job) b ,
5 (select job, count(*) cnt from scott.emp where deptno = 30 group by job) c,
6 (select job, count(*) cnt from scott.emp where deptno = 40 group by job) d
7 where x.job = a.job(+)
8 and x.job = b.job(+)
9 and x.job = c.job(+)
10 and x.job = d.job(+)
11 order by x.job
12 /
JOB CNT CNT CNT CNT
--------- ---------- ---------- ---------- ----------
ANALYST 2
CLERK 1 2 1
MANAGER 1 1 1
PRESIDENT 1
SALESMAN 4
ops$tkyte%ORA10GR2>
ops$tkyte%ORA10GR2> select job, sum(cnt10), sum(cnt20), sum(cnt30), sum(cnt40)
2 from (select job, 1 cnt10, 0 cnt20, 0 cnt30, 0 cnt40 from scott.emp where deptno = 10 union all
3 select job, 0 cnt10, 1 cnt20, 0 cnt30, 0 cnt40 from scott.emp where deptno = 20 union all
4 select job, 0 cnt10, 0 cnt20, 1 cnt30, 0 cnt40 from scott.emp where deptno = 30 union all
5 select job, 0 cnt10, 0 cnt20, 0 cnt30, 1 cnt40 from scott.emp where deptno = 40)
6 group by job
7 order by job
8 /
JOB SUM(CNT10) SUM(CNT20) SUM(CNT30) SUM(CNT40)
--------- ---------- ---------- ---------- ----------
ANALYST 0 2 0 0
CLERK 1 2 1 0
MANAGER 1 1 1 0
PRESIDENT 1 0 0 0
SALESMAN 0 0 4 0
ops$tkyte%ORA10GR2> select job, sum(a), sum(b), sum(c), sum(d)
2 from scott.emp a,
3 (select 10 deptno, 1 a, 0 b, 0 c, 0 d from dual union all
4 select 20 deptno, 0 a, 1 b, 0 c, 0 d from dual union all
5 select 30 deptno, 0 a, 0 b, 1 c, 0 d from dual union all
6 select 40 deptno, 0 a, 0 b, 0 c, 1 d from dual) b
7 where a.deptno = b.deptno
8 group by job
9 order by job
10 /
JOB SUM(A) SUM(B) SUM(C) SUM(D)
--------- ---------- ---------- ---------- ----------
ANALYST 0 2 0 0
CLERK 1 2 1 0
MANAGER 1 1 1 0
PRESIDENT 1 0 0 0
SALESMAN 0 0 4 0
ops$tkyte%ORA10GR2>
Pivot Query
Vitthal Pandey, June 17, 2010 - 7:13 am UTC
I'm working on oracle 10g rel 10.0.2.4.0 with HPUX as O/S. I need to produce the result in a pivot query, I cannot use PIVOT option as I'm using 10g release 2.
Because the domain/columns(colname in my calc_repo table) values are not fixed, I cannot go for an PIVOT using DECODE like stuff.
I've written a procedure to get these rows, but I need to use a SQL, I tried using MODEL clause but didn't succeded .
TABLE DATA
ID COLNAME COLVALUE MODDATE
------------------------------------------------
100256 DEPARTMENT NIH 1/1/2004
100256 DIVISION 15 1/1/2004
100256 LOCATION 1/1/2004
100256 MANAGER_TYPE 1/1/2004
100256 USER_DEF_12 1/1/2004
100256 USER_DEF_13 45216936 1/1/2004
100256 USER_DEF_14 15427844 1/1/2004
100256 USER_DEF_14 16289456 18/1/2010
100256 USER_DEF_15 45219687 1/1/2004
100256 USER_DEF_15 16295468 18/1/2010
100256 USER_DEF_16 1/1/2004
100256 USER_DEF_16 45215525 18/1/2010
100256 USER_DEF_19 3 1/1/2004
100256 USER_DEF_19 4 18/1/2010
100256 USER_DEF_24 0 1/1/2004
100256 USER_DEF_25 1 1/1/2004
100256 USER_DEF_27 1/1/2004
100256 USER_DEF_28 1/1/2004
100256 USER_DEF_48 1/1/2004
100256 USER_DEF_51 1/1/2004
100256 USER_DEF_53 0 1/1/2004
100256 USER_DEF_55 1/1/2004
100256 STATUS Calc Value 1/1/2004
100256 PP_ID 1/1/2004
DESIRED OUTPUT
----------------------
I Changed the column headings in the desired output just for the better understanding...like U_D_13 Belongs to User_Def_13. I also removed some of the columns from the output only to maintain the readibility and for better understanding.
ModDate Dept Div Loc U_D_13 U_D_14 U_D_15
1/1/2004 NIH 15 45216936 15427844 45219687
18/1/2010 NIH 15 45216936 16289456 16295468
SCRIPT
------------------------------
Create Table Calc_Repo
(
id number,
colname varchar2(40),
colvalue varchar2(50),
moddate date
);
Insert Into Calc_Repo( Id, Colname, ColValue, Moddate) Values (100256,'DEPARTMENT','NIH','1/1/2004');
Insert Into Calc_Repo( Id, Colname, ColValue, Moddate) Values (100256,'DIVISION','15','1/1/2004');
Insert Into Calc_Repo( Id, Colname, ColValue, Moddate) Values (100256,'LOCATION',NULL,'1/1/2004');
Insert Into Calc_Repo( Id, Colname, ColValue, Moddate) Values (100256,'MANAGER_TYPE',NULL,'1/1/2004');
Insert Into Calc_Repo( Id, Colname, ColValue, Moddate) Values (100256,'USER_DEF_12',NULL,'1/1/2004');
Insert Into Calc_Repo( Id, Colname, ColValue, Moddate) Values (100256,'USER_DEF_13','45216936','1/1/2004');
Insert Into Calc_Repo( Id, Colname, ColValue, Moddate) Values (100256,'USER_DEF_14','15427844','1/1/2004');
Insert Into Calc_Repo( Id, Colname, ColValue, Moddate) Values (100256,'USER_DEF_14','16289456','18/1/2010');
Insert Into Calc_Repo( Id, Colname, ColValue, Moddate) Values (100256,'USER_DEF_15','45219687','1/1/2004');
Insert Into Calc_Repo( Id, Colname, ColValue, Moddate) Values (100256,'USER_DEF_15','16295468','18/1/2010');
Insert Into Calc_Repo( Id, Colname, ColValue, Moddate) Values (100256,'USER_DEF_16',NULL,'1/1/2004');
Insert Into Calc_Repo( Id, Colname, ColValue, Moddate) Values (100256,'USER_DEF_16','45215525','18/1/2010');
Insert Into Calc_Repo( Id, Colname, ColValue, Moddate) Values (100256,'USER_DEF_19','3','1/1/2004');
Insert Into Calc_Repo( Id, Colname, ColValue, Moddate) Values (100256,'USER_DEF_19','4','18/01/2010');
Insert Into Calc_Repo( Id, Colname, ColValue, Moddate) Values (100256,'USER_DEF_24','0','1/1/2004');
Insert Into Calc_Repo( Id, Colname, ColValue, Moddate) Values (100256,'USER_DEF_25','1','1/1/2004');
Insert Into Calc_Repo( Id, Colname, ColValue, Moddate) Values (100256,'USER_DEF_27',NULL,'1/1/2004');
Insert Into Calc_Repo( Id, Colname, ColValue, Moddate) Values (100256,'USER_DEF_28',NULL,'1/1/2004');
Insert Into Calc_Repo( Id, Colname, ColValue, Moddate) Values (100256,'USER_DEF_48',NULL,'1/1/2004');
Insert Into Calc_Repo( Id, Colname, ColValue, Moddate) Values (100256,'USER_DEF_51',NULL,'1/1/2004');
Insert Into Calc_Repo( Id, Colname, ColValue, Moddate) Values (100256,'USER_DEF_53','0','1/1/2004');
Insert Into Calc_Repo( Id, Colname, ColValue, Moddate) Values (100256,'USER_DEF_55',NULL,'1/1/2004');
Insert Into Calc_Repo( Id, Colname, ColValue, Moddate) Values (100256,'STATUS','Calc Value','1/1/2004');
Insert Into Calc_Repo( Id, Colname, ColValue, Moddate) Values (100256,'PP_ID',NULL,'1/1/2004');
Can you help me in getting this? Thanks in Advance.
June 22, 2010 - 12:32 pm UTC
... Because the domain/columns(colname in my calc_repo table) values are not fixed,
I cannot go for an PIVOT using DECODE like stuff.
...
yes you can and even with PIVOT in 11g, you'd have the same issue to overcome.
when you parse a query, you need to know the number and datatypes of all columns.
the general approach will be:
a) run a query to get the number, names, and types of columns
b) use output of a to build a query that pivots those values (in 10g using decode/max, in 11g using PIVOT)
c) then execute that query.
Converting relational to vector form
MK, July 02, 2010 - 3:58 pm UTC
Hi,
I was wondering if I could get some help in a conversion that I have to do. I have been given relational data of the form
id, subx_seqid, submit_timestamp, seqid, edge_id_dir, xxx_sec, xxx_tuples
10403,20848, 61,43447,870,61.0,"<43447,870,61.0>"
10403,20848,61,43448,-1,0.0,"<43448,-1,0.0>"
10486,25266,61,52666,10084,2.3,"<52666,10084,2.3>"
10486,25266,61,52667,10083,1.1,"<52667,10083,1.1>"
10486,25266,61,52668,68,1.4,"<52668,68,1.4>"
10486,25266,61,52669,89,2.2,"<52669,89,2.2>"
10486,25266,61,52670,90,0.5,"<52670,90,0.5>"
10486,25266,61,52671,105,1.5,"<52671,105,1.5>"
10486,25266,61,52672,112,1.9,"<52672,112,1.9>"
10486,25266,61,52673,113,6.1,"<52673,113,6.1>"
10486,25266,61,52674,121,4.1,"<52674,121,4.1>"
10486,25266,61,52675,122,2.7,"<52675,122,2.7>"
10486,25266,61,52676,123,3.5,"<52676,123,3.5>"
10486,25266,61,52677,131,5.3,"<52677,131,5.3>"
10486,25266,61,52678,187,9.3,"<52678,187,9.3>"
10486,25266,61,52679,10219,1.9,"<52679,10219,1.9>"
10486,25266,61,52680,245,17.1,"<52680,245,17.1>"
10486,25266,61,52681,-1,0.0,"<52681,-1,0.0>"
10503,26181,61,54530,488,3.6,"<54530,488,3.6>"
10503,26181,61,54531,475,6.3,"<54531,475,6.3>"
10503,26181,61,54532,458,4.0,"<54532,458,4.0>"
10503,26181,61,54533,467,8.1,"<54533,467,8.1>"
10503,26181,61,54534,468,3.9,"<54534,468,3.9>"
10503,26181,61,54535,460,22.2,"<54535,460,22.2>"
10503,26181,61,54536,442,3.1,"<54536,442,3.1>"
10503,26181,61,54537,443,9.7,"<54537,443,9.7>"
which I then have to pivot "partially" such that its in increasing order of seqid (4th column)
to give a vector form like the following but ordered by seqid.
10486,25266,61,"<52677,131,5.3><52674,121,4.1><52670,90,0.5><52675,122,2.7><52676,123,3.5><52673,113,6.1><52672,112,1.9><52669,89,2.2><52671,105,1.5><52668,68,1.4><52679,10219,1.9><52678,187,9.3><52667,10083,1.1><52681,-1,0.0><52666,10084,2.3><52680,245,17.1>"
10801,42567,61,"<560865,-1,0.0>"
I am sure its some sort of analytics function to do this transformation, but haven't gotten around figuring it out yet. Also is it possible to load such CSV data into Oracle XE with data pump or sqlldr? Is this supported?
Thanks,
MK
July 06, 2010 - 2:42 pm UTC
no creates, no inserts, I don't even look.
I've no idea if there is an answer for you - only that I'm not going to turn your raw data into something I can execute.
Cross tab report in access to Oracle
Srinath, July 15, 2010 - 4:24 pm UTC
Hi Tom,
I have a Cross tab report in Ms Access. We are trying to import those reports in to Oracle.
Is there a way to create a cross tab report using sql or pl/sql in oracle. I have done lot of reasearch but couldn't find a solution.
Appreciate your time and consideration.
July 19, 2010 - 12:59 pm UTC
not ever having used MS access personally, how about you explain what you mean by "cross tab report".
Is it different from what I call a pivot query above, if so, how?
will Pivot work in Oracle 9i ans 10g?
Boopathy, October 05, 2010 - 6:06 am UTC
your Pivot query examples are very easily understandable.
But I couldnt work it on Oracle 9i and 10G.
October 05, 2010 - 12:23 pm UTC
the examples on this page were executed in releases from 8.1.6 till now. So, you'll need to be a tad more specific about what you are having a problem with.
All of my queries have the version right next to them in the sql prompt.
Boopathy, October 05, 2010 - 1:43 pm UTC
SQL> SELECT DEPTNO,CLERK,SALESMAN,MANAGER,ANALYST,PRESIDENT
2 FROM (SELECT DEPTNO,JOB,SAL FROM EMP)
3 PIVOT ( SUM(SAL) FOR JOB IN
4 ('CLERK' as clerk,
5 'SALESMAN' as salesman,
6 'MANAGER' as manager,
7 'ANALYST' as analyst,
8 'PRESIDENT' as president))
9 ORDER BY DEPTNO;
PIVOT ( SUM(SAL) FOR JOB IN
*
ERROR at line 3:
ORA-00933: SQL command not properly ended
I had run the above script in Oracle 8i,9i and 10g. All the 3 versions its raising same error.
It was taken from Oracle Magazine (JULY/AUGUST2010) given by you.
Kindly help.
October 06, 2010 - 4:40 am UTC
which was an article on.......
A brand new 11g feature
quote from the article:
http://www.oracle.com/technetwork/issue-archive/2010/o40asktom-094550.html <quote>
Pivot Query Examples
Please show an example of a pivot queryto turn rows into columns. Please also illustrate a pivot query using varrays or nested tables.
I’ll show you a couple of techniques -
an Oracle Database 11g Release 1 and above ANSI implementation and a technique that works in Oracle Database 10g Release 2 using DECODE (or CASE)and how to use the COLLECT aggregate built-in function in Oracle Database 10g and above to return a collection of data.
First,
here’s the latest technique using the new PIVOT clause. (Note that the converse UNPIVOTturns columns into rows.) In Listing 1, I use the SCOTT.EMP table with the goal of turning the DEPTNO data, which usually goes down the page in rows, into columns.
</quote>
If you critically read the article, it should be apparent that PIVOT is new, it is 11g and the decode/case approach is what works in 10g and before . Especially since it contains verbiage such as:
Another way to pivot columns into rows that works in releases preceding Oracle Database 11g would be to use DECODE (or CASE) and an aggregation to pivot.and one wonders why you would come to a page - entirely unrelated and unconnected to an ARTICLE in a print magazine - and think that someone one would put the two together???
Ian, October 05, 2010 - 4:53 pm UTC
I think you'll find that PIVOT is new in 11g.
Collections
Bala, October 06, 2010 - 3:05 pm UTC
Dear Tom,
Could u plz tell about collections and its 3 types with simple examples. I unable to find clear definitions with ex from websites. What are the features available in collections.
Tks in Advance
October 07, 2010 - 2:07 am UTC
"U" isn't available, "U" is dead as far as I know. Look it up, it is true.
http://en.wikipedia.org/wiki/U_of_Goryeo PLZ - what do German Postal codes have to do with anything?
tks?
ex?
I am unable to understand what you are trying to say - maybe your keyboard is malfunctioning?
(have you read the documentation? the PL/SQL guide does go into some detail regarding
o plsql index by tables
o nested table collections
o varray's
which is what I assume you mean by "collections and its 3 types")
In short - a varray is a non-sparse array (contiguous elements - no gaps) with a fixed maximum number of elements. It has a limit to how many elements it may contain. It is always indexed by a number (integer). You have to allocate manually (using extend or by assignment of one varray to another)
A nested table type collection is a non-sparse array with no fixed maximum number of elements. It is always indexed by a number (integer). You have to allocate manually (using extend or by assignment of one nested table to another)
A plsql index by table type is a SPARSE array (you don't need to have elements 1,2,3,4,5,6,.... you could have 100,1000003,2213432 if you wanted) that can index these table types by numbers, or strings - whatever you want. You do not allocate these arrays, they automagically allocate storage themselves.
they are all just "arrays", like in other programming languages
here are some of the basics:
ops$tkyte%ORA11GR2> declare
2 type va is varray(20) of number; -- VA = varray type
3 type nt is table of date; -- NT = nested table type
4 type ib is table of number index by varchar2(30); -- IB = Index By table type
5
6 subscript_error exception;
7 pragma exception_init( subscript_error, -6533 );
8 out_of_bounds exception;
9 pragma exception_init( out_of_bounds, -6532 );
10 a_va va;
11 a_nt nt;
12 a_ib ib;
13
14 l_idx varchar2(30);
15 begin
16 a_va := va(); -- construct the array - no slots are allocated - but now you can allocate them
17 a_va.extend(4); -- allocate four slots in the array, maximum 20 allowed
18 a_va(1) := 42;
19 a_va(2) := 42;
20 a_va(3) := 42;
21 a_va(4) := 42;
22 begin
23 a_va(5) := 42;
24 exception
25 when subscript_error
26 then
27 dbms_output.put_line( 'array out of bounds!' );
28 end;
29 a_va.extend(16); -- add 16 more slots - now 1..20 exist
30 a_va(20) := 42;
31 begin
32 a_va.extend(1);
33 exception
34 when out_of_bounds
35 then
36 dbms_output.put_line( 'cannot go that far' );
37 end;
38
39 a_nt := nt();
40 a_nt.extend(4);
41 -- .... do stuff like a_va did, only it will not fail when you allocate 21 of them ....
42
43 -- no allocation, no limits, sparse arrays....
44 a_ib( 'hello' ) := 42;
45 a_ib( 'world' ) := 55;
46
47 l_idx := a_ib.first;
48 while (l_idx is not null)
49 loop
50 dbms_output.put_line( 'a_ib(' || l_idx || ') = ' || a_ib(l_idx) );
51 l_idx := a_ib.next(l_idx);
52 end loop;
53
54 end;
55 /
array out of bounds!
cannot go that far
a_ib(hello) = 42
a_ib(world) = 55
PL/SQL procedure successfully completed.
again, plsql guide has examples - and documentation too!
Nik, October 10, 2010 - 7:50 pm UTC
Hi Tom,
I have table A as follows:
ID ID_TYPE ID_NUMBER
1 A 123
1 B 234
2 A 456
2 B 567
3 A 111
.
.
(>1000 rows)
I want the output to appear as
ID ID_TYPE ID_NUMBER ID_TYPE1 ID_NUMBER1
1 A 123 B 234
2 A 456 B 567
3 A 111 null null
....
...
the code that I am using now is as follows:
select ID,
max(decode(rownum, 1, ID_TYP, null))ID_TYP,
max(decode(rownum, 1, ID_NUMBER, null))ID_NUMBER
max(decode(rownum, 2, ID_TYP, null))ID_TYPE1,
max(decode(rownum, 2, ID_NUMBER, null))ID_NUMBER1
from (select id, id_type, id_number, row_number() over (partition by id order by id_type, id_number)
from A)
group by id;
However the result tht I am getting is as follows:
ID ID_TYPE ID_NUMBER ID_TYPE1 ID_NUMBER1
1 A 123 B 234
2
3
The values for the first row are only being populated. Can you tell me how to rectify this issue.
Thanks
October 11, 2010 - 12:10 pm UTC
no creates
no inserts
no look
well, I peeked. decoding on rownum???
tell us what you are trying to do, not how you are trying to do it. I cannot reverse engineer the logic of this query. You use row_number in one place, but never actually reference it. You use rownum in the decode. I think you mean to use an alias to the row_number() analytic - but you are not.
You are only decoding the first two rows - which in your example look like they happened to be for ID=1
Bulk Collect and Constraints
Satheesh, October 18, 2010 - 1:59 am UTC
How to disable all constarints in a table ?
Could you tell me how to use the bulk collect ?
if i use the limit 10 ,it will get the first 10 records it is fine.
In the second time i need to take the 11 to 20 records. How ?
October 25, 2010 - 8:46 am UTC
1) via the ALTER TABLE command. You'll need to know their names of course.
2) the documentation does that quite well, have you considered looking at it? Tons (as in hundreds, if not thousands) of examples already exist on this site as well
3) just bulk collect 10 more???
BOLD in SQL
Sankar, October 27, 2010 - 5:48 am UTC
Is there any function or keyword availablity to change a letter style to BOLD?
If yes means how we can use in Oracle 9i and Oracle Reports 6i?
October 27, 2010 - 6:31 am UTC
define what it means to be BOLD.
In html, that would just be
select '<b>'||string||'</b>' from t;
In reports - you do have the ability to format and customize the output to the n'th degree. But, I've never actually used reports so I'd be the wrong one to ask (try the forums on otn.oracle.com). You would not be using SQL really - but reports formatting features.
BOLD in SQL
Sankar, October 28, 2010 - 8:42 am UTC
Hi Tom,
In Oracle I would like to change the string style from regular to Bold.
I used the below query in Oracle 9i which you have replied.
SQL> select '<b>'||'s'||'</b>' from dual;
'<B>'||'S'||'</B>'
------------------------
<b>s</b>
But the output will be <b>s</b>. Is the output mentioned the string s style is Bold?
Please clarify.
Thanks.
October 28, 2010 - 12:15 pm UTC
you do understand that "bold" is a concept a client application can have. You don't "bold a string", you mark up a string somehow in a fashion that a given client would like to have it marked up in so the client knows "print bold" when it prints it.
I used html, it would work if the client were a browser.
My point being - you'd have to question the client tool you are using, ask it "how do I do this", not the database.
In reports - you do have the ability to format and customize the output to the n'th degree. But, I've never actually used reports so I'd be the wrong one to ask (try the forums on otn.oracle.com). You would not be using SQL really - but reports formatting features
Solution For The Question (Pivot)
Padma, November 18, 2010 - 5:24 am UTC
ID ID_TYPE ID_NUMBER ID_TYPE1 ID_NUMBER1
1 A 123 B 234
2 A 456 B 567
-3 A 111 null null
Select ID,Case When [A] is not null then 'A' else null end ID_Type,[A] ID_Number,
Case When [B] is not null then 'B' else null end ID_Type1,[B] Id_number1 from
(Select Id,ID_type,Id_number From A) p
pivot
(sum(Id_number) for ID_type in ([A],[B]))as pvt
another option for the example table t
A reader, December 15, 2010 - 9:12 am UTC
analytic's would work also
create table t (month_and_year date,
customer varchar2(20),
product varchar2(30),
invoice number)
/
insert into t values (to_date('15-Jul-2009','DD-MON-YYYY'),'Central','Dog Chow','100');
insert into t values (to_date('01-Jul-2009','DD-MON-YYYY'),'West','Dog Chow','100');
insert into t values (to_date('02-Jul-2009','DD-MON-YYYY'),'East','Dog Chow','100');
insert into t values (to_date('01-Jul-2009','DD-MON-YYYY'),'North','Dog Chow','100');
insert into t values (to_date('01-Jul-2009','DD-MON-YYYY'),'Central','Cat Chow','50');
insert into t values (to_date('01-Jul-2009','DD-MON-YYYY'),'West','Cat Chow','50');
insert into t values (to_date('01-Jul-2009','DD-MON-YYYY'),'East','Cat Chow','50');
insert into t values (to_date('01-Jul-2009','DD-MON-YYYY'),'North','Cat Chow','50');
insert into t values (to_date('01-Aug-2009','DD-MON-YYYY'),'Central','Dog Chow','75');
insert into t values (to_date('01-Aug-2009','DD-MON-YYYY'),'West','Dog Chow','75');
insert into t values (to_date('03-Aug-2009','DD-MON-YYYY'),'East','Dog Chow','75');
insert into t values (to_date('01-Aug-2009','DD-MON-YYYY'),'North','Dog Chow','75');
insert into t values (to_date('01-Sep-2009','DD-MON-YYYY'),'Central','Cat Chow','25');
insert into t values (to_date('01-Sep-2009','DD-MON-YYYY'),'West','Cat Chow','25');
insert into t values (to_date('01-Sep-2009','DD-MON-YYYY'),'East','Cat Chow','25');
insert into t values (to_date('03-Sep-2009','DD-MON-YYYY'),'North','Cat Chow','25');
insert into t values (to_date('01-Jul-2010','DD-MON-YYYY'),'Central','Dog Chow','200');
insert into t values (to_date('01-Jul-2010','DD-MON-YYYY'),'West','Dog Chow','200');
insert into t values (to_date('01-Jul-2010','DD-MON-YYYY'),'East','Dog Chow','200');
insert into t values (to_date('04-Jul-2010','DD-MON-YYYY'),'North','Dog Chow','200');
insert into t values (to_date('03-Jul-2010','DD-MON-YYYY'),'North','Dog Chow','200');
insert into t values (to_date('01-Jul-2010','DD-MON-YYYY'),'Central','Cat Chow','150');
insert into t values (to_date('01-Jul-2010','DD-MON-YYYY'),'West','Cat Chow','150');
insert into t values (to_date('01-Jul-2010','DD-MON-YYYY'),'East','Cat Chow','150');
insert into t values (to_date('01-Jul-2010','DD-MON-YYYY'),'North','Cat Chow','150');
insert into t values (to_date('01-Jul-2010','DD-MON-YYYY'),'Central','Beggin Strips','60');
insert into t values (to_date('01-Jul-2010','DD-MON-YYYY'),'West','Beggin Strips','60');
insert into t values (to_date('01-Jul-2010','DD-MON-YYYY'),'East','Beggin Strips','60');
insert into t values (to_date('01-Jul-2010','DD-MON-YYYY'),'North','Beggin Strips','60');
with
v10 as
(
select sum(invoice) this_year_this_month
,customer,product,trunc(month_and_year,'MONTH') MY
from t
group by customer,product,trunc(month_and_year,'MONTH')
)
SELECT V10.this_year_this_month
,V10.customer
,V10.product
,to_char(V10.MY,'MON-yyyy')
,SUM(this_year_this_month)
OVER(PARTITION BY customer,product
ORDER BY my
RANGE BETWEEN
NUMTOYMINTERVAL(12,'MONTH') PRECEDING
AND
NUMTOYMINTERVAL(12,'MONTH') PRECEDING
) last_year_last_month
from v10
WHERE CUSTOMER = 'Central';
THIS_YEAR_THIS_MONTH CUSTOMER PRODUCT TO_CHAR(V10.MY,'M LAST_YEAR_LAST_MONTH
-------------------- -------------------- ------------------------------ ----------------- --------------------
60 Central Beggin Strips JUL-2010
50 Central Cat Chow JUL-2009
25 Central Cat Chow SEP-2009
150 Central Cat Chow JUL-2010 50
100 Central Dog Chow JUL-2009
75 Central Dog Chow AUG-2009
200 Central Dog Chow JUL-2010 100
7 rows selected.
another advantage of the analytic
A reader, December 15, 2010 - 9:22 am UTC
it only hits the table once.
SQL> explain plan for
2 with
v10 as
3 (
4 5 select sum(invoice) this_year_this_month
6 ,customer,product,trunc(month_and_year,'MONTH') MY
7 from t
8 group by customer,product,trunc(month_and_year,'MONTH')
9 )
10 SELECT V10.this_year_this_month
11 ,V10.customer
12 ,V10.product
13 ,to_char(V10.MY,'MON-yyyy')
14 ,SUM(this_year_this_month)
15 OVER(PARTITION BY customer,product
16 ORDER BY my
17 RANGE BETWEEN
18 NUMTOYMINTERVAL(12,'MONTH') PRECEDING
19 AND
20 NUMTOYMINTERVAL(12,'MONTH') PRECEDING
21 ) last_year_last_month
22 from v10
23 WHERE CUSTOMER = 'Central';
Explained.
SQL> select * from table(dbms_xplan.display);
PLAN_TABLE_OUTPUT
--------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
Plan hash value: 3568709221
----------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time |
----------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 7 | 357 | 4 (50)| 00:00:01 |
| 1 | WINDOW SORT | | 7 | 357 | 4 (50)| 00:00:01 |
| 2 | HASH GROUP BY | | 7 | 357 | 4 (50)| 00:00:01 |
|* 3 | TABLE ACCESS FULL| T | 7 | 357 | 2 (0)| 00:00:01 |
----------------------------------------------------------------------------
PLAN_TABLE_OUTPUT
--------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
Predicate Information (identified by operation id):
---------------------------------------------------
3 - filter("CUSTOMER"='Central')
Note
-----
- dynamic sampling used for this statement
19 rows selected.
SQL> explain plan for
2 select cy.month_and_year,
3 cy.customer,
4 cy.product,
5 cy.cy_invoices,
6 ly.ly_invoices
7 from (select month_and_year,
8 customer,
9 product,
10 SUM(invoice) over
11 (partition by month_and_year, customer, product
12 order by month_and_year) cy_invoices
13 from t) cy,
14 (select month_and_year,
15 customer,
16 product,
17 SUM(invoice) over
18 (partition by month_and_year, customer, product
19 order by month_and_year) ly_invoices
20 from t) ly
21 where trunc(cy.month_and_year,'MONTH') = add_months(trunc(sysdate,'MONTH'),-5)
22 and trunc(cy.month_and_year,'MONTH') = add_months(trunc(ly.month_and_year,'MONTH'),+12)
23 and (cy.customer = nvl(ly.customer,cy.customer) or ly.customer = nvl(cy.customer,ly.customer))
24 and (cy.product = nvl(ly.product,cy.product) or ly.product = nvl(cy.product,ly.product))
25 order by cy.cy_invoices desc;
Explained.
SQL> select * from table(dbms_xplan.display);
PLAN_TABLE_OUTPUT
--------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
Plan hash value: 2710987095
------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time |
------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 1 | 102 | 8 (50)| 00:00:01 |
| 1 | SORT ORDER BY | | 1 | 102 | 8 (50)| 00:00:01 |
|* 2 | HASH JOIN | | 1 | 102 | 7 (43)| 00:00:01 |
| 3 | VIEW | | 13 | 663 | 3 (34)| 00:00:01 |
| 4 | WINDOW SORT | | 13 | 663 | 3 (34)| 00:00:01 |
|* 5 | TABLE ACCESS FULL| T | 13 | 663 | 2 (0)| 00:00:01 |
PLAN_TABLE_OUTPUT
--------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
| 6 | VIEW | | 29 | 1479 | 3 (34)| 00:00:01 |
| 7 | WINDOW SORT | | 29 | 1479 | 3 (34)| 00:00:01 |
| 8 | TABLE ACCESS FULL| T | 29 | 1479 | 2 (0)| 00:00:01 |
------------------------------------------------------------------------------
Predicate Information (identified by operation id):
---------------------------------------------------
2 - access(TRUNC(INTERNAL_FUNCTION("CY"."MONTH_AND_YEAR"),'fmmonth')=
ADD_MONTHS(TRUNC(INTERNAL_FUNCTION("LY"."MONTH_AND_YEAR"),'fmmonth'),12)
)
PLAN_TABLE_OUTPUT
--------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
filter(("CY"."CUSTOMER"=NVL("LY"."CUSTOMER","CY"."CUSTOMER") OR
"LY"."CUSTOMER"=NVL("CY"."CUSTOMER","LY"."CUSTOMER")) AND
("CY"."PRODUCT"=NVL("LY"."PRODUCT","CY"."PRODUCT") OR
"LY"."PRODUCT"=NVL("CY"."PRODUCT","LY"."PRODUCT")))
5 - filter(TRUNC(INTERNAL_FUNCTION("MONTH_AND_YEAR"),'fmmonth')=ADD_M
ONTHS(TRUNC(SYSDATE@!,'fmmonth'),(-5)))
Note
-----
- dynamic sampling used for this statement
Help - Pivoting with rows into dynamic columns
Sat, February 11, 2011 - 11:01 am UTC
I have a table where summary survey results are stored in a table, basically number of people that gave a specific answer to each question on the survey. Each question have have the different number of answers.
The summary survey table stores
ID, Survey, Date, Question No, Answer, AnswerResponses
1 1 1/6/2010 , 1 Agree 10
2 1 1/6/2010 , 1 Neutral 5
3 1 1/6/2010 , 1 Disagre 7
4 1 1/6/2010 , 1 Really Disagree 4
5 1 1/6/2010 , 2 Positive 10
6 1 1/6/2010 , 2 Neutral 5
7 1 1/6/2010 , 2 Negative 7
8 1 2/6/2010 , 1 Agree 5
9 1 2/6/2010 , 1 Neutral 7
10 1 2/6/2010 , 1 Disagre 9
11 1 2/6/2010 , 1 Really Agree 2
12 1 2/6/2010 , 2 Positive 10
13 1 2/6/2010 , 2 Negative 7
I have a summary survey result table that store the survey, date, question, answer type and number of responsjavascript:apex.submit('SUBMIT_REVIEW')es
How can I return the data for each question in the format below, the Total Response being a calculated field.
Question No, Date, Agree, Neutral,Disagree,Really Disagree, Really Agree, Total Response
1, 1/6/2010 10, 5, 7, 4, 0, 26
1, 2/6/2010 5, 7, 9, 0, 2, 23
Question No, Date, Positive,Neutral,Negative, Total Response
2, 1/6/2010 10, 5, 7, 22
2, 2/6/2010 10, 7, 0, 17
How can I pivot the table to return the data in the above format, There may be in future a different number of columns for each question with different heading.
I expect I can't do this in one sql and expect I will need to make seperate sql calls for each question, I dont expect there to be more than say 7 possible answers for each question, but it does need to be generic with each answer type in a seperate column, is this possible? I can't hardcode decode statements as the users may create new answers. In reality the answers types are stored in a seperate table and only an ID is being stored in this table
-- Create table
create table SUMMARYSURVEY
(
ID NUMBER not null,
SURVEYID NUMBER not null,
SURVEYTAKEN DATE not null,
QUESTIONNO NUMBER not null,
ANSWER NVARCHAR2(30) not null,
ANSWERRESPONSE NUMBER not null
)
insert into summarysurvey (ID, SURVEYID, SURVEYTAKEN, QUESTIONNO, ANSWER, ANSWERRESPONSE)
values (1, 1, to_date('01-06-2010', 'dd-mm-yyyy'), 1, 'Agree', 10);
insert into summarysurvey (ID, SURVEYID, SURVEYTAKEN, QUESTIONNO, ANSWER, ANSWERRESPONSE)
values (2, 1, to_date('01-06-2010', 'dd-mm-yyyy'), 1, 'Neutral', 5);
insert into summarysurvey (ID, SURVEYID, SURVEYTAKEN, QUESTIONNO, ANSWER, ANSWERRESPONSE)
values (3, 1, to_date('01-06-2010', 'dd-mm-yyyy'), 1, 'Disagree', 7);
insert into summarysurvey (ID, SURVEYID, SURVEYTAKEN, QUESTIONNO, ANSWER, ANSWERRESPONSE)
values (4, 1, to_date('01-06-2010', 'dd-mm-yyyy'), 1, 'Really Disagree', 4);
insert into summarysurvey (ID, SURVEYID, SURVEYTAKEN, QUESTIONNO, ANSWER, ANSWERRESPONSE)
values (5, 1, to_date('01-06-2010', 'dd-mm-yyyy'), 2, 'Positive', 10);
insert into summarysurvey (ID, SURVEYID, SURVEYTAKEN, QUESTIONNO, ANSWER, ANSWERRESPONSE)
values (6, 1, to_date('01-06-2010', 'dd-mm-yyyy'), 2, 'Neutral', 5);
insert into summarysurvey (ID, SURVEYID, SURVEYTAKEN, QUESTIONNO, ANSWER, ANSWERRESPONSE)
values (7, 1, to_date('01-06-2010', 'dd-mm-yyyy'), 2, 'Negative', 7);
insert into summarysurvey (ID, SURVEYID, SURVEYTAKEN, QUESTIONNO, ANSWER, ANSWERRESPONSE)
values (8, 1, to_date('02-06-2010', 'dd-mm-yyyy'), 1, 'Agree', 5);
insert into summarysurvey (ID, SURVEYID, SURVEYTAKEN, QUESTIONNO, ANSWER, ANSWERRESPONSE)
values (9, 1, to_date('02-06-2010', 'dd-mm-yyyy'), 1, 'Neutral', 7);
insert into summarysurvey (ID, SURVEYID, SURVEYTAKEN, QUESTIONNO, ANSWER, ANSWERRESPONSE)
values (10, 1, to_date('02-06-2010', 'dd-mm-yyyy'), 1, 'Disagree', 9);
insert into summarysurvey (ID, SURVEYID, SURVEYTAKEN, QUESTIONNO, ANSWER, ANSWERRESPONSE)
values (11, 1, to_date('02-06-2010', 'dd-mm-yyyy'), 1, 'Really Agree', 2);
insert into summarysurvey (ID, SURVEYID, SURVEYTAKEN, QUESTIONNO, ANSWER, ANSWERRESPONSE)
values (12, 1, to_date('02-06-2010', 'dd-mm-yyyy'), 2, 'Positive', 10);
insert into summarysurvey (ID, SURVEYID, SURVEYTAKEN, QUESTIONNO, ANSWER, ANSWERRESPONSE)
values (13, 1, to_date('02-06-2010', 'dd-mm-yyyy'), 2, 'Negative', 7);
February 14, 2011 - 7:25 am UTC
you have to
a) run a query to figure out the number of and names of the columns to be pivoted
b) dynamically construct a second query that uses the information from (a)
search for the word dynamic on this page - this has been covered numerous times
ROWS to COLUMNS
srnayak, March 24, 2011 - 6:06 am UTC
Hi Tom,
I went through many solutions you posted , really useful.
However , I have a strange requirement :
The table has following records (this table has only one column with many records)
PARM_VALUES
-------
0
-1
111
1000
2
My output requirement is :
O1 O2 O3 O4 O5
--- --- --- -- ----
0 -1 111 1000 2
let me know how to achieve this , so simply speaking I want to know how to convert rows to columns where the number of rows is fixed (known).
Thanks
Nayak
March 24, 2011 - 8:33 am UTC
select max( decode( r, 1, c ) ) 01,
max( decode( r, 2, c ) ) 02,
....
from (select rownum r, c from parm_values );
fact of 'PUT'
Ms praj, September 29, 2011 - 4:05 am UTC
SQL> ed
Wrote file afiedt.buf
1 declare
2 n number:=1;
3 begin
4 loop
5 dbms_output.put(n||chr(9));
6 --dbms_output.put_line(n );
7 n:=n+1;
8 exit when n>10;
9 end loop;
10 dbms_output.put_line(n );
11* end;
SQL> /
1 2 3 4 5 6 7 8 9 10 11
September 29, 2011 - 7:11 am UTC
what 'fact' are you trying to convey? (other than you write code in a complex fashion that should be avoided?)
begin
for i in 1 .. 10
loop
dbms_output.put( i || chr(9) );
end loop;
dbms_output.put_line( 11 );
end;
/
Or, more generically:
ops$tkyte%ORA11GR2> declare
2 l_sep varchar2(1);
3 begin
4 for i in 1 .. 11
5 loop
6 dbms_output.put( l_sep || i );
7 if (i=1) then l_sep := chr(9); end if;
8 end loop;
9 dbms_output.new_line;
10 end;
11 /
1 2 3 4 5 6 7 8 9 10 11
PL/SQL procedure successfully completed.
is what that code should have been....
but I'm not really sure what you were trying to demonstrate. Not anything related to anything on this page as far as I can see.
plz help sir
Ganesh.G, October 01, 2011 - 3:12 am UTC
how to write this query without usng NULL and NOT keyword
select * from Student where Id is not null;
advace thanks
October 01, 2011 - 7:00 am UTC
why?
if it is homework - you should do it.
if it is not homework, they you are done - because you have already coded it correctly. Any other way would be obscure.
where id > 0 or id <= 0
would work - but it would be silly.
so would
where id = id;
but it would be as silly if not worse.
Fernando del Peru
Artieboy, October 24, 2011 - 11:55 am UTC
Hi Tom:
Would this be considered a hacked example?
select id, id+5 id2, id+10 id3
from
(
select 1 as id from dual union all
select 2 from dual union all
select 3 from dual union all
select 4 from dual union all
select 5 from dual union all
select 6 from dual union all
select 7 from dual union all
select 8 from dual union all
select 9 from dual union all
select 10 from dual union all
select 11 from dual union all
select 12 from dual union all
select 13 from dual union all
select 14 from dual union all
select 15 from dual
)
where id <=5
It was asked in this thread by Fernando from Peru. At least it works :)
Cheers
Need to convert rows into columns
Rahul, October 28, 2011 - 11:52 am UTC
I have a table
with columns range_zip_code zone
now the data in the table is as follows
range_zip_code , zone
000-004 ,1
5 , 2
006-009, 3
10, 4
so i have to convert this into
range_zip_code , zone
000, 1
002,1
003,1
004,1
005, 2
006,3
007,3
008,3
009,9
010, 4
October 28, 2011 - 12:08 pm UTC
no create
no inserts
no look
and your subject is entirely wrong. You are not converting rows into columns at all.
Rank number Using PLSQL
Kalesh, November 04, 2011 - 6:59 am UTC
Hi can any one help me to create Rank numbers using PlSQL.
declare
v_empno emp.empno%type;
v_sal emp.sal%type;
v_deptno emp.deptno%type;
v_rank_num number:=1;
begin
select empno, deptno,sal, rank() OVER (PARTITION BY deptno ORDER BY empno,deptno,sal desc) rank
loop
insert into emp_rank(empno,sal,deptno,rank_num) values (v_empno,v_sal,v_deptno,v_rank_num);
if
v_deptno=10 then
v_rank_num:=v_rank_num+1;
end if;
exit when v_deptno>10;
end loop;
dbms_output.put_line('empno is : '||v_empno);
dbms_output.put_line('sal is : '|| v_sal);
dbms_output.put_line ('deptno : '|| v_deptno);
dbms_output.put_line ('v_rank_num : '|| V_rank_num);
end;
this is what I was trying with.
And error what
i am getting is
ORA-01422: exact fetch returns more than requested number of rows
ORA-06512: at line 7
November 07, 2011 - 9:51 am UTC
how about you tell us what you are trying to do using words instead of code that doesn't make any sense at all?
I cannot even begin to imagine what you were attempting to accomplish with that code.
How to find remainings
A reader, December 09, 2011 - 9:47 am UTC
CREATE TABLE t (id numner, p number, b number);
INSERT INTO t VALUES (1, 10, 100);
INSERT INTO t VALUES (2, 30, null);
INSERT INTO t VALUES (3, 20, null);
...
I need to get the results as:
ID P B DIFF (B-P)
1 10 100 90
2 30 90 60
3 20 60 40
Tom, how to write a query to get this?
Thanks.
December 11, 2011 - 2:49 pm UTC
select 1 id, 10 p, 100 p, 90 diff from dual union all
select 2, 30, 90, 60 from dual union all
select 3, 20, 60, 40 from dual
order by 1;
would be one approach. Since you gave no specification, no logic, that answer suffices.
Why wouldn't you explain in the form of a simple specification what actually needs to be done????
What if some other row doesn't have NULL but some value - what does that do the output? What is that column "diff", is it the sum of all b's minus the running total of P. Is it the running total of b minus the running total of p?
Here is one answer to some question that you may or may not have - since we don't really know what your question was, what the output represented. This is the running total of b minus the running total of p
ops$tkyte%ORA11GR2> select id, p, b, sum(b) over ( order by id ) - sum(p) over (order by id) diff
2 from t;
ID P B DIFF
---------- ---------- ---------- ----------
1 10 100 90
2 30 60
3 20 40
Question
sheheryar irafn, December 20, 2011 - 12:50 am UTC
how to write table of 2 with cursor in MS SQL ?
December 20, 2011 - 8:02 am UTC
eh?
"how to write table of 2 with cursor" doesn't make any sense.
And why would you ask a question about "MS SQL" on oracle.com?
Generating data
A reader, February 29, 2012 - 6:01 pm UTC
A general question related to sparse data storage. Let's take the classic student/test use case.
Say I have a student table and a subject table. The many-to-many intersection table is the test table. If a student takes a test in 1 subject, the score is recorded in the test table. How can I make-up data such that the scores for *all* the subjects where show up as 0 if the student has not taken the test?
create table student(id,name);
create table subjects(id,name);
create table test_tab(student_id,subject_id,score);
insert into student values (1,'John');
insert into subjects values (1,'Math');
insert into subjects values (2,'Science');
insert into subjects values (3,'English');
insert into test_tab values (1,1,10);
March 01, 2012 - 7:38 am UTC
NO DATATYPES!!! your example doesn't work
Only one student?
Here is my example:
create table student(id number,name varchar(10));
create table subjects(id number,name varchar(10));
create table test_tab(student_id number,subject_id number,score number);
insert into student values (1,'John');
insert into student values (2,'Mary');
insert into subjects values (1,'Math');
insert into subjects values (2,'Science');
insert into subjects values (3,'English');
insert into test_tab values (1,1,10);
insert into test_tab values (2,2,20);
select s.student_name, s.subject_name, nvl( test_tab.score, 0 )
from (select student.id student_id, student.name student_name,
subjects.id subject_id, subjects.name subject_name
from student, subjects ) s, test_tab
where s.student_id = test_tab.subject_id(+)
and s.subject_id = test_tab.student_id(+)
order by 1, 2
/
Just cartesian join students to subjects to get a record per pair and then outer join to the test scores.
ops$tkyte%ORA11GR2> select s.student_name, s.subject_name, nvl( test_tab.score, 0 )
2 from (select student.id student_id, student.name student_name,
3 subjects.id subject_id, subjects.name subject_name
4 from student, subjects ) s, test_tab
5 where s.student_id = test_tab.subject_id(+)
6 and s.subject_id = test_tab.student_id(+)
7 order by 1, 2
8 /
STUDENT_NA SUBJECT_NA NVL(TEST_TAB.SCORE,0)
---------- ---------- ---------------------
John English 0
John Math 10
John Science 0
Mary English 0
Mary Math 0
Mary Science 20
6 rows selected.
how to show output (each row) with 2 sec delay
friend, March 03, 2012 - 4:21 am UTC
hi,
i have a doubt .
i have a table employee having datas (20 rows)
now i want my output when running .
select * from employee
each datas fetched (each rows)
should be displayed with 2 sec delay
how to get my desired result ?
thanks and regards,
friend
March 03, 2012 - 8:58 am UTC
depends on what programming language you are using. I would refer to the documentation for that.
if you are in sqlplus, not really going to happen - well, it could be "close" but it would show 1 record, wait 4 seconds, show 2, wait 4, show 2, .... and so on.
ops$tkyte%ORA11GR2> create or replace function foo( n in number ) return sys.odciVarchar2List
2 pipelined
3 as
4 begin
5 for i in 1 .. n
6 loop
7 pipe row( systimestamp );
8 dbms_lock.sleep(2);
9 end loop;
10 return;
11 end;
12 /
Function created.
ops$tkyte%ORA11GR2>
ops$tkyte%ORA11GR2> set arraysize 1
ops$tkyte%ORA11GR2> select * from table( foo(5) );
COLUMN_VALUE
-------------------------------------------------------------------------------
03-MAR-12 09.56.55.691629000 AM -05:00
03-MAR-12 09.56.57.713543000 AM -05:00
03-MAR-12 09.56.59.786759000 AM -05:00
03-MAR-12 09.57.01.834486000 AM -05:00
03-MAR-12 09.57.03.839566000 AM -05:00
formating pivot query.
Biswaranjan, April 26, 2012 - 12:23 am UTC
Hi Tom,
I was seeing one of your post on this page and tried to write
a query .
##################your post.
1 select decode( r, 1, to_char(deptno), 2, dname, 3, loc )
2 from dept, (select rownum r from all_objects where rownum <= 3 )
3* where deptno = 10
ops$tkyte@ORA817DEV.US.ORACLE.COM> /
DECODE(R,1,TO_CHAR(DEPTNO),2,DNAME,3,LOC
----------------------------------------
10
ACCOUNTING
NEW YORK
##########
for all the deptno I just tried to write by using case statement with your posted query as below.
select (case when deptno=10 then decode( r, 1, to_char(deptno), 2, dname, 3, loc ) end) dept10,
(case when deptno=20 then decode( r, 1, to_char(deptno), 2, dname, 3, loc ) end) dept20,
(case when deptno=30 then decode( r, 1, to_char(deptno), 2, dname, 3, loc ) end) dept30
from dept, (select rownum r from all_objects where rownum <= 3 )
;
I got the below result.
#########
10
20
30
ACCOUNTING
RESEARCH
SALES
NEW YORK
DALLAS
CHICAGO
############(ignoring null values without using break concept).
Is it possible to make the out put as
10 20 30
ACCOUNTING RESEARCH SALES
NEW YORK DALLAS CHICAGO
Regards,
Biswaranjan.
April 26, 2012 - 7:59 am UTC
ops$tkyte%ORA11GR2> with data
2 as
3 (select level r
4 from dual
5 connect by level <= 3
6 )
7 select r,
8 max(
9 case when deptno = 10 and r = 1
10 then to_char(deptno)
11 when deptno = 10 and r = 2
12 then dname
13 when deptno = 10 and r = 3
14 then loc
15 end ) d10,
16 max(
17 case when deptno = 20 and r = 1
18 then to_char(deptno)
19 when deptno = 20 and r = 2
20 then dname
21 when deptno = 20 and r = 3
22 then loc
23 end ) d20,
24 max(
25 case when deptno = 30 and r = 1
26 then to_char(deptno)
27 when deptno = 30 and r = 2
28 then dname
29 when deptno = 30 and r = 3
30 then loc
31 end ) d30
32 from dept, data
33 group by r
34 order by r
35 /
R D10 D20 D30
---------- ---------- ---------- ----------
1 10 20 30
2 ACCOUNTING RESEARCH SALES
3 NEW YORK DALLAS CHICAGO
continuation to "formating pivot query"
Biswaranjan, April 26, 2012 - 8:57 am UTC
Hi Tom,
Many many thanks for your quick reply :).
Yah the query you wrote using with clause is working fine.
By seeing your query I rewrote my own query (little modification) which worked too.
But when I see the autotrace and v$mystat values for v$statname found no difference.
I rewrote my query like as below.
############
select max(case when deptno=10 then decode( r, 1, to_char(deptno), 2, dname, 3, loc ) end) dept10,
max(case when deptno=20 then decode( r, 1, to_char(deptno), 2, dname, 3, loc ) end) dept20,
max(case when deptno=30 then decode( r, 1, to_char(deptno), 2, dname, 3, loc ) end) dept30
from dept, (select LEVEL r from DUAL CONNECT BY LEVEL <= 3 ) group by r ORDER BY R
;
###########
Can you please tell my rewrote about the query will perform poor or as the query with "with" clause(I am learning performance tuning :)).
thanks,
Biswaranjan.
April 26, 2012 - 9:42 am UTC
they are basically the same - if you look at their plans, they are probably close to identical.
Thanks.
Biswaranjan, April 26, 2012 - 10:47 am UTC
A reader, June 05, 2012 - 10:37 am UTC
I would like to create a pivot table for 4 statement auditing.
select *
from
(select user_name,AUDIT_OPTION
from dba_stmt_audit_opts)
pivot
(count(AUDIT_OPTION)
for AUDIT_OPTION in ('DELETE TABLE', 'EXECUTE PROCEDURE', 'INSERT TABLE', 'UPDATE TABLE'));
It returns 1 for each column for each user. so does it mean that the auditing is enabled for that specific user.
jitesh, August 31, 2012 - 4:28 am UTC
can able to execute the querry
SELECT *
FROM (
SELECT root_cause,severity
FROM i_defect_mgmt_extract
WHERE version_id = 1
ORDER BY root_cause
)
Pivot
(
Count(Severity)
For severity IN (select value from Configuration where code = 'ALL_SEVERITY')
)
;
Query for transposing rows to columns
Vai, October 04, 2012 - 11:20 pm UTC
CREATE TABLE CFL (q_id Number(18),per_id number(18),PERIOD VARCHAR2(15 CHAR), AMOUNT NUMBER);
INSERT INTO CFL VALUES (11, 1, 'JAN-10', 10);
INSERT INTO CFL VALUES (21, 1, 'FEB-10', 20);
INSERT INTO CFL VALUES (31, 1, 'MAR-10', 10);
and so on (12 records for a year with same quota_id, e.g. here it is 1)
INSERT INTO CFL VALUES (121, 1, 'DEC-10', 10);
INSERT INTO CFL VALUES (12, 2, 'JAN-10', 10);
INSERT INTO CFL VALUES (22, 2, 'FEB-10', 20);
INSERT INTO CFL VALUES (32, 2, 'MAR-10', 10);
and so on (12 records for a year with same per_id, e.g. here it is 1)
INSERT INTO CFL VALUES (42, 2, 'DEC-10', 10);
COMMIT;
Also this column values period is dynamic.. it can be for any year.
The select will return values like
Select per_id, PERIOD, amount from cfl
where quota_id = 1
Basically 12 rows will be the output:
per_id period amount
1 JAN-10 10
1 FEB-10 20
1 MAR-10 10
..............and so on
1 DEC-10 10
The result output should be:
Per_id JAN-10 FEB-10 MAR-10.............DEC-10
1 10 20 10................10
October 09, 2012 - 12:07 pm UTC
Rows into columns
Pedro, November 23, 2012 - 11:06 am UTC
Hi Tom,
In advanced i appreciate any help you can give me. Also, i apologize for my inglish, i'm portuguese.
I have this table
Login Acc_ID Acc_Type
user1 acc_id_A A
user1 acc_id_B B
user2 acc_id_C A
user2 acc_id_D A
user3 acc_id_E B
The result i want to get is the follow:
login Acc_ID_1 Acc_Type_1 Acc_ID_2 Acc_Type_2
user1 acc_id_A A acc_id_B B
user2 acc_id_C A acc_id_D A
user3 acc_id_E B Null Null
Is this possible? I know the max number or columns that i will need.
Once again, thanks!
November 29, 2012 - 7:21 am UTC
no create tables
no inserts
no promise that this will be syntactically correct, but the gist is:
select login,
max( decode( rn, 1, acc_id ) ), max(decode( rn, 1, acc_type ) ),
max( decode( rn, 1, acc_id ) ), max(decode( rn, 1, acc_type ) ),
...
max( decode( rn, N, acc_id ) ), max(decode( rn, N, acc_type ) )
from (
select login, acc_id, acc_type, row_number() over (partition by login order by acc_id) rn
from t
)
group by login
order by login
A reader, June 25, 2013 - 1:32 pm UTC
Which of the following queries are legal?
SELECT deptno, count(deptno) FROM emp GROUP BY ename;
SELECT deptno, count(deptno), job FROM emp GROUP BY deptno;
SELECT deptno, avg(sal) FROM emp;
SELECT deptno, avg(sal) FROM emp GROUP BY deptno;
July 01, 2013 - 6:41 pm UTC
what is this? a quiz?
test them. and then study them to understand why three of them fail due to improper grouping and the one succeeds.
SQL
Amy, July 12, 2013 - 8:10 pm UTC
Tom,
If I want to report the user or role's privilege on the objects, the user or role has update,insert,delete, select
privs on the table, how can I only get 1 line to each table
for all these 4 privileges. Let us say, I use the SQL as below:
SELECT 'Grantee: '||p.grantee||' --> '|| p.owner||'.'||p.table_name ||' -- '||decode(p.privilege,'UPDATE','U','INSERT','I','DELETE','D',
'EXECUTE','E','SELECT','S')
FROM dba_tab_privs p, dba_roles r
WHERE p.GRANTEE = r.role
AND P.GRANTEE = 'STBYS_APP_ROLE'
and p.table_name in (select object_name from dba_objects where object_type IN ('TABLE', 'SEQUENCE', 'PACKAGE', 'PROCEDURE','FUNCTION') )
ORDER BY p.owner, p.table_name
/
I will get the results something like
......
Grantee: STBYS_APP_ROLE --> DSS.TRANSACTIONS_DSS -- I
Grantee: STBYS_APP_ROLE --> DSS.TRANSACTIONS_DSS -- S
Grantee: STBYS_APP_ROLE --> DSS.TRANSACTIONS_DSS -- D
Grantee: STBYS_APP_ROLE --> DSS.TRANSACTIONS_DSS -- U
......
How Can I get the result like
Grantee: STBYS_APP_ROLE --> DSS.TRANSACTIONS_DSS -- I,S,D,U
Thanks for your help
July 16, 2013 - 4:14 pm UTC
did you read the original answer??????
pretend that deptno=10 is I, deptno=20 is S and so on
and there you go.....
take your existing query that returns:
grantee, object_name, privilege
then
select grantee, object_name,
max(decode( privilege, 'I', 'I ' ) ||
max(decode( privilege, 'S', 'S ' ) ||
... the other two privs here ....
from (YOUR_QUERY)
group by grantee, object_name
order by ...
just like the original example above (eg: read, understand and then apply the technique. you'll find this technique applicable thousands of times)
also in 11g you could use the PIVOT builtin syntax (fully documented in the docs...)
a little doubt
john, August 01, 2013 - 5:57 pm UTC
hi tom, could you help me with this?, the first thing I did was make a simple query like this:
select job from emp;
JOB
---------
ANALYST
CLERK
CLERK
CLERK
MANAGER
MANAGER
MANAGER
PRESIDENT
SALESMAN
how could i get this result as columns if the values that can be taken for job are not static ?:
ANALYST CLERK MANAGER
--------- --------- --------- ...... etc
I hope I explained. Thank you
August 02, 2013 - 7:24 pm UTC
pivot query
Kim, September 29, 2014 - 9:42 pm UTC
Sample data
PROJ_NBR employee_nbr co_flag base_date
011777 cb7936 n 11-JUL-03
011777 kb2651 n 02-MAR-05
011777 kb2651 n 05-AUG-05
011777 nc1297 y 01-JAN-01
011777 sr1892 n 25-FEB-04
I want the result to be like this
PROJ_NBR y-date y-emp n-date n-emp
011777 01-JAN-01 nc1297 05-AUG-05 kb2651
Thank you
pivot query
Kim, September 30, 2014 - 4:51 am UTC
tried the following
with nqry as
(
select
a.prj_nbr,
max( decode ( a.co_flag, 'Y', a.baselined_date, null) ) y_date,
max( decode ( a.co_flag, 'N', a.baselined_date, null) ) n_date
from
sqry a
group by a.prj_nbr
)
select t.prj_nbr,
t.y-date,
decode( t.y_date, u.baselined_date, u.employee_number,1) as original_suits,
t.n-date ,
decode( t.n_date, u.baselined_date, u.employee_number,1) as suits
from nqry t, sqry u
where t.prj_nbr = u.prj_nbr and
(t.baseline_date = u.baselined_date or
t.original_baseline_date = u.baselined_date);
where sqry is the original table. All simplifications for more complex
I get data looking like
011777 01-JAN-01 1 05-AUG-05 kb2651
011777 01-JAN-01 nc1297 05-AUG-05 1
pivot query
Kim, September 30, 2014 - 3:06 pm UTC
Easier data - to play with
with tab as ( select '011777' prj_nbr, 'cb7936' employee_nbr, 'N' co_flag, '11-JUL-03' base_date from dual union all
select '011777' prj_nbr, 'kb2651' employee_nbr, 'N' co_flag, '02-MAR-05' base_date from dual union all
select '011777' prj_nbr, 'kb2651' employee_nbr, 'N' co_flag, '05-AUG-05' base_date from dual union all
select '011777' prj_nbr, 'nc1297' employee_nbr, 'Y' co_flag, '01-JAN-01' base_date from dual union all
select '011777' prj_nbr, 'sr1892' employee_nbr, 'N' co_flag, '25-FEB-04' base_date from dual )
select prj_nbr, max( decode(co_flag, 'Y', base_date )) y_date, max ( decode(co_flag, 'N', base_date)) n_date, row_number
from tab
group by prj_nbr
pivot query
Kim, September 30, 2014 - 6:14 pm UTC
with tab as ( select '011777' prj_nbr, 'cb7936' employee_nbr, 'N' co_flag, '11-JUL-03' base_date from dual union all
select '011777' prj_nbr, 'kb2651' employee_nbr, 'N' co_flag, '02-MAR-05' base_date from dual union all
select '011777' prj_nbr, 'kb2651' employee_nbr, 'N' co_flag, '05-AUG-05' base_date from dual union all
select '011777' prj_nbr, 'nc1297' employee_nbr, 'Y' co_flag, '01-JAN-01' base_date from dual union all
select '011777' prj_nbr, ' sr1892 ' employee_nbr, 'N' co_flag, '25-FEB-04' base_date from dual union all
select '011313' prj_nbr, 'hb1613' employee_nbr, 'Y' co_Flag, '01-JAN-02' base_date from dual union all
select '011313' prj_nbr, 'kb2651' employee_nbr, 'N' co_Flag, '14-JAN-06' base_date from dual union all
select '011313' prj_nbr, 'kb2651' employee_nbr, 'N' co_Flag, '14-JUN-06' base_date from dual
)
select prj_nbr, max( decode(co_flag, 'Y', base_date )) y_date, max ( decode(co_flag, 'N', base_date)) n_date
from tab
group by prj_nbr
more sample data. It looks like analytics - feature should do it - have to select the userid corresponding to the max y-date and max n-date and not really the max of the userids itself. I tried joining back to the tab table - that gives two rows per project number. I must be missing something - reading up more on analytics.
I would appreciate any help. Thank you.
pivot query
Kim, September 30, 2014 - 7:25 pm UTC
I did not need analytics to do in one way. I just needed to use nulls on the y-side when selecting the n-side and nulls on n-side when doing the y-side and union the results and then do a max on all columns with group by on prj_nbr. Had to have one aggregation and then the union, and then the max. Made it into two more query-factored-queries in addition to the data.
There might be a better way. I would be curious to see if analytics could be used.
pivot query
Kim, October 01, 2014 - 3:58 am UTC
This is the way - one way - to do it. There might be other ways. If you have another one, please post.
<code>
with tab as ( select '011777' prj_nbr, 'cb7936' employee_nbr, 'N' co_flag, '11-JUL-03' base_date from dual union all
select '011777' prj_nbr, 'kb2651' employee_nbr, 'N' co_flag, '02-MAR-05' base_date from dual union all
select '011777' prj_nbr, 'kb2651' employee_nbr, 'N' co_flag, '05-AUG-05' base_date from dual union all
select '011777' prj_nbr, 'nc1297' employee_nbr, 'Y' co_flag, '01-JAN-01' base_date from dual union all
select '011777' prj_nbr, 'sr1892' employee_nbr, 'N' co_flag, '25-FEB-04' base_date from dual union all
select '011313' prj_nbr, 'hb1613' employee_nbr, 'Y' co_Flag, '01-JAN-02' base_date from dual union all
select '011313' prj_nbr, 'kb2651' employee_nbr, 'N' co_Flag, '14-JAN-06' base_date from dual union all
select '011313' prj_nbr, 'kb2651' employee_nbr, 'N' co_Flag, '14-JUN-06' base_date from dual
),
date_agg as (
select prj_nbr, co_flag,
max( decode(co_flag, 'Y', base_date ) ) y_date,
max( decode(co_flag, 'N', base_date ) ) n_date
from tab
group by prj_nbr,co_flag) ,
test as (
select tab.prj_nbr, da.y_date, tab.employee_nbr as yenbr, null as n_date, null as nenbr
from date_agg da, tab
where da.prj_nbr = tab.prj_nbr
and tab.co_flag = da.co_flag
and ( tab.base_date = da.y_date )
union
select tab.prj_nbr, null as y_date, null as yenbr, da.n_date , tab.employee_nbr as nenbr
from date_agg da, tab
where da.prj_nbr = tab.prj_nbr
and tab.co_flag = da.co_flag
and ( tab.base_date = da.n_date )
)
select prj_nbr, max(y_date), max(yenbr), max(n_date), max(nenbr)
from test
group by prj_nbr
</code>