jon/jon/db/add_views.sql

114 lines
4.3 KiB
SQL

-- Modified version of garfield.inventory_item_overview.
CREATE TEMPORARY VIEW all_inventory_item_overview AS
SELECT
item_id,
inventory_items.item_barcode,
inventory_items.bought,
inventory_items.name,
inventory_items.sales_units,
inventory_items.unit_price,
inventory_items.available,
inventory_items.item_group,
inventory_items.location,
inventory_items.tax_group,
inventory_item_groups.group_name,
COALESCE(b.sales::numeric, 0::numeric) - COALESCE(cancel.count::numeric, 0::numeric) AS sales,
inventory_items.sales_units::numeric - COALESCE(b.sales, 0::bigint)::numeric + COALESCE(c.delta, 0::numeric) + COALESCE(cancel.count::numeric, 0::numeric) AS units_left,
COALESCE(c.delta, 0::numeric) AS correction_delta,
COALESCE(m.mappings::numeric, 0::numeric) AS active_mappings,
m.mappings_array AS active_mappings_array,
locations.location_name
FROM garfield.inventory_items
JOIN garfield.locations ON inventory_items.location = locations.location_id
LEFT JOIN garfield.inventory_item_groups ON inventory_item_groups.group_id = inventory_items.item_group
LEFT JOIN (
SELECT
snack_sales_log.inventory_line AS item_id,
count(*) AS sales
FROM garfield.snack_sales_log
WHERE snack_sales_log.inventory_line IS NOT NULL
AND snack_sales_log.type_id::text = 'SNACK_BUY'::text
GROUP BY snack_sales_log.inventory_line
) b USING (item_id)
LEFT JOIN (
SELECT
snack_sales_log.inventory_line AS item_id,
count(*) AS count
FROM garfield.snack_sales_log
WHERE snack_sales_log.inventory_line IS NOT NULL
AND snack_sales_log.type_id::text = 'SNACK_CANCEL'::text
GROUP BY snack_sales_log.inventory_line
) cancel USING (item_id)
LEFT JOIN (
SELECT
inventory_correction.item_id,
sum(inventory_correction.delta) AS delta
FROM garfield.inventory_correction
GROUP BY inventory_correction.item_id
) c USING (item_id)
LEFT JOIN (
SELECT
count(inventory_map.snack_id) AS mappings,
array_agg(inventory_map.snack_id) AS mappings_array,
inventory_map.inventory_id AS item_id
FROM garfield.inventory_map
JOIN garfield.snacks_available ON snacks_available.snack_available AND snacks_available.snack_id = inventory_map.snack_id
GROUP BY inventory_map.inventory_id
) m USING (item_id)
ORDER BY inventory_items.name;
-- How many *other* active inventory lines exist with the same barcode in the same location that are newer?
CREATE TEMPORARY VIEW more_recent_inventory_lines_with_same_barcode AS
SELECT
a.item_id,
-- It's important not to count(*) here because item_id is NULL
-- when no other inventory lines exist.
count(b.item_id) AS other_lines_count
FROM garfield.inventory_items AS a
LEFT JOIN garfield.inventory_items AS b
ON a.item_barcode = b.item_barcode
AND a.item_id != b.item_id
AND a.location = b.location
AND b.available
AND b.bought > a.bought
GROUP BY a.item_id;
-- We need to create this table so that we can put an index on it
-- Otherwise the join in the consumption graph query becomes much slower
-- Perhaps it would be nicer to use a materialized view instead
DROP TABLE IF EXISTS last_n_days;
CREATE TEMPORARY TABLE last_n_days AS (
SELECT
generate_series(now() - interval '14 days', now(), interval '1 day')::date AS sale_date
);
CREATE UNIQUE INDEX last_n_days_sale_date ON last_n_days (sale_date);
-- Get an array of how often items were sold over the last 14 days
CREATE TEMPORARY VIEW inventory_last_n_days_sales AS
WITH
sales_by_date AS (
SELECT
inventory_line AS item_id,
date_trunc('day', snack_sales_log_timestamp AT TIME ZONE 'UTC+1') AS sale_date,
count(*)::int AS sales
FROM garfield.snack_sales_log
GROUP BY item_id, sale_date
),
beeg AS (
SELECT item_id, sale_date, count(snack_sales_log_timestamp)::int AS sales
FROM garfield.inventory_items
CROSS JOIN last_n_days
LEFT JOIN garfield.snack_sales_log
ON inventory_line = item_id
-- snack_sales_log has an index on snack_sales_log_timestamp to speed up this query
-- If that index doesn't exist the query takes much longer.
AND sale_date = date_trunc('day', snack_sales_log_timestamp AT TIME ZONE 'UTC+1')
WHERE available
GROUP BY item_id, sale_date
ORDER BY item_id, sale_date
)
SELECT item_id, array_agg(sales) AS last_n_days_sales
FROM beeg
GROUP BY item_id