File tree 3 files changed +149
-0
lines changed
Find Cumulative Salary of an Employee
3 files changed +149
-0
lines changed Original file line number Diff line number Diff line change
1
+ # [ Find Cumulative Salary of an Employee] ( https://leetcode.com/problems/find-cumulative-salary-of-an-employee/description/ )
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 : Employee</b >
12
+
13
+ | Column Name | Type |
14
+ | ------------- | ------------- |
15
+ | id | int |
16
+ | month | int |
17
+ | salary | int |
18
+
19
+ * (id, month) is the primary key for this table.
20
+ * Each row in the table indicates the salary of an employee in one month during the year 2020.
21
+ <br />
22
+
23
+
24
+
25
+ Write an SQL query to calculate the cumulative salary summary for every employee in a single unified table.
26
+ </br >
27
+
28
+ The cumulative salary summary for an employee can be calculated as follows:
29
+ - For each month that the employee worked, sum up the salaries in that month and the previous two months.
30
+ - This is their 3-month sum for that month. If an employee did not work for the company in previous months,
31
+ their effective salary for those months is 0.
32
+ - Do not include the 3-month sum for the most recent month that the employee worked for in the summary.
33
+ - Do not include the 3-month sum for any month the employee did not work.
34
+
35
+
36
+ Return the result table ordered by id in ascending order. In case of a tie, order it by month in descending order.
37
+ The query result format is in the following example.
38
+ </br >
39
+ </br >
40
+ <details >
41
+ <summary >
42
+ Input
43
+ </summary >
44
+
45
+ <b >Table Name: Employee</b >
46
+
47
+ | id | month | salary |
48
+ | --- | ------ | -----|
49
+ | 1 | 1 | 20 |
50
+ | 2 | 1 | 20 |
51
+ | 1 | 2 | 30 |
52
+ | 2 | 2 | 30 |
53
+ | 3 | 2 | 40 |
54
+ | 1 | 3 | 40 |
55
+ | 3 | 3 | 60 |
56
+ | 1 | 4 | 60 |
57
+ | 3 | 4 | 70 |
58
+ | 1 | 7 | 90 |
59
+ | 1 | 8 | 90 |
60
+
61
+ </details >
62
+
63
+ <details >
64
+ <summary >
65
+ Output
66
+ </summary >
67
+
68
+ | id | month | salary |
69
+ | ---- | ---- | ----|
70
+ | 1 | 7 | 90 |
71
+ | 1 | 4 | 130 |
72
+ | 1 | 3 | 90 |
73
+ | 1 | 2 | 50 |
74
+ | 1 | 1 | 20 |
75
+ | 2 | 1 | 20 |
76
+ | 3 | 3 | 100 |
77
+ | 3 | 2 | 40 |
78
+ </details >
79
+
80
+ ---
Original file line number Diff line number Diff line change
1
+ CREATE TABLE employee (
2
+ id int ,
3
+ MONTH int ,
4
+ salary int ,
5
+ PRIMARY KEY (id, MONTH)
6
+ );
7
+
8
+ -- Insert Query:
9
+ INSERT INTO
10
+ employee (id, MONTH, salary)
11
+ VALUES
12
+ (1 , 1 , 20 ),
13
+ (2 , 1 , 20 ),
14
+ (1 , 2 , 30 ),
15
+ (2 , 2 , 30 ),
16
+ (3 , 2 , 40 ),
17
+ (1 , 3 , 40 ),
18
+ (3 , 3 , 60 ),
19
+ (1 , 4 , 60 ),
20
+ (3 , 4 , 70 ),
21
+ (1 , 7 , 90 ),
22
+ (1 , 8 , 90 );
23
+
24
+ COMMIT ;
Original file line number Diff line number Diff line change
1
+ WITH cte AS (
2
+ SELECT
3
+ a .id ,
4
+ a .month ,
5
+ b .salary
6
+ FROM
7
+ employee a
8
+ INNER JOIN employee b ON a .id = b .id
9
+ AND (
10
+ a .month = b .month
11
+ OR a .month = b .month + 1
12
+ OR a .month = b .month + 2
13
+ )
14
+ ),
15
+ cum_sum AS (
16
+ SELECT
17
+ id,
18
+ MONTH,
19
+ sum (salary) salary
20
+ FROM
21
+ cte
22
+ GROUP BY
23
+ id,
24
+ MONTH
25
+ ),
26
+ recent_month AS (
27
+ SELECT
28
+ id,
29
+ max (MONTH) recent_month
30
+ FROM
31
+ employee
32
+ GROUP BY
33
+ id
34
+ )
35
+ SELECT
36
+ a .id ,
37
+ a .month ,
38
+ a .salary
39
+ FROM
40
+ cum_sum a
41
+ INNER JOIN recent_month b ON a .id = b .id
42
+ AND a .month != b .recent_month
43
+ ORDER BY
44
+ a .id ,
45
+ a .month DESC ;
You can’t perform that action at this time.
0 commit comments