From 48f93f49aaa8be7c0fa8d8e54ee4f746c3072b3b Mon Sep 17 00:00:00 2001 From: Vera Date: Mon, 31 Mar 2025 19:28:19 +0100 Subject: [PATCH 1/6] Create employees table --- create_employees.sql | 21 +++++++++++++++++++++ 1 file changed, 21 insertions(+) diff --git a/create_employees.sql b/create_employees.sql index e69de29..ff61bbc 100644 --- a/create_employees.sql +++ b/create_employees.sql @@ -0,0 +1,21 @@ +USE memory.default; + +CREATE TABLE EMPLOYEE ( + employee_id TINYINT, + first_name VARCHAR, + last_name VARCHAR, + job_title VARCHAR, + manager_id TINYINT +) +COMMENT 'Employee table using data from hr/employee_index.csv file'; + +INSERT INTO EMPLOYEE VALUES +(1,'Ian','James','CEO',4), +(2,'Umberto','Torrielli','CSO',1), +(3,'Alex','Jacobson','MD EMEA',2), +(4,'Darren','Poynton','CFO',2), +(5,'Tim','Beard','MD APAC',2), +(6,'Gemma','Dodd','COS',1), +(7,'Lisa','Platten','CHR',6), +(8,'Stefano','Camisaca','GM Activation',2), +(9,'Andrea','Ghibaudi','MD NAM',2); From b1cab3befc5c7db248fc18b7947eb8093459ce32 Mon Sep 17 00:00:00 2001 From: Vera Date: Tue, 1 Apr 2025 14:15:04 +0100 Subject: [PATCH 2/6] create expenses table --- create_expenses.sql | 39 +++++++++++++++++++++++++++++++++++++++ 1 file changed, 39 insertions(+) diff --git a/create_expenses.sql b/create_expenses.sql index e69de29..5a97817 100644 --- a/create_expenses.sql +++ b/create_expenses.sql @@ -0,0 +1,39 @@ +USE memory.default; + +CREATE TABLE EXPENSES ( + employee_id TINYINT, + unit_price DECIMAL(8, 2), + quantity TINYINT +) +COMMENT 'Expenses table using data from finance/receipts_from_last_night folder mapped with Employee identifier'; + +DROP TABLE IF EXISTS TempExpenses; + +CREATE TABLE TempExpenses ( + employee_full_name VARCHAR, + unit_price DECIMAL(8, 2), + quantity TINYINT +) +COMMENT 'Expenses temporary table using data from finance/receipts_from_last_night folder'; + +INSERT INTO TempExpenses VALUES + ('Alex Jacobson', 6.50, 14), + ('Alex Jacobson', 11.00, 20), + ('Alex Jacobson', 22.00, 18), + ('Alex Jacobson', 13.00, 75), + ('Andrea Ghibaudi', 300, 1), + ('Darren Poynton', 40.00, 9), + ('Umberto Torrielli', 17.50, 4) +; + + +INSERT INTO EXPENSES +SELECT + e.employee_id + , t.unit_price + , t.quantity + +FROM TempExpenses t +INNER JOIN EMPLOYEE e + ON t.employee_full_name = concat(e.first_name, ' ', e.last_name) +; \ No newline at end of file From 341cb57f227bf8817f553cec73b1179475c4d7a6 Mon Sep 17 00:00:00 2001 From: Vera Date: Tue, 1 Apr 2025 14:44:07 +0100 Subject: [PATCH 3/6] created invoice and supplier tables --- create_invoices.sql | 51 +++++++++++++++++++++++++++++++++++++++++++++ 1 file changed, 51 insertions(+) diff --git a/create_invoices.sql b/create_invoices.sql index e69de29..fad5afc 100644 --- a/create_invoices.sql +++ b/create_invoices.sql @@ -0,0 +1,51 @@ +USE memory.default; + +CREATE TABLE INVOICE ( + supplier_id TINYINT, + invoice_ammount DECIMAL(8, 2), + due_date DATE +) +COMMENT 'Invoice table using data from finance/invoices_due folder'; + + +CREATE TABLE SUPPLIER ( + supplier_id TINYINT, + name VARCHAR +) +COMMENT 'Supplier table using data from finance/invoices_due folder to retrieve supplier ids'; + + +DROP TABLE IF EXISTS TempInvoice; + +CREATE TABLE TempInvoice ( + company_name VARCHAR, + invoice_ammount DECIMAL(8, 2), + due_date_in_months INT +) +COMMENT 'Invoice temporary table using data from finance/invoices_due folder'; + +INSERT INTO TempInvoice VALUES +('Party Animals', 6000.00, 3), +('Catering Plus', 2000.00, 2), +('Catering Plus', 1500.00, 3), +('Dave''s Discos', 500.00, 1), +('Entertainment tonight', 6000.00, 3), +('Ice Ice Baby', 4000.00, 6) +; + +INSERT INTO SUPPLIER +SELECT + row_number() over(order by company_name) as supplier_id + , company_name AS name + +FROM (SELECT DISTINCT company_name FROM TempInvoice) ; + + +INSERT INTO INVOICE +SELECT + s.supplier_id + , t.invoice_ammount + , last_day_of_month(date_add('month', t.due_date_in_months, now())) due_date +FROM TempInvoice t +INNER JOIN SUPPLIER s + ON t.company_name = s.name ; \ No newline at end of file From c764b692632c71ad9f09f01fecdf1950199fb3e7 Mon Sep 17 00:00:00 2001 From: Vera Date: Tue, 1 Apr 2025 16:07:53 +0100 Subject: [PATCH 4/6] Create a query to list the list of employees per manager --- find_manager_cycles.sql | 33 +++++++++++++++++++++++++++++++++ 1 file changed, 33 insertions(+) diff --git a/find_manager_cycles.sql b/find_manager_cycles.sql index e69de29..f05be2f 100644 --- a/find_manager_cycles.sql +++ b/find_manager_cycles.sql @@ -0,0 +1,33 @@ +USE memory.default; + +WITH RECURSIVE MANAGERS (manager_id, employee_id, employee_ids_list) AS ( + SELECT + manager_id + , employee_id + , cast(employee_id as VARCHAR) AS employee_ids_list + FROM EMPLOYEE + + UNION ALL + + SELECT + m.manager_id + , e.employee_id + , concat(m.employee_ids_list, ', ', cast(e.employee_id as VARCHAR)) AS employee_ids_list + FROM EMPLOYEE e + INNER JOIN MANAGERS m + ON m.employee_id = e.manager_id + WHERE + position(cast(e.employee_id as VARCHAR) in m.employee_ids_list) = 0 + +) + +SELECT + manager_id + , max(employee_ids_list) AS employee_ids_list +FROM MANAGERS + WHERE + position(cast(manager_id as VARCHAR) in employee_ids_list) > 0 +GROUP BY + manager_id +ORDER BY + manager_id; \ No newline at end of file From 486018308cf12fbae16ff244bb4d2bd79045c26c Mon Sep 17 00:00:00 2001 From: Vera Date: Tue, 1 Apr 2025 17:48:59 +0100 Subject: [PATCH 5/6] Created sripts for: - supplier schedule payment - list of employees that expend more than they should --- calculate_largest_expensors.sql | 23 +++++++++++ generate_supplier_payment_plans.sql | 59 +++++++++++++++++++++++++++++ 2 files changed, 82 insertions(+) diff --git a/calculate_largest_expensors.sql b/calculate_largest_expensors.sql index e69de29..109b800 100644 --- a/calculate_largest_expensors.sql +++ b/calculate_largest_expensors.sql @@ -0,0 +1,23 @@ +USE memory.default; + +SELECT + em.employee_id + , concat(em.first_name, ' ', em.last_name) AS employee_name + , em.manager_id + , concat(m.first_name, ' ', m.last_name) AS manager_name + , sum(ex.unit_price * ex.quantity) AS total_expense_amount +FROM + EMPLOYEE em +INNER JOIN EXPENSES ex + ON em.employee_id = ex.employee_id +LEFT JOIN EMPLOYEE m + ON m.employee_id = em.manager_id +GROUP BY + em.employee_id + , concat(em.first_name, ' ', em.last_name) + , em.manager_id + , concat(m.first_name, ' ', m.last_name) +HAVING + sum(ex.unit_price * ex.quantity) > 1000 +ORDER BY + sum(ex.unit_price * ex.quantity) DESC; \ No newline at end of file diff --git a/generate_supplier_payment_plans.sql b/generate_supplier_payment_plans.sql index e69de29..8e9a43c 100644 --- a/generate_supplier_payment_plans.sql +++ b/generate_supplier_payment_plans.sql @@ -0,0 +1,59 @@ +USE memory.default; + +WITH payments AS ( +SELECT + i.supplier_id + , s.name AS supplier_name + , i.invoice_ammount + , i.due_date + , date_diff('month', now(), i.due_date) + 1 AS remaining_months + , sum(i.invoice_ammount) over (partition by i.supplier_id) AS total_payment +FROM + INVOICE i +INNER JOIN SUPPLIER s + ON s.supplier_id = i.supplier_id +), +payments_per_supplier AS ( +SELECT + supplier_id + , supplier_name + , max(remaining_months) AS remaining_months + ,sum(invoice_ammount) AS invoice_ammount + , max(total_payment) AS total_payment +FROM payments +GROUP BY supplier_id, supplier_name +), +schedule_payment AS ( +SELECT + ps.supplier_id + , ps.supplier_name + , ps.invoice_ammount / ps.remaining_months AS monthly_amount + , last_day_of_month(date_add('month', months, now())) AS payment_date +FROM payments_per_supplier ps +CROSS JOIN unnest(sequence(0, ps.remaining_months - 1)) AS t(months) +), +balance AS ( +SELECT + supplier_id + , payment_date + , sum(monthly_amount) over (partition by supplier_id order by payment_date) AS balance + +FROM schedule_payment + +) + +SELECT + s.supplier_id + , s.supplier_name + , s.monthly_amount AS payment_amount + , p.total_payment - b.balance AS balance_outstanding + , s.payment_date +FROM schedule_payment s +INNER JOIN payments_per_supplier p + ON p.supplier_id = s.supplier_id +INNER JOIN balance b + ON b.supplier_id = s.supplier_id + AND b.payment_date = s.payment_date +ORDER BY + supplier_id + , supplier_name; From 4c60859eda65e108aab0071f2de260f2ee731987 Mon Sep 17 00:00:00 2001 From: Vera Date: Tue, 1 Apr 2025 18:11:07 +0100 Subject: [PATCH 6/6] Fix column name and add comments --- calculate_largest_expensors.sql | 1 + create_employees.sql | 4 ++++ create_expenses.sql | 5 +++++ create_invoices.sql | 16 ++++++++++------ find_manager_cycles.sql | 8 +++++--- generate_supplier_payment_plans.sql | 14 +++++++++----- 6 files changed, 34 insertions(+), 14 deletions(-) diff --git a/calculate_largest_expensors.sql b/calculate_largest_expensors.sql index 109b800..fa05fdc 100644 --- a/calculate_largest_expensors.sql +++ b/calculate_largest_expensors.sql @@ -1,5 +1,6 @@ USE memory.default; +-- get a list of employees that exceed the amount 1000 SELECT em.employee_id , concat(em.first_name, ' ', em.last_name) AS employee_name diff --git a/create_employees.sql b/create_employees.sql index ff61bbc..60da346 100644 --- a/create_employees.sql +++ b/create_employees.sql @@ -1,5 +1,7 @@ USE memory.default; +-- Creating EMPLOYEE table + CREATE TABLE EMPLOYEE ( employee_id TINYINT, first_name VARCHAR, @@ -9,6 +11,8 @@ CREATE TABLE EMPLOYEE ( ) COMMENT 'Employee table using data from hr/employee_index.csv file'; +-- Inserting data from hr/employee_index.csv file into EMPLOYEE table + INSERT INTO EMPLOYEE VALUES (1,'Ian','James','CEO',4), (2,'Umberto','Torrielli','CSO',1), diff --git a/create_expenses.sql b/create_expenses.sql index 5a97817..970185d 100644 --- a/create_expenses.sql +++ b/create_expenses.sql @@ -1,5 +1,6 @@ USE memory.default; +-- Creating EXPENSES table CREATE TABLE EXPENSES ( employee_id TINYINT, unit_price DECIMAL(8, 2), @@ -7,6 +8,7 @@ CREATE TABLE EXPENSES ( ) COMMENT 'Expenses table using data from finance/receipts_from_last_night folder mapped with Employee identifier'; +-- Clean expenses temporary table if exists DROP TABLE IF EXISTS TempExpenses; CREATE TABLE TempExpenses ( @@ -16,6 +18,8 @@ CREATE TABLE TempExpenses ( ) COMMENT 'Expenses temporary table using data from finance/receipts_from_last_night folder'; +-- Inserting expenses data into temporary table from finance/receipts_from_last_night folder + INSERT INTO TempExpenses VALUES ('Alex Jacobson', 6.50, 14), ('Alex Jacobson', 11.00, 20), @@ -26,6 +30,7 @@ INSERT INTO TempExpenses VALUES ('Umberto Torrielli', 17.50, 4) ; +-- Inserting into EXPENSES table data from EMPLOYEE and temporary expenses tables INSERT INTO EXPENSES SELECT diff --git a/create_invoices.sql b/create_invoices.sql index fad5afc..a18f835 100644 --- a/create_invoices.sql +++ b/create_invoices.sql @@ -1,29 +1,32 @@ USE memory.default; +-- Creating INVOICE table CREATE TABLE INVOICE ( supplier_id TINYINT, - invoice_ammount DECIMAL(8, 2), + invoice_amount DECIMAL(8, 2), due_date DATE ) COMMENT 'Invoice table using data from finance/invoices_due folder'; - +-- Creating SUPPLIER table CREATE TABLE SUPPLIER ( supplier_id TINYINT, name VARCHAR ) COMMENT 'Supplier table using data from finance/invoices_due folder to retrieve supplier ids'; - +-- Clean invoice temporary table if exists DROP TABLE IF EXISTS TempInvoice; +-- Create invoice temporary table CREATE TABLE TempInvoice ( company_name VARCHAR, - invoice_ammount DECIMAL(8, 2), + invoice_amount DECIMAL(8, 2), due_date_in_months INT ) COMMENT 'Invoice temporary table using data from finance/invoices_due folder'; +-- Inserting data from finance/invoices_due folder into temporary table INSERT INTO TempInvoice VALUES ('Party Animals', 6000.00, 3), ('Catering Plus', 2000.00, 2), @@ -33,6 +36,7 @@ INSERT INTO TempInvoice VALUES ('Ice Ice Baby', 4000.00, 6) ; +-- Inserting supplier name and create a unique id for each unique supplier INSERT INTO SUPPLIER SELECT row_number() over(order by company_name) as supplier_id @@ -40,11 +44,11 @@ SELECT FROM (SELECT DISTINCT company_name FROM TempInvoice) ; - +-- Inserting invoice data for each unique supplier for invoice end of month INSERT INTO INVOICE SELECT s.supplier_id - , t.invoice_ammount + , t.invoice_amount , last_day_of_month(date_add('month', t.due_date_in_months, now())) due_date FROM TempInvoice t INNER JOIN SUPPLIER s diff --git a/find_manager_cycles.sql b/find_manager_cycles.sql index f05be2f..7e98690 100644 --- a/find_manager_cycles.sql +++ b/find_manager_cycles.sql @@ -1,6 +1,7 @@ USE memory.default; WITH RECURSIVE MANAGERS (manager_id, employee_id, employee_ids_list) AS ( + -- base case, selecting manager-employee link SELECT manager_id , employee_id @@ -8,7 +9,7 @@ WITH RECURSIVE MANAGERS (manager_id, employee_id, employee_ids_list) AS ( FROM EMPLOYEE UNION ALL - + --recursive case, for a specific manager get all employees SELECT m.manager_id , e.employee_id @@ -17,16 +18,17 @@ WITH RECURSIVE MANAGERS (manager_id, employee_id, employee_ids_list) AS ( INNER JOIN MANAGERS m ON m.employee_id = e.manager_id WHERE - position(cast(e.employee_id as VARCHAR) in m.employee_ids_list) = 0 + position(cast(e.employee_id as VARCHAR) in m.employee_ids_list) = 0 -- in case the employee already was identified, it skips ) +-- returns a list of employees under a manager SELECT manager_id , max(employee_ids_list) AS employee_ids_list FROM MANAGERS WHERE - position(cast(manager_id as VARCHAR) in employee_ids_list) > 0 + position(cast(manager_id as VARCHAR) in employee_ids_list) > 0 -- it considers only employees that arent already in the list GROUP BY manager_id ORDER BY diff --git a/generate_supplier_payment_plans.sql b/generate_supplier_payment_plans.sql index 8e9a43c..4b16cca 100644 --- a/generate_supplier_payment_plans.sql +++ b/generate_supplier_payment_plans.sql @@ -1,38 +1,42 @@ USE memory.default; WITH payments AS ( +-- calculate remaining months per invoice and total balance SELECT i.supplier_id , s.name AS supplier_name - , i.invoice_ammount + , i.invoice_amount , i.due_date , date_diff('month', now(), i.due_date) + 1 AS remaining_months - , sum(i.invoice_ammount) over (partition by i.supplier_id) AS total_payment + , sum(i.invoice_amount) over (partition by i.supplier_id) AS total_payment FROM INVOICE i INNER JOIN SUPPLIER s ON s.supplier_id = i.supplier_id ), payments_per_supplier AS ( +-- calculate total amount, remaining months and invoice amount per supplier SELECT supplier_id , supplier_name , max(remaining_months) AS remaining_months - ,sum(invoice_ammount) AS invoice_ammount + ,sum(invoice_amount) AS invoice_amount , max(total_payment) AS total_payment FROM payments GROUP BY supplier_id, supplier_name ), schedule_payment AS ( +-- calculate invoice amount per month due SELECT ps.supplier_id , ps.supplier_name - , ps.invoice_ammount / ps.remaining_months AS monthly_amount + , ps.invoice_amount / ps.remaining_months AS monthly_amount , last_day_of_month(date_add('month', months, now())) AS payment_date FROM payments_per_supplier ps CROSS JOIN unnest(sequence(0, ps.remaining_months - 1)) AS t(months) ), balance AS ( +-- calculate monthly balance to pay per supplier SELECT supplier_id , payment_date @@ -41,7 +45,7 @@ SELECT FROM schedule_payment ) - +-- calculate the balance outstanding per month and supplier SELECT s.supplier_id , s.supplier_name