Quellcode durchsuchen

poc with nav and filtering

Daniel Sheffield vor 9 Monaten
Ursprung
Commit
96819ca264
1 geänderte Dateien mit 211 neuen und 81 gelöschten Zeilen
  1. 211 81
      transactions-sqlpage.sql

+ 211 - 81
transactions-sqlpage.sql

@@ -1,64 +1,170 @@
-SELECT
-  'tab' AS component
+SELECT 'shell' AS component,
+  'dark' AS theme,
+  COALESCE($tab, 'Transactions') AS title
 ;
-
 SELECT
- 'Products' AS title,
- 'products.sql' AS link
-UNION SELECT
- 'Categories' AS title,
- 'categories.sql' AS link
-UNION SELECT
- 'Groups' AS title,
- 'groups.sql' AS link
-UNION SELECT
- 'Transactions' AS title,
- 'transactions.sql' AS link
+  'text' AS component,
+  '<style>
+.nav { pointer-events: none }
+.navbar { display: none }
+input[value=Products].form-control,
+input[value=Categories].form-control,
+input[value=Groups].form-control,
+input[value=Transactions].form-control
+{
+    color: var(--tblr-secondary);
+    border-right: unset;
+    border-top: unset;
+    border-left: unset;
+}
+input[value='||CASE
+  WHEN $tab IN ('Products', 'Categories', 'Groups')
+  THEN $tab ELSE 'Transactions'
+END||'].form-control
+{
+    color: var(--tblr-primary);
+    border-right: unset;
+    border-top: unset;
+    border-left: unset;
+    border-bottom-color: var(--tblr-primary);
+    border-bottom-width: 2px;
+}
+</style>' AS html
+;
+  
+--SELECT
+--  'tab' AS component,
+--  TRUE AS center
+--;
+--
+--SELECT
+-- 'products' AS id,
+-- 'Products' AS title,
+-- (SELECT $tab = 'Products') AS active
+--;
+--SELECT
+-- 'categories' AS id,
+-- 'Categories' AS title,
+-- (SELECT $tab = 'Categories') AS active
+--;
+--SELECT
+-- 'groups' AS id,
+-- 'Groups' AS title,
+-- (SELECT $tab = 'Groups') AS active
+--;
+--SELECT
+-- 'transactions' AS id,
+-- 'Transactions' AS title,
+-- (SELECT $tab = 'Transactions' OR $tab IS NULL) AS active
+--;
 
-CREATE TEMPORARY TABLE IF NOT EXISTS filter(
-  p text, fp text,
-  c text, fc text,
-  g text, fg text
+CREATE TEMPORARY TABLE IF NOT EXISTS options(
+  "type" text,
+  name text,
+  selected boolean
 );
-DELETE FROM filter;
-INSERT INTO filter
-SELECT
-  p.name, fp.v#>>'{}',
-  c.name, fc.v#>>'{}',
-  g.name, fg.v#>>'{}'
-FROM groups g
-FULL JOIN
-  json_array_elements($groups::json) fg(v)
-ON g.name = fg.v#>>'{}'
-JOIN categories c
-ON c.group_id = g.id
-FULL JOIN
-  json_array_elements($categories::json) fc(v)
-ON c.name = fc.v#>>'{}'
-JOIN products p
-ON p.category_id = c.id
-FULL JOIN
-  json_array_elements($products::json) fp(v)
-ON p.name = fp.v#>>'{}'
-WHERE
-  (fg.v IS NOT NULL OR $groups IS NULL)
-AND
-  (fc.v IS NOT NULL OR $categories IS NULL)
-AND
-  (fp.v IS NOT NULL OR $products IS NULL)
+DELETE FROM options;
+INSERT INTO options
+SELECT
+  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
+  '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
+  '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
+  '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
 ;
 
 SELECT
   'form' AS component,
   'filter' AS id,
   'get' AS method,
-  'Filter' AS title,
+  '' AS title,
+  'transactions.sql' AS action,
   'Apply' AS validate
 ;
 
 SELECT
-  'Action' AS label,
-  'Refresh' AS value,
+  'tab' AS name,
+  '' AS label,
+  COALESCE($tab, 'Transactions') AS value,
+  '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
 ;
@@ -66,42 +172,57 @@ SELECT
 SELECT
   'products[]' AS name,
   'Product' AS label,
+  4 AS width,
   'select' AS "type",
   TRUE AS dropdown,
   TRUE AS multiple,
   json_agg(json_build_object(
-    'label', COALESCE(f.p, f.fp),
-    'value', COALESCE(f.p, f.fp),
-    'selected', f.fp <> ''
-  )) AS options
-FROM filter f
+    'label', o.name,
+    'value', o.name,
+    'selected', COALESCE(o.selected, FALSE)
+  ) ORDER BY o.name) AS options
+FROM options o
+WHERE o.type = 'product'
 ;
 SELECT
   'categories[]' AS name,
   'Categories' AS label,
+  4 AS width,
   'select' AS "type",
   TRUE AS dropdown,
   TRUE AS multiple,
   json_agg(json_build_object(
-    'label', COALESCE(f.c, f.fp),
-    'value', COALESCE(f.c, f.fp),
-    'selected', f.fc <> ''
-  )) AS options
-FROM filter f
+    'label', o.name,
+    'value', o.name,
+    'selected', COALESCE(o.selected, FALSE)
+  ) ORDER BY o.name) AS options
+FROM options o
+WHERE o.type = 'category'
 ;
 SELECT
   'groups[]' AS name,
   'Groups' AS label,
+  4 AS width,
   'select' AS "type",
   TRUE AS dropdown,
   TRUE AS multiple,
   json_agg(json_build_object(
-    'label', COALESCE(f.g, f.fg),
-    'value', COALESCE(f.g, f.fg),
-    'selected', f.fg <> ''
-  )) AS options
-FROM filter f
+    'label', o.name,
+    'value', o.name,
+    'selected', COALESCE(o.selected, FALSE)
+  ) ORDER BY o.name) AS options
+FROM options o
+WHERE o.type = 'group'
 ;
+SELECT
+  'clear' AS name,
+  'Clear' AS value,
+  '' AS label,
+  1 AS width,
+  'submit' AS type,
+  'entry.sql' AS formaction
+;
+
 SELECT
   'table' AS component,
   TRUE AS sort,
@@ -110,29 +231,38 @@ SELECT
   TRUE AS small,
   'Price' AS align_right,
   'Quantity' AS align_right,
-  'Unit' AS align_right
+  'Unit' AS align_right,
+  'Notice' AS markdown
 ;
 
-
-SELECT
+DROP TABLE IF EXISTS txn;
+CREATE TEMPORARY TABLE txn AS (SELECT
   to_char(
     (ts AT TIME ZONE 'UTC') AT TIME ZONE 'Pacific/Auckland', --COALESCE('$ParameterTZ', 'Pacific/Auckland'),
     'Mon DD HH24:MI:SS'
-  ) AS Time,
-  description AS Description,
-  stores.code AS Store,
-  products.name AS Product,
-  categories.name AS Category,
-  groups.name AS Group,
-  CASE WHEN organic THEN 'yes' ELSE 'no' END AS Organic,
-  to_char(price, 'FM999999999.00') AS "Price",
+  ) AS "Time",
+  t.description AS Description,
+  s.code AS "Store",
+  p.name AS "Product",
+  c.name AS "Category",
+  g.name AS "Group",
+  CASE WHEN t.organic THEN 'yes' ELSE 'no' END AS "Organic",
+  to_char(t.price, 'FM999999999.00') AS "Price",
   --to_char(quantity, '9.'||repeat('9',3-1)||'EEEE') AS Quantity,
-  to_char(price, 'FM999999999.000') AS "Quantity",
-  units.name AS "Unit"
+  to_char(t.price, 'FM999999999.000') AS "Quantity",
+  u.name AS "Unit"
 FROM transactions t
-JOIN products ON (product_id = products.id)
-JOIN categories ON (category_id = categories.id)
-JOIN groups ON (group_id = groups.id)
-JOIN stores ON (store_id = stores.id)
-JOIN units ON (t.unit_id = units.id)
-LIMIT 100;
+JOIN products p ON (product_id = p.id)
+JOIN categories c ON (category_id = c.id)
+JOIN groups g ON (group_id = g.id)
+JOIN stores s ON (store_id = s.id)
+JOIN units u ON (t.unit_id = u.id)
+JOIN options op ON op.type = 'product' AND p.name = op.name
+JOIN options oc ON oc.type = 'category' AND c.name = oc.name
+JOIN options og ON og.type = 'group' AND g.name = og.name
+WHERE COALESCE(op.selected, oc.selected, og.selected, TRUE)
+LIMIT 20);
+SELECT * FROM txn;
+SELECT 
+  '# No Data' AS "Notice"
+WHERE NOT EXISTS(SELECT * FROM txn LIMIT 1);