Skip to content

Commit

Permalink
[TECH] Migrer la colonne Answer.id de INTEGER en BIG INTEGER (Partie 3)
Browse files Browse the repository at this point in the history
  • Loading branch information
pix-service-auto-merge committed May 9, 2022
2 parents f00887e + a959396 commit aa6c183
Show file tree
Hide file tree
Showing 4 changed files with 366 additions and 2 deletions.
Original file line number Diff line number Diff line change
@@ -0,0 +1,177 @@
require('dotenv').config();
const { knex } = require('../../../db/knex-database-connection');
const { performance, PerformanceObserver } = require('perf_hooks');
const logger = require('../../../lib/infrastructure/logger');

const addConstraintsAndIndexesToAnswersKeBigintTemporaryTables = async () => {
logger.debug('Start adding constraints and indexes to answers ke bigint tables');

performance.mark('startTime');

const obs = new PerformanceObserver((list) => {
const entries = list.getEntries();
entries.forEach((entry) => {
logger.debug(entry.name + ' took : ' + entry.duration + ' milliseconds');
});
});

obs.observe({ entryTypes: ['measure'], buffered: true });

await knex.transaction(async (trx) => {
logger.debug('create indexes and constraints for answers_bigint table');

await knex.raw('ALTER TABLE "answers_bigint" ALTER COLUMN "id" SET NOT NULL').transacting(trx);
await knex.raw('ALTER TABLE "answers_bigint" ALTER COLUMN "challengeId" SET NOT NULL').transacting(trx);
await knex.raw('ALTER TABLE "answers_bigint" ALTER COLUMN "createdAt" SET NOT NULL').transacting(trx);
await knex.raw('ALTER TABLE "answers_bigint" ALTER COLUMN "updatedAt" SET NOT NULL').transacting(trx);
await knex.raw('ALTER TABLE "answers_bigint" ALTER COLUMN "isFocusedOut" SET NOT NULL').transacting(trx);

performance.mark('answersBigIntNotNullConstraintsTime');

await knex
.raw(
`ALTER TABLE "answers_bigint"
ADD CONSTRAINT "answers_bigint_pkey" PRIMARY KEY("id")`
)
.transacting(trx);

performance.mark('answersBigintPkey');
performance.measure('answers_bigint_pkey', 'answersBigIntNotNullConstraintsTime', 'answersBigintPkey');

await knex
.raw(
`ALTER TABLE "answers_bigint"
ADD CONSTRAINT "answers_bigint_assessmentid_foreign" FOREIGN KEY ("assessmentId")
REFERENCES "assessments" (id)`
)
.transacting(trx);

performance.mark('answersBigintAssessmentidForeign');
performance.measure('answers_bigint_pkey', 'answersBigintPkey', 'answersBigintAssessmentidForeign');

await knex
.raw(`CREATE INDEX "answers_bigint_assessmentid_index" ON "answers_bigint" USING btree ("assessmentId")`)
.transacting(trx);

performance.mark('answersBigintAssessmentidIndex');
performance.measure(
'answers_bigint_assessmentid_index',
'answersBigintAssessmentidForeign',
'answersBigintAssessmentidIndex'
);

await knex.raw('ALTER TABLE "knowledge-elements_bigint" ALTER COLUMN "id" SET NOT NULL').transacting(trx);
await knex.raw('ALTER TABLE "knowledge-elements_bigint" ALTER COLUMN "createdAt" SET NOT NULL').transacting(trx);
await knex.raw('ALTER TABLE "knowledge-elements_bigint" ALTER COLUMN "earnedPix" SET NOT NULL').transacting(trx);

performance.mark('keBigIntNotNullConstraintsTime');
performance.measure(
'keBigIntNotNullConstraints',
'answersBigintAssessmentidIndex',
'keBigIntNotNullConstraintsTime'
);

await knex
.raw('ALTER TABLE "knowledge-elements_bigint" ADD CONSTRAINT "knowledge-elements_bigint_pkey" PRIMARY KEY("id")')
.transacting(trx);

performance.mark('keBigintPkey');
performance.measure('knowledge-elements_bigint', 'keBigIntNotNullConstraintsTime', 'keBigintPkey');

await knex
.raw(
`ALTER TABLE "knowledge-elements_bigint"
ADD CONSTRAINT "knowledge_elements_bigint_answerid_foreign" FOREIGN KEY("answerId")
REFERENCES "answers_bigint"(id)`
)
.transacting(trx);

performance.mark('keBigintAnsweridForeign');
performance.measure('knowledge_elements_bigint_answerid_foreign', 'keBigintPkey', 'keBigintAnsweridForeign');

await knex
.raw(
`ALTER TABLE "knowledge-elements_bigint"
ADD CONSTRAINT "knowledge_elements_bigint_assessmentid_foreign" FOREIGN KEY ("assessmentId")
REFERENCES "assessments" (id)`
)
.transacting(trx);

performance.mark('keBigintAssessmentidForeign');
performance.measure(
'knowledge_elements_bigint_assessmentid_foreign',
'keBigintAnsweridForeign',
'keBigintAssessmentidForeign'
);

await knex
.raw(
`ALTER TABLE "knowledge-elements_bigint"
ADD CONSTRAINT "knowledge_elements_bigint_userid_foreign" FOREIGN KEY ("userId")
REFERENCES "users" (id)`
)
.transacting(trx);

performance.mark('keBigintUseridForeign');
performance.measure(
'knowledge_elements_bigint_userid_foreign',
'keBigintAssessmentidForeign',
'keBigintUseridForeign'
);

await knex
.raw(
'CREATE INDEX "knowledge_elements_bigint_userid_index" ON "knowledge-elements_bigint" USING btree ("userId")'
)
.transacting(trx);

performance.mark('keBigintUseridIndex');
performance.measure('knowledge_elements_bigint_userid_index', 'keBigintUseridForeign', 'keBigintUseridIndex');

await knex
.raw(
'CREATE INDEX "knowledge_elements_bigint_assessmentid_index" on "knowledge-elements_bigint" ("assessmentId")'
)
.transacting(trx);

performance.mark('keBigintAssessmentIdIndex');
performance.measure(
'knowledge_elements_bigint_assessmentid_index',
'keBigintUseridIndex',
'keBigintAssessmentIdIndex'
);
});

performance.mark('endTime');
performance.measure('Global time for adding constraints and indexes', 'startTime', 'endTime');

logger.debug('Finish adding constraints and indexes to answers ke bigint tables');

performance.clearMarks();
obs.disconnect();
};

const isLaunchedFromCommandLine = require.main === module;

async function main() {
try {
logger.info(`Start script ${__filename}... `);
await addConstraintsAndIndexesToAnswersKeBigintTemporaryTables();
logger.info('End script: copy done successfully.');
} catch (error) {
logger.error(error);
process.exit(1);
}
}

if (isLaunchedFromCommandLine) {
main().then(
() => process.exit(0),
(err) => {
console.error(err);
process.exit(1);
}
);
}

module.exports = { addConstraintsAndIndexesToAnswersKeBigintTemporaryTables };
Original file line number Diff line number Diff line change
Expand Up @@ -38,7 +38,7 @@ const isLaunchedFromCommandLine = require.main === module;

async function main() {
try {
logger.debug('Start script... ');
logger.info(`Start script ${__filename}... `);
await copyAnswerKeDataToTemporaryTables();
logger.debug('End script: copy done successfully.');
} catch (error) {
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -47,7 +47,7 @@ async function createAnswersBigintMigrationDatabaseStructures(knex) {
const isLaunchedFromCommandLine = require.main === module;

async function main() {
logger.info('Start script');
logger.info(`Start script ${__filename}... `);
await createAnswersBigintMigrationDatabaseStructures(knex);
logger.info('End script');
}
Expand Down
Original file line number Diff line number Diff line change
@@ -0,0 +1,187 @@
const {
createAnswersBigintMigrationDatabaseStructures,
} = require('../../../../../scripts/bigint/answer/create-migration-database-structure');
const {
addConstraintsAndIndexesToAnswersKeBigintTemporaryTables,
} = require('../../../../../scripts/bigint/answer/add-constraints-and-indexes-to-answers-ke-temporary-tables-with-bigint.js');
const { expect, knex } = require('../../../../test-helper');

describe('#addConstraintsAndIndexesToAnswersKeBigintTemporaryTables', function () {
beforeEach(async function () {
// given
await knex.raw('DROP TABLE IF EXISTS "bigint-migration-settings"');
await knex.raw('DROP TABLE IF EXISTS "knowledge-elements_bigint"');
await knex.raw('DROP TABLE IF EXISTS "answers_bigint"');
await createAnswersBigintMigrationDatabaseStructures(knex);

// when
await addConstraintsAndIndexesToAnswersKeBigintTemporaryTables();
});
it('should create NOT NULL constraints', async function () {
// then
const { rows: notNullableAnswersBigintColumns } = await knex.raw(
`SELECT c.column_name FROM information_schema.columns c WHERE c.table_name = 'answers_bigint' AND c.is_nullable = 'NO' ORDER BY c.column_name`
);
expect(notNullableAnswersBigintColumns).to.deep.equal([
{ column_name: 'challengeId' },
{ column_name: 'createdAt' },
{ column_name: 'id' },
{ column_name: 'isFocusedOut' },
{ column_name: 'updatedAt' },
]);
const { rows: notNullableKnowledgeElementsBigintColumns } = await knex.raw(
`SELECT c.column_name FROM information_schema.columns c WHERE c.table_name = 'knowledge-elements_bigint' AND c.is_nullable = 'NO' ORDER BY c.column_name`
);
expect(notNullableKnowledgeElementsBigintColumns).to.deep.equal([
{ column_name: 'createdAt' },
{ column_name: 'earnedPix' },
{ column_name: 'id' },
]);
});
it('should create PK constraints', async function () {
// then
const { rows: primaryKeyAnswersBigintColumn } = await knex.raw(
`SELECT ccu.column_name
FROM pg_constraint pgc
JOIN pg_namespace nsp ON nsp.oid = pgc.connamespace
JOIN pg_class cls ON pgc.conrelid = cls.oid
JOIN information_schema.constraint_column_usage ccu ON pgc.conname = ccu.constraint_name AND nsp.nspname = ccu.constraint_schema
WHERE pgc.contype = 'p' AND ccu.table_name = 'answers_bigint'`
);
expect(primaryKeyAnswersBigintColumn).to.deep.equal([{ column_name: 'id' }]);

const { rows: primaryKeyKnowledgeElementsBigintColumn } = await knex.raw(
`SELECT ccu.column_name
FROM pg_constraint pgc
JOIN pg_namespace nsp ON nsp.oid = pgc.connamespace
JOIN pg_class cls ON pgc.conrelid = cls.oid
JOIN information_schema.constraint_column_usage ccu ON pgc.conname = ccu.constraint_name AND nsp.nspname = ccu.constraint_schema
WHERE pgc.contype = 'p' AND ccu.table_name = 'knowledge-elements_bigint'`
);
expect(primaryKeyKnowledgeElementsBigintColumn).to.deep.equal([{ column_name: 'id' }]);
});
it('should create FK constraints', async function () {
// then
const { rows: foreignKeysAnswersBigintColumns } = await knex.raw(
`SELECT
kcu.column_name AS referencing_column_name,
ccu.table_name AS referenced_table_name,
ccu.column_name AS referenced_column_name
FROM
information_schema.table_constraints AS tc
JOIN information_schema.key_column_usage AS kcu
ON tc.constraint_name = kcu.constraint_name
AND tc.table_schema = kcu.table_schema
JOIN information_schema.columns c
ON c.table_name = tc.table_name
AND c.column_name = kcu.column_name
JOIN information_schema.constraint_column_usage AS ccu
ON ccu.constraint_name = tc.constraint_name
AND ccu.table_schema = tc.table_schema
WHERE 1=1
AND tc.constraint_type = 'FOREIGN KEY'
AND tc.table_name = 'answers_bigint'
ORDER BY kcu.column_name
`
);
expect(foreignKeysAnswersBigintColumns).to.deep.equal([
{
referenced_column_name: 'id',
referenced_table_name: 'assessments',
referencing_column_name: 'assessmentId',
},
]);

const { rows: foreignKeysKnowledgeElementsBigintColumns } = await knex.raw(
`SELECT
kcu.column_name AS referencing_column_name,
ccu.table_name AS referenced_table_name,
ccu.column_name AS referenced_column_name
FROM
information_schema.table_constraints AS tc
JOIN information_schema.key_column_usage AS kcu
ON tc.constraint_name = kcu.constraint_name
AND tc.table_schema = kcu.table_schema
JOIN information_schema.columns c
ON c.table_name = tc.table_name
AND c.column_name = kcu.column_name
JOIN information_schema.constraint_column_usage AS ccu
ON ccu.constraint_name = tc.constraint_name
AND ccu.table_schema = tc.table_schema
WHERE 1=1
AND tc.constraint_type = 'FOREIGN KEY'
AND tc.table_name = 'knowledge-elements_bigint'
ORDER BY kcu.column_name
`
);
expect(foreignKeysKnowledgeElementsBigintColumns).to.deep.equal([
{
referenced_column_name: 'id',
referenced_table_name: 'answers_bigint',
referencing_column_name: 'answerId',
},
{
referenced_column_name: 'id',
referenced_table_name: 'assessments',
referencing_column_name: 'assessmentId',
},
{
referenced_column_name: 'id',
referenced_table_name: 'users',
referencing_column_name: 'userId',
},
]);
});
it('should create indexes', async function () {
// then
const { rows: indexAnswersBigintColumns } = await knex.raw(
`SELECT
a.attname,
am.amname index_type
FROM pg_index idx
INNER JOIN pg_class cls ON cls.oid=idx.indexrelid
INNER JOIN pg_class tab ON tab.oid=idx.indrelid
INNER JOIN pg_am am ON am.oid=cls.relam
INNER JOIN pg_attribute a ON a.attrelid = cls.oid
WHERE tab.relname = 'answers_bigint'
ORDER BY a.attname`
);
expect(indexAnswersBigintColumns).to.deep.equal([
{
attname: 'assessmentId',
index_type: 'btree',
},
{
attname: 'id',
index_type: 'btree',
},
]);

const { rows: indexKnowledgeElementsBigintColumns } = await knex.raw(
`SELECT
a.attname,
am.amname index_type
FROM pg_index idx
INNER JOIN pg_class cls ON cls.oid=idx.indexrelid
INNER JOIN pg_class tab ON tab.oid=idx.indrelid
INNER JOIN pg_am am ON am.oid=cls.relam
INNER JOIN pg_attribute a ON a.attrelid = cls.oid
WHERE tab.relname = 'knowledge-elements_bigint'
ORDER BY a.attname`
);
expect(indexKnowledgeElementsBigintColumns).to.deep.equal([
{
attname: 'assessmentId',
index_type: 'btree',
},
{
attname: 'id',
index_type: 'btree',
},
{
attname: 'userId',
index_type: 'btree',
},
]);
});
});

0 comments on commit aa6c183

Please sign in to comment.