Fix quantity_unit_conversions_resolved view (#2057)

This change makes the view work for products to which only default
conversions apply.
Before, they would not have appeared in the results.
This commit is contained in:
Daniel Albert 2022-12-04 18:39:33 +01:00 committed by GitHub
parent 4be447fc60
commit d889e9d3ad
No known key found for this signature in database
GPG Key ID: 4AEE18F83AFDEB23

View File

@ -15,22 +15,22 @@ WITH RECURSIVE conversion_factors_dup(product_id, from_qu_id, to_qu_id, factor,
AS ( AS (
-- 1. Product "purchase to stock" factors ... -- 1. Product "purchase to stock" factors ...
SELECT SELECT
p.id, id,
p.qu_id_purchase, qu_id_purchase,
p.qu_id_stock, qu_id_stock,
p.qu_factor_purchase_to_stock, qu_factor_purchase_to_stock,
50 50
FROM products p FROM products
WHERE p.qu_id_stock != p.qu_id_purchase WHERE qu_id_stock != qu_id_purchase
UNION -- ... and the inverse factors UNION -- ... and the inverse factors
SELECT SELECT
p.id, id,
p.qu_id_stock, qu_id_stock,
p.qu_id_purchase, qu_id_purchase,
1.0 / p.qu_factor_purchase_to_stock, 1.0 / qu_factor_purchase_to_stock,
50 50
FROM products p FROM products
WHERE p.qu_id_stock != p.qu_id_purchase WHERE qu_id_stock != qu_id_purchase
UNION UNION
@ -53,9 +53,20 @@ AS (
from_qu_id, from_qu_id,
to_qu_id, to_qu_id,
factor, factor,
10 20
FROM quantity_unit_conversions FROM quantity_unit_conversions
WHERE product_id IS NULL WHERE product_id IS NULL
UNION
-- 4. QU conversions with a factor of 1.0 from the stock unit to the stock unit
SELECT
id,
qu_id_stock,
qu_id_stock,
1.0,
10
FROM products
), ),
-- Now, remove duplicate conversions, only retaining the entries with the highest priority -- Now, remove duplicate conversions, only retaining the entries with the highest priority
@ -151,41 +162,22 @@ AS (
AND c.path LIKE ('%/' || s.from_qu_id || '/' || s.to_qu_id || '/%') AND c.path LIKE ('%/' || s.from_qu_id || '/' || s.to_qu_id || '/%')
) )
SELECT * SELECT DISTINCT
FROM ( -1 AS id, -- Dummy, LessQL needs an id column
SELECT DISTINCT c.product_id,
-1 AS id, -- Dummy, LessQL needs an id column c.from_qu_id,
c.product_id, qu_from.name AS from_qu_name,
c.from_qu_id, qu_from.name_plural AS from_qu_name_plural,
qu_from.name AS from_qu_name, c.to_qu_id,
qu_from.name_plural AS from_qu_name_plural, qu_to.name AS to_qu_name,
c.to_qu_id, qu_to.name_plural AS to_qu_name_plural,
qu_to.name AS to_qu_name, FIRST_VALUE(factor) OVER win AS factor,
qu_to.name_plural AS to_qu_name_plural, FIRST_VALUE(c.path) OVER win AS source
FIRST_VALUE(factor) OVER (PARTITION BY product_id, from_qu_id, to_qu_id ORDER BY depth ASC) AS factor, FROM closure c
c.path AS source JOIN quantity_units qu_from
FROM closure c ON c.from_qu_id = qu_from.id
JOIN quantity_units qu_from JOIN quantity_units qu_to
ON c.from_qu_id = qu_from.id ON c.to_qu_id = qu_to.id
JOIN quantity_units qu_to GROUP BY product_id, from_qu_id, to_qu_id
ON c.to_qu_id = qu_to.id WINDOW win AS (PARTITION BY product_id, from_qu_id, to_qu_id ORDER BY depth ASC)
ORDER BY product_id, from_qu_id, to_qu_id;
UNION
-- Also return a conversion from/to the products stock QU (with a factor of 1)
SELECT
-1 AS id, -- Dummy, LessQL needs an id column
p.id AS product_id,
p.qu_id_stock AS from_qu_id,
qu.name AS from_qu_name,
qu.name_plural AS from_qu_name_plural,
p.qu_id_stock AS to_qu_id,
qu.name AS to_qu_name,
qu.name_plural AS to_qu_name_plural,
1.0 AS factor,
'/' || p.qu_id_stock AS source
FROM products p
JOIN quantity_units qu
ON p.qu_id_stock = qu.id
) x
ORDER BY x.product_id, x.from_qu_id, x.to_qu_id;