traxxx/migrations/20250307030844_quick_alerts.js

103 lines
3.9 KiB
JavaScript

const config = require('config');
exports.up = async (knex) => {
await knex.schema.alterTable('alerts', (table) => {
table.boolean('from_preset')
.notNullable()
.defaultTo(false);
table.text('comment');
});
await knex.schema.createMaterializedView('alerts_users_actors', (view) => {
view.columns('user_id', 'actor_id', 'alert_ids');
view.as(
knex('alerts_actors')
.select(
'alerts.user_id',
'alerts_actors.actor_id',
knex.raw('array_agg(distinct alerts.id) as alert_ids'),
knex.raw('(alerts_tags.id is null and alerts_entities.id is null and alerts_matches.id is null and related_actors.id is null) as is_only'),
)
.leftJoin('alerts', 'alerts.id', 'alerts_actors.alert_id')
.leftJoin('alerts_entities', 'alerts_entities.alert_id', 'alerts_actors.alert_id')
.leftJoin('alerts_tags', 'alerts_tags.alert_id', 'alerts_actors.alert_id')
.leftJoin('alerts_matches', 'alerts_matches.alert_id', 'alerts_actors.alert_id')
.leftJoin('alerts_actors as related_actors', (joinBuilder) => {
joinBuilder
.on('related_actors.alert_id', 'alerts_actors.alert_id')
.on('related_actors.actor_id', '!=', 'alerts_actors.actor_id');
})
.groupBy(['user_id', 'alerts_actors.actor_id', 'is_only']),
);
});
await knex.schema.createMaterializedView('alerts_users_tags', (view) => {
view.columns('user_id', 'tag_id', 'alert_ids');
view.as(
knex('alerts_tags')
.select(
'alerts.user_id',
'alerts_tags.tag_id',
knex.raw('array_agg(distinct alerts.id) as alert_ids'),
knex.raw('(alerts_actors.id is null and alerts_entities.id is null and alerts_matches.id is null and related_tags.id is null) as is_only'),
)
.leftJoin('alerts', 'alerts.id', 'alerts_tags.alert_id')
.leftJoin('alerts_entities', 'alerts_entities.alert_id', 'alerts_tags.alert_id')
.leftJoin('alerts_actors', 'alerts_actors.alert_id', 'alerts_tags.alert_id')
.leftJoin('alerts_matches', 'alerts_matches.alert_id', 'alerts_tags.alert_id')
.leftJoin('alerts_tags as related_tags', (joinBuilder) => {
joinBuilder
.on('related_tags.alert_id', 'alerts_tags.alert_id')
.on('related_tags.tag_id', '!=', 'alerts_tags.tag_id');
})
.groupBy(['user_id', 'alerts_tags.tag_id', 'is_only']),
);
});
await knex.schema.createMaterializedView('alerts_users_entities', (view) => {
view.columns('user_id', 'entity_id', 'alert_ids');
view.as(
knex('alerts_entities')
.select(
'alerts.user_id',
'alerts_entities.entity_id',
knex.raw('array_agg(distinct alerts.id) as alert_ids'),
knex.raw('(alerts_actors.id is null and alerts_tags.id is null and alerts_matches.id is null and related_entities.id is null) as is_only'),
)
.leftJoin('alerts', 'alerts.id', 'alerts_entities.alert_id')
.leftJoin('alerts_tags', 'alerts_tags.alert_id', 'alerts_entities.alert_id')
.leftJoin('alerts_actors', 'alerts_actors.alert_id', 'alerts_entities.alert_id')
.leftJoin('alerts_matches', 'alerts_matches.alert_id', 'alerts_entities.alert_id')
.leftJoin('alerts_entities as related_entities', (joinBuilder) => {
joinBuilder
.on('related_entities.alert_id', 'alerts_entities.alert_id')
.on('related_entities.entity_id', '!=', 'alerts_entities.entity_id');
})
.groupBy(['user_id', 'alerts_entities.entity_id', 'is_only']),
);
});
await knex.raw(`
GRANT SELECT ON alerts_users_actors TO :visitor;
GRANT SELECT ON alerts_users_entities TO :visitor;
GRANT SELECT ON alerts_users_tags TO :visitor;
`, {
visitor: knex.raw(config.database.query.user),
});
};
exports.down = async (knex) => {
await knex.schema.alterTable('alerts', (table) => {
table.dropColumn('from_preset');
table.dropColumn('comment');
});
await knex.schema.dropMaterializedView('alerts_users_actors');
await knex.schema.dropMaterializedView('alerts_users_tags');
await knex.schema.dropMaterializedView('alerts_users_entities');
};