Skip to content

Commit 865d787

Browse files
Added Vacant Positions
1 parent 340351d commit 865d787

File tree

3 files changed

+201
-0
lines changed

3 files changed

+201
-0
lines changed

Vacant Positions/READme.md

Lines changed: 112 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,112 @@
1+
# Vacant Positions
2+
![Star Badge](https://img.shields.io/static/v1?label=%F0%9F%8C%9F&message=If%20Useful&style=style=flat&color=BC4E99)
3+
[![View Main Folder](https://img.shields.io/badge/View-Main_Folder-971901?)](https://github.com/thecoddiwompler/SQL-Practice-Questions/tree/main)
4+
[![View Repositories](https://img.shields.io/badge/View-My_Repositories-blue?logo=GitHub)](https://github.com/thecoddiwompler?tab=repositories)
5+
[![View My Profile](https://img.shields.io/badge/View-My_Profile-green?logo=GitHub)](https://github.com/thecoddiwompler)
6+
7+
---
8+
9+
## 🛠️ Problem Statement
10+
11+
<b>Table Name : job_positions</b>
12+
</br>
13+
| Column Name |Type |
14+
| ------------- | ------------- |
15+
| id | int |
16+
| title | varchar(100) |
17+
| groups | varchar(10) |
18+
| levels | varchar(10) |
19+
| payscale | int |
20+
| totalpost | int |
21+
22+
* <b> id is the primary key to this table </b>
23+
* This table includes various details of a given job position including the total number of post (totalpost)
24+
25+
<br>
26+
27+
<b>Table Name : job_employees</b>
28+
</br>
29+
| Column Name |Type |
30+
| ------------- | ------------- |
31+
| id | int |
32+
| name | varchar(100) |
33+
| position_id | int |
34+
35+
* <b> id is the primary key to this table </b>
36+
* position_id is the Foreign key to id column in job_positions
37+
38+
Write a SQL query to generate an Employee Position Report that includes the following columns:
39+
40+
* title: The title of the job position.
41+
* groups: The group to which the position belongs.
42+
* levels: The level of the position.
43+
* payscale: The payscale associated with the position.
44+
* employee_name: The name of the employee currently occupying the position, or 'Vacant' if the position is unoccupied.
45+
46+
Ensure that the report includes all job positions, even those without assigned employees. Please note that there would be as many rows as the total number of totalpost for each Job Position.
47+
48+
Please refer to the sample output given below for better understanding.
49+
50+
<details>
51+
<summary>
52+
Input
53+
</summary>
54+
<br>
55+
<b>Table Name : job_positions</b><br><br>
56+
57+
| id | title | groups | levels | payscale | totalpost |
58+
|----|------------------|--------|--------|----------|-----------|
59+
| 1 | General manager | A | l-15 | 10000 | 1 |
60+
| 2 | Manager | B | l-14 | 9000 | 5 |
61+
| 3 | Asst. Manager | C | l-13 | 8000 | 10 |
62+
63+
64+
<br>
65+
<b>Table Name : job_employees</b><br><br>
66+
67+
| id | name | position_id |
68+
|----|---------------------|-------------|
69+
| 1 | John Smith | 1 |
70+
| 2 | Jane Doe | 2 |
71+
| 3 | Michael Brown | 2 |
72+
| 4 | Emily Johnson | 2 |
73+
| 5 | William Lee | 3 |
74+
| 6 | Jessica Clark | 3 |
75+
| 7 | Christopher Harris | 3 |
76+
| 8 | Olivia Wilson | 3 |
77+
| 9 | Daniel Martinez | 3 |
78+
| 10 | Sophia Miller | 3 |
79+
80+
81+
</details>
82+
83+
<details>
84+
<summary>
85+
Output
86+
</summary>
87+
<br>
88+
89+
| title | groups | levels | payscale | employee_name |
90+
|------------------|--------|--------|----------|--------------------|
91+
| General manager | A | l-15 | 10000 | John Smith|
92+
| Manager | B | l-14 | 9000 |Jane Doe |
93+
| Manager | B | l-14 | 9000 |Michael Brown |
94+
| Manager | B | l-14 | 9000 |Emily Johnson |
95+
| Manager | B | l-14 | 9000 | Vacant |
96+
| Manager | B | l-14 | 9000 | Vacant |
97+
| Asst. Manager | C | l-13 | 8000 |William Lee |
98+
| Asst. Manager | C | l-13 | 8000 |Jessica Clark |
99+
| Asst. Manager | C | l-13 | 8000 | Christopher Harris|
100+
| Asst. Manager | C | l-13 | 8000 | Olivia Wilson|
101+
| Asst. Manager | C | l-13 | 8000 |Daniel Martinez|
102+
| Asst. Manager | C | l-13 | 8000 |Sophia Miller |
103+
| Asst. Manager | C | l-13 | 8000 | Vacant|
104+
| Asst. Manager | C | l-13 | 8000 | Vacant|
105+
| Asst. Manager | C | l-13 | 8000 | Vacant|
106+
| Asst. Manager | C | l-13 | 8000 | Vacant|
107+
108+
109+
</details>
110+
111+
---
112+

Vacant Positions/schema.sql

Lines changed: 39 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,39 @@
1+
CREATE TABLE job_positions (
2+
id int,
3+
title varchar(100),
4+
groups varchar(10),
5+
levels varchar(10),
6+
payscale int,
7+
totalpost int
8+
);
9+
10+
CREATE TABLE job_employees (
11+
id int,
12+
name varchar(100),
13+
position_id int
14+
);
15+
16+
INSERT INTO
17+
job_positions
18+
VALUES
19+
(1, 'General manager', 'A', 'l-15', 10000, 1),
20+
(2, 'Manager', 'B', 'l-14', 9000, 5),
21+
(3, 'Asst. Manager', 'C', 'l-13', 8000, 10);
22+
23+
COMMIT;
24+
25+
INSERT INTO
26+
job_employees
27+
VALUES
28+
(1, 'John Smith', 1),
29+
(2, 'Jane Doe', 2),
30+
(3, 'Michael Brown', 2),
31+
(4, 'Emily Johnson', 2),
32+
(5, 'William Lee', 3),
33+
(6, 'Jessica Clark', 3),
34+
(7, 'Christopher Harris', 3),
35+
(8, 'Olivia Wilson', 3),
36+
(9, 'Daniel Martinez', 3),
37+
(10, 'Sophia Miller', 3);
38+
39+
COMMIT;

Vacant Positions/solution.sql

Lines changed: 50 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,50 @@
1+
WITH RECURSIVE cte AS (
2+
SELECT
3+
id,
4+
1 AS generated_int
5+
FROM
6+
job_positions
7+
UNION
8+
SELECT
9+
cte.id,
10+
generated_int + 1
11+
FROM
12+
cte
13+
INNER JOIN job_positions ON cte.id = job_positions.id
14+
AND generated_int + 1 <= job_positions.totalpost
15+
),
16+
employees AS (
17+
SELECT
18+
id,
19+
name,
20+
position_id,
21+
ROW_NUMBER() OVER(
22+
PARTITION BY position_id
23+
ORDER BY
24+
id
25+
) rn
26+
FROM
27+
job_employees
28+
),
29+
positions AS (
30+
SELECT
31+
cte.id,
32+
a.title,
33+
a.groups,
34+
a.levels,
35+
a.payscale,
36+
cte.generated_int
37+
FROM
38+
job_positions a
39+
INNER JOIN cte ON a.id = cte.id
40+
)
41+
SELECT
42+
a.title,
43+
a.groups,
44+
a.levels,
45+
a.payscale,
46+
COALESCE(b.name, 'Vacant') employee_name
47+
FROM
48+
positions a
49+
LEFT OUTER JOIN employees b ON a.id = b.position_id
50+
AND a.generated_int = b.rn

0 commit comments

Comments
 (0)