HackerRank: Occupations | Pivot Table | MySQL.

Azul Rosales
4 min readDec 9, 2022

--

HackerRank > SQL Prep > Advanced Select > Occupations

Hello! I was stuck for a while trying to understand the solution for this problem, but I wasn’t able to find a pellucid explanation of the logic behind it — hence I decided to break the solution into easy-to-follow and intuitive steps. Let’s begin…

The Problem

Pivot the Occupation column in OCCUPATIONS 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.

Input Format

The OCCUPATIONS table is described as follows:

Format of the input database.
Table 1.1. Input Format.

Occupation will only contain one of the following values: Doctor, Professor, Singer or Actor.

Sample Input

Sample Input Table
Table 1.2. Sample Input.

Sample Output

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

Explanation

  • 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.

If you want to create the Table used in the Sample Test and try it out outside of HackerRank, use this code:

CREATE TABLE Occupations(
Name VARCHAR(20),
Occupation VARCHAR(20)
);

INSERT INTO Occupations
VALUES ('Ashley', 'Professor'),
('Samantha', 'Actor'),
('Julia', 'Doctor'),
('Britney', 'Professor'),
('Maria', 'Professor'),
('Meera', 'Professor'),
('Priya', 'Doctor'),
('Priyanka', 'Professor'),
('Jennifer', 'Actor'),
('Ketty', 'Actor'),
('Belvet', 'Professor'),
('Naomi', 'Professor'),
('Jane', 'Singer'),
('Jenny', 'Singer'),
('Kristeen', 'Singer'),
('Christeen', 'Singer'),
('Eve', 'Actor'),
('Aamina', 'Doctor');

The Solution

Step 1:

Create a pivot table with OCCUPATION as the columns. Select NAME when its OCCUPATION matches the OCCUPATION's column, else the value is NULL.

SELECT
CASE WHEN Occupation='Doctor' THEN Name END AS Doctor,
CASE WHEN Occupation='Professor' THEN Name END AS Professor,
CASE WHEN Occupation='Singer' THEN Name END AS Singer,
CASE WHEN Occupation='Actor' THEN Name END AS Actor
FROM Occupations

Note: You can make the NULL value assignment more explicit by using this notation:

CASE WHEN Occupation='Doctor' THEN Name ELSE NULL END AS Doctor
-- Is the same as...
CASE WHEN Occupation='Doctor' THEN Name END AS Doctor

The table generated should look something like this:

Table 1
Table 2.1. Occupation Pivot Table.

Step 2:

Create a partition by OCCUPATION and enumerate each instance of the partition using the ROW_NUMBER() function, that creates an index column with the sequential number for each row within its partition. And order the partitions by NAME (ASC by default) to make it alphabetically ordered.

SELECT Occupation, Name, ROW_NUMBER() 
OVER (PARTITION BY Occupation ORDER BY Name) AS Row_Num
FROM Occupations

The table generated should look something like this:

Table with Occupation partitions and row number column.
Table 2.2. Partition Table w/ Row Numbers.

Note: PARTITION BY orders the partitions alphabetically by default.

Step 3:

Combine the results from the previous steps.

SELECT 
CASE WHEN Occupation='Doctor' THEN Name END AS Doctor,
CASE WHEN Occupation='Professor' THEN Name END AS Professor,
CASE WHEN Occupation='Singer' THEN Name END AS Singer,
CASE WHEN Occupation='Actor' THEN Name END AS Actor
FROM
(SELECT Occupation, Name, ROW_NUMBER()
OVER (PARTITION BY Occupation ORDER BY Name) AS Occupation_Partition
FROM Occupations) AS Pivot_Occupations
Pivot table of occupation partitions.
Table 2.3. Occupations Pivot Table.

Step 4:

GROUP BY the Occupation partition. Use GROUP BY with either of the aggregation functions MIN() or MAX() to get only the Names and not the NULL values.

Without the GROUP BY clause, when using one of those aggregation functions we would only get an element from each column — we’d get the “lowest” value with MIN(), and the “highest” with MAX(). However, with the clause the result set will have one row for each group in OCCUPATION_PARTITION.

SELECT 
MIN(CASE WHEN Occupation='Doctor' THEN Name END) AS Doctor,
MIN(CASE WHEN Occupation='Professor' THEN Name END) AS Professor,
MIN(CASE WHEN Occupation='Singer' THEN Name END) AS Singer,
MIN(CASE WHEN Occupation='Actor' THEN Name END) AS Actor
FROM
(SELECT Occupation, Name, ROW_NUMBER()
OVER (PARTITION BY Occupation ORDER BY Name) AS Occupation_Partition
FROM Occupations) AS Pivot_Occupations
GROUP BY Occupation_Partition

The complete solution table should look like this:

Table of the complete solution.
Table 2.4. Solution Table.

And we’re done!

I hope you found this helpful! Feel free to leave any doubt you may have in the comments.

Let’s connect on LinkedIn! https://www.linkedin.com/in/azulrosales/

--

--

Azul Rosales

Computer Science student with a passion for all things data - I hope to inspire others to combine their interests and skills in unique and meaningful ways.