Reference LP# 1206936. Money views have been using the last()
authorChris Sharp <csharp@georgialibraries.org>
Wed, 31 Jul 2013 17:45:41 +0000 (13:45 -0400)
committerChris Sharp <csharp@georgialibraries.org>
Wed, 31 Jul 2013 17:45:41 +0000 (13:45 -0400)
aggregate function to get the "last" value of billing type and
billing notes.  Mike Rylander suggested the approach of using
window functions to accomplish the same thing, grabbing the
correct data in the process.

Signed-off-by: Chris Sharp <csharp@georgialibraries.org>
Open-ILS/src/sql/Pg/080.schema.money.sql
Open-ILS/src/sql/Pg/upgrade/XXXX.schema.money.replace_views_with_window_functions.sql [new file with mode: 0644]

index 5004f00..ce1dd0c 100644 (file)
@@ -83,90 +83,88 @@ CREATE OR REPLACE RULE money_payment_view_update AS ON UPDATE TO money.payment_v
     UPDATE money.payment SET xact = NEW.xact, payment_ts = NEW.payment_ts, voided = NEW.voided, amount = NEW.amount, note = NEW.note WHERE id = NEW.id;
 
 CREATE OR REPLACE VIEW money.transaction_billing_type_summary AS
-       SELECT  xact,
-               billing_type AS last_billing_type,
-               LAST(note) AS last_billing_note,
-               MAX(billing_ts) AS last_billing_ts,
-               SUM(COALESCE(amount,0)) AS total_owed
-         FROM  money.billing
-         WHERE voided IS FALSE
-         GROUP BY xact,billing_type
-         ORDER BY MAX(billing_ts);
+    SELECT DISTINCT billing.xact,
+        billing.billing_type AS last_billing_type,
+        LAST_VALUE(billing.note) OVER w AS last_billing_note,
+        MAX(billing.billing_ts) OVER w AS last_billing_ts,
+        SUM(COALESCE(billing.amount, 0::numeric)) AS total_owed
+    FROM money.billing
+    WHERE billing.voided IS FALSE
+    WINDOW w AS (PARTITION BY billing.xact, billing.billing_type ORDER BY billing.billing_ts ROW BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING);
 
 CREATE OR REPLACE VIEW money.transaction_billing_summary AS
-       SELECT  xact,
-               LAST(billing_type) AS last_billing_type,
-               LAST(note) AS last_billing_note,
-               MAX(billing_ts) AS last_billing_ts,
-               SUM(COALESCE(amount,0)) AS total_owed
-         FROM  money.billing
-         WHERE voided IS FALSE
-         GROUP BY xact
-         ORDER BY MAX(billing_ts);
-
-CREATE OR REPLACE VIEW money.transaction_payment_summary AS
-       SELECT  xact,
-               LAST(payment_type) AS last_payment_type,
-               LAST(note) AS last_payment_note,
-               MAX(payment_ts) as last_payment_ts,
-               SUM(COALESCE(amount,0)) AS total_paid
-         FROM  money.payment_view
-         WHERE voided IS FALSE
-         GROUP BY xact
-         ORDER BY MAX(payment_ts);
+    SELECT DISTINCT billing.xact,
+        LAST_VALUE(billing.billing_type) OVER w AS last_billing_type,
+        LAST_VALUE(billing.note) OVER w AS last_billing_note,
+        MAX(billing.billing_ts) OVER w AS last_billing_ts,
+        SUM(COALESCE(billing.amount,0)) OVER w AS total_owed
+      FROM  money.billing
+      WHERE billing.voided IS FALSE
+      WINDOW w AS (PARTITION BY billing.xact ORDER BY billing.billing_ts ROWS BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING);
+
+CREATE OR REPLACE VIEW money.open_transaction_payment_summary AS
+    SELECT DISTINCT payment_view.xact,
+        LAST_VALUE(payment_view.payment_type) OVER w AS last_payment_type,
+        LAST_VALUE(payment_view.note) OVER w AS last_payment_note,
+        MAX(payment_view.payment_ts) OVER w AS last_payment_ts, sum(COALESCE(payment_view.amount, 0::numeric)) AS total_paid
+    FROM money.payment_view
+    WHERE payment_view.voided IS FALSE
+    WINDOW w AS (PARTITION BY payment_view.xact ORDER BY payment_view.payment_ts ROWS BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING);
+
 
 CREATE OR REPLACE VIEW money.transaction_billing_with_void_summary AS
-       SELECT  xact,
-               LAST(billing_type) AS last_billing_type,
-               LAST(note) AS last_billing_note,
-               MAX(billing_ts) AS last_billing_ts,
-               SUM(CASE WHEN voided THEN 0 ELSE COALESCE(amount,0) END) AS total_owed
-         FROM  money.billing
-         GROUP BY xact
-         ORDER BY MAX(billing_ts);
-
-CREATE OR REPLACE VIEW money.transaction_payment_with_void_summary AS
-       SELECT  xact,
-               LAST(payment_type) AS last_payment_type,
-               LAST(note) AS last_payment_note,
-               MAX(payment_ts) as last_payment_ts,
-               SUM(CASE WHEN voided THEN 0 ELSE COALESCE(amount,0) END) AS total_paid
-         FROM  money.payment_view
-         GROUP BY xact
-         ORDER BY MAX(payment_ts);
+    SELECT DISTINCT billing.xact,
+        LAST_VALUE(billing.billing_type) OVER w AS last_billing_type,
+        LAST_VALUE(billing.note) OVER w AS last_billing_note,
+        MAX(billing.billing_ts) OVER w AS last_billing_ts,
+        SUM(
+            CASE
+                WHEN billing.voided THEN 0::numeric
+                ELSE COALESCE(billing.amount, 0::numeric)
+            END) OVER w AS total_owed
+    FROM money.billing
+    WINDOW w AS (PARTITION BY billing.xact ORDER BY billing_ts ROWS BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING);
+
+
+CREATE OR REPLACE VIEW money.open_transaction_billing_type_summary AS
+    SELECT DISTINCT billing.xact,
+       billing.billing_type AS last_billing_type,
+       LAST_VALUE(billing.note) OVER w AS last_billing_note,
+       MAX(billing.billing_ts) OVER w AS last_billing_ts,
+       SUM(COALESCE(billing.amount, 0::numeric)) OVER w AS total_owed
+    FROM money.billing
+    WHERE billing.voided IS FALSE
+    WINDOW w AS (PARTITION BY billing.xact, billing.billing_type ORDER BY billing.billing_ts ROWS BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING);
+
 
 CREATE OR REPLACE VIEW money.open_transaction_billing_type_summary AS
-       SELECT  xact,
-               billing_type AS last_billing_type,
-               LAST(note) AS last_billing_note,
-               MAX(billing_ts) AS last_billing_ts,
-               SUM(COALESCE(amount,0)) AS total_owed
-         FROM  money.billing
-         WHERE voided IS FALSE
-         GROUP BY xact,billing_type
-         ORDER BY MAX(billing_ts);
+    SELECT DISTINCT billing.xact,
+        billing.billing_type AS last_billing_type,
+        LAST_VALUE(billing.note) OVER w AS last_billing_note,
+        MAX(billing.billing_ts) OVER w AS last_billing_ts,
+        SUM(COALESCE(billing.amount, 0::numeric)) OVER w AS total_owed
+    FROM money.billing
+    WHERE billing.voided IS FALSE
+    WINDOW w AS (PARTITION BY billing.xact, billing.billing_type ORDER BY billing.billing_ts ROW BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING);
 
 CREATE OR REPLACE VIEW money.open_transaction_billing_summary AS
-       SELECT  xact,
-               LAST(billing_type) AS last_billing_type,
-               LAST(note) AS last_billing_note,
-               MAX(billing_ts) AS last_billing_ts,
-               SUM(COALESCE(amount,0)) AS total_owed
-         FROM  money.billing
-         WHERE voided IS FALSE
-         GROUP BY xact
-         ORDER BY MAX(billing_ts);
+    SELECT DISTINCT xact,
+        LAST_VALUE(billing_type) OVER w AS last_billing_type,
+        LAST_VALUE(billing.note) OVER w AS last_billing_note,
+        MAX(billing_ts) OVER w AS last_billing_ts,
+        SUM(COALESCE(amount, 0)) OVER w AS total_owed
+    FROM money.billing
+    WHERE voided IS FALSE
+    WINDOW w AS (PARTITION BY xact ORDER BY billing_ts ROWS BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING);
 
 CREATE OR REPLACE VIEW money.open_transaction_payment_summary AS
-       SELECT  xact,
-               LAST(payment_type) AS last_payment_type,
-               LAST(note) AS last_payment_note,
-               MAX(payment_ts) as last_payment_ts,
-               SUM(COALESCE(amount,0)) AS total_paid
-         FROM  money.payment_view
-         WHERE voided IS FALSE
-         GROUP BY xact
-         ORDER BY MAX(payment_ts);
+    SELECT DISTINCT payment_view.xact,
+        LAST_VALUE(payment_view.payment_type) OVER w AS last_payment_type,
+        LAST_VALUE(payment_view.note) OVER w AS last_payment_note,
+        MAX(payment_view.payment_ts) OVER w AS last_payment_ts, sum(COALESCE(payment_view.amount, 0::numeric)) AS total_paid
+    FROM money.payment_view
+    WHERE payment_view.voided IS FALSE
+    WINDOW w AS (PARTITION BY payment_view.xact ORDER BY payment_view.payment_ts ROWS BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING);
 
 /* Replacing with the one below.
 CREATE OR REPLACE VIEW money.billable_xact_with_void_summary AS
diff --git a/Open-ILS/src/sql/Pg/upgrade/XXXX.schema.money.replace_views_with_window_functions.sql b/Open-ILS/src/sql/Pg/upgrade/XXXX.schema.money.replace_views_with_window_functions.sql
new file mode 100644 (file)
index 0000000..25cb8ef
--- /dev/null
@@ -0,0 +1,107 @@
+-- Evergreen DB patch XXXX.schema.money.replace_views_with_window_functions.sql
+--
+-- Replaces money schema views with ones that use window functions
+
+-- check whether patch can be applied
+-- SELECT evergreen.upgrade_deps_block_check('XXXX', :eg_version);
+
+BEGIN;
+
+-- money.transaction_billing_summary
+
+CREATE OR REPLACE VIEW money.transaction_billing_summary AS
+    SELECT DISTINCT xact,
+        LAST_VALUE(billing_type) OVER w AS last_billing_type,
+        LAST_VALUE(note) OVER w AS last_billing_note,
+        MAX(billing_ts) OVER w AS last_billing_ts,
+        SUM(COALESCE(amount,0)) OVER w AS total_owed
+      FROM  money.billing
+      WHERE voided IS FALSE
+      WINDOW w AS (PARTITION BY xact ORDER BY billing_ts ROWS BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING);
+
+-- money.open_transaction_billing_summary
+
+CREATE OR REPLACE VIEW money.open_transaction_billing_summary AS
+    SELECT DISTINCT xact,
+        LAST_VALUE(billing_type) OVER w AS last_billing_type,
+        LAST_VALUE(billing.note) OVER w AS last_billing_note,
+        MAX(billing_ts) OVER w AS last_billing_ts,
+        SUM(COALESCE(amount, 0)) OVER w AS total_owed
+    FROM money.billing
+    WHERE voided IS FALSE
+    WINDOW w AS (PARTITION BY xact ORDER BY billing_ts ROWS BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING);
+
+-- money.open_transaction_billing_type_summary
+
+CREATE OR REPLACE VIEW money.open_transaction_billing_type_summary AS
+    SELECT DISTINCT billing.xact,
+        billing.billing_type AS last_billing_type,
+        LAST_VALUE(billing.note) OVER w AS last_billing_note,
+        MAX(billing.billing_ts) OVER w AS last_billing_ts,
+        SUM(COALESCE(billing.amount, 0::numeric)) OVER w AS total_owed
+    FROM money.billing
+    WHERE billing.voided IS FALSE
+    WINDOW w AS (PARTITION BY billing.xact, billing.billing_type ORDER BY billing.billing_ts ROW BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING);
+
+-- money.open_transaction_payment_summary
+
+CREATE OR REPLACE VIEW money.open_transaction_payment_summary AS
+    SELECT DISTINCT payment_view.xact,
+        LAST_VALUE(payment_view.payment_type) OVER w AS last_payment_type,
+        LAST_VALUE(payment_view.note) OVER w AS last_payment_note,
+        MAX(payment_view.payment_ts) OVER w AS last_payment_ts, sum(COALESCE(payment_view.amount, 0::numeric)) AS total_paid
+    FROM money.payment_view
+    WHERE payment_view.voided IS FALSE
+    WINDOW w AS (PARTITION BY payment_view.xact ORDER BY payment_view.payment_ts ROWS BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING);
+
+-- money.transaction_billing_type_summary
+
+CREATE OR REPLACE VIEW money.transaction_billing_type_summary AS
+    SELECT DISTINCT billing.xact,
+        billing.billing_type AS last_billing_type,
+        LAST_VALUE(billing.note) OVER w AS last_billing_note,
+        MAX(billing.billing_ts) OVER w AS last_billing_ts,
+        SUM(COALESCE(billing.amount, 0::numeric)) AS total_owed
+    FROM money.billing
+    WHERE billing.voided IS FALSE
+    WINDOW w AS (PARTITION BY billing.xact, billing.billing_type ORDER BY billing.billing_ts ROW BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING);
+
+-- money.transaction_billing_with_void_summary
+
+CREATE OR REPLACE VIEW money.transaction_billing_with_void_summary AS
+    SELECT DISTINCT billing.xact,
+        LAST_VALUE(billing.billing_type) OVER w AS last_billing_type,
+        LAST_VALUE(billing.note) OVER w AS last_billing_note,
+        MAX(billing.billing_ts) OVER w AS last_billing_ts,
+        SUM(
+            CASE
+                WHEN billing.voided THEN 0::numeric
+                ELSE COALESCE(billing.amount, 0::numeric)
+            END) OVER w AS total_owed
+    FROM money.billing
+    WINDOW w AS (PARTITION BY billing.xact ORDER BY billing_ts ROWS BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING);
+
+-- money.transaction_payment_summary
+
+CREATE OR REPLACE VIEW money.transaction_payment_summary AS
+    SELECT DISTINCT payment_view.xact,
+        LAST_VALUE(payment_view.payment_type) OVER w AS last_payment_type,
+        LAST_VALUE(payment_view.note) OVER w AS last_payment_note,
+        MAX(payment_view.payment_ts) OVER w AS last_payment_ts,
+        SUM(COALESCE(payment_view.amount, 0::numeric)) OVER w AS total_paid
+    FROM money.payment_view
+    WHERE payment_view.voided IS FALSE
+    WINDOW w AS (PARTITION BY payment_view.xact ORDER BY payment_ts ROWS BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING);
+
+-- money.transaction_payment_with_void_summary
+
+CREATE OR REPLACE VIEW money.open_transaction_billing_type_summary AS
+    SELECT DISTINCT billing.xact,
+    billing.billing_type AS last_billing_type,
+    LAST_VALUE(billing.note) OVER w AS last_billing_note,
+    MAX(billing.billing_ts) OVER w AS last_billing_ts,
+    SUM(COALESCE(billing.amount, 0::numeric)) OVER w AS total_owed
+   FROM money.billing
+  WHERE billing.voided IS FALSE
+    WINDOW w AS (PARTITION BY billing.xact, billing.billing_type ORDER BY billing.billing_ts ROWS BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING);
+