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)) 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.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 ROWS 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)) 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_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
--- /dev/null
+-- 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 ROWS 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)) 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_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)) 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);
+
+-- 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);
+
+COMMIT;