Skip to content

Commit

Permalink
Merge pull request #403 from internxt/fix/cleanup-files-name-indexes
Browse files Browse the repository at this point in the history
[IN-79]: fix/cleanup-files-name-indexes
  • Loading branch information
sg-gs authored Oct 1, 2024
2 parents eb6dd33 + 080afed commit 4b374f9
Show file tree
Hide file tree
Showing 3 changed files with 160 additions and 0 deletions.
36 changes: 36 additions & 0 deletions migrations/20241001112638-drop-name-indexes-files.js
Original file line number Diff line number Diff line change
@@ -0,0 +1,36 @@
'use strict';

const indexName = 'files_status_index';

/** @type {import('sequelize-cli').Migration} */
module.exports = {
async up(queryInterface, Sequelize) {
await queryInterface.sequelize.query(
`
DROP INDEX IF EXISTS files_status_index;
DROP INDEX IF EXISTS files_name_type_folderid_deleted_unique;
DROP INDEX IF EXISTS files_plainname_type_folderid_deleted_key;
`,
);
},

async down(queryInterface, Sequelize) {
await queryInterface.sequelize.query(
`CREATE INDEX CONCURRENTLY ${indexName} ON files (status)`,
);
await queryInterface.addIndex('files', ['name', 'type', 'folder_id'], {
name: 'files_name_type_folderid_deleted_unique',
unique: true,
where: { deleted: { [Sequelize.Op.eq]: false } },
});
await queryInterface.addIndex(
'files',
['plain_name', 'type', 'folder_id'],
{
name: 'files_plainname_type_folderid_deleted_key',
unique: true,
where: { deleted: { [Sequelize.Op.eq]: false } },
},
);
},
};
Original file line number Diff line number Diff line change
@@ -0,0 +1,104 @@
'use strict';

/** @type {import('sequelize-cli').Migration} */
module.exports = {
async up(queryInterface, Sequelize) {
await queryInterface.sequelize.query(
`
DO $$
DECLARE
outer_rec RECORD;
inner_rec RECORD;
new_name TEXT;
suffix INT;
total_duplicates INT;
renamed_count INT := 0;
BEGIN
-- Find and loop over duplicates
FOR outer_rec IN
SELECT plain_name, COALESCE(type, '') AS type, folder_id, user_id
FROM public.files
WHERE status = 'EXISTS'
AND plain_name IS NOT NULL
GROUP BY plain_name, COALESCE(type, ''), folder_id, user_id
HAVING COUNT(*) > 1
ORDER BY user_id
LOOP
SELECT COUNT(*)
INTO total_duplicates
FROM public.files
WHERE plain_name = outer_rec.plain_name
AND COALESCE(type, '') = outer_rec.type
AND folder_id = outer_rec.folder_id
AND user_id = outer_rec.user_id
AND status = 'EXISTS'
AND plain_name is not null;
RAISE NOTICE 'Found % duplicates for plain_name: %, type: %, folder_id: %, user_id: %',
total_duplicates, outer_rec.plain_name, outer_rec.type, outer_rec.folder_id, outer_rec.user_id;
suffix := 1;
-- Renaming loop
FOR inner_rec IN
SELECT id, plain_name
FROM public.files
WHERE plain_name = outer_rec.plain_name
AND COALESCE(type, '') = outer_rec.type
AND folder_id = outer_rec.folder_id
AND user_id = outer_rec.user_id
AND status = 'EXISTS'
ORDER BY id
LOOP
-- Prepare the new name for the duplicates
new_name := inner_rec.plain_name;
-- If it is not the first file, then generate a suffix
IF suffix > 1 THEN
-- Try diff suffixes until finding one which is free
LOOP
new_name := inner_rec.plain_name || ' (' || suffix || ')';
-- Is the suffix already taken?
EXIT WHEN NOT EXISTS (
SELECT 1
FROM public.files
WHERE plain_name = new_name
AND folder_id = outer_rec.folder_id
AND user_id = outer_rec.user_id
AND status = 'EXISTS'
);
-- If it is taken, try with the next one
suffix := suffix + 1;
END LOOP;
-- Update the row with the new name
UPDATE public.files
SET plain_name = new_name
WHERE id = inner_rec.id;
renamed_count := renamed_count + 1; -- Count renamed items
RAISE NOTICE 'Renamed plain_name from % to %', inner_rec.plain_name, new_name;
END IF;
-- Inc suffix for the next duplicate
suffix := suffix + 1;
END LOOP;
RAISE NOTICE 'Total duplicates found: %, Total renamed: %',
total_duplicates, renamed_count;
END LOOP;
RAISE NOTICE 'Renaming completed. Total renamed: %', renamed_count;
END $$;
`,
);
},

async down(queryInterface, Sequelize) {
/**
* no op
*/
},
};
Original file line number Diff line number Diff line change
@@ -0,0 +1,20 @@
'use strict';

/** @type {import('sequelize-cli').Migration} */
module.exports = {
async up(queryInterface, Sequelize) {
await queryInterface.sequelize.query(
`
CREATE UNIQUE INDEX CONCURRENTLY files_plainname_type_folderid_exists_unique
ON files USING btree (plain_name, type, folder_id)
WHERE (status = 'EXISTS');
`,
);
},

async down(queryInterface, Sequelize) {
await queryInterface.sequelize.query(
`DROP INDEX IF EXISTS files_plainname_type_folderid_exists_unique`,
);
},
};

0 comments on commit 4b374f9

Please sign in to comment.