PIVOT OCCUPATIONS TABLE DATA QUERY

PROBLEM STATEMENT:

Pivot the ‘Occupation’ column in OCCUPATIONS table so that each ‘Name’ is sorted alphabetically and displayed underneath its corresponding Occupation. The output column headers should be Doctor, Professor, Singer, and Actor, respectively.

Note: Print NULL when there are no more names corresponding to an occupation.

The OCCUPATIONS table is given as follows:

CREATE TABLE OCCUPATIONS
(
NAME VARCHAR2(50),
OCCUPATION VARCHAR2(50)
);

Use below INSERT statements to load the sample records into OCCUPATIONS table.

INSERT INTO OCCUPATIONS(NAME,OCCUPATION) VALUES(‘Samantha’,’Doctor’);
INSERT INTO OCCUPATIONS(NAME,OCCUPATION) VALUES(‘Julia’,’Actor’);
INSERT INTO OCCUPATIONS(NAME,OCCUPATION) VALUES(‘Maria’,’Actor’);
INSERT INTO OCCUPATIONS(NAME,OCCUPATION) VALUES(‘Meera’,’Singer’);
INSERT INTO OCCUPATIONS(NAME,OCCUPATION) VALUES(‘Ashley’,’Professor’);
INSERT INTO OCCUPATIONS(NAME,OCCUPATION) VALUES(‘Ketty’,’Professor’);
INSERT INTO OCCUPATIONS(NAME,OCCUPATION) VALUES(‘Christeen’,’Professor’);
INSERT INTO OCCUPATIONS(NAME,OCCUPATION) VALUES(‘Jane’,’Actor’);
INSERT INTO OCCUPATIONS(NAME,OCCUPATION) VALUES(‘Jenny’,’Doctor’);
INSERT INTO OCCUPATIONS(NAME,OCCUPATION) VALUES(‘Priya’,’Singer’);
COMMIT;

select * from OCCUPATIONS will give below results:

NAMEOCCUPATION
SamanthaDoctor
JuliaActor
MariaActor
MeeraSinger
AshleyProfessor
KettyProfessor
ChristeenProfessor
JaneActor
JennyDoctor
PriyaSinger

Expected Output:

Jenny Ashley Meera Jane
Samantha Christeen Priya Julia
NULL Ketty NULL Maria

Explanation of output:

  • The first column is an alphabetically ordered list of Doctor names.
  • The second column is an alphabetically ordered list of Professor names.
  • The third column is an alphabetically ordered list of Singer names.
  • The fourth column is an alphabetically ordered list of Actor names.
  • The empty cell data for columns with less than the maximum number of names per occupation (in this case, the Professor and Actor columns) are filled with NULL values.

SOLUTION:

SELECT Min(a.doctors), 
       Min(a.professors), 
       Min(a.singers), 
       Min(a.actors) 
FROM   (SELECT Row_number() 
                 over ( 
                   PARTITION BY occupation 
                   ORDER BY name) row_num, 
               CASE 
                 WHEN occupation = ‘Doctor’ THEN name 
               END                AS Doctors, 
               CASE 
                 WHEN occupation = ‘Professor’ THEN name 
               END                AS Professors, 
               CASE 
                 WHEN occupation = ‘Singer’ THEN name 
               END                AS Singers, 
               CASE 
                 WHEN occupation = ‘Actor’ THEN name 
               END                AS Actors 
        FROM   occupations) a 
GROUP  BY a.row_num 
ORDER  BY a.row_num; 

Comments

comments

Leave a Reply

This site uses Akismet to reduce spam. Learn how your comment data is processed.

%d bloggers like this: