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
23 changes: 23 additions & 0 deletions calculate_largest_expensors.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,23 @@
-- Report employees whose total expensed amount exceeds 1,000

WITH aggregated_expenses AS (
-- Aggregate expenses per employee
SELECT
employee_id,
SUM(unit_price * quantity) AS total_expensed_amount
FROM memory.default.expense
GROUP BY employee_id
)
SELECT
e.employee_id,
CONCAT(e.first_name, ' ', e.last_name) AS employee_name,
e.manager_id,
CONCAT(m.first_name, ' ', m.last_name) AS manager_name,
ag.total_expensed_amount
FROM aggregated_expenses ag
JOIN memory.default.employee e
ON e.employee_id = ag.employee_id
LEFT JOIN memory.default.employee m
ON m.employee_id = e.manager_id
WHERE ag.total_expensed_amount > 1000
ORDER BY ag.total_expensed_amount DESC;
23 changes: 23 additions & 0 deletions create_employees.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,23 @@
-- Rebuild SExI: create and populate EMPLOYEE table in the memory.default schema

-- Employees table: stores company employee information
DROP TABLE IF EXISTS memory.default.employee;
CREATE TABLE memory.default.employee (
employee_id TINYINT NOT NULL,
first_name VARCHAR NOT NULL,
last_name VARCHAR NOT NULL,
job_title VARCHAR NOT NULL,
manager_id TINYINT -- nullable if top-level executive
);

-- Populate the table with initial data
INSERT INTO memory.default.employee (employee_id, first_name, last_name, job_title, manager_id) 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);
19 changes: 19 additions & 0 deletions create_expenses.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,19 @@
-- Rebuild SExI: create and populate EXPENSE table in the memory.default schema

-- Expenses table: tracks individual employee expenses
DROP TABLE IF EXISTS memory.default.expense;
CREATE TABLE memory.default.expense (
employee_id TINYINT NOT NULL,
unit_price DECIMAL(8,2) NOT NULL,
quantity TINYINT NOT NULL
);

-- Populate the EXPENSE table with initial data
INSERT INTO memory.default.expense (employee_id, unit_price, quantity) VALUES
(3, 6.50, 14), -- Alex Jacobson
(3, 11.00, 20), -- Alex Jacobson
(3, 22.00, 18), -- Alex Jacobson
(3, 13.00, 75), -- Alex Jacobson
(9, 300.00, 1), -- Andrea Ghibaudi
(4, 40.00, 9), -- Darren Poynton
(2, 17.50, 4); -- Umberto Torrielli
33 changes: 33 additions & 0 deletions create_invoices.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,33 @@
-- Rebuild SExI: create and populate SUPPLIER and INVOICE tables in the memory.default schema

DROP TABLE IF EXISTS memory.default.invoice;
DROP TABLE IF EXISTS memory.default.supplier;

CREATE TABLE memory.default.supplier (
supplier_id TINYINT NOT NULL,
name VARCHAR NOT NULL
);

-- Populate SUPPLIER table
INSERT INTO memory.default.supplier (supplier_id, name) VALUES
(1, 'Catering Plus'),
(2, 'Dave''s Discos'),
(3, 'Entertainment tonight'),
(4, 'Ice Ice Baby'),
(5, 'Party Animals');

-- Create INVOICE table
CREATE TABLE memory.default.invoice (
supplier_id TINYINT NOT NULL,
invoice_ammount DECIMAL(8, 2) NOT NULL,
due_date DATE NOT NULL
);

-- Populate INVOICE table
INSERT INTO memory.default.invoice (supplier_id, invoice_ammount, due_date) VALUES
(5, 6000.0, DATE_TRUNC('month', CURRENT_DATE + INTERVAL '3' MONTH) + INTERVAL '1' MONTH - INTERVAL '1' DAY),
(1, 2000.0, DATE_TRUNC('month', CURRENT_DATE + INTERVAL '2' MONTH) + INTERVAL '1' MONTH - INTERVAL '1' DAY),
(1, 1500.0, DATE_TRUNC('month', CURRENT_DATE + INTERVAL '3' MONTH) + INTERVAL '1' MONTH - INTERVAL '1' DAY),
(2, 500.0, DATE_TRUNC('month', CURRENT_DATE + INTERVAL '1' MONTH) + INTERVAL '1' MONTH - INTERVAL '1' DAY),
(3, 6000.0, DATE_TRUNC('month', CURRENT_DATE + INTERVAL '3' MONTH) + INTERVAL '1' MONTH - INTERVAL '1' DAY),
(4, 4000.0, DATE_TRUNC('month', CURRENT_DATE + INTERVAL '6' MONTH) + INTERVAL '1' MONTH - INTERVAL '1' DAY);
7 changes: 7 additions & 0 deletions data_tests/employee_integrity.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,7 @@
USE memory.default;

SELECT CASE WHEN COUNT(*) = 0 THEN 'PASS' ELSE 'FAIL' END AS result,
COUNT(*) AS invalid_manager_refs
FROM employee
WHERE manager_id IS NOT NULL
AND manager_id NOT IN (SELECT employee_id FROM employee);
8 changes: 8 additions & 0 deletions data_tests/employee_row_count.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,8 @@
USE memory.default;

WITH stats AS (
SELECT COUNT(*) AS cnt FROM employee
)
SELECT CASE WHEN cnt = 9 THEN 'PASS' ELSE 'FAIL' END AS result,
cnt
FROM stats;
11 changes: 11 additions & 0 deletions data_tests/employee_uniqueness.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,11 @@
USE memory.default;

WITH d AS (
SELECT employee_id, COUNT(*) AS c
FROM employee
GROUP BY employee_id
HAVING COUNT(*) > 1
)
SELECT CASE WHEN COUNT(*) = 0 THEN 'PASS' ELSE 'FAIL' END AS result,
COUNT(*) AS duplicate_ids
FROM d;
7 changes: 7 additions & 0 deletions data_tests/expense_integrity.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,7 @@
USE memory.default;

SELECT CASE WHEN COUNT(*) = 0 THEN 'PASS' ELSE 'FAIL' END AS result,
COUNT(*) AS orphan_rows
FROM expense e
LEFT JOIN employee emp USING (employee_id)
WHERE emp.employee_id IS NULL;
7 changes: 7 additions & 0 deletions data_tests/expense_positive_prices_quantities.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,7 @@
USE memory.default;

SELECT CASE WHEN COUNT(*) = 0 THEN 'PASS' ELSE 'FAIL' END AS result,
COUNT(*) AS bad_rows
FROM expense
WHERE unit_price <= 0
OR quantity <= 0;
6 changes: 6 additions & 0 deletions data_tests/invoice_due_date.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,6 @@
USE memory.default;

SELECT CASE WHEN COUNT(*) = 0 THEN 'PASS' ELSE 'FAIL' END AS result,
COUNT(*) AS past_due_rows
FROM invoice
WHERE due_date <= CURRENT_DATE;
6 changes: 6 additions & 0 deletions data_tests/invoice_invoice_ammount.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,6 @@
USE memory.default;

SELECT CASE WHEN COUNT(*) = 0 THEN 'PASS' ELSE 'FAIL' END AS result,
COUNT(*) AS non_positive_amounts
FROM invoice
WHERE invoice_ammount <= 0;
1 change: 1 addition & 0 deletions data_tests/test
Original file line number Diff line number Diff line change
@@ -0,0 +1 @@

31 changes: 31 additions & 0 deletions find_manager_cycles.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,31 @@
-- Detect manager approval cycles in the EMPLOYEE hierarchy

WITH RECURSIVE manager_path (employee_id, manager_id, path, cycle_detected) AS (
-- Base row for each employee
SELECT
employee_id,
manager_id,
ARRAY[employee_id] AS path,
FALSE AS cycle_detected
FROM memory.default.employee

UNION ALL

-- Recurse up the hierarchy
SELECT
e.employee_id,
e.manager_id,
mp.path || ARRAY[e.employee_id] AS path,
contains(mp.path, e.employee_id) AS cycle_detected
FROM memory.default.employee e
JOIN manager_path mp
ON e.employee_id = mp.manager_id
WHERE NOT mp.cycle_detected -- Stop expanding once a cycle is found
AND e.manager_id IS NOT NULL
)

SELECT
employee_id,
array_join(path, ',') AS manager_cycle_path
FROM manager_path
WHERE cycle_detected;
108 changes: 108 additions & 0 deletions generate_supplier_payment_plans.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,108 @@
-- ==============================================================
-- Monthly payment plan for all suppliers
-- Each invoice is split into equal monthly instalments that finish in the month *before* its due date
-- A supplier receives at most one payment row per month
-- First payment is the end of the current month
-- The final row per supplier is rounded/adjusted so the running balance never drifts by a cent
-- ==============================================================

WITH invoices AS (
-- One row per invoice
SELECT
i.supplier_id,
i.invoice_ammount,
i.due_date,
date_trunc('month', CURRENT_DATE) AS start_month,
date_trunc('month', i.due_date) - INTERVAL '1' MONTH AS last_pay_month,
date_diff( -- full months *before* the due month
'month',
date_trunc('month', CURRENT_DATE),
date_trunc('month', i.due_date)
) AS pay_months
FROM memory.default.invoice i
),
inv_schedule AS (
-- Spread each invoice across its pay-months
SELECT
supplier_id,
invoice_ammount,
pay_months,
sequence(start_month, last_pay_month, INTERVAL '1' MONTH) AS months_seq
FROM invoices
),
exploded AS (
-- One row per invoice-month, un-rounded
SELECT
supplier_id,
date_trunc('month', m) + INTERVAL '1' MONTH - INTERVAL '1' DAY
AS payment_date, -- month-end
CAST(invoice_ammount / pay_months AS DECIMAL(12,2)) AS raw_payment
FROM inv_schedule
CROSS JOIN UNNEST(months_seq) AS t(m)
),
month_sum AS (
-- Aggregate if a supplier has >1 invoice in a month
SELECT
supplier_id,
payment_date,
SUM(raw_payment) AS month_payment_raw
FROM exploded
GROUP BY supplier_id, payment_date
),
running AS (
-- Running totals per supplier (pre-rounding)
SELECT
supplier_id,
payment_date,
month_payment_raw,
SUM(month_payment_raw) OVER (
PARTITION BY supplier_id
ORDER BY payment_date
) AS cumulative_paid_raw,
SUM(month_payment_raw) OVER (
PARTITION BY supplier_id
) AS grand_total
FROM month_sum
),
final_per_month AS (
-- Round; adjust the last month per supplier
SELECT
supplier_id,
payment_date,
CASE
WHEN payment_date = MAX(payment_date) OVER (PARTITION BY supplier_id)
THEN -- final month - fix rounding so total = invoice sum
ROUND(
grand_total
- LAG(cumulative_paid_raw,1,0)
OVER (PARTITION BY supplier_id ORDER BY payment_date),
2
)
ELSE
ROUND(month_payment_raw, 2)
END AS payment_amount
FROM running
),
balances AS (
-- Compute cumulative paid & outstanding balance
SELECT
supplier_id,
payment_date,
payment_amount,
SUM(payment_amount) OVER (
PARTITION BY supplier_id
ORDER BY payment_date
) AS cumulative_paid,
SUM(payment_amount) OVER (PARTITION BY supplier_id) AS grand_total
FROM final_per_month
)
SELECT
s.supplier_id,
s.name AS supplier_name,
b.payment_amount,
ROUND(b.grand_total - b.cumulative_paid, 2) AS balance_outstanding,
b.payment_date
FROM balances b
JOIN memory.default.supplier s
ON s.supplier_id = b.supplier_id
ORDER BY s.supplier_id, b.payment_date;