jon/jon/db/get_inventory_report.sql

38 lines
1.2 KiB
SQL

WITH
most_recent_sales AS (
SELECT DISTINCT ON (inventory_line)
inventory_line, snack_sales_log_id, snack_sales_log_timestamp AS most_recent_sale
FROM garfield.snack_sales_log
ORDER BY inventory_line ASC, snack_sales_log_timestamp DESC
),
enhanced_overview AS (
SELECT
inventory_items.item_id,
inventory_items.item_barcode,
inventory_items.name,
units_left,
location_name,
location,
CASE
WHEN snack_sales_log_id IS NULL THEN 0
ELSE sales / (EXTRACT(EPOCH FROM most_recent_sale) - EXTRACT(EPOCH FROM bought)) * 24 * 3600
END AS per_day
FROM garfield.inventory_item_overview
LEFT JOIN garfield.inventory_items USING (item_id)
LEFT JOIN most_recent_sales ON item_id = inventory_line
)
SELECT
*,
CASE
WHEN per_day = 0 THEN NULL
ELSE GREATEST(0, units_left / per_day)
END AS days_left,
CASE
WHEN per_day = 0 THEN NULL
ELSE GREATEST(0, (60 - GREATEST(0, units_left / per_day)) * per_day)
END AS for_two_months
FROM enhanced_overview
WHERE (%(location_id)s IS NULL OR location = %(location_id)s)
ORDER BY days_left ASC, per_day DESC