traxxx/migrations/20220304233846_series.js

216 lines
5.5 KiB
JavaScript
Raw Permalink Normal View History

2022-03-26 16:40:20 +00:00
const config = require('config');
exports.up = async (knex) => Promise.resolve()
.then(() => knex.schema.createTable('series', (table) => {
table.increments('id', 16);
table.integer('entity_id', 12)
.references('id')
.inTable('entities')
.notNullable();
table.integer('studio_id', 12)
.references('id')
.inTable('entities');
table.text('entry_id');
table.unique(['entity_id', 'entry_id']);
table.text('url', 1000);
table.text('title');
table.text('slug');
table.timestamp('date');
table.index('date');
table.enum('date_precision', ['year', 'month', 'week', 'day', 'hour', 'minute', 'second'])
.defaultTo('day');
table.text('description');
table.boolean('deep');
table.text('deep_url', 1000);
table.text('comment');
table.integer('created_batch_id', 12)
.references('id')
.inTable('batches')
.onDelete('cascade');
table.integer('updated_batch_id', 12)
.references('id')
.inTable('batches')
.onDelete('cascade');
table.datetime('created_at')
.defaultTo(knex.fn.now());
}))
.then(() => knex.schema.createTable('series_scenes', (table) => {
table.integer('serie_id', 16)
.notNullable()
.references('id')
.inTable('series')
.onDelete('cascade');
table.integer('scene_id', 16)
.notNullable()
.references('id')
.inTable('releases')
.onDelete('cascade');
table.unique(['serie_id', 'scene_id']);
table.datetime('created_at')
.defaultTo(knex.fn.now());
}))
.then(() => knex.schema.createTable('series_trailers', (table) => {
table.integer('serie_id', 16)
.unique()
.notNullable()
.references('id')
.inTable('series')
.onDelete('cascade');
table.text('media_id', 21)
.notNullable()
.references('id')
.inTable('media');
}))
.then(() => knex.schema.createTable('series_posters', (table) => {
table.integer('serie_id', 16)
.notNullable()
.references('id')
.inTable('series')
.onDelete('cascade');
table.text('media_id', 21)
.notNullable()
.references('id')
.inTable('media')
.onDelete('cascade');
table.unique('serie_id');
2022-03-26 16:40:20 +00:00
}))
.then(() => knex.schema.createTable('series_covers', (table) => {
table.integer('serie_id', 16)
.notNullable()
.references('id')
.inTable('series')
.onDelete('cascade');
table.text('media_id', 21)
.notNullable()
.references('id')
.inTable('media');
table.unique(['serie_id', 'media_id']);
}))
.then(() => knex.schema.createTable('series_search', (table) => {
table.integer('serie_id', 16)
.references('id')
.inTable('series')
.onDelete('cascade');
}))
.then(() => knex.schema.createTable('stashes_series', (table) => {
table.integer('stash_id')
.notNullable()
.references('id')
.inTable('stashes')
.onDelete('cascade');
table.integer('serie_id')
.notNullable()
.references('id')
.inTable('series')
.onDelete('cascade');
table.unique(['stash_id', 'serie_id']);
table.string('comment');
table.datetime('created_at')
.notNullable()
.defaultTo(knex.fn.now());
}))
.then(() => knex.raw(`
ALTER TABLE series_search ADD COLUMN document tsvector;
CREATE UNIQUE INDEX series_search_unique ON series_search (serie_id);
CREATE INDEX series_search_index ON series_search USING GIN (document);
CREATE FUNCTION series_actors(serie series) RETURNS SETOF actors AS $$
SELECT actors.*
FROM series_scenes
LEFT JOIN
releases ON releases.id = series_scenes.scene_id
LEFT JOIN
releases_actors ON releases_actors.release_id = releases.id
LEFT JOIN
actors ON actors.id = releases_actors.actor_id
WHERE series_scenes.serie_id = serie.id
AND actors.id IS NOT NULL
GROUP BY actors.id
ORDER BY actors.name, actors.gender
$$ LANGUAGE SQL STABLE;
CREATE FUNCTION series_tags(serie series) RETURNS SETOF tags AS $$
SELECT tags.*
FROM series_scenes
LEFT JOIN
releases ON releases.id = series_scenes.scene_id
LEFT JOIN
releases_tags ON releases_tags.release_id = releases.id
LEFT JOIN
tags ON tags.id = releases_tags.tag_id
WHERE series_scenes.serie_id = serie.id
AND tags.id IS NOT NULL
GROUP BY tags.id
ORDER BY tags.priority DESC
$$ LANGUAGE SQL STABLE;
CREATE FUNCTION series_photos(serie series) RETURNS SETOF media AS $$
SELECT media.*
FROM series_scenes
LEFT JOIN
releases ON releases.id = series_scenes.scene_id
INNER JOIN
releases_photos ON releases_photos.release_id = releases.id
LEFT JOIN
media ON media.id = releases_photos.media_id
WHERE series_scenes.serie_id = serie.id
GROUP BY media.id
ORDER BY media.index ASC
$$ LANGUAGE SQL STABLE;
GRANT ALL ON ALL TABLES IN SCHEMA public TO :visitor;
GRANT USAGE, SELECT ON ALL SEQUENCES IN SCHEMA public TO :visitor;
ALTER TABLE stashes_series ENABLE ROW LEVEL SECURITY;
CREATE POLICY stashes_policy ON stashes_series
USING (EXISTS (
SELECT *
FROM stashes
WHERE stashes.id = stashes_series.stash_id
AND (stashes.user_id = current_user_id() OR stashes.public)
));
`, {
visitor: knex.raw(config.database.query.user),
}));
exports.down = async (knex) => Promise.resolve()
2022-03-26 16:40:20 +00:00
.then(() => knex.raw(`
DROP FUNCTION IF EXISTS series_actors;
DROP FUNCTION IF EXISTS series_tags;
DROP FUNCTION IF EXISTS series_photos;
DROP TABLE IF EXISTS stashes_series CASCADE;
DROP TABLE IF EXISTS series_scenes CASCADE;
DROP TABLE IF EXISTS series_trailers CASCADE;
DROP TABLE IF EXISTS series_posters CASCADE;
DROP TABLE IF EXISTS series_covers CASCADE;
DROP TABLE IF EXISTS series_search CASCADE;
DROP TABLE IF EXISTS series CASCADE;
`));