exports.up = knex => Promise.resolve() .then(() => knex.schema.createTable('countries', (table) => { table.string('alpha2', 2) .unique() .primary(); table.string('alpha3', 3) .unique(); table.string('name') .notNullable(); table.string('alias'); table.integer('code', 3); table.string('nationality'); table.integer('priority', 2) .defaultTo(0); })) .then(() => knex.schema.createTable('media', (table) => { table.string('id', 21) .primary(); table.string('path'); table.string('thumbnail'); table.string('lazy'); table.integer('index'); table.string('mime'); table.string('hash'); table.integer('size', 12); table.integer('quality', 6); table.integer('width', 6); table.integer('height', 6); table.float('entropy'); table.string('scraper', 32); table.string('copyright', 100); table.string('source', 2100); table.string('source_page', 2100); table.text('comment'); table.string('group'); table.unique('hash'); table.unique('source'); table.datetime('created_at') .defaultTo(knex.fn.now()); })) .then(() => knex.schema.createTable('media_sfw', (table) => { table.string('id', 21) .primary(); table.string('media_id', 21) .references('id') .inTable('media') .unique(); })) .then(() => knex.raw(` CREATE FUNCTION get_random_sfw_media_id() RETURNS varchar AS $$ SELECT media_id FROM media_sfw ORDER BY random() LIMIT 1; $$ LANGUAGE sql STABLE; `)) .then(() => knex.schema.alterTable('media', (table) => { table.string('sfw_media_id', 21) .references('id') .inTable('media') .defaultTo(knex.raw('get_random_sfw_media_id()')); })) .then(() => knex.schema.createTable('tags_groups', (table) => { table.increments('id', 12); table.string('name', 32); table.text('description'); table.string('slug', 32) .unique(); table.datetime('created_at') .defaultTo(knex.fn.now()); })) .then(() => knex.schema.createTable('tags', (table) => { table.increments('id', 12); table.string('name'); table.text('description'); table.integer('priority', 2) .defaultTo(0); 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.string('slug', 32) .unique(); table.datetime('created_at') .defaultTo(knex.fn.now()); })) .then(() => knex.schema.createTable('tags_posters', (table) => { table.integer('tag_id', 12) .notNullable() .references('id') .inTable('tags'); table.string('media_id', 21) .notNullable() .references('id') .inTable('media'); table.unique('tag_id'); })) .then(() => knex.schema.createTable('tags_photos', (table) => { table.integer('tag_id', 12) .notNullable() .references('id') .inTable('tags'); table.string('media_id', 21) .notNullable() .references('id') .inTable('media'); table.unique(['tag_id', 'media_id']); })) .then(() => knex.schema.createTable('networks', (table) => { table.increments('id', 12); table.string('name'); table.string('url'); table.text('description'); table.json('parameters'); table.integer('parent_id', 12) .references('id') .inTable('networks'); table.string('slug', 32) .unique(); table.datetime('created_at') .defaultTo(knex.fn.now()); })) .then(() => knex.schema.createTable('networks_social', (table) => { table.increments('id', 16); table.string('url'); table.string('platform'); table.integer('network_id', 12) .notNullable() .references('id') .inTable('networks'); table.unique(['url', 'network_id']); table.datetime('created_at') .defaultTo(knex.fn.now()); })) .then(() => knex.schema.createTable('sites', (table) => { table.increments('id', 12); table.integer('network_id', 12) .notNullable() .references('id') .inTable('networks'); table.string('name'); table.string('slug', 32) .unique(); table.string('alias'); table.string('url'); table.text('description'); table.json('parameters'); table.integer('priority', 3) .defaultTo(0); table.boolean('show') .defaultTo(true); table.datetime('created_at') .defaultTo(knex.fn.now()); })) .then(() => knex.schema.createTable('sites_tags', (table) => { table.integer('tag_id', 12) .notNullable() .references('id') .inTable('tags'); table.integer('site_id', 12) .notNullable() .references('id') .inTable('sites'); table.boolean('inherit') .defaultTo(false); table.unique(['tag_id', 'site_id']); })) .then(() => knex.schema.createTable('sites_social', (table) => { table.increments('id', 16); table.string('url'); table.string('platform'); table.integer('site_id', 12) .notNullable() .references('id') .inTable('sites'); table.unique(['url', 'site_id']); table.datetime('created_at') .defaultTo(knex.fn.now()); })) .then(() => knex.schema.createTable('studios', (table) => { table.increments('id', 12); table.integer('network_id', 12) .notNullable() .references('id') .inTable('networks'); table.string('name'); table.string('url'); table.text('description'); table.string('slug', 32) .unique(); table.datetime('created_at') .defaultTo(knex.fn.now()); })) .then(() => knex.schema.createTable('batches', (table) => { table.increments('id', 12); table.text('comment'); table.datetime('created_at') .defaultTo(knex.fn.now()); })) .then(() => knex.schema.createTable('actors', (table) => { table.increments('id', 12); table.string('name') .notNullable(); table.string('slug', 32); table.integer('network_id', 12) .references('id') .inTable('networks'); table.unique(['slug', 'network_id']); table.integer('alias_for', 12) .references('id') .inTable('actors'); table.date('birthdate'); table.string('gender', 18); table.text('description'); table.string('birth_city'); table.string('birth_state'); table.string('birth_country_alpha2', 2) .references('alpha2') .inTable('countries'); table.string('residence_city'); table.string('residence_state'); table.string('residence_country_alpha2', 2) .references('alpha2') .inTable('countries'); table.string('ethnicity'); table.string('bust', 10); table.integer('waist', 3); table.integer('hip', 3); table.boolean('natural_boobs'); table.integer('height', 3); table.integer('weight', 3); table.string('eyes'); table.string('hair'); table.boolean('has_tattoos'); table.boolean('has_piercings'); table.string('piercings'); table.string('tattoos'); table.integer('batch_id', 12) .references('id') .inTable('batches'); table.datetime('updated_at') .defaultTo(knex.fn.now()); table.datetime('created_at') .defaultTo(knex.fn.now()); })) .then(() => knex.schema.createTable('actors_profiles', (table) => { table.increments('id', 12); table.integer('actor_id', 12) .references('id') .inTable('actors'); table.integer('network_id', 12) .references('id') .inTable('networks'); table.integer('site_id', 12) .references('id') .inTable('sites'); table.unique(['actor_id', 'network_id']); table.unique(['actor_id', 'site_id']); table.date('birthdate'); table.string('gender', 18); table.text('description'); table.string('birth_city'); table.string('birth_state'); table.string('birth_country_alpha2', 2) .references('alpha2') .inTable('countries'); table.string('residence_city'); table.string('residence_state'); table.string('residence_country_alpha2', 2) .references('alpha2') .inTable('countries'); table.string('ethnicity'); table.string('bust', 10); table.integer('waist', 3); table.integer('hip', 3); table.boolean('natural_boobs'); table.integer('height', 3); table.integer('weight', 3); table.string('eyes'); table.string('hair'); table.boolean('has_tattoos'); table.boolean('has_piercings'); table.string('piercings'); table.string('tattoos'); table.datetime('scraped_at'); table.boolean('scrape_success'); table.datetime('updated_at') .defaultTo(knex.fn.now()); table.datetime('created_at') .defaultTo(knex.fn.now()); })) .then(() => knex.schema.createTable('body', (table) => { table.string('slug', 20) .primary(); table.string('name'); })) .then(() => 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' }, ])) .then(() => knex.schema.createTable('actors_tattoos', (table) => { table.increments('id'); table.integer('actor_id', 12) .notNullable() .references('id') .inTable('actors'); table.string('body_slug', 20) .references('slug') .inTable('body'); table.enum('side', ['left', 'right', 'center', 'both']); table.string('description'); table.datetime('created_at') .defaultTo(knex.fn.now()); })) .then(() => knex.schema.createTable('actors_piercings', (table) => { table.increments('id'); table.integer('actor_id', 12) .notNullable() .references('id') .inTable('actors'); table.string('body_slug', 20) .references('slug') .inTable('body'); table.enum('side', ['left', 'right', 'center', 'both']); table.string('description'); table.datetime('created_at') .defaultTo(knex.fn.now()); })) .then(() => knex.schema.createTable('actors_avatars', (table) => { table.integer('profile_id', 12) .notNullable() .references('id') .inTable('actors_profiles'); table.string('media_id', 21) .notNullable() .references('id') .inTable('media'); table.unique('profile_id'); })) .then(() => knex.schema.createTable('actors_photos', (table) => { table.integer('actor_id', 12) .notNullable() .references('id') .inTable('actors'); table.string('media_id', 21) .notNullable() .references('id') .inTable('media'); table.unique(['actor_id', 'media_id']); })) .then(() => knex.schema.createTable('actors_social', (table) => { table.increments('id', 16); table.string('url'); table.string('platform'); table.integer('actor_id', 12) .notNullable() .references('id') .inTable('actors'); table.unique(['url', 'actor_id']); table.datetime('created_at') .defaultTo(knex.fn.now()); })) .then(() => knex.schema.createTable('directors', (table) => { table.increments('id', 12); table.string('name'); table.integer('alias_for', 12) .references('id') .inTable('directors'); table.string('slug', 32) .unique(); table.datetime('created_at') .defaultTo(knex.fn.now()); })) .then(() => knex.schema.createTable('releases', (table) => { table.increments('id', 16); table.integer('site_id', 12) .references('id') .inTable('sites'); table.integer('network_id', 12) .references('id') .inTable('networks'); table.integer('studio_id', 12) .references('id') .inTable('studios'); table.string('type', 10) .defaultTo('scene'); table.string('shoot_id'); table.string('entry_id'); table.unique(['site_id', 'network_id', 'entry_id', 'type']); table.string('url', 1000); table.string('title'); table.string('slug'); table.date('date'); table.text('description'); table.integer('duration') .unsigned(); table.boolean('deep'); table.string('deep_url', 1000); table.integer('created_batch_id', 12) .references('id') .inTable('batches'); table.integer('updated_batch_id', 12) .references('id') .inTable('batches'); table.datetime('created_at') .defaultTo(knex.fn.now()); })) .then(() => knex.schema.createTable('releases_actors', (table) => { table.integer('release_id', 16) .notNullable() .references('id') .inTable('releases'); table.integer('actor_id', 12) .notNullable() .references('id') .inTable('actors'); table.unique(['release_id', 'actor_id']); table.datetime('created_at') .defaultTo(knex.fn.now()); })) .then(() => knex.schema.createTable('releases_movies', (table) => { table.integer('movie_id', 16) .notNullable() .references('id') .inTable('releases'); table.integer('scene_id', 16) .notNullable() .references('id') .inTable('releases'); table.unique(['movie_id', 'scene_id']); table.datetime('created_at') .defaultTo(knex.fn.now()); })) .then(() => knex.schema.createTable('releases_directors', (table) => { table.integer('release_id', 16) .notNullable() .references('id') .inTable('releases'); table.integer('director_id', 8) .notNullable() .references('id') .inTable('directors'); table.unique(['release_id', 'director_id']); })) .then(() => knex.schema.createTable('releases_posters', (table) => { table.integer('release_id', 16) .notNullable() .references('id') .inTable('releases'); table.string('media_id', 21) .notNullable() .references('id') .inTable('media'); table.unique('release_id'); })) .then(() => knex.schema.createTable('releases_covers', (table) => { table.integer('release_id', 16) .notNullable() .references('id') .inTable('releases'); table.string('media_id', 21) .notNullable() .references('id') .inTable('media'); table.unique(['release_id', 'media_id']); })) .then(() => knex.schema.createTable('releases_trailers', (table) => { table.integer('release_id', 16) .notNullable() .references('id') .inTable('releases'); table.string('media_id', 21) .notNullable() .references('id') .inTable('media'); table.unique('release_id'); })) .then(() => knex.schema.createTable('releases_teasers', (table) => { table.integer('release_id', 16) .notNullable() .references('id') .inTable('releases'); table.string('media_id', 21) .notNullable() .references('id') .inTable('media'); table.unique('release_id'); })) .then(() => knex.schema.createTable('releases_photos', (table) => { table.integer('release_id', 16) .notNullable() .references('id') .inTable('releases'); table.string('media_id', 21) .notNullable() .references('id') .inTable('media'); table.unique(['release_id', 'media_id']); })) .then(() => knex.schema.createTable('releases_tags', (table) => { table.integer('tag_id', 12) .notNullable() .references('id') .inTable('tags'); table.integer('release_id', 16) .notNullable() .references('id') .inTable('releases'); table.unique(['tag_id', 'release_id']); })) .then(() => knex.schema.createTable('releases_search', (table) => { table.integer('release_id', 16) .references('id') .inTable('releases'); })) .then(() => knex.raw(` ALTER TABLE releases ADD CONSTRAINT ensure_site_or_network CHECK (site_id IS NOT NULL OR network_id IS NOT NULL); ALTER TABLE releases_search ADD COLUMN document tsvector; CREATE TEXT SEARCH DICTIONARY traxxx_dict ( TEMPLATE = pg_catalog.simple, stopwords = traxxx ); CREATE TEXT SEARCH CONFIGURATION traxxx ( COPY = english ); ALTER TEXT SEARCH CONFIGURATION traxxx ALTER MAPPING FOR word, numword, hword, numhword, hword_part, hword_numpart, asciiword, asciihword, hword_asciipart WITH traxxx_dict, simple, english_stem; CREATE UNIQUE INDEX releases_search_unique ON releases_search (release_id); CREATE INDEX releases_search_index ON releases_search USING GIN (document); CREATE FUNCTION search_releases(query text) RETURNS SETOF releases AS $$ SELECT * FROM releases WHERE releases.id IN ( SELECT release_id FROM releases_search AS search WHERE search.document @@ plainto_tsquery('traxxx', regexp_replace(query, '\\.|-|(XXX\\.[\\d+|hd|sd].*$)', ' ', 'ig')) ORDER BY ts_rank(search.document, plainto_tsquery('traxxx', regexp_replace(query, '\\.|-|(XXX\\.[\\d+|hd|sd].*$)', ' ', 'ig'))) DESC ); $$ LANGUAGE SQL STABLE; CREATE FUNCTION search_sites(search text) RETURNS SETOF sites AS $$ SELECT * FROM sites WHERE name ILIKE ('%' || search || '%') OR slug ILIKE ('%' || search || '%') OR url ILIKE ('%' || search || '%') $$ LANGUAGE SQL STABLE; CREATE FUNCTION releases_is_new(release releases) RETURNS boolean AS $$ SELECT NOT EXISTS(SELECT true FROM batches WHERE batches.id = release.created_batch_id + 1 LIMIT 1); $$ LANGUAGE sql STABLE; CREATE VIEW movie_actors AS SELECT releases_movies.movie_id, releases_actors.actor_id FROM releases_movies LEFT JOIN releases ON releases.id = releases_movies.scene_id LEFT JOIN releases_actors ON releases_actors.release_id = releases.id GROUP BY movie_id, actor_id; CREATE VIEW movie_tags AS SELECT releases_movies.movie_id, releases_tags.tag_id FROM releases_movies LEFT JOIN releases ON releases.id = releases_movies.scene_id LEFT JOIN releases_tags ON releases_tags.release_id = releases.id GROUP BY movie_id, tag_id; COMMENT ON VIEW movie_actors IS E'@foreignKey (movie_id) references releases (id)\n@foreignKey (actor_id) references actors (id)'; COMMENT ON VIEW movie_tags IS E'@foreignKey (movie_id) references releases (id)\n@foreignKey (tag_id) references tags (id)'; COMMENT ON COLUMN actors.height IS E'@omit read,update,create,delete,all,many'; COMMENT ON COLUMN actors.weight IS E'@omit read,update,create,delete,all,many'; `)); exports.down = knex => knex.raw(` DROP VIEW IF EXISTS movie_actors; DROP VIEW IF EXISTS movie_tags; 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_trailers CASCADE; DROP TABLE IF EXISTS releases_teasers CASCADE; DROP TABLE IF EXISTS releases_tags CASCADE; DROP TABLE IF EXISTS releases_search CASCADE; DROP TABLE IF EXISTS batches 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 body 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 releases CASCADE; DROP TABLE IF EXISTS actors CASCADE; DROP TABLE IF EXISTS directors 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 FUNCTION IF EXISTS releases_by_tag_slugs; DROP FUNCTION IF EXISTS search_sites; DROP FUNCTION IF EXISTS get_random_sfw_media_id; DROP TEXT SEARCH CONFIGURATION IF EXISTS traxxx; DROP TEXT SEARCH DICTIONARY IF EXISTS traxxx_dict; `);