Pivot Tables in Oracle

Oracle PIVOT allows you to “pivot” a column of repeating values into columns of a display table. Data displayed in the table can be aggregated into these columns. For example, lets say we have an inventory table that receives one entry per day for each inventory category:

SQL> DESC inventory;
 Name                                      Null?    Type
 ----------------------------------------- -------- ----------------------------
 CATEGORY                                           VARCHAR2(20)
 INV_DATE                                           DATE
 INV_COUNT                                          NUMBER


SQL> SELECT *
  2  FROM inventory
  3  ORDER BY inv_date, category;

CATEGORY             INV_DATE   INV_COUNT
-------------------- --------- ----------
apples               12-DEC-14          4
bananas              12-DEC-14          2
oranges              12-DEC-14          5
apples               13-DEC-14          3
bananas              13-DEC-14          9
oranges              13-DEC-14          4
apples               14-DEC-14          3
bananas              14-DEC-14          3
oranges              14-DEC-14          6

9 rows selected.

Given this, we can simply query an aggregation using the SUM() function:

SQL> SELECT category, SUM( inv_count )
  2  FROM inventory
  3  GROUP BY category;

CATEGORY             SUM(INV_COUNT)
-------------------- --------------
oranges                          15
bananas                          14
apples                           10

But what if we wanted to see this same data as columns a table?

SQL> SELECT *
  2  FROM
  3  (
  4    SELECT category, inv_count
  5    FROM inventory
  6  )
  7  PIVOT ( SUM( inv_count ) qty FOR ( category ) IN ( 'apples', 'oranges', 'bananas' ) );

'apples'_QTY 'oranges'_QTY 'bananas'_QTY
------------ ------------- -------------
          10            15            14

Now we are ready to see the real utility of PIVOT(). What if we want to see the inventory counts broken out by category and date in a two-dimensional table?

SQL> SELECT *
  2  FROM
  3  (
  4    SELECT category, inv_date, inv_count
  5    FROM inventory
  6  )
  7  PIVOT ( SUM( inv_count ) qty FOR ( category ) IN ( 'apples', 'oranges', 'bananas' ) );

INV_DATE  'apples'_QTY 'oranges'_QTY 'bananas'_QTY
--------- ------------ ------------- -------------
12-DEC-14            4             5             2
13-DEC-14            3             4             9
14-DEC-14            3             6             3

This shows breakouts using SUM() for numbers, but MAX() can be substituted for non-numerical values such as VARCHARs.

Advertisements

Leave a Reply

Fill in your details below or click an icon to log in:

WordPress.com Logo

You are commenting using your WordPress.com account. Log Out / Change )

Twitter picture

You are commenting using your Twitter account. Log Out / Change )

Facebook photo

You are commenting using your Facebook account. Log Out / Change )

Google+ photo

You are commenting using your Google+ account. Log Out / Change )

Connecting to %s