Skip to content

Commit

Permalink
[MODFISTO-482] - Migration script to separate credits from expenditur…
Browse files Browse the repository at this point in the history
…es (#422)

* Migration script to separate credits from expenditures

* Improved query

* Improved query

* updated sql query
  • Loading branch information
azizbekxm authored Jul 19, 2024
1 parent 8af5c99 commit d2a8dd0
Show file tree
Hide file tree
Showing 2 changed files with 63 additions and 0 deletions.
Original file line number Diff line number Diff line change
@@ -0,0 +1,58 @@
-- Extract credits from expenditures in each budget
-- 1. Calculate all credits values within budget fiscal year
-- 2. Set to budget credits fields
-- 3. Subtract from expenditures amount

WITH credit_sums AS (
SELECT
budget.id AS budget_id,
SUM((trx.jsonb->>'amount')::numeric) AS total_credits
FROM ${myuniversity}_${mymodule}.budget AS budget
JOIN ${myuniversity}_${mymodule}.transaction AS trx
ON trx.fiscalyearid = budget.fiscalyearid AND trx.tofundid = budget.fundid
WHERE trx.jsonb->>'transactionType' = 'Credit'
GROUP BY budget.id
)
UPDATE ${myuniversity}_${mymodule}.budget AS budget
SET
jsonb = jsonb_set(
jsonb_set(
budget.jsonb,
'{credits}',
to_jsonb((budget.jsonb->>'credits')::numeric + credit_sums.total_credits)
),
'{expenditures}',
to_jsonb((budget.jsonb->>'expenditures')::numeric - credit_sums.total_credits)
)
FROM credit_sums
WHERE budget.id = credit_sums.budget_id;


-- Recalculate amountExpended/amountCredited values in encumbrance transaction
-- 1. Calculate each amount with Payment and Credit transactions
-- 2. Set calculated values for amountExpended and amountCredits, respectively

WITH aggregated_amounts AS (
SELECT
encumbrance.id AS encumbrance_id,
SUM(CASE WHEN trx.jsonb->>'transactionType' = 'Payment' THEN (trx.jsonb->>'amount')::numeric ELSE 0 END) AS total_expended,
SUM(CASE WHEN trx.jsonb->>'transactionType' = 'Credit' THEN (trx.jsonb->>'amount')::numeric ELSE 0 END) AS total_credited
FROM ${myuniversity}_${mymodule}.transaction AS encumbrance
LEFT JOIN ${myuniversity}_${mymodule}.transaction AS trx
ON trx.jsonb->>'paymentEncumbranceId' = encumbrance.id::text
WHERE encumbrance.jsonb->>'transactionType' = 'Encumbrance'
GROUP BY encumbrance.id
)
UPDATE ${myuniversity}_${mymodule}.transaction AS encumbrance
SET
jsonb = jsonb_set(
jsonb_set(
encumbrance.jsonb,
'{encumbrance,amountExpended}',
to_jsonb(aggregated_amounts.total_expended)
),
'{encumbrance,amountCredited}',
to_jsonb(aggregated_amounts.total_credited)
)
FROM aggregated_amounts
WHERE encumbrance.id = aggregated_amounts.encumbrance_id;
5 changes: 5 additions & 0 deletions src/main/resources/templates/db_scripts/schema.json
Original file line number Diff line number Diff line change
Expand Up @@ -90,6 +90,11 @@
"run": "after",
"snippetPath": "migration/transform_location_ids_array.sql",
"fromModuleVersion": "mod-finance-storage-8.7.0"
},
{
"run": "after",
"snippetPath": "migration/extract_credits_from_expenditures.sql",
"fromModuleVersion": "mod-finance-storage-8.7.0"
}
],
"tables": [
Expand Down

0 comments on commit d2a8dd0

Please sign in to comment.