Merged the by @alkuzman contributed new quantity_unit_conversions_resolved view (closes #2297)

This commit is contained in:
Bernd Bestel 2023-08-19 08:13:34 +02:00
parent 03f9ba45ea
commit 9b119da8e0
No known key found for this signature in database
GPG Key ID: 71BD34C0D4891300
2 changed files with 357 additions and 63 deletions

View File

@ -2,10 +2,64 @@ DROP VIEW quantity_unit_conversions_resolved;
CREATE VIEW quantity_unit_conversions_resolved
AS
-- First, determine conversions that are a single step.
WITH RECURSIVE conversion_factors(product_id, from_qu_id, to_qu_id, factor)
WITH RECURSIVE
-- Default QU conversions are handled in a later CTE, as we can't determine yet, for which products they are applicable.
default_conversions(from_qu_id, to_qu_id, factor)
AS (
-- Priority 1: Product specific QU overrides
SELECT
from_qu_id,
to_qu_id,
factor
FROM quantity_unit_conversions
WHERE product_id IS NULL
),
-- First find the closure for all default conversions. This will allow for further pruning when looking for product closure.
default_closure(depth, from_qu_id, to_qu_id, factor, path)
AS (
-- As a base case, select all available default conversions
SELECT
1 as depth,
from_qu_id,
to_qu_id,
factor,
'/' || from_qu_id || '/' || to_qu_id || '/' -- We need to keep track of the conversion path in order to prevent cycles
FROM default_conversions
UNION
-- Recursive case: Find all paths
SELECT
c.depth + 1,
c.from_qu_id,
s.to_qu_id,
c.factor * s.factor,
c.path || s.to_qu_id || '/'
FROM default_closure c
JOIN default_conversions s
ON c.to_qu_id = s.from_qu_id
WHERE c.path NOT LIKE ('%/' || s.to_qu_id || '/%') -- Prevent cycles
AND NOT EXISTS(SELECT 1 FROM default_conversions ci WHERE ci.from_qu_id = c.from_qu_id AND ci.to_qu_id = s.to_qu_id) -- Prune if one of the existing conversions repeats (saves a lot of processing time)
),
default_closure_distinct(from_qu_id, to_qu_id, factor, path)
AS (
SELECT DISTINCT
from_qu_id,
to_qu_id,
FIRST_VALUE(factor) OVER win AS factor,
FIRST_VALUE(path) OVER win AS path
FROM default_closure
GROUP BY from_qu_id, to_qu_id
WINDOW win AS (PARTITION BY from_qu_id, to_qu_id ORDER BY depth)
ORDER BY from_qu_id, to_qu_id
),
product_conversions(product_id, from_qu_id, to_qu_id, factor)
AS (
-- Priority 1: Product-specific QU overrides
-- Note that the quantity_unit_conversions table already contains both conversion directions for every conversion.
SELECT
product_id,
@ -26,21 +80,9 @@ AS (
FROM products
),
default_conversions(from_qu_id, to_qu_id, factor)
product_closure(depth, product_id, from_qu_id, to_qu_id, factor, path)
AS (
-- Default QU conversions are handled in a later CTE, as we can't determine yet, for which products they are applicable.
SELECT
from_qu_id,
to_qu_id,
factor
FROM quantity_unit_conversions
WHERE product_id IS NULL
),
-- Now build the closure of posisble conversions using a recursive CTE
closure(depth, product_id, from_qu_id, to_qu_id, factor, path)
AS (
-- As a base case, select the conversions that refer to a concrete product
-- As a base case, select all available product-specific conversions
SELECT
1 as depth,
product_id,
@ -48,11 +90,11 @@ AS (
to_qu_id,
factor,
'/' || from_qu_id || '/' || to_qu_id || '/' -- We need to keep track of the conversion path in order to prevent cycles
FROM conversion_factors
FROM product_conversions
UNION
-- First recursive case: Add a product-associated conversion to the chain
-- Recursive case: Find all paths
SELECT
c.depth + 1,
c.product_id,
@ -60,31 +102,84 @@ AS (
s.to_qu_id,
c.factor * s.factor,
c.path || s.to_qu_id || '/'
FROM closure c
JOIN conversion_factors s
FROM product_closure c
JOIN product_conversions s
ON c.product_id = s.product_id
AND c.to_qu_id = s.from_qu_id
WHERE c.path NOT LIKE ('%/' || s.to_qu_id || '/%') -- Prevent cycles
AND NOT EXISTS(SELECT 1 FROM product_conversions ci WHERE ci.product_id = c.product_id AND ci.from_qu_id = c.from_qu_id AND ci.to_qu_id = s.to_qu_id) -- Prune if one of the existing conversions repeats (saves a lot of processing time)
),
UNION
product_closure_distinct(product_id, from_qu_id, to_qu_id, factor, path)
AS (
SELECT DISTINCT
product_id,
from_qu_id,
to_qu_id,
FIRST_VALUE(factor) OVER win AS factor,
FIRST_VALUE(path) OVER win AS path
FROM product_closure
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)
ORDER BY product_id, from_qu_id, to_qu_id
),
-- Second recursive case: Add a default unit conversion to the *start* of the conversion chain
-- Now we connect the two closures by adding the reachable conversions from product specific conversions to default conversions
product_reachable(product_id, from_qu_id, to_qu_id, factor, path)
AS (
SELECT
c.depth + 1,
c.product_id,
s.from_qu_id,
c.to_qu_id,
s.factor * c.factor,
'/' || s.from_qu_id || c.path
FROM closure c
JOIN default_conversions s
ON s.to_qu_id = c.from_qu_id
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
AND c.path NOT LIKE ('%/' || s.from_qu_id || '/%') -- Prevent cycles
product_id,
from_qu_id,
to_qu_id,
factor,
path
FROM product_closure_distinct
UNION
-- Third recursive case: Add a default unit conversion to the *end* of the conversion chain
SELECT
cd.product_id,
dcd.from_qu_id,
dcd.to_qu_id,
dcd.factor,
'/' || dcd.from_qu_id || '/' || dcd.to_qu_id || '/'
FROM product_closure_distinct cd
JOIN default_closure_distinct dcd
ON cd.to_qu_id = dcd.from_qu_id
OR cd.to_qu_id = dcd.to_qu_id
WHERE NOT EXISTS(SELECT 1 FROM product_closure_distinct ci WHERE ci.product_id = cd.product_id AND ci.from_qu_id = dcd.from_qu_id AND ci.to_qu_id = dcd.to_qu_id)
),
product_reachable_distinct(product_id, from_qu_id, to_qu_id, factor, path)
AS (
SELECT DISTINCT
product_id,
from_qu_id,
to_qu_id,
FIRST_VALUE(factor) OVER win AS factor,
FIRST_VALUE(path) OVER win AS path
FROM product_reachable
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 product_id, from_qu_id, to_qu_id
),
-- Finally we build the combined closure
closure_final(depth, product_id, from_qu_id, to_qu_id, factor, path)
AS (
-- As a base case, select the product closure
SELECT
1,
product_id,
from_qu_id,
to_qu_id,
factor,
path -- We need to keep track of the conversion path in order to prevent cycles
FROM product_reachable_distinct
UNION
-- Add a default unit conversion to the *end* of the conversion chain
SELECT
c.depth + 1,
c.product_id,
@ -92,29 +187,12 @@ AS (
s.to_qu_id,
c.factor * s.factor,
c.path || s.to_qu_id || '/'
FROM closure c
JOIN default_conversions s
ON c.to_qu_id = s.from_qu_id
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
AND c.path NOT LIKE ('%/' || s.to_qu_id || '/%') -- Prevent cycles
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,
-- where at least one of the units is 'reachable' from the product's stock quantity unit
-- (and thus the conversion is sensible). Thus we add these cases here.
SELECT
1,
c.product_id,
s.from_qu_id,
s.to_qu_id,
s.factor,
'/' || s.from_qu_id || '/' || s.to_qu_id || '/'
FROM closure c
JOIN default_conversions s
ON c.path LIKE ('%/' || s.from_qu_id || '/' || s.to_qu_id || '/%') -- the conversion has been used as part of another path ...
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) -- ... and is itself new
FROM closure_final c
JOIN product_reachable_distinct s
ON c.product_id = s.product_id
AND c.to_qu_id = s.from_qu_id
WHERE c.path NOT LIKE ('%/' || s.to_qu_id || '/%') -- Prevent cycles
AND NOT EXISTS(SELECT 1 FROM product_reachable_distinct ci WHERE ci.product_id = c.product_id AND ci.from_qu_id = c.from_qu_id AND ci.to_qu_id = s.to_qu_id) -- Prune (if already exists)
)
SELECT DISTINCT
@ -126,13 +204,13 @@ SELECT DISTINCT
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.factor) OVER win AS factor,
FIRST_VALUE(c.path) OVER win AS path
FROM closure c
FROM closure_final 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;
GROUP BY c.product_id, c.from_qu_id, c.to_qu_id
WINDOW win AS (PARTITION BY c.product_id, c.from_qu_id, c.to_qu_id ORDER BY c.depth)
ORDER BY c.product_id, c.from_qu_id, c.to_qu_id;

216
migrations/0232.sql Normal file
View File

@ -0,0 +1,216 @@
DROP VIEW quantity_unit_conversions_resolved;
CREATE VIEW quantity_unit_conversions_resolved
AS
WITH RECURSIVE
-- Default QU conversions are handled in a later CTE, as we can't determine yet, for which products they are applicable.
default_conversions(from_qu_id, to_qu_id, factor)
AS (
SELECT
from_qu_id,
to_qu_id,
factor
FROM quantity_unit_conversions
WHERE product_id IS NULL
),
-- First find the closure for all default conversions. This will allow for further pruning when looking for product closure.
default_closure(depth, from_qu_id, to_qu_id, factor, path)
AS (
-- As a base case, select all available default conversions
SELECT
1 as depth,
from_qu_id,
to_qu_id,
factor,
'/' || from_qu_id || '/' || to_qu_id || '/' -- We need to keep track of the conversion path in order to prevent cycles
FROM default_conversions
UNION
-- Recursive case: Find all paths
SELECT
c.depth + 1,
c.from_qu_id,
s.to_qu_id,
c.factor * s.factor,
c.path || s.to_qu_id || '/'
FROM default_closure c
JOIN default_conversions s
ON c.to_qu_id = s.from_qu_id
WHERE c.path NOT LIKE ('%/' || s.to_qu_id || '/%') -- Prevent cycles
AND NOT EXISTS(SELECT 1 FROM default_conversions ci WHERE ci.from_qu_id = c.from_qu_id AND ci.to_qu_id = s.to_qu_id) -- Prune if one of the existing conversions repeats (saves a lot of processing time)
),
default_closure_distinct(from_qu_id, to_qu_id, factor, path)
AS (
SELECT DISTINCT
from_qu_id,
to_qu_id,
FIRST_VALUE(factor) OVER win AS factor,
FIRST_VALUE(path) OVER win AS path
FROM default_closure
GROUP BY from_qu_id, to_qu_id
WINDOW win AS (PARTITION BY from_qu_id, to_qu_id ORDER BY depth)
ORDER BY from_qu_id, to_qu_id
),
product_conversions(product_id, from_qu_id, to_qu_id, factor)
AS (
-- Priority 1: Product-specific QU overrides
-- Note that the quantity_unit_conversions table already contains both conversion directions for every conversion.
SELECT
product_id,
from_qu_id,
to_qu_id,
factor
FROM quantity_unit_conversions
WHERE product_id IS NOT NULL
UNION
-- Priority 2: 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
FROM products
),
product_closure(depth, product_id, from_qu_id, to_qu_id, factor, path)
AS (
-- As a base case, select all available product-specific conversions
SELECT
1 as depth,
product_id,
from_qu_id,
to_qu_id,
factor,
'/' || from_qu_id || '/' || to_qu_id || '/' -- We need to keep track of the conversion path in order to prevent cycles
FROM product_conversions
UNION
-- Recursive case: Find all paths
SELECT
c.depth + 1,
c.product_id,
c.from_qu_id,
s.to_qu_id,
c.factor * s.factor,
c.path || s.to_qu_id || '/'
FROM product_closure c
JOIN product_conversions s
ON c.product_id = s.product_id
AND c.to_qu_id = s.from_qu_id
WHERE c.path NOT LIKE ('%/' || s.to_qu_id || '/%') -- Prevent cycles
AND NOT EXISTS(SELECT 1 FROM product_conversions ci WHERE ci.product_id = c.product_id AND ci.from_qu_id = c.from_qu_id AND ci.to_qu_id = s.to_qu_id) -- Prune if one of the existing conversions repeats (saves a lot of processing time)
),
product_closure_distinct(product_id, from_qu_id, to_qu_id, factor, path)
AS (
SELECT DISTINCT
product_id,
from_qu_id,
to_qu_id,
FIRST_VALUE(factor) OVER win AS factor,
FIRST_VALUE(path) OVER win AS path
FROM product_closure
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)
ORDER BY product_id, from_qu_id, to_qu_id
),
-- Now we connect the two closures by adding the reachable conversions from product specific conversions to default conversions
product_reachable(product_id, from_qu_id, to_qu_id, factor, path)
AS (
SELECT
product_id,
from_qu_id,
to_qu_id,
factor,
path
FROM product_closure_distinct
UNION
SELECT
cd.product_id,
dcd.from_qu_id,
dcd.to_qu_id,
dcd.factor,
'/' || dcd.from_qu_id || '/' || dcd.to_qu_id || '/'
FROM product_closure_distinct cd
JOIN default_closure_distinct dcd
ON cd.to_qu_id = dcd.from_qu_id
OR cd.to_qu_id = dcd.to_qu_id
WHERE NOT EXISTS(SELECT 1 FROM product_closure_distinct ci WHERE ci.product_id = cd.product_id AND ci.from_qu_id = dcd.from_qu_id AND ci.to_qu_id = dcd.to_qu_id)
),
product_reachable_distinct(product_id, from_qu_id, to_qu_id, factor, path)
AS (
SELECT DISTINCT
product_id,
from_qu_id,
to_qu_id,
FIRST_VALUE(factor) OVER win AS factor,
FIRST_VALUE(path) OVER win AS path
FROM product_reachable
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 product_id, from_qu_id, to_qu_id
),
-- Finally we build the combined closure
closure_final(depth, product_id, from_qu_id, to_qu_id, factor, path)
AS (
-- As a base case, select the product closure
SELECT
1,
product_id,
from_qu_id,
to_qu_id,
factor,
path -- We need to keep track of the conversion path in order to prevent cycles
FROM product_reachable_distinct
UNION
-- Add a default unit conversion to the *end* of the conversion chain
SELECT
c.depth + 1,
c.product_id,
c.from_qu_id,
s.to_qu_id,
c.factor * s.factor,
c.path || s.to_qu_id || '/'
FROM closure_final c
JOIN product_reachable_distinct s
ON c.product_id = s.product_id
AND c.to_qu_id = s.from_qu_id
WHERE c.path NOT LIKE ('%/' || s.to_qu_id || '/%') -- Prevent cycles
AND NOT EXISTS(SELECT 1 FROM product_reachable_distinct ci WHERE ci.product_id = c.product_id AND ci.from_qu_id = c.from_qu_id AND ci.to_qu_id = s.to_qu_id) -- Prune (if already exists)
)
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(c.factor) OVER win AS factor,
FIRST_VALUE(c.path) OVER win AS path
FROM closure_final 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 c.product_id, c.from_qu_id, c.to_qu_id
WINDOW win AS (PARTITION BY c.product_id, c.from_qu_id, c.to_qu_id ORDER BY c.depth)
ORDER BY c.product_id, c.from_qu_id, c.to_qu_id;