price_api/tables/lastpricedetail.pg.sql

142 lines
4.2 KiB
SQL

REFRESH MATERIALIZED VIEW pricequote.lastpricedetail;
--DROP MATERIALIZED VIEW pricequote.lastpricedetail
CREATE MATERIALIZED VIEW pricequote.lastpricedetail AS
WITH base AS (
SELECT
customer,
partgroup,
part,
dataseg,
version,
qtyord AS qty,
ROUND(sales_usd/qty,5) AS price,
odate,
ordnum,
quoten
FROM rlarp.osm_stack
WHERE
version IN ('Actual','Quotes')
AND customer IS NOT NULL
AND fs_line = '41010'
AND calc_status <> 'CANCELLED'
AND qty <> 0
AND partgroup <> ''
AND version IN ('Actual', 'Quotes')
),
ranked AS (
SELECT b.*,
-- Most recent sale (Actuals first, newest date first)
ROW_NUMBER() OVER (
PARTITION BY customer, partgroup
ORDER BY (version = 'Actual') DESC,
odate DESC NULLS LAST
) AS rn_mrs,
-- Most recent quote (Quotes first, newest date first)
ROW_NUMBER() OVER (
PARTITION BY customer, partgroup
ORDER BY (version = 'Quotes') DESC,
odate DESC NULLS LAST
) AS rn_mrq,
-- Largest volume sale in last year (those inside window first)
ROW_NUMBER() OVER (
PARTITION BY customer, partgroup
ORDER BY (version = 'Actual' AND odate >= CURRENT_DATE - INTERVAL '1 year') DESC,
qty DESC NULLS LAST
) AS rn_lvs,
-- Largest volume quote in last year (those inside window first)
ROW_NUMBER() OVER (
PARTITION BY customer, partgroup
ORDER BY (version = 'Quotes' AND odate >= CURRENT_DATE - INTERVAL '1 year') DESC,
qty DESC NULLS LAST
) AS rn_lvq,
-- Per dataseg/version: most recent (version fixed in partition, so just date)
ROW_NUMBER() OVER (
PARTITION BY customer, partgroup, dataseg, version
ORDER BY odate DESC NULLS LAST
) AS rn_dss,
ROW_NUMBER() OVER (
PARTITION BY customer, partgroup, dataseg, version
ORDER BY odate DESC NULLS LAST
) AS rn_dsq
FROM base b
),
flagged AS (
SELECT *,
CASE WHEN rn_mrs = 1 THEN 'mrs' END AS f1,
CASE WHEN rn_mrq = 1 THEN 'mrq' END AS f2,
CASE WHEN rn_lvs = 1 THEN 'lvs' END AS f3,
CASE WHEN rn_lvq = 1 THEN 'lvq' END AS f4,
CASE WHEN rn_dss = 1 THEN 'dss' END AS f5,
CASE WHEN rn_dsq = 1 THEN 'dsq' END AS f6
FROM ranked
WHERE
rn_mrs = 1 OR rn_mrq = 1 OR rn_lvs = 1 OR rn_lvq = 1 OR rn_dss = 1 OR rn_dsq = 1
)
--SELECT * FROM flagged WHERE customer = 'HYBELS' AND partgroup = 'HZP3E100'
,exploded_flags AS (
SELECT
customer, partgroup, part, dataseg, version, qty, price, odate, ordnum, quoten,
unnest(ARRAY[f1, f2, f3, f4, f5, f6]) AS flag
FROM flagged
),
serialized_flags AS (
SELECT
customer,
partgroup,
dataseg,
flag,
jsonb_build_object(
'version', version,
'datasegment', dataseg,
'part', part,
'qty', qty,
'price', price,
'odate', odate,
'ordnum', ordnum,
'quoten', quoten,
'flag', flag
) AS json_piece
FROM exploded_flags
WHERE flag IS NOT NULL
),
flag_json AS (
SELECT
customer,
partgroup,
jsonb_object_agg(flag, json_piece) AS global_flags
FROM serialized_flags
WHERE flag IN ('mrs', 'mrq', 'lvs', 'lvq')
GROUP BY customer, partgroup
),
seg_pieces AS (
SELECT
customer,
partgroup,
dataseg,
jsonb_object_agg(flag, json_piece) AS seg_flags
FROM serialized_flags
WHERE flag IN ('dss', 'dsq')
GROUP BY customer, partgroup, dataseg
),
seg_json AS (
SELECT
customer,
partgroup,
jsonb_object_agg(dataseg, seg_flags) AS dataseg_block
FROM seg_pieces
GROUP BY customer, partgroup
)
SELECT
COALESCE(f.customer, s.customer) AS customer,
COALESCE(f.partgroup, s.partgroup) AS partgroup,
(COALESCE(f.global_flags, '{}'::jsonb) || COALESCE(s.dataseg_block, '{}'::jsonb)) AS part_stats
FROM flag_json f
FULL OUTER JOIN seg_json s
ON f.customer = s.customer AND f.partgroup = s.partgroup
WITH DATA;
--SELECT * FROM pricequote.lastpricedetail;
CREATE INDEX lastpricedetail_idx ON pricequote.lastpricedetail(customer, partgroup);