--- /dev/null
+-- Deploy kcls-evergreen:invoice-exports to pg
+-- requires: refundable-xact-summary-view-speed
+
+BEGIN;
+
+SET STATEMENT_TIMEOUT = 0;
+
+SELECT CLOCK_TIMESTAMP(),
+ 'Adding export date to legacy invoices closed 2018-05-22';
+
+-- Mark all invoices closed before today as exported so they
+-- are not re-exported.
+UPDATE acq.invoice SET erp_export_date = '2018-05-22'
+WHERE erp_export_date IS NULL AND DATE(close_date) < '2019-03-15';
+
+SELECT CLOCK_TIMESTAMP(), 'Done with legacy invoices';
+
+/**
+External script does this:
+SELECT acq.export_invoices();
+SELECT * FROM acq.last_invoice_export;
+
+In dry_run mode, the table of exported data is rebuilt as usual
+but the erp_export_date values on the acq.invoice rows are not set.
+*/
+
+CREATE OR REPLACE FUNCTION acq.export_invoices(dry_run BOOLEAN DEFAULT FALSE)
+ RETURNS INTEGER AS -- RETURNS number of invoices exported
+$FUNK$
+DECLARE
+ num_invoices INTEGER;
+BEGIN
+ -- DROP instead of TRUNCATE so it's easier to modify
+ -- columns later if needed by simply modifying this function.
+ DROP TABLE IF EXISTS acq.last_invoice_export;
+
+ CREATE TABLE acq.last_invoice_export AS
+ SELECT
+ *
+ FROM
+ (
+ SELECT
+ acq.invoice.ID AS internal_id,
+ acq.invoice.inv_ident AS vendor_inv_id,
+ acq.provider.ID AS provider_id,
+ to_char( acq.invoice.recv_date, 'MM/DD/YYYY' ) AS recv_date,
+ SUM ( acq.fund_debit.amount ) :: money AS amount_paid,
+ acq.fund_debit.fund AS fund_id,
+ 'inv_detail' AS entry_type,
+ acq.fund.code AS fund_code,
+ acq.fund.NAME AS fund_name,
+ acq.provider.code AS provider_code,
+ acq.provider.NAME AS provider_name,
+ acq.fund.YEAR AS fund_year,
+ acq.fund_tag.NAME AS fund_tag,
+ acq.invoice_entry.ID,
+ acq.invoice.close_date,
+ acq.invoice.closed_by
+ FROM
+ acq.invoice
+ INNER JOIN acq.provider ON acq.invoice.provider = acq.provider.ID
+ INNER JOIN acq.invoice_entry ON acq.invoice_entry.invoice = acq.invoice.ID
+ FULL OUTER JOIN acq.fund_debit ON acq.fund_debit.invoice_entry = acq.invoice_entry.ID
+ INNER JOIN acq.fund ON acq.fund_debit.fund = acq.fund.ID
+ LEFT JOIN acq.fund_tag_map ON acq.fund_tag_map.fund = acq.fund.ID
+ LEFT JOIN acq.fund_tag ON acq.fund_tag_map.tag = acq.fund_tag.ID
+ WHERE
+ acq.invoice.close_date IS NOT NULL
+ AND acq.provider.prepayment_required = 'f'
+ AND acq.invoice.erp_export_date IS NULL
+ GROUP BY
+ acq.invoice.ID,
+ acq.invoice.inv_ident,
+ acq.provider.ID,
+ acq.fund_debit.fund,
+ acq.fund.code,
+ acq.fund.NAME,
+ acq.fund.YEAR,
+ acq.fund_tag.NAME,
+ acq.invoice_entry.ID UNION ALL
+ SELECT
+ acq.invoice.ID AS internal_id,
+ acq.invoice.inv_ident AS vendor_inv_id,
+ acq.provider.ID AS provider_id,
+ to_char( acq.invoice.recv_date, 'MM/DD/YYYY' ) AS recv_date,
+ SUM ( acq.fund_debit.amount ) :: money AS amount_paid,
+ acq.fund_debit.fund AS fund_id,
+ acq.invoice_item_type.NAME AS entry_type,
+ acq.fund.code AS fund_code,
+ acq.fund.NAME AS fund_name,
+ acq.provider.code AS provider_code,
+ acq.provider.NAME AS provider_name,
+ acq.fund.YEAR AS fund_year,
+ acq.fund_tag.NAME AS fund_tag,
+ acq.invoice_item.ID,
+ acq.invoice.close_date,
+ acq.invoice.closed_by
+ FROM
+ acq.invoice
+ INNER JOIN acq.provider ON acq.invoice.provider = acq.provider.ID
+ INNER JOIN acq.invoice_item ON acq.invoice_item.invoice = acq.invoice.ID
+ INNER JOIN acq.invoice_item_type ON acq.invoice_item.inv_item_type = acq.invoice_item_type.code
+ FULL OUTER JOIN acq.fund_debit ON acq.invoice_item.fund_debit = acq.fund_debit.ID
+ INNER JOIN acq.fund ON acq.fund_debit.fund = acq.fund.ID
+ LEFT JOIN acq.fund_tag_map ON acq.fund_tag_map.fund = acq.fund.ID
+ LEFT JOIN acq.fund_tag ON acq.fund_tag_map.tag = acq.fund_tag.ID
+ WHERE
+ acq.invoice.close_date IS NOT NULL
+ AND acq.provider.prepayment_required = 'f'
+ AND acq.invoice.erp_export_date IS NULL
+ GROUP BY
+ acq.invoice.ID,
+ acq.invoice.inv_ident,
+ acq.provider.ID,
+ acq.fund_debit.fund,
+ acq.invoice_item_type.NAME,
+ acq.fund.code,
+ acq.fund.NAME,
+ acq.provider.code,
+ acq.provider.NAME,
+ acq.fund.YEAR,
+ acq.fund_tag.NAME,
+ acq.invoice_item.ID
+ ) AS inv
+ ORDER BY
+ 1
+ ;
+
+ -- Stamp the selected invoices as exported.
+ IF NOT dry_run THEN
+ UPDATE acq.invoice
+ SET erp_export_date = NOW()
+ WHERE id IN (
+ SELECT DISTINCT(internal_id) FROM acq.last_invoice_export
+ );
+ END IF;
+
+ SELECT INTO num_invoices COUNT(*) FROM acq.last_invoice_export;
+ RAISE NOTICE '% Invoices stamped as exported', num_invoices;
+
+ RETURN num_invoices;
+END;
+$FUNK$ LANGUAGE PLPGSQL;
+
+COMMIT;
+
lost-paid-receipts-data [lost-paid-receipts] 2017-08-02T15:28:08Z Bill Erickson,,, <berick@kcls-dev-local> # Lost/Paid permissions and receipts
aged-money-purge [lost-paid-receipts-data] 2018-10-16T19:33:11Z Bill Erickson,,, <berick@kcls-dev> # aged billing/payment migration
refundable-xact-summary-view-speed [aged-money-purge] 2018-11-14T16:49:15Z Bill Erickson,,, <berick@kcls-dev> # Speed up refundable xact summary
+invoice-exports [refundable-xact-summary-view-speed] 2019-01-17T20:58:17Z berick <berick@kcls-dev> # Exporting invoices
stock-browse-schema [ecard-notice-validator] 2018-08-31T15:22:58Z Bill Erickson,,, <berick@kcls-dev-local> # Recover stock browse data tables, etc.
stock-browse-headings-report [stock-browse-schema] 2018-10-04T15:56:18Z Bill Erickson,,, <berick@kcls-dev> # New heading report updates for stock browse
stock-browse-cleanup [stock-browse-schema] 2018-10-03T18:05:49Z Bill Erickson,,, <berick@kcls-dev> # Delete old browse data