Skip to content
Open
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
28 changes: 28 additions & 0 deletions calculate_largest_expensors.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,28 @@
WITH expenses_calculated AS (
SELECT
employee_id,
-- Calculate total expense for each record
(unit_price * quantity) AS expense
FROM memory.default.expense
),

expenses_aggregated_filtered AS (
SELECT
employee_id,
-- Sum up the expenses for each employee
SUM(expense) AS total_expense
FROM expenses_calculated
GROUP BY employee_id
)

SELECT
ex.employee_id,
em.manager_id,
ex.total_expense AS total_expensed_amount,
CONCAT(em.first_name, ' ', em.last_name) AS employee_name,
CONCAT(ma.first_name, ' ', ma.last_name) AS manager_name
FROM expenses_aggregated_filtered AS ex
LEFT JOIN memory.default.employee AS em ON ex.employee_id = em.employee_id
LEFT JOIN memory.default.employee AS ma ON em.manager_id = ma.employee_id
WHERE ex.total_expense > 1000 -- Filter for employees with total expenses greater than 1000
ORDER BY ex.total_expense DESC;
21 changes: 21 additions & 0 deletions create_employees.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,21 @@
-- Table creation
CREATE TABLE memory.default.EMPLOYEE (
employee_id TINYINT,
first_name VARCHAR,
last_name VARCHAR,
job_title VARCHAR,
manager_id TINYINT
);


-- Data Insertion
INSERT INTO memory.default.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);
17 changes: 17 additions & 0 deletions create_expenses.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,17 @@
-- Table creation
CREATE TABLE memory.default.EXPENSE (
employee_id TINYINT,
unit_price DECIMAL(8, 2),
quantity TINYINT
);


-- Data Insertion
INSERT INTO memory.default.EXPENSE VALUES
(3, 6.50, 14),
(3, 11, 20),
(3, 22, 18),
(3, 13, 75),
(9, 300, 1),
(4, 40, 9),
(2, 17.50, 4);
52 changes: 52 additions & 0 deletions create_invoices.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,52 @@
CREATE TABLE memory.default.supplier AS
WITH sorted_suppliers AS (
SELECT
name,
-- Assigning a unique ID based on alphabetical order
ROW_NUMBER() OVER (ORDER BY name) AS supplier_id
FROM (
VALUES -- List of suppliers from finance/invoices_due invoices
('Party Animals'),
('Catering Plus'),
('Dave''s Discos'),
('Entertainment tonight'),
('Ice Ice Baby')
)
)

SELECT
CAST(supplier_id AS TINYINT) AS supplier_id,
name
FROM sorted_suppliers;


CREATE TABLE memory.default.invoice AS
WITH transformed_invoices AS (
SELECT
supplier.supplier_id,
t.invoice_amount,
/* Calculating due date based on the number of months from the current date
The due date is the last day of the month that is 'due months' from now */
LAST_DAY_OF_MONTH(
DATE_ADD(
'MONTH', t.due_months, DATE_TRUNC('MONTH', CURRENT_DATE)
)

) AS due_date
FROM
(
VALUES ('Party Animals', 6000, 3),
('Catering Plus', 2000, 2),
('Catering Plus', 1500, 3),
('Dave''s Discos', 500, 1),
('Entertainment tonight', 6000, 3),
('Ice Ice Baby', 4000, 6)
) AS t (supplier_name, invoice_amount, due_months)
LEFT JOIN memory.default.supplier ON t.supplier_name = supplier.name
)

SELECT
supplier_id,
CAST(invoice_amount AS DECIMAL(8, 2)) AS invoice_amount,
due_date
FROM transformed_invoices;
36 changes: 36 additions & 0 deletions find_manager_cycles.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,36 @@
-- Find management cycles using recursive CTE
WITH RECURSIVE managament_chain (employee_id, manager_id, chain) AS (
-- Entry point: select all employees with their direct managers
SELECT
employee_id,
manager_id,
ARRAY[employee_id, manager_id] AS chain
FROM memory.default.employee

UNION ALL
-- Recursive point: follow the chain of managers
SELECT
mc.employee_id, -- Root employee_id
e.manager_id, -- Get next manager in chain
array_union(mc.chain, ARRAY[e.manager_id]) AS chain -- Build chain array
FROM managament_chain AS mc
INNER JOIN memory.default.employee AS e
ON mc.manager_id = e.employee_id
WHERE NOT contains(mc.chain, e.manager_id) -- Prevent overlapping cycles
),

max_chain (employee_id, chain, max_size_chain) AS (
SELECT
employee_id,
chain,
max(cardinality(chain)) -- Get max size of the chain
OVER (PARTITION BY employee_id)
AS max_size_chain
FROM managament_chain
)

SELECT
employee_id,
chain
FROM max_chain
WHERE cardinality(chain) = max_size_chain; -- Select only records with full chain
90 changes: 90 additions & 0 deletions generate_supplier_payment_plans.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,90 @@
WITH invoice_aggregated AS ( -- Agggregate payments per supplier and due date
SELECT
supplier_id,
due_date,
-- Calculate total invoice amount per supplier and due date
sum(invoice_amount)
OVER (PARTITION BY supplier_id, due_date)
AS invoices_total_due_date,
sum(invoice_amount)
OVER (PARTITION BY supplier_id)
AS invoices_total_per_supplier
FROM memory.default.invoice
),

installment_per_invoice AS ( -- Calculate installment for 1 month
SELECT
supplier_id,
due_date,
-- Calculate installment per each invoice by
-- dividing total invoice amount by the number of month until due date
invoices_total_due_date
/ (
(
date_diff(
'MONTH',
date_add('MONTH', 1, date_trunc('month', current_date)), -- Start from next month not current to match results with example
date_trunc('month', due_date)
)
)
+ 1
) AS installment_per_due_date
FROM invoice_aggregated
),

-- Generate months in which installment is paid
installment_per_invoice_per_month AS (
SELECT
i.supplier_id,
i.due_date,
i.installment_per_due_date,
payment_month
FROM installment_per_invoice AS i
CROSS JOIN
-- Explode due date into months between next month and due date
unnest(
sequence(
date_add('MONTH', 1, date_trunc('month', current_date)),
date_trunc('month', due_date),
INTERVAL '1' MONTH
)
)
),

total_installment_per_month AS ( -- Aggregate installments
SELECT
supplier_id,
payment_month,
sum(installment_per_due_date) AS payment_amount
FROM installment_per_invoice_per_month
GROUP BY supplier_id, payment_month
),

balance_outstanding_calculated AS ( -- Calculate balance outstanding per month
SELECT DISTINCT
t1.supplier_id,
s.name AS supplier_name,
t1.payment_amount,
t1.payment_month AS payment_date,
-- Sum of all payments that will be paid in the future
coalesce(
sum(t2.payment_amount)
OVER (PARTITION BY t1.supplier_id, t1.payment_month),
0
) AS balance_outstanding
FROM total_installment_per_month AS t1
LEFT JOIN
total_installment_per_month AS t2
ON
t1.supplier_id = t2.supplier_id
AND t1.payment_month < t2.payment_month -- Future payments
LEFT JOIN memory.default.supplier AS s ON t1.supplier_id = s.supplier_id
)

SELECT
supplier_id,
supplier_name,
payment_amount,
balance_outstanding,
payment_date
FROM balance_outstanding_calculated;