Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

[TTAHUB-2439] Grant replacement: models and migrations #2344

Draft
wants to merge 3 commits into
base: main
Choose a base branch
from
Draft
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
2 changes: 1 addition & 1 deletion docs/logical_data_model.encoded

Large diffs are not rendered by default.

65 changes: 62 additions & 3 deletions docs/logical_data_model.puml
Original file line number Diff line number Diff line change
Expand Up @@ -435,9 +435,30 @@ class GrantNumberLinks{
deletedAt : timestamp with time zone
}

!issue='model missing for table'
class GrantReplacement #pink;line:red;line.bold;text:red {
!issue='column should not allow null' * id : integer : <generated>
!issue='column reference missing' grantReplacementTypeId : integer : REFERENCES "GrantReplacementTypes".id
!issue='column should not allow null'
!issue='column reference missing' * replacedGrantId : integer : REFERENCES "Grants".id
!issue='column should not allow null'
!issue='column reference missing' * replacingGrantId : integer : REFERENCES "Grants".id
!issue='column should not allow null' * createdAt : timestamp with time zone : now()
!issue='column should not allow null' * updatedAt : timestamp with time zone : now()
replacementDate : date
}

class GrantReplacementTypes{
* id : integer : <generated>
!issue='column reference missing' mapsTo : integer : REFERENCES "GrantReplacementTypes".id
!issue='column should not allow null' * createdAt : timestamp with time zone : now()
!issue='column should not allow null' * name : text
!issue='column should not allow null' * updatedAt : timestamp with time zone : now()
deletedAt : timestamp with time zone
}

class Grants{
* id : integer
oldGrantId : integer : REFERENCES "Grants".id
regionId : integer : REFERENCES "Regions".id
* recipientId : integer : REFERENCES "Recipients".id
* createdAt : timestamp with time zone : now()
Expand All @@ -450,8 +471,6 @@ class Grants{
granteeName : varchar(255)
grantSpecialistEmail : varchar(255)
grantSpecialistName : varchar(255)
inactivationDate : timestamp with time zone
inactivationReason : enum
programSpecialistEmail : varchar(255)
programSpecialistName : varchar(255)
startDate : timestamp with time zone
Expand Down Expand Up @@ -1614,6 +1633,35 @@ class ZALGrantNumberLinks{
session_sig : text
}

!issue='model missing for table'
class ZALGrantReplacement #pink;line:red;line.bold;text:red {
!issue='column should not allow null' * id : bigint : <generated>
!issue='column should not allow null' * data_id : bigint
!issue='column should not allow null' * dml_as : bigint
!issue='column should not allow null' * dml_by : bigint
!issue='column should not allow null' * dml_timestamp : timestamp with time zone
!issue='column should not allow null' * dml_txid : uuid
!issue='column should not allow null' * dml_type : enum
descriptor_id : integer
new_row_data : jsonb
old_row_data : jsonb
session_sig : text
}

class ZALGrantReplacementTypes{
* id : bigint : <generated>
* data_id : bigint
* dml_as : bigint
* dml_by : bigint
* dml_timestamp : timestamp with time zone
* dml_txid : uuid
* dml_type : enum
descriptor_id : integer
new_row_data : jsonb
old_row_data : jsonb
session_sig : text
}

class ZALGrants{
* id : bigint : <generated>
* data_id : bigint
Expand Down Expand Up @@ -2481,12 +2529,16 @@ Goals "1" --[#black,dashed,thickness=2]--{ "n" Objectives : objectives, goal
Goals "1" --[#black,dashed,thickness=2]--{ "n" SimScoreGoalCaches : scoreOne, scoreTwo, goalOne, goalTwo
GrantNumberLinks "1" --[#black,dashed,thickness=2]--{ "n" MonitoringClassSummaries : monitoringClassSummaries, grantNumberLink
GrantNumberLinks "1" --[#black,dashed,thickness=2]--{ "n" MonitoringReviewGrantees : monitoringReviewGrantees, grantNumberLink
!issue='associations need to be defined both directions'
!issue='associations need to be camel case'
GrantReplacementTypes "1" --[#d54309,dashed,thickness=2]--{ "n" undefined : <color:#d54309>GrantReplacements</color>
Grants "1" --[#black,dashed,thickness=2]--{ "n" ActivityRecipients : grant, activityRecipients
Grants "1" --[#black,dashed,thickness=2]--{ "n" Goals : grant, goals
Grants "1" --[#black,dashed,thickness=2]--{ "n" Grants : oldGrants, grant
Grants "1" --[#black,dashed,thickness=2]--{ "n" GroupGrants : groupGrants, grant
Grants "1" --[#black,dashed,thickness=2]--{ "n" ProgramPersonnel : programPersonnel, grant
Grants "1" --[#black,dashed,thickness=2]--{ "n" Programs : programs, grant
Grants "1" --[#black,dashed,thickness=2]--{ "n" undefined : grantRelationships, activeGrantRelationships, replacedGrantReplacements, replacingGrantReplacements
Groups "1" --[#black,dashed,thickness=2]--{ "n" GroupCollaborators : group, groupCollaborators
Groups "1" --[#black,dashed,thickness=2]--{ "n" GroupGrants : group, groupGrants
ImportFiles "1" --[#black,dashed,thickness=2]--{ "n" ImportDataFiles : importFile, importDataFiles
Expand Down Expand Up @@ -2600,4 +2652,11 @@ Roles "n" }--[#black,dotted,thickness=2]--{ "n" Topics : topics, roles
Roles "n" }--[#black,dotted,thickness=2]--{ "n" Users : users, roles
Scopes "n" }--[#black,dotted,thickness=2]--{ "n" Users : users, scopes

!issue='association missing from models'!issue='associations need to be defined both directions'
GrantReplacementTypes o--[#yellow,bold,thickness=2]--o GrantReplacement : <color:#2491FF>missing-from-model</color>
!issue='associations need to be defined both directions'
GrantReplacementTypes o--[#yellow,bold,thickness=2]--o GrantReplacementTypes : <color:#2491FF>missing-from-model</color>
!issue='associations need to be defined both directions'
Grants o--[#yellow,bold,thickness=2]--o GrantReplacement : <color:#2491FF>missing-from-model</color>

@enduml
2 changes: 1 addition & 1 deletion src/goalServices/changeGoalStatus.test.js
Original file line number Diff line number Diff line change
Expand Up @@ -55,7 +55,7 @@ describe('changeGoalStatus service', () => {
afterAll(async () => {
await db.Goal.destroy({ where: { id: goal.id }, force: true });
await db.GrantNumberLink.destroy({ where: { grantId: grant.id }, force: true });
await db.Grant.destroy({ where: { id: grant.id } });
await db.Grant.destroy({ where: { id: grant.id }, individualHooks: true });
await db.Recipient.destroy({ where: { id: recipient.id } });
await db.UserRole.destroy({ where: { userId: user.id } });
await db.Role.destroy({ where: { id: role.id } });
Expand Down
141 changes: 141 additions & 0 deletions src/migrations/20240830172706-populate-grant-replacements.js
Original file line number Diff line number Diff line change
@@ -0,0 +1,141 @@
const { prepMigration } = require('../lib/migration');

const { GRANT_INACTIVATION_REASONS } = require('../constants');

const inactivationReasons = Object.values(GRANT_INACTIVATION_REASONS);

module.exports = {
up: async (queryInterface, Sequelize) => queryInterface.sequelize.transaction(
async (transaction) => {
await prepMigration(queryInterface, transaction, __filename);
// Create GrantReplacementTypes table
await queryInterface.createTable('GrantReplacementTypes', {
id: {
type: Sequelize.INTEGER,
autoIncrement: true,
primaryKey: true,
},
name: {
type: Sequelize.TEXT,
allowNull: false,
},
createdAt: {
type: Sequelize.DATE,
allowNull: false,
defaultValue: Sequelize.fn('NOW'),
},
updatedAt: {
type: Sequelize.DATE,
allowNull: false,
defaultValue: Sequelize.fn('NOW'),
},
deletedAt: {
type: Sequelize.DATE,
allowNull: true,
},
mapsTo: {
type: Sequelize.INTEGER,
references: {
model: 'GrantReplacementTypes',
key: 'id',
},
allowNull: true,
},
}, { transaction });

// Create GrantReplacement table
await queryInterface.createTable('GrantReplacement', {
id: {
type: Sequelize.INTEGER,
autoIncrement: true,
primaryKey: true,
},
replacedGrantId: {
type: Sequelize.INTEGER,
allowNull: false,
references: {
model: 'Grants',
key: 'id',
},
},
replacingGrantId: {
type: Sequelize.INTEGER,
allowNull: false,
references: {
model: 'Grants',
key: 'id',
},
},
grantReplacementTypeId: {
type: Sequelize.INTEGER,
allowNull: true,
references: {
model: 'GrantReplacementTypes',
key: 'id',
},
},
replacementDate: {
type: Sequelize.DATEONLY,
allowNull: true,
},
createdAt: {
type: Sequelize.DATE,
allowNull: false,
defaultValue: Sequelize.fn('NOW'),
},
updatedAt: {
type: Sequelize.DATE,
allowNull: false,
defaultValue: Sequelize.fn('NOW'),
},
}, { transaction });

await queryInterface.sequelize.query(/* sql */`
INSERT INTO "GrantReplacement" (
"replacedGrantId",
"replacingGrantId",
"replacementDate",
"createdAt",
"updatedAt"
)
SELECT
gr1."oldGrantId" AS "replacedGrantId",
gr1."id" AS "replacingGrantId",
gr2."inactivationDate" AS "replacementDate",
gr1."createdAt",
gr1."updatedAt"
FROM "Grants" gr1
JOIN "Grants" gr2
ON gr1."oldGrantId" = gr2.id
WHERE gr1."oldGrantId" IS NOT NULL;
`, { transaction });

await queryInterface.removeColumn('Grants', 'oldGrantId', { transaction });
await queryInterface.removeColumn('Grants', 'inactivationDate', { transaction });
await queryInterface.removeColumn('Grants', 'inactivationReason', { transaction });
},
),

down: async (queryInterface, Sequelize) => queryInterface.sequelize.transaction(
async (transaction) => {
await prepMigration(queryInterface, transaction, __filename);
await queryInterface.addColumn('Grants', 'oldGrantId', {
type: Sequelize.INTEGER,
allowNull: true,
}, { transaction });

await queryInterface.addColumn('Grants', 'inactivationDate', {
type: Sequelize.DATE,
allowNull: true,
}, { transaction });

await queryInterface.addColumn('Grants', 'inactivationReason', {
type: Sequelize.ENUM(...inactivationReasons),
allowNull: true,
}, { transaction });

await queryInterface.dropTable('GrantReplacement', { transaction });
await queryInterface.dropTable('GrantReplacementTypes', { transaction });
},
),
};
Original file line number Diff line number Diff line change
@@ -0,0 +1,91 @@
const { prepMigration } = require('../lib/migration');

module.exports = {
up: async (queryInterface) => queryInterface.sequelize.transaction(
async (transaction) => {
await prepMigration(queryInterface, transaction, __filename);

await queryInterface.sequelize.query(/* sql */`
CREATE MATERIALIZED VIEW "GrantRelationshipToActive" AS
WITH RECURSIVE recursive_cte AS (
-- Base query: Case 1: Select all Active grants from the "Grants" table
SELECT
g."id" AS "grantId",
g."id" AS "activeGrantId",
ARRAY[g."id"] AS "visited_grantIds" -- Initialize the array with the first grantId
FROM "Grants" g
WHERE g."status" = 'Active'

UNION ALL

-- Base query: Case 2: Select all inactive grants from the "Grants" table that have replaced other grants, but that have not been replaced
SELECT
g."id" AS "grantId",
NULL::int AS "activeGrantId",
ARRAY[g."id"] AS "visited_grantIds" -- Initialize the array with the first grantId
FROM "Grants" g
JOIN "GrantReplacement" gr1
ON g.id = gr1."replacingGrantId"
LEFT JOIN "GrantReplacement" gr2
ON g.id = gr2."replacedGrantId"
WHERE g.status != 'Active'
AND gr2.id IS NULL

UNION ALL

-- Base query: Case 3: Select all inactive grants from the "Grants" table that have never replaced other grants or been replaced
SELECT
g."id" AS "grantId",
NULL::int AS "activeGrantId",
ARRAY[g."id"] AS "visited_grantIds" -- Initialize the array with the first grantId
FROM "Grants" g
JOIN "GrantReplacement" gr
ON g.id = gr."replacingGrantId"
OR g.id = gr."replacedGrantId"
WHERE g.status != 'Active'
AND gr.id IS NULL

UNION ALL

-- Recursive query: Use an array to track visited grantIds
SELECT
g."id" AS "grantId",
rcte."activeGrantId",
"visited_grantIds" || g."id" -- Append the current grantId to the array
FROM recursive_cte rcte
JOIN "GrantReplacement" gr
ON rcte."grantId" = gr."replacingGrantId"
JOIN "Grants" g
ON g."id" = gr."replacedGrantId"
WHERE g."id" != ALL("visited_grantIds") -- Ensure the current grantId hasn't been visited
)
SELECT DISTINCT
ROW_NUMBER() OVER (ORDER BY rcte."grantId", rcte."activeGrantId") AS "id", -- Add row number as "id"
rcte."grantId",
rcte."activeGrantId"
FROM recursive_cte rcte
WITH NO DATA;
`, { transaction });

await queryInterface.sequelize.query(/* sql */`
CREATE INDEX "idx_GrantRelationshipToActive_grantId_activeGrantId"
ON "GrantRelationshipToActive" ("grantId", "activeGrantId");
`, { transaction });

// Initial refresh without CONCURRENTLY to populate the materialized view
await queryInterface.sequelize.query(/* sql */`
REFRESH MATERIALIZED VIEW "GrantRelationshipToActive";
`, { transaction });
},
),

down: async (queryInterface) => queryInterface.sequelize.transaction(
async (transaction) => {
await prepMigration(queryInterface, transaction, __filename);

await queryInterface.sequelize.query(/* sql */`
DROP MATERIALIZED VIEW IF EXISTS "GrantRelationshipToActive";
`, { transaction });
},
),
};
Loading