Jelajahi Sumber

fix filters - still to apply unit selections

Daniel Sheffield 9 bulan lalu
induk
melakukan
ff4bbf740d
6 mengubah file dengan 257 tambahan dan 130 penghapusan
  1. 12 0
      sqlpage/apply.sql
  2. 3 3
      sqlpage/clear.sql
  3. 115 0
      sqlpage/filter.sql
  4. 86 127
      sqlpage/nav.sql
  5. 18 0
      sqlpage/tags.sql
  6. 23 0
      sqlpage/transactions.sql

+ 12 - 0
sqlpage/apply.sql

@@ -0,0 +1,12 @@
+SELECT
+  'dynamic' as component,
+  sqlpage.run_sql('filter.sql') AS properties
+;
+
+SELECT
+  'redirect' AS component,
+  (SELECT CASE
+    WHEN $path IN ('/products.sql', '/categories.sql', '/groups.sql', '/tags.sql')
+    THEN $path ELSE '/transactions.sql'
+    END
+  ) AS link;

+ 3 - 3
sqlpage/clear.sql

@@ -1,7 +1,7 @@
 SELECT
   'redirect' AS component,
-  (SELECT CASE
-    WHEN $path IN ('/products.sql', '/categories.sql', '/groups.sql')
+  'apply.sql?path='||(SELECT CASE
+    WHEN $path IN ('/products.sql', '/categories.sql', '/groups.sql', '/tags.sql')
     THEN $path ELSE '/transactions.sql'
-    END||'?clear=Clear'
+    END
   ) AS link;

+ 115 - 0
sqlpage/filter.sql

@@ -0,0 +1,115 @@
+CREATE TABLE IF NOT EXISTS sqlpage_options(
+  session text,
+  "type" text,
+  name text,
+  selected boolean
+);
+DELETE FROM sqlpage_options
+WHERE
+  session = sqlpage.cookie('session')
+
+INSERT INTO sqlpage_options(session, type, name, selected)
+VALUES (
+  sqlpage.cookie('session'),
+  'start',
+  $start,
+  TRUE
+), (
+  sqlpage.cookie('session'),
+  'end',
+  $end,
+  TRUE
+)
+;
+
+INSERT INTO sqlpage_options
+SELECT
+  sqlpage.cookie('session'),
+  CASE
+  WHEN ut.name = 'Volume' THEN 'unit_volume' 
+  WHEN ut.name = 'Mass' THEN 'unit_mass' 
+  WHEN ut.name = 'Count' THEN 'unit_count' 
+  END,
+  u.name,
+  CASE
+  WHEN ut.name = 'Volume' THEN u.name = COALESCE($unit_volume, 'L')
+  WHEN ut.name = 'Mass' THEN u.name = COALESCE($unit_mass, 'kg')
+  WHEN ut.name = 'Count' THEN CASE WHEN $unit_count IS NOT NULL THEN f.v IS NOT NULL ELSE NULL END
+  END
+FROM units u
+JOIN unit_types ut
+ON ut.id = u.unit_type_id
+LEFT JOIN json_array_elements($unit_count::json) f(v)
+ON u.name = f.v#>>'{}' AND ut.name = 'Count'
+;
+
+INSERT INTO sqlpage_options
+SELECT
+  sqlpage.cookie('session'),
+  'tag',
+  t.name,
+  CASE WHEN $tags IS NOT NULL THEN f.v IS NOT NULL ELSE NULL END
+FROM tags t
+LEFT JOIN json_array_elements($tags::json) f(v)
+ON t.name = f.v#>>'{}'
+;
+
+INSERT INTO sqlpage_options
+SELECT
+  sqlpage.cookie('session'),
+  UNNEST(ARRAY['product', 'category', 'group']) AS "type",
+  UNNEST(q.name) AS name,
+  UNNEST(selected)
+FROM (
+  SELECT
+    ARRAY[p.name, c.name, g.name] AS name,
+    ARRAY[
+      CASE WHEN $products IS NOT NULL THEN fp.v IS NOT NULL ELSE NULL END,
+      CASE WHEN $categories IS NOT NULL THEN fc.v IS NOT NULL ELSE NULL END,
+      CASE WHEN $groups IS NOT NULL THEN fg.v IS NOT NULL ELSE NULL END
+    ]
+  FROM products p
+  LEFT JOIN json_array_elements($products::json) fp(v)
+  ON p.name = fp.v#>>'{}'
+  JOIN categories c ON p.category_id = c.id
+  LEFT JOIN json_array_elements($categories::json) fc(v)
+  ON c.name = fc.v#>>'{}'
+  JOIN groups g ON c.group_id = g.id
+  LEFT JOIN json_array_elements($groups::json) fg(v)
+  ON g.name = fg.v#>>'{}'
+  WHERE (
+    (p.name = fp.v#>>'{}' OR $products IS NULL)
+  AND
+    (c.name = fc.v#>>'{}' OR $categories IS NULL)
+  AND
+    (g.name = fg.v#>>'{}' OR $groups IS NULL)
+  )
+) q(name, selected)
+UNION
+SELECT
+  sqlpage.cookie('session'),
+  'group',
+  f.v#>>'{}',
+  TRUE
+FROM json_array_elements($groups::json) f(v)
+LEFT JOIN groups g ON g.name = f.v#>>'{}'
+WHERE g.name is NULL
+UNION
+SELECT
+  sqlpage.cookie('session'),
+  'category',
+  f.v#>>'{}',
+  TRUE
+FROM json_array_elements($categories::json) f(v)
+LEFT JOIN categories c ON c.name = f.v#>>'{}'
+WHERE c.name is NULL
+UNION
+SELECT
+  sqlpage.cookie('session'),
+  'product',
+  f.v#>>'{}',
+  TRUE
+FROM json_array_elements($products::json) f(v)
+LEFT JOIN products p ON p.name = f.v#>>'{}'
+WHERE p.name is NULL
+;

+ 86 - 127
sqlpage/nav.sql

@@ -1,96 +1,3 @@
-CREATE TABLE IF NOT EXISTS sqlpage_options(
-  session text,
-  "type" text,
-  name text,
-  selected boolean
-);
-DELETE FROM sqlpage_options
-WHERE
-  session = sqlpage.cookie('session')
-AND (
-    $clear = 'Clear'
-  OR
-    $products IS NOT NULL
-  OR
-    $categories IS NOT NULL
-  OR
-    $groups IS NOT NULL
-);
-
-CREATE TEMPORARY TABLE IF NOT EXISTS state(update boolean);
-TRUNCATE state;
-INSERT INTO state(update)
-SELECT NOT EXISTS (SELECT 1 FROM sqlpage_options WHERE session = sqlpage.cookie('session'));
-
-INSERT INTO sqlpage_options
-SELECT
-  sqlpage.cookie('session'),
-  UNNEST(ARRAY['product', 'category', 'group']) AS "type",
-  UNNEST(q.name) AS name,
-  UNNEST(selected)
-FROM (
-  SELECT
-    ARRAY[p.name, c.name, g.name] AS name,
-    ARRAY[
-      CASE WHEN $products IS NOT NULL THEN fp.v IS NOT NULL ELSE NULL END,
-      CASE WHEN $categories IS NOT NULL THEN fc.v IS NOT NULL ELSE NULL END,
-      CASE WHEN $groups IS NOT NULL THEN fg.v IS NOT NULL ELSE NULL END
-    ]
-  FROM products p
-  LEFT JOIN json_array_elements($products::json) fp(v)
-  ON p.name = fp.v#>>'{}'
-  JOIN categories c ON p.category_id = c.id
-  LEFT JOIN json_array_elements($categories::json) fc(v)
-  ON c.name = fc.v#>>'{}'
-  JOIN groups g ON c.group_id = g.id
-  LEFT JOIN json_array_elements($groups::json) fg(v)
-  ON g.name = fg.v#>>'{}'
-  WHERE (
-    (p.name = fp.v#>>'{}' OR $products IS NULL)
-  AND
-    (c.name = fc.v#>>'{}' OR $categories IS NULL)
-  AND
-    (g.name = fg.v#>>'{}' OR $groups IS NULL)
-  AND
-    EXISTS (SELECT 1 FROM state WHERE update IS TRUE)
-  )
-) q(name, selected)
-UNION
-SELECT
-  sqlpage.cookie('session'),
-  'group',
-  f.v#>>'{}',
-  TRUE
-FROM json_array_elements($groups::json) f(v)
-LEFT JOIN groups g ON g.name = f.v#>>'{}'
-WHERE g.name is NULL
-  AND
-    EXISTS (SELECT 1 FROM state WHERE update IS TRUE)
-UNION
-SELECT
-  sqlpage.cookie('session'),
-  'category',
-  f.v#>>'{}',
-  TRUE
-FROM json_array_elements($categories::json) f(v)
-LEFT JOIN categories c ON c.name = f.v#>>'{}'
-WHERE c.name is NULL
-  AND
-    EXISTS (SELECT 1 FROM state WHERE update IS TRUE)
-UNION
-SELECT
-  sqlpage.cookie('session'),
-  'product',
-  f.v#>>'{}',
-  TRUE
-FROM json_array_elements($products::json) f(v)
-LEFT JOIN products p ON p.name = f.v#>>'{}'
-WHERE p.name is NULL
-  AND
-    EXISTS (SELECT 1 FROM state WHERE update IS TRUE)
-;
-
- 
 SELECT
   'tab' AS component,
   TRUE AS center
@@ -132,6 +39,7 @@ SELECT
   'filter' AS id,
   'get' AS method,
   '' AS title,
+  'apply.sql' AS action,
   'Apply' AS validate
 ;
 
@@ -142,39 +50,6 @@ SELECT
   'hidden' AS type
 ;
 
---SELECT
---  'tab' AS name,
---  'Products' AS value,
---  '' AS label,
---  3 AS width,
---  'submit' AS type,
---  'transactions.sql' AS formaction
---;
---SELECT
---  'tab' AS name,
---  'Categories' AS value,
---  '' AS label,
---  3 AS width,
---  'submit' AS type,
---  'transactions.sql' AS formaction
---;
---SELECT
---  'tab' AS name,
---  'Groups' AS value,
---  '' AS label,
---  3 AS width,
---  'submit' AS type,
---  'transactions.sql' AS formaction
---;
---SELECT
---  'tab' AS name,
---  'Transactions' AS value,
---  '' AS label,
---  3 AS width,
---  'submit' AS type,
---  'transactions.sql' AS formaction
---;
-
 SELECT
   'products[]' AS name,
   'Product' AS label,
@@ -229,12 +104,96 @@ WHERE
 AND
   o.session = sqlpage.cookie('session')
 ;
+SELECT
+  'start' AS name,
+  'From' AS label,
+  2 AS width,
+  (SELECT COALESCE((SELECT name FROM sqlpage_options WHERE type = 'start'), to_char(now()-'30 days'::interval, 'YYYY-MM-DD'))) AS value,
+  'date' AS type
+;
+SELECT
+  'end' AS name,
+  'To' AS label,
+  2 AS width,
+  (SELECT COALESCE((SELECT name FROM sqlpage_options WHERE type = 'end'), to_char(now(), 'YYYY-MM-DD'))) AS value,
+  'date' AS type
+;
+SELECT
+  'tags[]' AS name,
+  'Tags' AS label,
+  4 AS width,
+  'select' AS "type",
+  TRUE AS dropdown,
+  TRUE AS multiple,
+  json_agg(json_build_object(
+    'label', o.name,
+    'value', o.name,
+    'selected', COALESCE(o.selected, FALSE)
+  ) ORDER BY o.name) AS options
+FROM sqlpage_options o
+WHERE
+  o.type = 'tag'
+AND
+  o.session = sqlpage.cookie('session')
+;
+SELECT
+  'unit_volume' AS name,
+  'Unit (vol.)' AS label,
+  1 AS width,
+  'select' AS type,
+  json_agg(json_build_object(
+    'label', o.name,
+    'value', o.name,
+    'selected', COALESCE(o.selected, FALSE)
+  ) ORDER BY o.name) AS options
+FROM sqlpage_options o
+WHERE
+  o.type = 'unit_volume'
+AND
+  o.session = sqlpage.cookie('session')
+;
+SELECT
+  'unit_mass' AS name,
+  'Unit (mass)' AS label,
+  1 AS width,
+  'select' AS type,
+  $unit_mass AS value,
+  json_agg(json_build_object(
+    'label', o.name,
+    'value', o.name,
+    'selected', COALESCE(o.selected, FALSE)
+  ) ORDER BY o.name) AS options
+FROM sqlpage_options o
+WHERE
+  o.type = 'unit_mass'
+AND
+  o.session = sqlpage.cookie('session')
+;
+SELECT
+  'unit_count[]' AS name,
+  'Unit (count)' AS label,
+  1 AS width,
+  'select' AS type,
+  TRUE AS multiple,
+  TRUE AS dropdown,
+  '' AS value,
+  json_agg(json_build_object(
+    'label', o.name,
+    'value', o.name,
+    'selected', COALESCE(o.selected, FALSE)
+  ) ORDER BY o.name) AS options
+FROM sqlpage_options o
+WHERE
+  o.type = 'unit_count'
+AND
+  o.session = sqlpage.cookie('session')
+;
 SELECT
   'clear' AS name,
   'Clear' AS value,
   '' AS label,
   1 AS width,
   'submit' AS type,
-  'clear.sql?page='||sqlpage.path() AS formaction
+  'clear.sql?path='||sqlpage.path() AS formaction
 ;
 

+ 18 - 0
sqlpage/tags.sql

@@ -33,6 +33,7 @@ JOIN groups g ON c.group_id = g.id
 JOIN sqlpage_options op ON op.type = 'product' AND p.name = op.name
 JOIN sqlpage_options oc ON oc.type = 'category' AND c.name = oc.name
 JOIN sqlpage_options og ON og.type = 'group' AND g.name = og.name
+JOIN sqlpage_options ot ON ot.type = 'tag' AND tg.name = ot.name
 WHERE 
   COALESCE(op.selected, oc.selected, og.selected, TRUE)
 AND
@@ -41,6 +42,15 @@ AND
   oc.session = sqlpage.cookie('session')
 AND
   og.session = sqlpage.cookie('session')
+AND
+  ot.session = sqlpage.cookie('session')
+AND
+  ((ts AT TIME ZONE 'UTC') AT TIME ZONE 'Pacific/Auckland')::date
+  BETWEEN (
+    SELECT name FROM sqlpage_options WHERE type = 'start'
+  )::date AND (
+    SELECT name FROM sqlpage_options WHERE type = 'end'
+  )::date
 GROUP BY tg.name
 ORDER BY 1 DESC, 2) q
 UNION ALL
@@ -54,14 +64,22 @@ JOIN groups g ON c.group_id = g.id
 JOIN sqlpage_options op ON op.type = 'product' AND p.name = op.name
 JOIN sqlpage_options oc ON oc.type = 'category' AND c.name = oc.name
 JOIN sqlpage_options og ON og.type = 'group' AND g.name = og.name
+JOIN sqlpage_options ot ON ot.type = 'tag' AND tg.name = ot.name
 WHERE
   COALESCE(op.selected, oc.selected, og.selected, TRUE)
+AND
+  COALESCE(ot.selected, TRUE)
 AND
   op.session = sqlpage.cookie('session')
 AND
   oc.session = sqlpage.cookie('session')
 AND
   og.session = sqlpage.cookie('session')
+AND
+  ot.session = sqlpage.cookie('session')
+AND
+  ((ts AT TIME ZONE 'UTC') AT TIME ZONE 'Pacific/Auckland')::date
+  BETWEEN $start::date AND $end::date
 );
 SELECT * FROM sqlpage_tags;
 

+ 23 - 0
sqlpage/transactions.sql

@@ -59,6 +59,29 @@ AND
   oc.session = sqlpage.cookie('session')
 AND
   og.session = sqlpage.cookie('session')
+AND
+  ((ts AT TIME ZONE 'UTC') AT TIME ZONE 'Pacific/Auckland')::date
+  BETWEEN (
+    SELECT name FROM sqlpage_options WHERE type = 'start'
+  )::date AND (
+    SELECT name FROM sqlpage_options WHERE type = 'end'
+  )::date
+AND
+  t.id IN (
+    SELECT
+      transaction_id
+    FROM tags_map
+    WHERE tag_id IN (
+      SELECT
+        id
+      FROM tags
+      JOIN sqlpage_options ot
+      ON ot.type = 'tag' AND ot.name = tags.name
+      WHERE COALESCE(ot.selected, TRUE)
+      AND ot.session = sqlpage.cookie('session')
+    )
+  )
+ORDER BY ts DESC
 LIMIT 100);
 SELECT * FROM sqlpage_txn;