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

feat: triggers for fts on units and projects in sqlite #61

Merged
merged 1 commit into from
Dec 20, 2021
Merged
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
52 changes: 7 additions & 45 deletions migrations/20211212200953-fulltext-search.cjs
Original file line number Diff line number Diff line change
Expand Up @@ -4,56 +4,18 @@ module.exports = {
up: async (queryInterface, Sequelize) => {
if (queryInterface.sequelize.getDialect() === 'sqlite') {
await queryInterface.sequelize.query(`
create virtual table projects_fts using fts5 (
warehouseProjectId,
currentRegistry,
registryOfOrigin,
originProjectId,
program,
projectName,
projectLink,
projectDeveloper,
sector,
projectType,
coveredByNDC,
NDCLinkage,
projectStatus,
projectStatusDate,
unitMetric,
methodology,
methodologyVersion,
validationApproach,
validationDate,
projectTag,
estimatedAnnualAverageEmissionReduction,
);`);
await queryInterface.sequelize.query(
`create virtual table units_fts using fts5 (
projectId,
buyer,
registry,
blockIdentifier,
identifier,
qualificationId,
unitType,
unitCount,
unitStatus,
unitStatusDate,
transactionType,
unitIssuanceLocation,
unitLink,
correspondingAdjustment,
unitTag,
vintageId
);`,
);
CREATE VIRTUAL TABLE projects_fts USING fts5(projects);
`);
await queryInterface.sequelize.query(`
CREATE VIRTUAL TABLE units_fts USING fts5(units);
`);
}
},

down: async (queryInterface, Sequelize) => {
if (queryInterface.sequelize.getDialect() === 'sqlite') {
await queryInterface.sequelize.query(`drop virtual table projects_fts;`);
await queryInterface.sequelize.query('drop virtual table units_fts;');
await queryInterface.sequelize.query(`drop table projects_fts;`);
await queryInterface.sequelize.query('drop table units_fts;');
}
},
};
120 changes: 120 additions & 0 deletions migrations/20211219182106-sqlite-triggers-projects.cjs
Original file line number Diff line number Diff line change
@@ -0,0 +1,120 @@
'use strict';

module.exports = {
up: async (queryInterface, Sequelize) => {
if (queryInterface.sequelize.getDialect() === 'sqlite') {
await queryInterface.sequelize.query(`
CREATE TRIGGER project_insert_fts AFTER INSERT ON projects BEGIN
INSERT INTO projects_fts(
id,
warehouseProjectId,
currentRegistry,
registryOfOrigin,
originProjectId,
program,
projectName,
projectLink,
projectDeveloper,
sector,
projectType,
coveredByNDC,
NDCLinkage,
projectStatus,
projectStatusDate,
unitMetric,
methodology,
methodologyVersion,
validationApproach,
validationDate,
projectTag
) VALUES (
new.id,
new.warehouseProjectId,
new.currentRegistry,
new.registryOfOrigin,
new.originProjectId,
new.program,
new.projectName,
new.projectLink,
new.projectDeveloper,
new.sector,
new.projectType,
new.coveredByNDC,
new.NDCLinkage,
new.projectStatus,
new.projectStatusDate,
new.unitMetric,
new.methodology,
new.methodologyVersion,
new.validationApproach,
new.validationDate,
new.projectTag
);
END;`);

await queryInterface.sequelize.query(`
CREATE TRIGGER project_delete_fts AFTER DELETE ON projects BEGIN
DELETE FROM projects_fts WHERE id = old.id;
END;
`);

await queryInterface.sequelize.query(`
CREATE TRIGGER project_update_fts AFTER UPDATE ON projects BEGIN
DELETE FROM projects_fts WHERE id = old.id;
INSERT INTO projects_fts(
id,
warehouseProjectId,
currentRegistry,
registryOfOrigin,
originProjectId,
program,
projectName,
projectLink,
projectDeveloper,
sector,
projectType,
coveredByNDC,
NDCLinkage,
projectStatus,
projectStatusDate,
unitMetric,
methodology,
methodologyVersion,
validationApproach,
validationDate,
projectTag
) VALUES (
new.id,
new.warehouseProjectId,
new.currentRegistry,
new.registryOfOrigin,
new.originProjectId,
new.program,
new.projectName,
new.projectLink,
new.projectDeveloper,
new.sector,
new.projectType,
new.coveredByNDC,
new.NDCLinkage,
new.projectStatus,
new.projectStatusDate,
new.unitMetric,
new.methodology,
new.methodologyVersion,
new.validationApproach,
new.validationDate,
new.projectTag
);
END;
`);
}},

down: async (queryInterface, Sequelize) => {
if (queryInterface.sequelize.getDialect() === 'sqlite') {
await queryInterface.sequelize.query("DROP TRIGGER project_insert_fts;");
await queryInterface.sequelize.query("DROP TRIGGER project_delete_fts;");
await queryInterface.sequelize.query("DROP TRIGGER project_update_fts;");
}
}
};
105 changes: 105 additions & 0 deletions migrations/20211219184405-sqlite-triggers-units.cjs
Original file line number Diff line number Diff line change
@@ -0,0 +1,105 @@
'use strict';

module.exports = {
up: async (queryInterface, Sequelize) => {
if (queryInterface.sequelize.getDialect() === 'sqlite') {
await queryInterface.sequelize.query(`
CREATE TRIGGER unit_insert_fts AFTER INSERT ON units BEGIN
INSERT INTO units_fts(
id,
projectId,
buyer,
registry,
blockIdentifier,
identifier,
qualificationId,
unitType,
unitCount,
unitStatus,
unitStatusDate,
transactionType,
unitIssuanceLocation,
unitLink,
correspondingAdjustment,
unitTag,
vintageId
) VALUES (
new.id,
new.projectId,
new.buyer,
new.registry,
new.blockIdentifier,
new.identifier,
new.qualificationId,
new.unitType,
new.unitCount,
new.unitStatus,
new.unitStatusDate,
new.transactionType,
new.unitIssuanceLocation,
new.unitLink,
new.correspondingAdjustment,
new.unitTag,
new.vintageId
);
END;`);

await queryInterface.sequelize.query(`
CREATE TRIGGER unit_delete_fts AFTER DELETE ON units BEGIN
DELETE FROM unit_insert_fts WHERE id = old.id;
END;
`);

await queryInterface.sequelize.query(`
CREATE TRIGGER unit_update_fts AFTER UPDATE ON units BEGIN
DELETE FROM units_fts WHERE id = old.id;
INSERT INTO units_fts(
id,
projectId,
buyer,
registry,
blockIdentifier,
identifier,
qualificationId,
unitType,
unitCount,
unitStatus,
unitStatusDate,
transactionType,
unitIssuanceLocation,
unitLink,
correspondingAdjustment,
unitTag,
vintageId
) VALUES (
new.id,
new.projectId,
new.buyer,
new.registry,
new.blockIdentifier,
new.identifier,
new.qualificationId,
new.unitType,
new.unitCount,
new.unitStatus,
new.unitStatusDate,
new.transactionType,
new.unitIssuanceLocation,
new.unitLink,
new.correspondingAdjustment,
new.unitTag,
new.vintageId
);
END;
`);
}
},

down: async (queryInterface, Sequelize) => {
if (queryInterface.sequelize.getDialect() === 'sqlite') {
await queryInterface.sequelize.query("DROP TRIGGER unit_insert_fts;");
await queryInterface.sequelize.query("DROP TRIGGER unit_delete_fts;");
await queryInterface.sequelize.query("DROP TRIGGER unit_update_fts;");
}
}
};