exports.up = async (knex) => { await knex.schema.createTable('countries', (table) => { table.string('alpha2', 2) .unique() .primary(); table.string('alpha3', 3) .unique(); table.text('name') .notNullable(); table.text('alias'); table.integer('code', 3); table.text('nationality'); table.integer('priority', 2) .defaultTo(0); }); await knex.schema.createTable('entities_types', (table) => { table.text('type') .primary(); }); await knex('entities_types').insert([ { type: 'network' }, { type: 'channel' }, { type: 'studio' }, { type: 'info' }, ]); await knex.schema.createTable('entities', (table) => { table.increments('id'); table.integer('parent_id', 12) .references('id') .inTable('entities') .index(); table.text('name'); table.text('slug', 32); table.text('type') .notNullable() .references('type') .inTable('entities_types') .defaultTo('channel'); table.unique(['slug', 'type']); table.specificType('alias', 'text[]'); table.text('url'); table.text('description'); table.json('parameters'); table.json('options'); table.integer('priority', 3) .defaultTo(0); table.boolean('independent') .defaultTo(false); table.boolean('showcased'); table.boolean('visible') .defaultTo(true); table.boolean('has_logo') .defaultTo(true); table.datetime('created_at') .defaultTo(knex.fn.now()); }); await knex.schema.createTable('media', (table) => { table.text('id', 21) .primary(); table.text('path'); table.text('thumbnail'); table.text('lazy'); table.integer('index'); table.text('mime'); table.boolean('is_s3') .defaultTo(false); table.text('hash'); table.bigInteger('size', 12); table.integer('quality', 6); table.integer('width', 6); table.integer('height', 6); table.boolean('is_vr'); table.float('entropy'); table.float('sharpness'); table.text('source', 2100); table.text('source_page', 2100); table.string('source_version'); // usually etag table.text('scraper', 32); table.text('credit', 100); table.integer('entity_id') .references('id') .inTable('entities') .onDelete('cascade'); table.date('date'); table.enum('date_precision', ['year', 'month', 'week', 'day', 'hour', 'minute', 'second']) .defaultTo('year'); table.text('comment'); table.text('group'); table.boolean('is_sfw') .defaultTo(false); table.unique('hash'); table.datetime('created_at') .defaultTo(knex.fn.now()); }); await knex.raw(` CREATE FUNCTION get_random_sfw_media_id() RETURNS varchar AS $$ SELECT id FROM media WHERE is_sfw = true ORDER BY random() LIMIT 1; $$ LANGUAGE sql STABLE; `); await knex.schema.alterTable('media', (table) => { table.text('sfw_media_id', 21) .index() .references('id') .inTable('media') .defaultTo(knex.raw('get_random_sfw_media_id()')); }); await knex.schema.createTable('tags_groups', (table) => { table.increments('id'); table.text('name', 32); table.text('description'); table.text('slug', 32) .unique(); table.datetime('created_at') .defaultTo(knex.fn.now()); }); await knex.schema.createTable('tags', (table) => { table.increments('id'); table.text('name'); table.text('description'); table.integer('priority', 2) .defaultTo(0); table.boolean('filter') .defaultTo(false); table.boolean('secondary') .defaultTo(false); table.integer('group_id', 12) .references('id') .inTable('tags_groups'); table.integer('alias_for', 12) .references('id') .inTable('tags'); table.text('slug', 32) .unique(); table.specificType('implied_tag_ids', 'integer[]'); table.datetime('created_at') .defaultTo(knex.fn.now()); }); await knex.schema.createTable('tags_posters', (table) => { table.integer('tag_id', 12) .notNullable() .references('id') .inTable('tags'); table.text('media_id', 21) .index() .notNullable() .references('id') .inTable('media'); table.unique('tag_id'); }); await knex.schema.createTable('tags_photos', (table) => { table.integer('tag_id', 12) .notNullable() .references('id') .inTable('tags'); table.text('media_id', 21) .index() .notNullable() .references('id') .inTable('media'); table.unique(['tag_id', 'media_id']); }); await knex.schema.createTable('entities_tags', (table) => { table.integer('tag_id', 12) .notNullable() .references('id') .inTable('tags') .onDelete('cascade'); table.integer('entity_id', 12) .notNullable() .references('id') .inTable('entities') .onDelete('cascade'); table.boolean('inherit') .defaultTo(false); table.unique(['tag_id', 'entity_id']); }); await knex.schema.createTable('entities_social', (table) => { table.increments('id'); table.text('url'); table.text('platform'); table.integer('entity_id', 12) .notNullable() .references('id') .inTable('entities'); table.unique(['url', 'entity_id']); table.datetime('created_at') .defaultTo(knex.fn.now()); }); await knex.schema.createTable('batches', (table) => { table.increments('id'); table.text('comment'); table.boolean('showcased') .notNullable() .defaultTo(true); table.datetime('created_at') .defaultTo(knex.fn.now()); }); await knex.schema.createTable('actors', (table) => { table.increments('id'); table.text('name') .notNullable(); table.text('slug', 32) .notNullable(); table.integer('entity_id', 12) .references('id') .inTable('entities'); table.text('entry_id'); table.integer('alias_for', 12) .references('id') .inTable('actors'); table.text('real_name'); table.date('date_of_birth'); table.date('date_of_death'); table.integer('age', 3); table.text('gender', 18); table.text('orientation'); table.text('description'); table.text('birth_city'); table.text('birth_state'); table.text('birth_country_alpha2', 2) .references('alpha2') .inTable('countries'); table.text('residence_city'); table.text('residence_state'); table.text('residence_country_alpha2', 2) .references('alpha2') .inTable('countries'); table.text('ethnicity'); table.text('cup', 4); table.integer('bust', 3); table.integer('waist', 3); table.integer('hip', 3); table.boolean('natural_boobs'); table.integer('penis_length', 3); table.integer('penis_girth', 3); table.boolean('circumcised'); table.integer('height', 3); table.integer('weight', 3); table.text('eyes'); table.text('hair_color'); table.text('hair_length'); table.string('hair_type'); table.boolean('has_tattoos'); table.boolean('has_piercings'); table.text('piercings'); table.text('tattoos'); table.decimal('shoe_size'); table.integer('leg'); table.integer('foot'); table.integer('thigh'); table.string('blood_type'); table.integer('boobs_volume'); table.enum('boobs_implant', ['saline', 'silicone', 'gummy', 'fat']); table.enum('boobs_placement', ['over', 'under']); table.string('boobs_surgeon'); table.enum('boobs_incision', ['mammary', 'areolar', 'crescent', 'lollipop', 'anchor', 'axillary', 'umbilical']); table.boolean('natural_butt'); table.integer('butt_volume'); table.enum('butt_implant', ['bbl', 'lift', 'silicone', 'lipo', 'filler', 'mms']); table.boolean('natural_lips'); table.integer('lips_volume'); table.boolean('natural_labia'); table.string('agency'); table.text('avatar_media_id', 21) .references('id') .inTable('media'); table.integer('batch_id', 12) .references('id') .inTable('batches') .onDelete('cascade'); table.datetime('updated_at') .defaultTo(knex.fn.now()); table.datetime('created_at') .defaultTo(knex.fn.now()); }); await knex.schema.createTable('actors_profiles', (table) => { table.increments('id'); table.integer('actor_id', 12) .notNullable() .references('id') .inTable('actors') .onDelete('cascade'); table.integer('entity_id', 12) .references('id') .inTable('entities'); table.unique(['actor_id', 'entity_id']); table.integer('priority', 4) .defaultTo(1); table.text('url'); table.text('real_name'); table.text('gender', 18); table.text('orientation'); table.date('date_of_birth'); table.date('date_of_death'); table.integer('age', 3); table.text('description'); table.text('description_hash'); table.text('birth_city'); table.text('birth_state'); table.text('birth_country_alpha2', 2) .references('alpha2') .inTable('countries'); table.text('residence_city'); table.text('residence_state'); table.text('residence_country_alpha2', 2) .references('alpha2') .inTable('countries'); table.text('ethnicity'); table.text('cup', 4); table.integer('bust', 3); table.integer('waist', 3); table.integer('hip', 3); table.boolean('natural_boobs'); table.integer('penis_length', 3); table.integer('penis_girth', 3); table.boolean('circumcised'); table.integer('height', 3); table.integer('weight', 3); table.text('eyes'); table.text('hair_color'); table.text('hair_length'); table.string('hair_type'); table.boolean('has_tattoos'); table.boolean('has_piercings'); table.text('piercings'); table.text('tattoos'); table.decimal('shoe_size'); table.integer('leg'); table.integer('foot'); table.integer('thigh'); table.string('blood_type'); table.integer('boobs_volume'); table.enum('boobs_implant', ['saline', 'silicone', 'gummy', 'fat']); table.enum('boobs_placement', ['over', 'under']); table.string('boobs_surgeon'); table.enum('boobs_incision', ['mammary', 'areolar', 'crescent', 'lollipop', 'anchor', 'axillary', 'umbilical']); table.boolean('natural_butt'); table.integer('butt_volume'); table.enum('butt_implant', ['bbl', 'lift', 'silicone', 'lipo', 'filler', 'mms']); table.boolean('natural_lips'); table.integer('lips_volume'); table.boolean('natural_labia'); table.string('agency'); table.text('avatar_media_id', 21) .index() .references('id') .inTable('media'); table.datetime('scraped_at'); table.boolean('scrape_success'); table.datetime('updated_at') .defaultTo(knex.fn.now()); table.datetime('created_at') .defaultTo(knex.fn.now()); }); await knex.raw('CREATE UNIQUE INDEX unique_main_profiles ON actors_profiles (actor_id) WHERE (entity_id IS NULL);'); await knex.schema.createTable('body', (table) => { table.text('slug', 20) .primary(); table.text('name'); }); await knex('body').insert([ // head { slug: 'head', name: 'head' }, { slug: 'face', name: 'face' }, { slug: 'scalp', name: 'scalp' }, { slug: 'forehead', name: 'forehead' }, { slug: 'temple', name: 'temple' }, { slug: 'cheek', name: 'cheek' }, { slug: 'jaw', name: 'jaw' }, { slug: 'chin', name: 'chin' }, { slug: 'neck', name: 'neck' }, { slug: 'throat', name: 'throat' }, // eyes { slug: 'eyelid', name: 'eyelid' }, { slug: 'eyeball', name: 'eyeball' }, { slug: 'eyebrow', name: 'eyebrow' }, // mouth { slug: 'tongue', name: 'tongue' }, { slug: 'lip', name: 'lip' }, { slug: 'upper-lip', name: 'upper lip' }, { slug: 'lower-lip', name: 'lower lip' }, { slug: 'inner-lip', name: 'inner lip' }, { slug: 'inner-lower-lip', name: 'inner lower lip' }, { slug: 'inner-upper-lip', name: 'inner upper lip' }, { slug: 'philtrum', name: 'philtrum' }, { slug: 'above-lip', name: 'above lip' }, { slug: 'below-lip', name: 'below lip' }, // nose { slug: 'nose', name: 'nose' }, { slug: 'third-eye', name: 'third eye' }, { slug: 'bridge', name: 'bridge' }, { slug: 'nostril', name: 'nostril' }, { slug: 'septum', name: 'septum' }, { slug: 'septril', name: 'septril' }, // ear { slug: 'ear', name: 'ear' }, { slug: 'earlobe', name: 'earlobe' }, { slug: 'helix', name: 'helix' }, { slug: 'tragus', name: 'tragus' }, { slug: 'conch', name: 'conch' }, { slug: 'rook', name: 'rook' }, { slug: 'behind-ear', name: 'behind ear' }, // arms { slug: 'arm', name: 'arm' }, { slug: 'upper-arm', name: 'upper arm' }, { slug: 'forearm', name: 'forearm' }, { slug: 'elbow', name: 'elbow' }, { slug: 'inner-elbow', name: 'inner elbow' }, { slug: 'outer-elbow', name: 'outer elbow' }, // hands { slug: 'hand', name: 'hand' }, { slug: 'fingers', name: 'fingers' }, { slug: 'knuckles', name: 'knuckles' }, { slug: 'thumb', name: 'thumb' }, { slug: 'index-finger', name: 'index finger' }, { slug: 'middle-finger', name: 'middle finger' }, { slug: 'ring-finger', name: 'ring finger' }, { slug: 'pinky', name: 'pinky' }, { slug: 'back-of-hand', name: 'back of hand' }, { slug: 'inner-wrist', name: 'inner wrist' }, { slug: 'outer-wrist', name: 'outer wrist' }, // torso { slug: 'shoulder', name: 'shoulder' }, { slug: 'collarbone', name: 'collarbone' }, { slug: 'chest', name: 'chest' }, { slug: 'rib-cage', name: 'rib cage' }, { slug: 'breastbone', name: 'breastbone' }, { slug: 'underboob', name: 'underboob' }, { slug: 'sideboob', name: 'sideboob' }, { slug: 'boob', name: 'boob' }, { slug: 'nipple', name: 'nipple' }, { slug: 'abdomen', name: 'abdomen' }, { slug: 'navel', name: 'navel' }, { slug: 'pelvis', name: 'pelvis' }, // back { slug: 'back', name: 'back' }, { slug: 'upper-back', name: 'upper back' }, { slug: 'middle-back', name: 'lower back' }, { slug: 'lower-back', name: 'lower back' }, { slug: 'spine', name: 'spine' }, // bottom { slug: 'butt', name: 'butt' }, { slug: 'hip', name: 'hip' }, { slug: 'anus', name: 'anus' }, // genitals { slug: 'pubic-mound', name: 'pubic mound' }, { slug: 'vagina', name: 'vagina' }, { slug: 'outer-labia', name: 'outer labia' }, { slug: 'inner-labia', name: 'inner labia' }, { slug: 'clitoris', name: 'clitoris' }, { slug: 'penis', name: 'penis' }, { slug: 'glans', name: 'glans' }, { slug: 'foreskin', name: 'foreskin' }, { slug: 'shaft', name: 'shaft' }, { slug: 'scrotum', name: 'scrotum' }, // legs { slug: 'leg', name: 'leg' }, { slug: 'groin', name: 'groin' }, { slug: 'upper-leg', name: 'upper leg' }, { slug: 'thigh', name: 'thigh' }, { slug: 'lower-leg', name: 'lower leg' }, { slug: 'shin', name: 'shin' }, { slug: 'calf', name: 'calf' }, { slug: 'knee', name: 'knee' }, { slug: 'inner-knee', name: 'inner knee' }, // feet { slug: 'inner-ankle', name: 'inner ankle' }, { slug: 'outer-ankle', name: 'outer ankle' }, { slug: 'foot', name: 'foot' }, { slug: 'toes', name: 'toes' }, { slug: 'big-toe', name: 'big toe' }, { slug: 'index-toe', name: 'index toe' }, { slug: 'middle-toe', name: 'middle toe' }, { slug: 'fourth-toe', name: 'fourth toe' }, { slug: 'little-toe', name: 'little toe' }, ]); await knex.schema.createTable('actors_tattoos', (table) => { table.increments('id'); table.integer('actor_id', 12) .notNullable() .references('id') .inTable('actors') .onDelete('cascade'); table.text('body_slug', 20) .references('slug') .inTable('body'); table.enum('side', ['left', 'right', 'center', 'both']); table.text('description'); table.datetime('created_at') .defaultTo(knex.fn.now()); }); await knex.schema.createTable('actors_piercings', (table) => { table.increments('id'); table.integer('actor_id', 12) .notNullable() .references('id') .inTable('actors') .onDelete('cascade'); table.text('body_slug', 20) .references('slug') .inTable('body'); table.enum('side', ['left', 'right', 'center', 'both']); table.text('description'); table.datetime('created_at') .defaultTo(knex.fn.now()); }); await knex.schema.createTable('actors_avatars', (table) => { table.integer('actor_id') .notNullable() .references('id') .inTable('actors'); table.integer('profile_id', 12) .references('id') .inTable('actors_profiles') .onDelete('cascade'); table.text('media_id', 21) .index() .notNullable() .references('id') .inTable('media'); table.datetime('created_at') .notNullable() .defaultTo(knex.fn.now()); table.unique(['profile_id', 'media_id']); }); await knex.raw('CREATE UNIQUE INDEX unique_main_avatars ON actors_avatars (actor_id) WHERE (profile_id IS NULL);'); await knex.schema.createTable('actors_photos', (table) => { table.integer('actor_id', 12) .notNullable() .references('id') .inTable('actors') .onDelete('cascade'); table.text('media_id', 21) .index() .notNullable() .references('id') .inTable('media'); table.unique(['actor_id', 'media_id']); }); await knex.schema.createTable('actors_socials', (table) => { table.increments('id'); table.text('url'); table.text('platform'); table.integer('actor_id', 12) .notNullable() .references('id') .inTable('actors'); table.string('handle'); table.boolean('is_broken') .notNullable() .defaultTo(false); table.datetime('created_at') .defaultTo(knex.fn.now()); table.datetime('pinged_at'); table.datetime('verified_at'); table.unique(['actor_id', 'platform', 'handle']); table.unique(['actor_id', 'url']); }); await knex.raw('ALTER TABLE actors_socials ADD CONSTRAINT socials_url_or_handle CHECK (num_nulls(handle, url) = 1);'); await knex.raw('ALTER TABLE actors_socials ADD CONSTRAINT socials_handle_and_platform CHECK (num_nulls(platform, handle) = 2 or num_nulls(platform, handle) = 0);'); await knex.schema.createTable('releases', (table) => { table.increments('id'); table.integer('entity_id', 12) .notNullable() .references('id') .inTable('entities') .onDelete('cascade'); table.integer('studio_id', 12) .references('id') .inTable('entities'); table.text('shoot_id'); table.text('entry_id'); table.unique(['entity_id', 'entry_id']); table.text('url', 1000); table.text('title'); table.specificType('alt_titles', 'text ARRAY'); table.text('slug'); table.timestamp('date'); table.index('date'); table.date('production_date'); table.text('production_location'); table.text('production_city'); table.text('production_state'); table.text('production_country_alpha2', 2) .references('alpha2') .inTable('countries'); table.enum('date_precision', ['year', 'month', 'week', 'day', 'hour', 'minute', 'second']) .defaultTo('day'); table.text('description'); table.integer('duration') .unsigned(); table.specificType('qualities', 'text[]'); table.integer('photo_count'); table.integer('video_count'); 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') .notNullable() .defaultTo(knex.fn.now()); table.datetime('updated_at') .notNullable() .defaultTo(knex.fn.now()); }); await knex.schema.createTable('releases_actors', (table) => { table.integer('release_id', 16) .notNullable() .references('id') .inTable('releases') .onDelete('cascade'); table.integer('actor_id', 12) .notNullable() .references('id') .inTable('actors') .onDelete('cascade'); table.integer('alias_id', 12) .references('id') .inTable('actors') .onDelete('cascade'); table.unique(['release_id', 'actor_id']); table.datetime('created_at') .defaultTo(knex.fn.now()); }); await knex.schema.createTable('releases_directors', (table) => { table.integer('release_id', 16) .notNullable() .references('id') .inTable('releases') .onDelete('cascade'); table.integer('director_id', 12) .notNullable() .references('id') .inTable('actors') .onDelete('cascade'); table.integer('alias_id', 12) .references('id') .inTable('actors') .onDelete('cascade'); table.unique(['release_id', 'director_id']); table.datetime('created_at') .defaultTo(knex.fn.now()); }); await knex.schema.createTable('releases_posters', (table) => { table.integer('release_id', 16) .notNullable() .references('id') .inTable('releases') .onDelete('cascade'); table.text('media_id', 21) .index() .notNullable() .references('id') .inTable('media'); table.unique('release_id'); }); await knex.schema.createTable('releases_covers', (table) => { table.integer('release_id', 16) .notNullable() .references('id') .inTable('releases') .onDelete('cascade'); table.text('media_id', 21) .index() .notNullable() .references('id') .inTable('media'); table.unique(['release_id', 'media_id']); }); await knex.schema.createTable('releases_trailers', (table) => { table.integer('release_id', 16) .notNullable() .references('id') .inTable('releases') .onDelete('cascade'); table.text('media_id', 21) .index() .notNullable() .references('id') .inTable('media'); table.unique('release_id'); }); await knex.schema.createTable('releases_teasers', (table) => { table.integer('release_id', 16) .notNullable() .references('id') .inTable('releases') .onDelete('cascade'); table.text('media_id', 21) .index() .notNullable() .references('id') .inTable('media'); table.unique('release_id'); }); await knex.schema.createTable('releases_photos', (table) => { table.integer('release_id', 16) .notNullable() .references('id') .inTable('releases') .onDelete('cascade'); table.text('media_id', 21) .index() .notNullable() .references('id') .inTable('media'); table.unique(['release_id', 'media_id']); }); await knex.schema.createTable('releases_caps', (table) => { table.integer('release_id') .notNullable() .references('id') .inTable('releases') .onDelete('cascade'); table.text('media_id') .index() .notNullable() .references('id') .inTable('media'); table.unique(['release_id', 'media_id']); }); await knex.schema.createTable('releases_tags', (table) => { table.integer('tag_id', 12) .references('id') .inTable('tags'); table.integer('release_id', 16) .notNullable() .references('id') .inTable('releases') .onDelete('cascade'); table.text('original_tag'); table.unique(['tag_id', 'release_id']); table.index('tag_id'); table.index('release_id'); table.enum('source', ['scraper', 'editor', 'implied']) .notNullable() .defaultTo('scraper'); }); await knex.schema.createTable('releases_search', (table) => { table.integer('release_id', 16) .references('id') .inTable('releases') .onDelete('cascade'); }); await knex.schema.createTable('movies', (table) => { table.increments('id'); 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.specificType('alt_titles', 'text ARRAY'); 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.integer('photo_count'); 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()); }); await knex.schema.createTable('movies_scenes', (table) => { table.integer('movie_id', 16) .notNullable() .references('id') .inTable('movies') .onDelete('cascade'); table.integer('scene_id', 16) .notNullable() .references('id') .inTable('releases') .onDelete('cascade'); table.unique(['movie_id', 'scene_id']); table.datetime('created_at') .defaultTo(knex.fn.now()); table.index('scene_id'); }); await knex.schema.createTable('movies_tags', (table) => { table.integer('tag_id') .references('id') .inTable('tags'); table.integer('movie_id') .notNullable() .references('id') .inTable('movies') .onDelete('cascade'); table.text('original_tag'); table.text('source') .defaultTo('scraper'); table.unique(['tag_id', 'movie_id']); }); await knex.schema.createTable('movies_covers', (table) => { table.integer('movie_id', 16) .notNullable() .references('id') .inTable('movies') .onDelete('cascade'); table.text('media_id', 21) .index() .notNullable() .references('id') .inTable('media'); table.unique(['movie_id', 'media_id']); }); await knex.schema.createTable('movies_trailers', (table) => { table.integer('movie_id', 16) .unique() .notNullable() .references('id') .inTable('movies') .onDelete('cascade'); table.text('media_id', 21) .index() .notNullable() .references('id') .inTable('media'); }); await knex.schema.createTable('movies_teasers', (table) => { table.integer('movie_id', 16) .notNullable() .references('id') .inTable('movies') .onDelete('cascade'); table.text('media_id', 21) .index() .notNullable() .references('id') .inTable('media'); table.unique('movie_id'); }); await knex.schema.createTable('movies_posters', (table) => { table.integer('movie_id', 16) .notNullable() .references('id') .inTable('movies') .onDelete('cascade'); table.text('media_id', 21) .index() .notNullable() .references('id') .inTable('media') .onDelete('cascade'); table.unique('movie_id'); }); await knex.schema.createTable('movies_photos', (table) => { table.integer('movie_id', 16) .notNullable() .references('id') .inTable('movies') .onDelete('cascade'); table.text('media_id', 21) .index() .notNullable() .references('id') .inTable('media'); table.unique(['movie_id', 'media_id']); }); await knex.schema.createTable('movies_search', (table) => { table.integer('movie_id', 16) .references('id') .inTable('movies') .onDelete('cascade'); }); await knex.schema.createTable('series', (table) => { table.increments('id'); 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.specificType('alt_titles', 'text ARRAY'); 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.integer('photo_count'); 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()); }); await 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()); }); await knex.schema.createTable('series_trailers', (table) => { table.integer('serie_id', 16) .unique() .notNullable() .references('id') .inTable('series') .onDelete('cascade'); table.text('media_id', 21) .index() .notNullable() .references('id') .inTable('media'); }); await knex.schema.createTable('series_teasers', (table) => { table.integer('serie_id', 16) .notNullable() .references('id') .inTable('series') .onDelete('cascade'); table.text('media_id', 21) .index() .notNullable() .references('id') .inTable('media'); table.unique('serie_id'); }); await knex.schema.createTable('series_posters', (table) => { table.integer('serie_id', 16) .notNullable() .references('id') .inTable('series') .onDelete('cascade'); table.text('media_id', 21) .index() .notNullable() .references('id') .inTable('media') .onDelete('cascade'); table.unique('serie_id'); }); await knex.schema.createTable('series_covers', (table) => { table.integer('serie_id', 16) .notNullable() .references('id') .inTable('series') .onDelete('cascade'); table.text('media_id', 21) .index() .notNullable() .references('id') .inTable('media'); table.unique(['serie_id', 'media_id']); }); await knex.schema.createTable('series_photos', (table) => { table.integer('serie_id', 16) .notNullable() .references('id') .inTable('series') .onDelete('cascade'); table.text('media_id', 21) .index() .notNullable() .references('id') .inTable('media'); table.unique(['serie_id', 'media_id']); }); await knex.schema.createTable('series_search', (table) => { table.integer('serie_id', 16) .references('id') .inTable('series') .onDelete('cascade'); }); await knex.schema.createTable('chapters', (table) => { table.increments('id'); table.integer('release_id', 12) .references('id') .inTable('releases') .notNullable() .onDelete('cascade'); table.integer('index'); table.unique(['release_id', 'index']); table.integer('time') .unsigned(); table.integer('duration') .unsigned(); table.text('title'); table.text('description'); 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()); }); await knex.schema.createTable('chapters_posters', (table) => { table.integer('chapter_id', 16) .notNullable() .references('id') .inTable('chapters') .onDelete('cascade'); table.text('media_id', 21) .index() .notNullable() .references('id') .inTable('media'); table.unique('chapter_id'); }); await knex.schema.createTable('chapters_photos', (table) => { table.integer('chapter_id', 16) .notNullable() .references('id') .inTable('chapters') .onDelete('cascade'); table.text('media_id', 21) .index() .notNullable() .references('id') .inTable('media'); table.unique(['chapter_id', 'media_id']); }); await knex.schema.createTable('chapters_tags', (table) => { table.integer('tag_id', 12) .references('id') .inTable('tags') .onDelete('cascade'); table.integer('chapter_id', 16) .notNullable() .references('id') .inTable('chapters') .onDelete('cascade'); table.text('original_tag'); table.unique(['tag_id', 'chapter_id']); }); await knex.schema.createTable('users_roles', (table) => { table.string('role') .primary(); table.json('abilities'); }); await knex('users_roles').insert([ { role: 'admin', abilities: JSON.stringify([ // serialization necessary to avoid array being interpreted as a PG array { subject: 'scene', action: 'create' }, { subject: 'scene', action: 'update' }, { subject: 'scene', action: 'delete' }, { subject: 'actor', action: 'create' }, { subject: 'actor', action: 'update' }, { subject: 'actor', action: 'delete' }, ]), }, { role: 'editor', abilities: JSON.stringify([ // serialization necessary to avoid array being interpreted as a PG array { subject: 'scene', action: 'update' }, { subject: 'actor', action: 'update' }, ]), }, { role: 'user', }, ]); await knex.schema.createTable('users', (table) => { table.increments('id'); table.text('username') .notNullable(); table.text('email') .unique() .notNullable(); table.text('password') .notNullable(); table.string('role') .references('role') .inTable('users_roles') .defaultTo('user') .notNullable(); table.json('abilities'); table.boolean('email_verified') .notNullable() .defaultTo(false); table.boolean('identity_verified') .notNullable() .defaultTo(false); table.specificType('last_ip', 'cidr'); table.datetime('created_at') .notNullable() .defaultTo(knex.fn.now()); table.datetime('last_login'); }); await knex.raw(` CREATE UNIQUE INDEX username_unique_index ON users (LOWER(username)); CREATE UNIQUE INDEX email_unique_index ON users (LOWER(email)); `); await knex.schema.createTable('users_templates', (table) => { table.increments('id'); table.integer('user_id') .notNullable() .references('id') .inTable('users'); table.string('name') .notNullable(); table.text('template') .notNullable(); table.unique(['user_id', 'name']); table.datetime('created_at') .defaultTo(knex.fn.now()); }); await knex.schema.createTable('users_keys', (table) => { table.increments('id'); table.integer('user_id') .notNullable() .references('id') .inTable('users'); table.text('key') .notNullable(); table.string('identifier'); table.unique(['user_id', 'identifier']); table.datetime('last_used_at'); table.specificType('last_used_ip', 'inet'); table.datetime('created_at') .notNullable() .defaultTo(knex.fn.now()); }); await knex.schema.createTable('bans', (table) => { table.increments('id'); table.integer('user_id') .references('id') .inTable('users') .onDelete('set null'); table.string('username'); table.specificType('ip', 'cidr'); table.boolean('match_all') .notNullable() .defaultTo(false); table.string('scope'); table.boolean('shadow'); table.integer('banned_by') .references('id') .inTable('users') .onDelete('set null'); table.datetime('expires_at') .notNullable(); table.datetime('created_at') .notNullable() .defaultTo(knex.fn.now()); }); await knex.schema.createTable('stashes', (table) => { table.increments('id'); table.integer('user_id') .references('id') .inTable('users') .onDelete('cascade'); table.string('name') .notNullable(); table.string('slug') .notNullable(); table.boolean('public') .notNullable() .defaultTo(false); table.boolean('primary') .notNullable() .defaultTo(false); table.json('meta'); table.text('comment'); table.datetime('created_at') .notNullable() .defaultTo(knex.fn.now()); table.unique(['user_id', 'slug']); }); await knex.raw(` CREATE UNIQUE INDEX unique_primary ON stashes (user_id, "primary") WHERE ("primary" = TRUE); `); await knex.schema.createTable('stashes_scenes', (table) => { table.increments('id'); table.integer('stash_id') .notNullable() .references('id') .inTable('stashes') .onDelete('cascade'); table.integer('scene_id') .notNullable() .references('id') .inTable('releases') .onDelete('cascade'); table.unique(['stash_id', 'scene_id']); table.string('comment'); table.datetime('created_at') .notNullable() .defaultTo(knex.fn.now()); }); await knex.schema.createTable('stashes_movies', (table) => { table.increments('id'); table.integer('stash_id') .notNullable() .references('id') .inTable('stashes') .onDelete('cascade'); table.integer('movie_id') .notNullable() .references('id') .inTable('movies') .onDelete('cascade'); table.unique(['stash_id', 'movie_id']); table.string('comment'); table.datetime('created_at') .notNullable() .defaultTo(knex.fn.now()); }); await knex.schema.createTable('stashes_actors', (table) => { table.increments('id'); table.integer('stash_id') .notNullable() .references('id') .inTable('stashes') .onDelete('cascade'); table.integer('actor_id') .notNullable() .references('id') .inTable('actors') .onDelete('cascade'); table.unique(['stash_id', 'actor_id']); table.string('comment'); table.datetime('created_at') .notNullable() .defaultTo(knex.fn.now()); }); await knex.schema.createTable('stashes_series', (table) => { table.increments('id'); 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()); }); await knex.schema.createTable('alerts', (table) => { table.increments('id'); table.integer('user_id') .notNullable() .references('id') .inTable('users') .onDelete('cascade'); table.boolean('notify') .defaultTo(false); table.boolean('email') .defaultTo(false); table.boolean('all') .defaultTo(true); table.boolean('all_actors') .notNullable() .defaultTo(true); table.boolean('all_entities') .notNullable() .defaultTo(true); table.boolean('all_tags') .notNullable() .defaultTo(true); table.boolean('all_matches') .notNullable() .defaultTo(true); table.boolean('from_preset') .notNullable() .defaultTo(false); table.json('meta'); table.text('comment'); table.datetime('created_at') .notNullable() .defaultTo(knex.fn.now()); }); await knex.schema.createTable('alerts_scenes', (table) => { table.increments('id'); table.integer('alert_id') .notNullable() .references('id') .inTable('alerts') .onDelete('cascade'); table.integer('scene_id') .notNullable() .references('id') .inTable('releases') .onDelete('cascade'); table.unique(['alert_id', 'scene_id']); }); await knex.schema.createTable('alerts_actors', (table) => { table.increments('id'); table.integer('alert_id') .notNullable() .references('id') .inTable('alerts') .onDelete('cascade'); table.integer('actor_id') .notNullable() .references('id') .inTable('actors') .onDelete('cascade'); table.unique(['alert_id', 'actor_id']); }); await knex.schema.createTable('alerts_tags', (table) => { table.increments('id'); table.integer('alert_id') .notNullable() .references('id') .inTable('alerts') .onDelete('cascade'); table.integer('tag_id') .notNullable() .references('id') .inTable('tags') .onDelete('cascade'); table.unique(['alert_id', 'tag_id']); }); await knex.schema.createTable('alerts_entities', (table) => { table.increments('id'); table.integer('alert_id') .notNullable() .references('id') .inTable('alerts') .onDelete('cascade'); table.integer('entity_id') .notNullable() .references('id') .inTable('entities') .onDelete('cascade'); }); await knex.schema.createTable('alerts_stashes', (table) => { table.increments('id'); table.integer('alert_id') .notNullable() .references('id') .inTable('alerts') .onDelete('cascade'); table.integer('stash_id') .notNullable() .references('id') .inTable('stashes') .onDelete('cascade'); table.unique(['alert_id', 'stash_id']); }); await knex.schema.createTable('alerts_matches', (table) => { table.increments('id'); table.integer('alert_id') .references('id') .inTable('alerts') .onDelete('cascade'); table.string('property'); table.string('expression'); }); 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.schema.createTable('notifications', (table) => { table.increments('id'); table.integer('user_id') .notNullable() .references('id') .inTable('users') .onDelete('cascade'); table.integer('scene_id') .references('id') .inTable('releases') .onDelete('cascade'); table.integer('alert_id') .references('id') .inTable('alerts') .onDelete('set null'); table.boolean('seen') .notNullable() .defaultTo(false); table.datetime('created_at') .notNullable() .defaultTo(knex.fn.now()); }); await knex.schema.createTable('fingerprints_types', (table) => { table.string('type') .primary(); }); await knex('fingerprints_types').insert([ 'oshash', 'phash', 'md5', 'blake2', ].map((type) => ({ type }))); await knex.schema.createTable('releases_fingerprints', (table) => { table.increments('id'); table.integer('scene_id') .notNullable() .references('id') .inTable('releases') .onDelete('cascade'); table.string('hash') .notNullable() .index(); table.string('type') .notNullable() .references('type') .inTable('fingerprints_types'); table.integer('duration'); table.integer('width'); table.integer('height'); table.integer('user_id') .references('id') .inTable('users') .onDelete('set null'); table.string('source'); table.integer('source_submissions'); table.json('source_meta'); table.integer('batch_id') .notNullable() .references('id') .inTable('batches'); table.datetime('source_created_at'); table.datetime('created_at') .notNullable() .defaultTo(knex.fn.now()); }); await knex.raw(` CREATE UNIQUE INDEX scenes_fingerprints_unique ON releases_fingerprints (scene_id, hash, source, user_id) NULLS NOT DISTINCT `); await knex.schema.createTable('scenes_revisions', (table) => { table.increments('id'); table.integer('scene_id') .references('id') .inTable('releases') .onDelete('set null'); table.integer('user_id') .references('id') .inTable('users') .onDelete('set null'); table.json('base') .notNullable(); table.json('deltas') .notNullable(); table.text('hash') .notNullable(); table.text('comment'); table.boolean('approved'); table.integer('reviewed_by') .references('id') .inTable('users') .onDelete('set null'); table.datetime('reviewed_at'); table.text('feedback'); table.datetime('applied_at'); table.datetime('created_at') .notNullable() .defaultTo(knex.fn.now()); }); await knex.schema.createTable('actors_revisions', (table) => { table.increments('id'); table.integer('actor_id') .references('id') .inTable('actors') .onDelete('set null'); table.integer('profile_id') .references('id') .inTable('actors_profiles') .onDelete('set null'); table.integer('user_id') .references('id') .inTable('users') .onDelete('set null'); table.json('base') .notNullable(); table.json('deltas') .notNullable(); table.text('hash') .notNullable(); table.text('comment'); table.boolean('approved'); table.integer('reviewed_by') .references('id') .inTable('users') .onDelete('set null'); table.datetime('reviewed_at'); table.text('feedback'); table.datetime('applied_at'); table.datetime('created_at') .notNullable() .defaultTo(knex.fn.now()); }); await knex.schema.createTable('affiliates', (table) => { table.string('id') .primary() .unique() .notNullable(); table.integer('entity_id', 12) .references('id') .inTable('entities'); table.text('url'); table.json('parameters'); table.unique(['entity_id', 'url']); table.text('comment'); table.datetime('created_at') .notNullable() .defaultTo(knex.fn.now()); }); await knex.schema.createTable('banners', (table) => { table.string('id') .primary() .unique() .notNullable(); table.string('type') .defaultTo('jpg'); table.integer('width') .notNullable(); table.integer('height') .notNullable(); table.integer('entity_id', 12) .references('id') .inTable('entities'); table.text('comment'); table.datetime('created_at') .notNullable() .defaultTo(knex.fn.now()); }); await knex.raw(` ALTER TABLE banners ADD COLUMN ratio numeric GENERATED ALWAYS AS (ROUND(width::decimal/ height::decimal, 2)) STORED; `); await knex.schema.createTable('banners_tags', (table) => { table.increments('id'); table.string('banner_id') .notNullable() .references('id') .inTable('banners'); table.integer('tag_id') .notNullable() .references('id') .inTable('tags'); table.unique(['banner_id', 'tag_id']); table.datetime('created_at') .notNullable() .defaultTo(knex.fn.now()); }); await knex.schema.createTable('campaigns', (table) => { table.increments('id'); table.integer('entity_id', 12) .notNullable() .references('id') .inTable('entities'); table.text('affiliate_id') .references('id') .inTable('affiliates'); table.text('url'); table.string('banner_id') .references('id') .inTable('banners'); table.text('comment'); table.datetime('created_at') .notNullable() .defaultTo(knex.fn.now()); }); await knex.schema.createTable('random_campaign', (table) => { table.integer('id') .notNullable() .references('id') .inTable('campaigns'); table.text('banner_id') .references('id') .inTable('banners'); table.text('url'); table.integer('entity_id') .references('id') .inTable('entities'); table.string('affiliate_id') .references('id') .inTable('affiliates'); table.integer('parent_id') .references('id') .inTable('entities'); }); // SEARCH AND SORT await knex.raw(` ALTER TABLE releases_search ADD COLUMN document tsvector; ALTER TABLE movies_search ADD COLUMN document tsvector; ALTER TABLE series_search ADD COLUMN document tsvector; /* allow scenes without dates to be mixed inbetween scenes with dates */ ALTER TABLE releases ADD COLUMN effective_date timestamptz GENERATED ALWAYS AS (COALESCE(date, created_at)) STORED; ALTER TABLE movies ADD COLUMN effective_date timestamptz GENERATED ALWAYS AS (COALESCE(date, created_at)) STORED; ALTER TABLE series ADD COLUMN effective_date timestamptz GENERATED ALWAYS AS (COALESCE(date, created_at)) STORED; `); // INDEXES await knex.raw(` CREATE UNIQUE INDEX unique_actor_slugs_network ON actors (slug, entity_id, entry_id); CREATE UNIQUE INDEX unique_actor_slugs ON actors (slug) WHERE entity_id IS NULL; CREATE UNIQUE INDEX unique_entity_campaigns_banner_url ON campaigns (entity_id, url, banner_id) WHERE affiliate_id IS NULL; CREATE UNIQUE INDEX unique_entity_campaigns_url ON campaigns (entity_id, url) WHERE banner_id IS NULL AND affiliate_id IS NULL; CREATE UNIQUE INDEX unique_entity_campaigns_banner_affiliate ON campaigns (entity_id, affiliate_id, banner_id) WHERE url IS NULL; CREATE UNIQUE INDEX unique_entity_campaigns_affiliate ON campaigns (entity_id, affiliate_id) WHERE banner_id IS NULL AND url IS NULL; CREATE UNIQUE INDEX releases_search_unique ON releases_search (release_id); CREATE UNIQUE INDEX movies_search_unique ON movies_search (movie_id); CREATE INDEX releases_search_index ON releases_search USING GIN (document); CREATE INDEX movies_search_index ON movies_search USING GIN (document); CREATE UNIQUE INDEX series_search_unique ON series_search (serie_id); CREATE INDEX series_search_index ON series_search USING GIN (document); `); // FUNCTIONS await knex.raw(` CREATE EXTENSION IF NOT EXISTS pg_trgm; CREATE FUNCTION current_user_id() RETURNS INTEGER AS $$ /* if the user ID is undefined, the adapter will pass it as a string, which cannot be cast as NULL by ::integer */ SELECT NULLIF(current_setting('user.id', true), '')::integer; $$ LANGUAGE SQL STABLE; `); // VIEWS AND COMMENTS await knex.raw(` CREATE MATERIALIZED VIEW actors_meta AS ( SELECT actors.id as actor_id, COUNT(DISTINCT stashes_actors)::integer as stashed, COUNT(DISTINCT releases_actors)::integer as scenes, row_to_json(avatars) as avatar FROM actors LEFT JOIN stashes_actors ON stashes_actors.actor_id = actors.id LEFT JOIN releases_actors ON releases_actors.actor_id = actors.id LEFT JOIN media AS avatars ON avatars.id = actors.avatar_media_id GROUP BY actors.id, avatars.id ); CREATE MATERIALIZED VIEW scenes_meta AS ( SELECT releases.id as scene_id, COUNT(DISTINCT stashes_scenes)::integer as stashed FROM releases LEFT JOIN stashes_scenes ON stashes_scenes.scene_id = releases.id GROUP BY releases.id ); CREATE MATERIALIZED VIEW movies_meta AS ( SELECT movie_id, stashed, stashed_scenes, stashed + stashed_scenes as stashed_total FROM ( SELECT movies.id as movie_id, COUNT(DISTINCT stashes_movies)::integer as stashed, COUNT(DISTINCT stashes_scenes)::integer as stashed_scenes FROM movies LEFT JOIN stashes_movies ON stashes_movies.movie_id = movies.id LEFT JOIN movies_scenes ON movies_scenes.movie_id = movies.id LEFT JOIN stashes_scenes ON stashes_scenes.scene_id = movies_scenes.scene_id GROUP BY movies.id ) AS meta ); CREATE MATERIALIZED VIEW stashes_meta AS ( SELECT stashes.id as stash_id, COUNT(DISTINCT stashes_scenes)::integer as stashed_scenes, COUNT(DISTINCT stashes_movies)::integer as stashed_movies, COUNT(DISTINCT stashes_actors)::integer as stashed_actors FROM stashes LEFT JOIN stashes_scenes ON stashes_scenes.stash_id = stashes.id LEFT JOIN stashes_movies ON stashes_movies.stash_id = stashes.id LEFT JOIN stashes_actors ON stashes_actors.stash_id = stashes.id GROUP BY stashes.id ); CREATE MATERIALIZED VIEW releases_not_showcased AS ( SELECT releases.id AS release_id FROM releases LEFT JOIN entities AS channels ON channels.id = releases.entity_id LEFT JOIN entities AS studios ON studios.id = releases.studio_id LEFT JOIN entities AS networks ON networks.id = channels.parent_id WHERE (studios.showcased = false) OR (channels.showcased = false AND studios.showcased IS NOT true) OR (networks.showcased = false AND channels.showcased IS NOT true AND studios.showcased IS NOT true) ); CREATE UNIQUE INDEX ON releases_not_showcased (release_id); CREATE MATERIALIZED VIEW releases_summaries AS ( SELECT releases.id as release_id, channels.slug as channel_slug, channels.type as channel_type, networks.slug as network_slug, networks.type as network_type, parent_networks.slug as parent_network_slug, parent_networks.type as parent_network_type, studios.showcased IS NOT false AND (channels.showcased IS NOT false OR COALESCE(studios.showcased, false) = true) AND (networks.showcased IS NOT false OR COALESCE(channels.showcased, false) = true OR COALESCE(studios.showcased, false) = true) AS showcased, batches.showcased AS batch_showcased, releases.effective_date, releases.created_at, array_agg(tags.slug ORDER BY tags.priority DESC) FILTER (WHERE tags.slug IS NOT NULL) AS tags FROM releases LEFT JOIN releases_tags ON releases_tags.release_id = releases.id LEFT JOIN tags ON tags.id = releases_tags.tag_id LEFT JOIN entities AS channels ON channels.id = releases.entity_id LEFT JOIN entities AS studios ON studios.id = releases.studio_id LEFT JOIN entities AS networks ON networks.id = channels.parent_id LEFT JOIN entities AS parent_networks ON parent_networks.id = networks.parent_id LEFT JOIN batches ON batches.id = releases.updated_batch_id GROUP BY releases.id, studios.showcased, batches.showcased, channels.showcased, channels.slug, channels.type, networks.showcased, networks.slug, networks.type, parent_networks.slug, parent_networks.type ); `); }; exports.down = (knex) => { // eslint-disable-line arrow-body-style // allow vim fold return knex.raw(` DROP TABLE IF EXISTS releases_actors CASCADE; DROP TABLE IF EXISTS releases_movies CASCADE; DROP TABLE IF EXISTS releases_directors CASCADE; DROP TABLE IF EXISTS releases_posters CASCADE; DROP TABLE IF EXISTS releases_photos CASCADE; DROP TABLE IF EXISTS releases_covers CASCADE; DROP TABLE IF EXISTS releases_caps CASCADE; DROP TABLE IF EXISTS releases_trailers CASCADE; DROP TABLE IF EXISTS releases_teasers CASCADE; DROP TABLE IF EXISTS releases_tags CASCADE; DROP TABLE IF EXISTS releases_fingerprints CASCADE; DROP TABLE IF EXISTS releases_search CASCADE; DROP TABLE IF EXISTS movies_search CASCADE; DROP TABLE IF EXISTS scenes_revisions CASCADE; DROP TABLE IF EXISTS movies_scenes CASCADE; DROP TABLE IF EXISTS movies_covers CASCADE; DROP TABLE IF EXISTS movies_posters CASCADE; DROP TABLE IF EXISTS movies_photos CASCADE; DROP TABLE IF EXISTS movies_trailers CASCADE; DROP TABLE IF EXISTS movies_teasers CASCADE; DROP TABLE IF EXISTS movies_tags CASCADE; 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_teasers CASCADE; DROP TABLE IF EXISTS series_posters CASCADE; DROP TABLE IF EXISTS series_covers CASCADE; DROP TABLE IF EXISTS series_photos CASCADE; DROP TABLE IF EXISTS series_search CASCADE; DROP TABLE IF EXISTS series_revisions CASCADE; DROP TABLE IF EXISTS clips_tags CASCADE; DROP TABLE IF EXISTS clips_posters CASCADE; DROP TABLE IF EXISTS clips_photos CASCADE; DROP TABLE IF EXISTS chapters_tags CASCADE; DROP TABLE IF EXISTS chapters_posters CASCADE; DROP TABLE IF EXISTS chapters_photos CASCADE; DROP TABLE IF EXISTS banners_tags CASCADE; DROP TABLE IF EXISTS banners CASCADE; DROP TABLE IF EXISTS campaigns CASCADE; DROP TABLE IF EXISTS random_campaign CASCADE; DROP TABLE IF EXISTS affiliates CASCADE; DROP TABLE IF EXISTS batches CASCADE; DROP TABLE IF EXISTS fingerprints_types CASCADE; DROP TABLE IF EXISTS actors_avatars CASCADE; DROP TABLE IF EXISTS actors_photos CASCADE; DROP TABLE IF EXISTS actors_social CASCADE; DROP TABLE IF EXISTS actors_profiles CASCADE; DROP TABLE IF EXISTS actors_tattoos CASCADE; DROP TABLE IF EXISTS actors_piercings CASCADE; DROP TABLE IF EXISTS actors_revisions CASCADE; DROP TABLE IF EXISTS actors_socials CASCADE; DROP TABLE IF EXISTS body CASCADE; DROP TABLE IF EXISTS entities_tags CASCADE; DROP TABLE IF EXISTS entities_social CASCADE; DROP TABLE IF EXISTS sites_tags CASCADE; DROP TABLE IF EXISTS sites_social CASCADE; DROP TABLE IF EXISTS networks_social CASCADE; DROP TABLE IF EXISTS tags_posters CASCADE; DROP TABLE IF EXISTS tags_photos CASCADE; DROP TABLE IF EXISTS movies CASCADE; DROP TABLE IF EXISTS clips CASCADE; DROP TABLE IF EXISTS chapters CASCADE; DROP TABLE IF EXISTS series CASCADE; DROP TABLE IF EXISTS releases CASCADE; DROP TABLE IF EXISTS actors CASCADE; DROP TABLE IF EXISTS tags CASCADE; DROP TABLE IF EXISTS tags_groups CASCADE; DROP TABLE IF EXISTS social CASCADE; DROP TABLE IF EXISTS sites CASCADE; DROP TABLE IF EXISTS studios CASCADE; DROP TABLE IF EXISTS media_sfw CASCADE; DROP TABLE IF EXISTS media CASCADE; DROP TABLE IF EXISTS countries CASCADE; DROP TABLE IF EXISTS networks CASCADE; DROP TABLE IF EXISTS entities_types CASCADE; DROP TABLE IF EXISTS entities CASCADE; DROP TABLE IF EXISTS notifications CASCADE; DROP TABLE IF EXISTS stashes_scenes CASCADE; DROP TABLE IF EXISTS stashes_movies CASCADE; DROP TABLE IF EXISTS stashes_actors CASCADE; DROP TABLE IF EXISTS stashes CASCADE; DROP TABLE IF EXISTS alerts_scenes CASCADE; DROP TABLE IF EXISTS alerts_actors CASCADE; DROP TABLE IF EXISTS alerts_tags CASCADE; DROP TABLE IF EXISTS alerts_entities CASCADE; DROP TABLE IF EXISTS alerts_stashes CASCADE; DROP TABLE IF EXISTS alerts_matches CASCADE; DROP TABLE IF EXISTS alerts CASCADE; DROP TABLE IF EXISTS bans CASCADE; DROP TABLE IF EXISTS users_keys CASCADE; DROP TABLE IF EXISTS users_templates CASCADE; DROP TABLE IF EXISTS users CASCADE; DROP TABLE IF EXISTS users_roles CASCADE; DROP FUNCTION IF EXISTS search_releases; DROP FUNCTION IF EXISTS search_sites; DROP FUNCTION IF EXISTS search_entities; DROP FUNCTION IF EXISTS search_actors; DROP FUNCTION IF EXISTS search_movies; DROP FUNCTION IF EXISTS search_tags; DROP FUNCTION IF EXISTS get_random_sfw_media_id; DROP FUNCTION IF EXISTS releases_is_new; DROP FUNCTION IF EXISTS entities_scenes; DROP FUNCTION IF EXISTS entities_scene_total; DROP FUNCTION IF EXISTS entities_scene_tags; DROP FUNCTION IF EXISTS actors_tags; DROP FUNCTION IF EXISTS actors_channels; DROP FUNCTION IF EXISTS actors_actors; DROP FUNCTION IF EXISTS actors_scenes; DROP FUNCTION IF EXISTS movies_actors; DROP FUNCTION IF EXISTS movies_tags; DROP FUNCTION IF EXISTS movies_scenes_photos; DROP FUNCTION IF EXISTS series_actors; DROP FUNCTION IF EXISTS series_tags; DROP FUNCTION IF EXISTS series_scenes_photos; DROP POLICY IF EXISTS stashes_policy ON stashes; DROP POLICY IF EXISTS stashes_policy ON stashes_scenes; DROP POLICY IF EXISTS stashes_policy ON stashes_actors; DROP FUNCTION IF EXISTS current_user_id; DROP FUNCTION IF EXISTS get_random_campaign; DROP TABLE IF EXISTS releases_search_results; DROP TABLE IF EXISTS movies_search_results; `); };