2022-12-04 12:33:12 +01:00
DROP VIEW quantity_unit_conversions_resolved ;
CREATE VIEW quantity_unit_conversions_resolved
AS
2022-12-04 12:18:18 +01:00
2022-12-04 12:33:12 +01:00
/*
First , determine conversions that are a single step .
There may be multiple definitions for conversions between two units
( e . g . due to purchase - to - stock , product - specific and default conversions ) ,
thus priorities are used to disambiguate conversions .
Later , we ' ll only use the factor with the highest priority to convert between two units.
* /
2022-12-04 12:18:18 +01:00
2022-12-04 12:33:12 +01:00
WITH RECURSIVE conversion_factors_dup ( product_id , from_qu_id , to_qu_id , factor , priority )
2022-12-04 12:18:18 +01:00
AS (
-- 1. Product "purchase to stock" factors ...
SELECT
2022-12-04 18:39:33 +01:00
id ,
qu_id_purchase ,
qu_id_stock ,
qu_factor_purchase_to_stock ,
2022-12-04 12:33:12 +01:00
50
2022-12-04 18:39:33 +01:00
FROM products
WHERE qu_id_stock ! = qu_id_purchase
2022-12-04 12:33:12 +01:00
UNION -- ... and the inverse factors
2022-12-04 12:18:18 +01:00
SELECT
2022-12-04 18:39:33 +01:00
id ,
qu_id_stock ,
qu_id_purchase ,
1 . 0 / qu_factor_purchase_to_stock ,
2022-12-04 12:33:12 +01:00
50
2022-12-04 18:39:33 +01:00
FROM products
WHERE qu_id_stock ! = qu_id_purchase
2022-12-04 12:18:18 +01:00
UNION
-- 2. Product specific QU overrides
-- Note that the quantity_unit_conversions table already contains both conversion directions for every conversion.
SELECT
2022-12-04 12:33:12 +01:00
product_id ,
from_qu_id ,
to_qu_id ,
factor ,
30
2022-12-04 12:18:18 +01:00
FROM quantity_unit_conversions
WHERE product_id IS NOT NULL
UNION
2022-12-04 12:33:12 +01:00
-- 3. Default QU conversions are handled in a later CTE, as we can't determine yet, for which products they are applicable.
2022-12-04 12:18:18 +01:00
SELECT
2022-12-04 12:33:12 +01:00
product_id ,
from_qu_id ,
to_qu_id ,
factor ,
2022-12-04 18:39:33 +01:00
20
2022-12-04 12:18:18 +01:00
FROM quantity_unit_conversions
WHERE product_id IS NULL
2022-12-04 18:39:33 +01:00
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
2022-12-04 12:18:18 +01:00
) ,
-- Now, remove duplicate conversions, only retaining the entries with the highest priority
2022-12-04 12:33:12 +01:00
conversion_factors ( product_id , from_qu_id , to_qu_id , factor )
2022-12-04 12:18:18 +01:00
AS (
2022-12-04 12:33:12 +01:00
SELECT
product_id ,
from_qu_id ,
to_qu_id ,
FIRST_VALUE ( factor ) OVER win
2022-12-04 12:18:18 +01:00
FROM conversion_factors_dup
GROUP BY product_id , from_qu_id , to_qu_id
2022-12-04 12:33:12 +01:00
WINDOW win AS ( PARTITION BY product_id , from_qu_id , to_qu_id ORDER BY priority DESC )
2022-12-04 12:18:18 +01:00
) ,
-- Now build the closure of posisble conversions using a recursive CTE
2022-12-04 12:33:12 +01:00
closure ( depth , product_id , path , from_qu_id , to_qu_id , factor )
2022-12-04 12:18:18 +01:00
AS (
-- As a base case, select the conversions that refer to a concrete product
SELECT
2022-12-04 12:33:12 +01:00
1 as depth ,
product_id ,
' / ' | | from_qu_id | | ' / ' | | to_qu_id | | ' / ' , -- We need to keep track of the conversion path in order to prevent cycles
from_qu_id ,
to_qu_id ,
factor
2022-12-04 12:18:18 +01:00
FROM conversion_factors
WHERE product_id IS NOT NULL
UNION
-- First recursive case: Add a product-associated conversion to the chain
SELECT
2022-12-04 12:33:12 +01:00
c . depth + 1 ,
c . product_id ,
2022-12-04 12:18:18 +01:00
c . path | | s . to_qu_id | | ' / ' ,
2022-12-04 12:33:12 +01:00
c . from_qu_id ,
s . to_qu_id ,
2022-12-04 12:18:18 +01:00
c . factor * s . factor
FROM closure c
JOIN conversion_factors s
2022-12-04 12:33:12 +01:00
ON c . product_id = s . product_id
2022-12-04 12:18:18 +01:00
AND c . to_qu_id = s . from_qu_id
WHERE c . path NOT LIKE ( ' %/ ' | | s . to_qu_id | | ' /% ' ) -- prevent cycles
UNION
-- Second recursive case: Add a default unit conversion to the *start* of the conversion chain
SELECT
2022-12-04 12:33:12 +01:00
c . depth + 1 ,
c . product_id ,
2022-12-04 12:18:18 +01:00
' / ' | | s . from_qu_id | | c . path ,
2022-12-04 12:33:12 +01:00
s . from_qu_id ,
c . to_qu_id ,
2022-12-04 12:18:18 +01:00
s . factor * c . factor
FROM closure c
JOIN conversion_factors s
2022-12-04 12:33:12 +01:00
ON s . to_qu_id = c . from_qu_id
2022-12-04 12:18:18 +01:00
AND s . product_id IS NULL
2022-12-04 12:33:12 +01:00
WHERE NOT EXISTS ( SELECT 1 FROM conversion_factors ci WHERE ci . product_id = c . product_id AND ci . from_qu_id = s . from_qu_id AND ci . to_qu_id = s . to_qu_id ) -- Do this only, if there is no product_specific conversion between the units in s
2022-12-04 19:02:15 +01:00
AND c . path NOT LIKE ( ' %/ ' | | s . from_qu_id | | ' /% ' )
2022-12-04 12:18:18 +01:00
UNION
-- Third recursive case: Add a default unit conversion to the *end* of the conversion chain
SELECT
2022-12-04 12:33:12 +01:00
c . depth + 1 ,
c . product_id ,
2022-12-04 12:18:18 +01:00
c . path | | s . to_qu_id | | ' / ' ,
2022-12-04 12:33:12 +01:00
c . from_qu_id ,
s . to_qu_id ,
2022-12-04 12:18:18 +01:00
c . factor * s . factor
FROM closure c
JOIN conversion_factors s
2022-12-04 12:33:12 +01:00
ON c . to_qu_id = s . from_qu_id
2022-12-04 12:18:18 +01:00
AND s . product_id IS NULL
2022-12-04 12:33:12 +01:00
WHERE NOT EXISTS ( SELECT 1 FROM conversion_factors ci WHERE ci . product_id = c . product_id AND ci . from_qu_id = s . from_qu_id AND ci . to_qu_id = s . to_qu_id ) -- Do this only, if there is no product_specific conversion between the units in s
2022-12-04 19:02:15 +01:00
AND c . path NOT LIKE ( ' %/ ' | | s . to_qu_id | | ' /% ' )
2022-12-04 12:18:18 +01:00
UNION
-- Fourth case: Add the default unit conversions that are reachable by a given product.
-- We cannot start with them directly, as we only want to add default conversions,
2022-12-04 19:02:15 +01:00
-- where at least one of the units is 'reachable' from the product's stock quantity unit.
2022-12-04 12:18:18 +01:00
-- Thus we add these cases here.
SELECT DISTINCT
1 , c . product_id ,
' / ' | | s . from_qu_id | | ' / ' | | s . to_qu_id | | ' / ' ,
s . from_qu_id , s . to_qu_id ,
s . factor
FROM closure c , conversion_factors s
2022-12-04 12:33:12 +01:00
WHERE NOT EXISTS ( SELECT 1 FROM conversion_factors ci WHERE ci . product_id = c . product_id AND ci . from_qu_id = s . from_qu_id AND ci . to_qu_id = s . to_qu_id )
2022-12-04 19:02:15 +01:00
AND c . path LIKE ( ' %/ ' | | s . from_qu_id | | ' / ' | | s . to_qu_id | | ' /% ' )
2022-12-04 12:18:18 +01:00
)
2022-12-04 18:39:33 +01:00
SELECT DISTINCT
- 1 AS id , -- Dummy, LessQL needs an id column
c . product_id ,
c . from_qu_id ,
qu_from . name AS from_qu_name ,
qu_from . name_plural AS from_qu_name_plural ,
c . to_qu_id ,
qu_to . name AS to_qu_name ,
qu_to . name_plural AS to_qu_name_plural ,
FIRST_VALUE ( factor ) OVER win AS factor ,
FIRST_VALUE ( c . path ) OVER win AS source
FROM closure c
JOIN quantity_units qu_from
ON c . from_qu_id = qu_from . id
JOIN quantity_units qu_to
ON c . to_qu_id = qu_to . id
GROUP BY product_id , from_qu_id , to_qu_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 ;