Oracle Pivot function

I was amazed at how handy the Pivot function can be. It empowers the user to provide aggregate and denormalized view of a data set which could be a query or a table. In this article I am going to provide a brief example of the pivot function.

First of all let us set some data: 


CREATE TABLE SAMPLE_TRANSACTIONS
(
TRANSACTION_ID NUMBER(8),
COMPANY_NAME VARCHAR2(30),
STATE VARCHAR2(2),
TRANSACTION_AMOUNT NUMBER(10,2)
);
INSERT INTO SAMPLE_TRANSACTIONS VALUES
( 1 , 'PALERMO' , 'TX' , 300.22
);
INSERT INTO SAMPLE_TRANSACTIONS VALUES
( 2 , 'PALERMO' , 'CT' , 600.22
);
INSERT INTO SAMPLE_TRANSACTIONS VALUES
( 3 , 'PALERMO' , 'PA' , 900.669
);
INSERT INTO SAMPLE_TRANSACTIONS VALUES
( 4 , 'BOLOGNA' , 'TX' , 500.22
);
INSERT INTO SAMPLE_TRANSACTIONS VALUES
( 5 , 'BOLOGNA' , 'CT' , 1100.22
);
INSERT INTO SAMPLE_TRANSACTIONS VALUES
( 6 , 'BOLOGNA' , 'PA' , 100.669
);
INSERT INTO SAMPLE_TRANSACTIONS VALUES
( 7 , 'PARMA' , 'NY' , 1300.22
);
INSERT INTO SAMPLE_TRANSACTIONS VALUES
( 8 , 'PARMA' , 'NJ' , 1600.22
);
INSERT INTO SAMPLE_TRANSACTIONS VALUES
( 9 , 'PARMA' , 'CA' , 1900.669
);

Now let us view the data:

SELECT * FROM SAMPLE_TRANSACTIONS;

 

TRANSACTION_IDCOMPANY_NAMESTATETRANSACTION_AMOUNT
1PALERMOTX300.22
2PALERMOCT600.22
3PALERMOPA900.67
4BOLOGNATX500.22
5BOLOGNACT1100.22
6BOLOGNAPA100.67
7PARMANY1300.22
8PARMANJ1600.22
9PARMACA1900.67

 

Now let us create a report that provides the sum of the transactions by company at a state level:
Let us first execute this query:


SELECT *
FROM
( SELECT COMPANY_NAME , STATE , TRANSACTION_AMOUNT
FROM SAMPLE_TRANSACTIONS
) PIVOT
( SUM(TRANSACTION_AMOUNT)
FOR
COMPANY_NAME IN
('BOLOGNA' AS BOLOGNA , 'PARMA' AS PARMA, 'PALERMO' AS PALERMO) )
ORDER BY STATE;

Results:

STATEBOLOGNAPARMAPALERMO
CA{null}1900.67{null}
CT1100.22{null}600.22
NJ{null}1600.22{null}
NY{null}1300.22{null}
PA100.67{null}900.67
TX500.22{null}300.22

 

Now let us create a report that provides the sum of the transactions by state at a company level:

Let us first execute this query:


SELECT *
FROM
( SELECT COMPANY_NAME , STATE , TRANSACTION_AMOUNT FROM SAMPLE_TRANSACTIONS
) PIVOT
( SUM(TRANSACTION_AMOUNT)
FOR STATE IN ('CT' CT , 'NY' NY, 'TX' TX) )
ORDER BY COMPANY_NAME;

Results

COMPANY_NAMECTNYTX
BOLOGNA1100.22{null}500.22
PALERMO600.22{null}300.22
PARMA{null}1300.22{null}

 

As you can see above there are a lot of possibilities on how to leverage the pivot function. For further reading I recommend this link Oracle Pivot.

 

How to efficiently de-dupe a table in Oracle

A bad approach to de-dupe a table is to delete the dupes. Unfortunately, when dealing with tables that have millions of rows the delete method is going to take a long time and consume a lot of server resources. Below is a step by step example that shows how we can de-dupe a table using “Partition By” Oracle command.

Step 1:
Let us create a table and load data into it.

CREATE TABLE TEST_DEDUPE
(
CUSTOMER_ID NUMBER(10),
BRAND       VARCHAR2(20),
TRANSACTION_DATE DATE
);
INSERT
INTO TEST_DEDUPE VALUES
(
1 ,
'GREAT VALUE' ,
TO_DATE('01/20/2011' , 'MM/DD/YYYY')
);
INSERT
INTO TEST_DEDUPE VALUES
(
1 ,
'GREAT VALUE' ,
TO_DATE('01/20/2011' , 'MM/DD/YYYY')
);
INSERT
INTO TEST_DEDUPE VALUES
(
1 ,
'GREAT VALUE' ,
TO_DATE('01/20/2011' , 'MM/DD/YYYY')
);
INSERT
INTO TEST_DEDUPE VALUES
(
1 ,
'GREAT VALUE' ,
TO_DATE('01/22/2011' , 'MM/DD/YYYY')
);
INSERT
INTO TEST_DEDUPE VALUES
(
1 ,
'GREAT VALUE' ,
TO_DATE('01/22/2011' , 'MM/DD/YYYY')
);
INSERT
INTO TEST_DEDUPE VALUES
(
2 ,
'MEMBERS MARK' ,
TO_DATE('01/22/2011' , 'MM/DD/YYYY')
);
INSERT
INTO TEST_DEDUPE VALUES
(
2 ,
'MEMBERS MARK' ,
TO_DATE('01/22/2011' , 'MM/DD/YYYY')
);
INSERT
INTO TEST_DEDUPE VALUES
(
2 ,
'MEMBERS MARK' ,
TO_DATE('01/22/2011' , 'MM/DD/YYYY')
);
INSERT
INTO TEST_DEDUPE VALUES
(
2 ,
'MEMBERS MARK' ,
TO_DATE('01/15/2011' , 'MM/DD/YYYY')
);
INSERT
INTO TEST_DEDUPE VALUES
(
2 ,
'MEMBERS MARK' ,
TO_DATE('01/15/2011' , 'MM/DD/YYYY')
);
INSERT
INTO TEST_DEDUPE VALUES
(
3 ,
'MEMBERS MARK' ,
TO_DATE('01/15/2011' , 'MM/DD/YYYY')
);
INSERT
INTO TEST_DEDUPE VALUES
(
3 ,
'MEMBERS MARK' ,
TO_DATE('01/15/2011' , 'MM/DD/YYYY')
);
INSERT
INTO TEST_DEDUPE VALUES
(
4 ,
'MEMBERS MARK' ,
TO_DATE('01/15/2011' , 'MM/DD/YYYY')
);

Now let us look at the data:

SELECT * FROM TEST_DEDUPE
CUSTOMER_IDBRANDTRANSACTION_DATE
1GREAT VALUE20-JAN-11
1GREAT VALUE20-JAN-11
1GREAT VALUE20-JAN-11
1GREAT VALUE22-JAN-11
1GREAT VALUE22-JAN-11
2MEMBERS MARK22-JAN-11
2MEMBERS MARK22-JAN-11
2MEMBERS MARK22-JAN-11
2MEMBERS MARK15-JAN-11
2MEMBERS MARK15-JAN-11
3MEMBERS MARK15-JAN-11
3MEMBERS MARK15-JAN-11
4MEMBERS MARK15-JAN-11

 

We noticed that Customer_IDs {1, 2, 3} have duplicates. For instance, Customer_ID 1 have three rows with Brand = “Great Value” and Purchase date = “20-JAN-11”. After de-duping we should only have one row.


Step 2:

Now let us rename the table that we need to de-dupe.

ALTER TABLE TEST_DEDUPE
RENAME TO TEST_DEDUPE_OLD;

Step 3:
Now let’s create a new table that has the same name as the original table.

CREATE TABLE TEST_DEDUPE AS
(SELECT CUSTOMER_ID ,
BRAND ,
TRANSACTION_DATE
FROM
(SELECT CUSTOMER_ID ,
BRAND ,
TRANSACTION_DATE ,
ROW_NUMBER()
OVER
(PARTITION BY CUSTOMER_ID , BRAND , TRANSACTION_DATE
ORDER BY TRANSACTION_DATE ) AS RN
FROM TEST_DEDUPE_OLD
)
WHERE RN = 1
);

Final Step:
Let us view the data without dupes:

SELECT * FROM TEST_DEDUPE;
CUSTOMER_IDBRANDTRANSACTION_DATE
1GREAT VALUE20-Jan-11
1GREAT VALUE22-Jan-11
2MEMBERS MARK15-Jan-11
2MEMBERS MARK22-Jan-11
3MEMBERS MARK15-Jan-11
4MEMBERS MARK15-Jan-11

 

 

How to extract the domain name from an email address

Method 1:

SELECT SUBSTR(
'EXAMPLE@YAHOO.COM' ,
INSTR('EXAMPLE@YAHOO.COM' , '@' ) + 1 )
AS EMAIL_DOMAIN
FROM DUAL;

Method 2:

SELECT
REPLACE(
REGEXP_SUBSTR( 'EXAMPLE@YAHOO.COM' , '@.*' ) , '@' )
AS EMAIL_DOMAIN
FROM DUAL;

All you need to do now is to replace ‘EXAMPLE@YAHOO.COM’ with your email address column name or value.

 

How to denormalize a table in oracle.

Let us first begin by creating a table and setting up some data.

Topic 1:
Customer and Brand are a one to one relationship.

 CREATE TABLE CUSTOMER_BRAND
(
CUSTOMER_ID NUMBER(10),
BRAND VARCHAR2(20)
);
INSERT INTO CUSTOMER_BRAND VALUES( 1 , 'BMW' );
INSERT INTO CUSTOMER_BRAND VALUES( 1, 'CHEVY' );
INSERT INTO CUSTOMER_BRAND VALUES( 1, 'FORD' );
INSERT INTO CUSTOMER_BRAND VALUES( 2 , 'BMW' );
INSERT INTO CUSTOMER_BRAND VALUES( 2 , 'FORD');
INSERT INTO CUSTOMER_BRAND VALUES( 3 , 'CHEVY');

Please note that a customer can only have one brand.

Now let’s try to view the data in the table.

SELECT * FROM CUSTOMER_BRAND;

CUSTOMER_BRAND

CUSTOMER_IDBRAND
1BMW
1CHEVY
1FORD
2BMW
2FORD
3CHEVY

Now we would like to flatten the data (aka pivot).

SELECT DISTINCT CUSTOMER_ID ,
(
CASE
WHEN (SELECT 'Y'
FROM CUSTOMER_BRAND A
WHERE BRAND       = 'BMW'
AND A.CUSTOMER_ID = B.CUSTOMER_ID ) = 'Y'
THEN 'Y'
ELSE 'N'
END) AS BMW ,
(
CASE
WHEN (SELECT 'Y'
FROM CUSTOMER_BRAND A
WHERE BRAND       = 'FORD'
AND A.CUSTOMER_ID = B.CUSTOMER_ID) = 'Y'
THEN 'Y'
ELSE 'N'
END) AS FORD,
(
CASE
WHEN (SELECT 'Y'
FROM CUSTOMER_BRAND A
WHERE BRAND       = 'CHEVY'
AND A.CUSTOMER_ID = B.CUSTOMER_ID ) = 'Y'
THEN 'Y'
ELSE 'N'
END) AS CHEVY
FROM CUSTOMER_BRAND B;

Results:

CUSTOMER_IDBMWFORDCHEVY
1YYY
3NNY
2YYN