From: miker Date: Tue, 19 Jun 2007 17:34:20 +0000 (+0000) Subject: Moving cross-schema views out of the main schema creation script. --miker X-Git-Url: https://old-git.evergreen-ils.org/?a=commitdiff_plain;h=a6b16032f358fece7dbc384c8117eb3be0d39a71;p=Evergreen.git Moving cross-schema views out of the main schema creation script. --miker git-svn-id: svn://svn.open-ils.org/ILS/trunk@7448 dcc99617-32d9-48b4-a31d-7c20da2025e4 --- diff --git a/Open-ILS/src/sql/Pg/080.schema.money.sql b/Open-ILS/src/sql/Pg/080.schema.money.sql index c8bfa745a2..19b8994161 100644 --- a/Open-ILS/src/sql/Pg/080.schema.money.sql +++ b/Open-ILS/src/sql/Pg/080.schema.money.sql @@ -233,70 +233,6 @@ CREATE OR REPLACE VIEW money.billable_xact_summary AS GROUP BY 1,2,3,4,14 ORDER BY MAX(debit.billing_ts), MAX(credit.payment_ts); -CREATE OR REPLACE VIEW money.open_billable_xact_summary AS - SELECT xact.id AS id, - xact.usr AS usr, - COALESCE(circ.circ_lib,groc.billing_location) AS billing_location, - xact.xact_start AS xact_start, - xact.xact_finish AS xact_finish, - SUM(credit.amount) AS total_paid, - MAX(credit.payment_ts) AS last_payment_ts, - LAST(credit.note) AS last_payment_note, - LAST(credit.payment_type) AS last_payment_type, - SUM(debit.amount) AS total_owed, - MAX(debit.billing_ts) AS last_billing_ts, - LAST(debit.note) AS last_billing_note, - LAST(debit.billing_type) AS last_billing_type, - COALESCE(SUM(debit.amount),0) - COALESCE(SUM(credit.amount),0) AS balance_owed, - p.relname AS xact_type - FROM money.billable_xact xact - JOIN pg_class p ON (xact.tableoid = p.oid) - LEFT JOIN "action".circulation circ ON (circ.id = xact.id) - LEFT JOIN money.grocery groc ON (groc.id = xact.id) - LEFT JOIN ( - SELECT billing.xact, - billing.voided, - sum(billing.amount) AS amount, - max(billing.billing_ts) AS billing_ts, - last(billing.note) AS note, - last(billing.billing_type) AS billing_type - FROM money.billing - WHERE billing.voided IS FALSE - GROUP BY billing.xact, billing.voided - ) debit ON (xact.id = debit.xact AND debit.voided IS FALSE) - LEFT JOIN ( - SELECT payment_view.xact, - payment_view.voided, - sum(payment_view.amount) AS amount, - max(payment_view.payment_ts) AS payment_ts, - last(payment_view.note) AS note, - last(payment_view.payment_type) AS payment_type - FROM money.payment_view - WHERE payment_view.voided IS FALSE - GROUP BY payment_view.xact, payment_view.voided - ) credit ON (xact.id = credit.xact AND credit.voided IS FALSE) - WHERE xact.xact_finish IS NULL - GROUP BY 1,2,3,4,5,15 - ORDER BY MAX(debit.billing_ts), MAX(credit.payment_ts); - - -CREATE OR REPLACE VIEW money.open_usr_summary AS - SELECT usr, - SUM(total_paid) AS total_paid, - SUM(total_owed) AS total_owed, - SUM(balance_owed) AS balance_owed - FROM money.open_billable_xact_summary - GROUP BY 1; - -CREATE OR REPLACE VIEW money.open_usr_circulation_summary AS - SELECT usr, - SUM(total_paid) AS total_paid, - SUM(total_owed) AS total_owed, - SUM(balance_owed) AS balance_owed - FROM money.open_billable_xact_summary - WHERE xact_type = 'circulation' - GROUP BY 1; - CREATE OR REPLACE VIEW money.usr_summary AS SELECT usr, SUM(total_paid) AS total_paid, diff --git a/Open-ILS/src/sql/Pg/500.view.cross-schema.sql b/Open-ILS/src/sql/Pg/500.view.cross-schema.sql new file mode 100644 index 0000000000..23c2b2c17f --- /dev/null +++ b/Open-ILS/src/sql/Pg/500.view.cross-schema.sql @@ -0,0 +1,68 @@ +BEGIN; + +CREATE OR REPLACE VIEW money.open_billable_xact_summary AS + SELECT xact.id AS id, + xact.usr AS usr, + COALESCE(circ.circ_lib,groc.billing_location) AS billing_location, + xact.xact_start AS xact_start, + xact.xact_finish AS xact_finish, + SUM(credit.amount) AS total_paid, + MAX(credit.payment_ts) AS last_payment_ts, + LAST(credit.note) AS last_payment_note, + LAST(credit.payment_type) AS last_payment_type, + SUM(debit.amount) AS total_owed, + MAX(debit.billing_ts) AS last_billing_ts, + LAST(debit.note) AS last_billing_note, + LAST(debit.billing_type) AS last_billing_type, + COALESCE(SUM(debit.amount),0) - COALESCE(SUM(credit.amount),0) AS balance_owed, + p.relname AS xact_type + FROM money.billable_xact xact + JOIN pg_class p ON (xact.tableoid = p.oid) + LEFT JOIN "action".circulation circ ON (circ.id = xact.id) + LEFT JOIN money.grocery groc ON (groc.id = xact.id) + LEFT JOIN ( + SELECT billing.xact, + billing.voided, + sum(billing.amount) AS amount, + max(billing.billing_ts) AS billing_ts, + last(billing.note) AS note, + last(billing.billing_type) AS billing_type + FROM money.billing + WHERE billing.voided IS FALSE + GROUP BY billing.xact, billing.voided + ) debit ON (xact.id = debit.xact AND debit.voided IS FALSE) + LEFT JOIN ( + SELECT payment_view.xact, + payment_view.voided, + sum(payment_view.amount) AS amount, + max(payment_view.payment_ts) AS payment_ts, + last(payment_view.note) AS note, + last(payment_view.payment_type) AS payment_type + FROM money.payment_view + WHERE payment_view.voided IS FALSE + GROUP BY payment_view.xact, payment_view.voided + ) credit ON (xact.id = credit.xact AND credit.voided IS FALSE) + WHERE xact.xact_finish IS NULL + GROUP BY 1,2,3,4,5,15 + ORDER BY MAX(debit.billing_ts), MAX(credit.payment_ts); + + +CREATE OR REPLACE VIEW money.open_usr_summary AS + SELECT usr, + SUM(total_paid) AS total_paid, + SUM(total_owed) AS total_owed, + SUM(balance_owed) AS balance_owed + FROM money.open_billable_xact_summary + GROUP BY 1; + +CREATE OR REPLACE VIEW money.open_usr_circulation_summary AS + SELECT usr, + SUM(total_paid) AS total_paid, + SUM(total_owed) AS total_owed, + SUM(balance_owed) AS balance_owed + FROM money.open_billable_xact_summary + WHERE xact_type = 'circulation' + GROUP BY 1; + +COMMIT; + diff --git a/Open-ILS/src/sql/Pg/build-db.sh b/Open-ILS/src/sql/Pg/build-db.sh index f6632aa368..7a53b8565c 100755 --- a/Open-ILS/src/sql/Pg/build-db.sh +++ b/Open-ILS/src/sql/Pg/build-db.sh @@ -18,6 +18,8 @@ PGUSER=$4 PGHOST=$1 PGPORT=$2 PGDATABASE=$3 psql -f 070.schema.container.sql PGUSER=$4 PGHOST=$1 PGPORT=$2 PGDATABASE=$3 psql -f 080.schema.money.sql PGUSER=$4 PGHOST=$1 PGPORT=$2 PGDATABASE=$3 psql -f 090.schema.action.sql +PGUSER=$4 PGHOST=$1 PGPORT=$2 PGDATABASE=$3 psql -f 500.view.cross-schema.sql + PGUSER=$4 PGHOST=$1 PGPORT=$2 PGDATABASE=$3 psql -f 800.fkeys.sql PGUSER=$4 PGHOST=$1 PGPORT=$2 PGDATABASE=$3 psql -f 900.audit-functions.sql PGUSER=$4 PGHOST=$1 PGPORT=$2 PGDATABASE=$3 psql -f 901.audit-tables.sql