diff --git a/migrations/20240108_130100_add_event_tags_table.js b/migrations/20240108_130100_add_event_tags_table.js new file mode 100644 index 00000000..2c57180a --- /dev/null +++ b/migrations/20240108_130100_add_event_tags_table.js @@ -0,0 +1,87 @@ +exports.up = async function (knex) { + // Create the event_tags table + await knex.schema.createTable('event_tags', function (table) { + table.uuid('id').primary().defaultTo(knex.raw('uuid_generate_v4()')) + table.binary('event_id').notNullable() + table.text('tag_name').notNullable() + table.text('tag_value').notNullable() + }) + + // Add indexes + await knex.schema.table('event_tags', function (table) { + table.index('event_id') + table.index(['tag_name', 'tag_value']) + }) + + // Add triggers + await knex.raw( + `CREATE OR REPLACE FUNCTION process_event_tags() RETURNS TRIGGER AS $$ + DECLARE + tag_element jsonb; + tag_name text; + tag_value text; + BEGIN + DELETE FROM event_tags WHERE event_id = OLD.event_id; + + IF TG_OP = 'INSERT' OR TG_OP = 'UPDATE' THEN + FOR tag_element IN SELECT jsonb_array_elements(NEW.event_tags) + LOOP + tag_name := trim((tag_element->0)::text, '"'); + tag_value := trim((tag_element->1)::text, '"'); + IF length(tag_name) = 1 AND tag_value IS NOT NULL AND tag_value <> '' THEN + INSERT INTO event_tags (event_id, tag_name, tag_value) VALUES (NEW.event_id, tag_name, tag_value); + END IF; + END LOOP; + END IF; + + RETURN NEW; + END; + $$ LANGUAGE plpgsql; + + CREATE TRIGGER insert_event_tags + AFTER INSERT OR UPDATE OR DELETE ON events + FOR EACH ROW + EXECUTE FUNCTION process_event_tags(); + `) + + // Migrate jsonb event_tags to event_tags table + const events = await knex.select('event_id', 'event_tags').from('events') + const totalEvents = events.length + let processedEvents = 0 + let lastPercentage = 0 + + for (const event of events) { + const exists = await knex('event_tags').where('event_id', event.event_id).first() + if (exists) { + continue + } + + for (const tag of event.event_tags) { + const [tag_name, tag_value] = tag + if (tag_name.length === 1 && tag_value) { + await knex('event_tags').insert({ + event_id: event.event_id, + tag_name: tag_name, + tag_value: tag_value, + }) + } + } + + processedEvents++ + const currentPercentage = Math.floor(processedEvents / totalEvents * 100) + if (currentPercentage > lastPercentage) { + console.log(`${new Date().toLocaleString()} Migration progress: ${currentPercentage}% (${processedEvents}/${totalEvents})`) + lastPercentage = currentPercentage + } + } +} + +exports.down = function (knex) { + return knex.schema + // Drop the trigger first + .raw('DROP TRIGGER IF EXISTS insert_event_tags ON events') + // Then drop the function + .raw('DROP FUNCTION IF EXISTS process_event_tags') + // Finally, drop the table + .dropTable('event_tags') +} diff --git a/src/repositories/event-repository.ts b/src/repositories/event-repository.ts index 46353171..bc510860 100644 --- a/src/repositories/event-repository.ts +++ b/src/repositories/event-repository.ts @@ -131,19 +131,19 @@ export class EventRepository implements IEventRepository { const andWhereRaw = invoker(1, 'andWhereRaw') const orWhereRaw = invoker(2, 'orWhereRaw') + let isTagQuery = false pipe( toPairs, filter(pipe(nth(0) as () => string, isGenericTagQuery)) as any, forEach(([filterName, criteria]: [string, string[]]) => { + isTagQuery = true builder.andWhere((bd) => { ifElse( isEmpty, () => andWhereRaw('1 = 0', bd), forEach((criterion: string) => void orWhereRaw( - '"event_tags" @> ?', - [ - JSON.stringify([[filterName[1], criterion]]) as any, - ], + 'event_tags.tag_name = ? AND event_tags.tag_value = ?', + [filterName[1], criterion], bd, )), )(criteria) @@ -151,6 +151,11 @@ export class EventRepository implements IEventRepository { }), )(currentFilter as any) + if (isTagQuery) { + builder.leftJoin('event_tags', 'events.event_id', 'event_tags.event_id') + .select('events.*') + } + return builder }) diff --git a/test/unit/repositories/event-repository.spec.ts b/test/unit/repositories/event-repository.spec.ts index ea925066..c235c3d5 100644 --- a/test/unit/repositories/event-repository.spec.ts +++ b/test/unit/repositories/event-repository.spec.ts @@ -274,7 +274,7 @@ describe('EventRepository', () => { const query = repository.findByFilters(filters).toString() - expect(query).to.equal('select * from "events" where (1 = 0) order by "event_created_at" asc limit 500') + expect(query).to.equal('select "events".* from "events" left join "event_tags" on "events"."event_id" = "event_tags"."event_id" where (1 = 0) order by "event_created_at" asc limit 500') }) it('selects events by one #e tag', () => { @@ -282,7 +282,7 @@ describe('EventRepository', () => { const query = repository.findByFilters(filters).toString() - expect(query).to.equal('select * from "events" where ("event_tags" @> \'[["e","aaaaaa"]]\') order by "event_created_at" asc limit 500') + expect(query).to.equal('select "events".* from "events" left join "event_tags" on "events"."event_id" = "event_tags"."event_id" where (event_tags.tag_name = \'e\' AND event_tags.tag_value = \'aaaaaa\') order by "event_created_at" asc limit 500') }) it('selects events by two #e tag', () => { @@ -290,7 +290,7 @@ describe('EventRepository', () => { const query = repository.findByFilters(filters).toString() - expect(query).to.equal('select * from "events" where ("event_tags" @> \'[["e","aaaaaa"]]\' or "event_tags" @> \'[["e","bbbbbb"]]\') order by "event_created_at" asc limit 500') + expect(query).to.equal('select "events".* from "events" left join "event_tags" on "events"."event_id" = "event_tags"."event_id" where (event_tags.tag_name = \'e\' AND event_tags.tag_value = \'aaaaaa\' or event_tags.tag_name = \'e\' AND event_tags.tag_value = \'bbbbbb\') order by "event_created_at" asc limit 500') }) }) @@ -300,7 +300,7 @@ describe('EventRepository', () => { const query = repository.findByFilters(filters).toString() - expect(query).to.equal('select * from "events" where (1 = 0) order by "event_created_at" asc limit 500') + expect(query).to.equal('select "events".* from "events" left join "event_tags" on "events"."event_id" = "event_tags"."event_id" where (1 = 0) order by "event_created_at" asc limit 500') }) it('selects events by one #p tag', () => { @@ -308,7 +308,7 @@ describe('EventRepository', () => { const query = repository.findByFilters(filters).toString() - expect(query).to.equal('select * from "events" where ("event_tags" @> \'[["p","aaaaaa"]]\') order by "event_created_at" asc limit 500') + expect(query).to.equal('select "events".* from "events" left join "event_tags" on "events"."event_id" = "event_tags"."event_id" where (event_tags.tag_name = \'p\' AND event_tags.tag_value = \'aaaaaa\') order by "event_created_at" asc limit 500') }) it('selects events by two #p tag', () => { @@ -316,7 +316,7 @@ describe('EventRepository', () => { const query = repository.findByFilters(filters).toString() - expect(query).to.equal('select * from "events" where ("event_tags" @> \'[["p","aaaaaa"]]\' or "event_tags" @> \'[["p","bbbbbb"]]\') order by "event_created_at" asc limit 500') + expect(query).to.equal('select "events".* from "events" left join "event_tags" on "events"."event_id" = "event_tags"."event_id" where (event_tags.tag_name = \'p\' AND event_tags.tag_value = \'aaaaaa\' or event_tags.tag_name = \'p\' AND event_tags.tag_value = \'bbbbbb\') order by "event_created_at" asc limit 500') }) }) @@ -326,7 +326,7 @@ describe('EventRepository', () => { const query = repository.findByFilters(filters).toString() - expect(query).to.equal('select * from "events" where (1 = 0) order by "event_created_at" asc limit 500') + expect(query).to.equal('select "events".* from "events" left join "event_tags" on "events"."event_id" = "event_tags"."event_id" where (1 = 0) order by "event_created_at" asc limit 500') }) it('selects events by one #r tag', () => { @@ -334,7 +334,7 @@ describe('EventRepository', () => { const query = repository.findByFilters(filters).toString() - expect(query).to.equal('select * from "events" where ("event_tags" @> \'[["r","aaaaaa"]]\') order by "event_created_at" asc limit 500') + expect(query).to.equal('select "events".* from "events" left join "event_tags" on "events"."event_id" = "event_tags"."event_id" where (event_tags.tag_name = \'r\' AND event_tags.tag_value = \'aaaaaa\') order by "event_created_at" asc limit 500') }) it('selects events by two #r tag', () => { @@ -342,7 +342,7 @@ describe('EventRepository', () => { const query = repository.findByFilters(filters).toString() - expect(query).to.equal('select * from "events" where ("event_tags" @> \'[["r","aaaaaa"]]\' or "event_tags" @> \'[["r","bbbbbb"]]\') order by "event_created_at" asc limit 500') + expect(query).to.equal('select "events".* from "events" left join "event_tags" on "events"."event_id" = "event_tags"."event_id" where (event_tags.tag_name = \'r\' AND event_tags.tag_value = \'aaaaaa\' or event_tags.tag_name = \'r\' AND event_tags.tag_value = \'bbbbbb\') order by "event_created_at" asc limit 500') }) }) })