Skip to Main Content
  • Questions
  • Creating a view using dynamic pivot table

Breadcrumb

Question and Answer

Connor McDonald

Thanks for the question, Naushad.

Asked: August 01, 2016 - 9:00 pm UTC

Last updated: August 02, 2016 - 2:57 pm UTC

Version: 11.2.0.4

Viewed 1000+ times

You Asked

Hi Tom

I apologize if this has been posted before. I am trying to build a web page that will provide information from AWR tables and I would like to compare two months data in a chart.

select *
from
(
select to_char(end_time,'dd') Day
,to_char(end_time,'hh24') hr
,to_char(end_time,'MM/YYYY') mmyyyy
,round(maxval,2) act_s
from DBA_HIST_SYSMETRIC_SUMMARY
WHERE metric_id IN (2121) AND maxval > 0
order by 1,2
)
PIVOT ( avg(act_s) active_executions for mmyyyy in ( '06/2016' Jun, '07/2016' July ))
order by 1

It doesnt like when I change the pivot table to

-- PIVOT ( avg(act_s) active_executions for mmyyyy in ( to_char(add_months(sysdate, -1), 'MM/YYYY'), '08/2016' AUG ))

Is there any other method where I can use dynamic values in the PIVOT?

I appreciate your input.

and Chris said...

You can use XML pivoting. But this returns the data as XML:

select *
from
 (select to_char ( end_time,'dd' ) day ,to_char ( end_time,'hh24' ) hr ,to_char ( end_time,'MM/YYYY' ) mmyyyy ,
  round ( maxval,2 ) act_s
 from dba_hist_sysmetric_summary
 where metric_id in ( 2121 )
 and maxval       > 0
 order by 1,2
 )
pivot xml ( avg ( act_s ) active_executions for mmyyyy in ( 
  select to_char ( end_time,'MM/YYYY' ) mmyyyy from dba_hist_sysmetric_summary) 
)
order by 1;

DA HR
-- --
MMYYYY_XML
--------------------------------------------------------------------------------

28 06
<PivotSet><item><column name = "MMYYYY">07/2016</column><column name = "ACTIVE_E

28 07
<PivotSet><item><column name = "MMYYYY">07/2016</column><column name = "ACTIVE_E

28 09
<PivotSet><item><column name = "MMYYYY">07/2016</column><column name = "ACTIVE_E

28 10
<PivotSet><item><column name = "MMYYYY">07/2016</column><column name = "ACTIVE_E

28 11
<PivotSet><item><column name = "MMYYYY">07/2016</column><column name = "ACTIVE_E
...


Or you could look into this dynamic pivoting solution provided by Anton at AMIS:

https://technology.amis.nl/2006/05/24/dynamic-sql-pivoting-stealing-antons-thunder

Rating

  (2 ratings)

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

Comments

Pivot Table with Dynamic values

Naushad Bhamani, August 02, 2016 - 3:39 pm UTC

Thanks a bunch,
I can try this out. I really appreciate your help.

The decode in the link you provided helped me :)

Naushad Bhamani, August 05, 2016 - 4:06 pm UTC

SELECT TO_CHAR (a.end_time, 'dd') Day,
TO_CHAR (a.end_time, 'hh24') hr,
DECODE (
ROUND (
MAX (
DECODE (TO_CHAR (end_time, 'MM'),
TO_CHAR (ADD_MONTHS (SYSDATE, -1), 'MM'), a.maxval,
0)),
2),
0, NULL,
ROUND (
MAX (
DECODE (TO_CHAR (end_time, 'MM'),
TO_CHAR (ADD_MONTHS (SYSDATE, -1), 'MM'), a.maxval,
0)),
2))
prev_month,
DECODE (
ROUND (
MAX (
DECODE (TO_CHAR (end_time, 'MM'),
TO_CHAR (SYSDATE, 'MM'), a.maxval,
0)),
2),
0, NULL,
ROUND (
MAX (
DECODE (TO_CHAR (end_time, 'MM'),
TO_CHAR (SYSDATE, 'MM'), a.maxval,
0)),
2))
curr_month
FROM DBA_HIST_SYSMETRIC_SUMMARY a
WHERE a.metric_id IN (2121) AND maxval > 0 GROUP BY TO_CHAR (a.end_time, 'dd'), TO_CHAR (a.end_time, 'hh24') ORDER BY 1, 2

More to Explore

Performance

Get all the information about database performance in the Database Performance guide.