Merged database migrations.
This commit is contained in:
		
							parent
							
								
									85942c5d00
								
							
						
					
					
						commit
						dbaddfb291
					
				|  | @ -38,7 +38,7 @@ module.exports = { | |||
| 		login: true, | ||||
| 		signup: true, | ||||
| 		usernameLength: [2, 24], | ||||
| 		usernamePattern: /^[a-zA-Z0-9_-]$/, | ||||
| 		usernamePattern: /^[a-zA-Z0-9_-]+$/, | ||||
| 	}, | ||||
| 	exclude: { | ||||
| 		channels: [ | ||||
|  |  | |||
|  | @ -64,6 +64,7 @@ exports.up = (knex) => Promise.resolve() | |||
| 		table.boolean('independent') | ||||
| 			.defaultTo(false); | ||||
| 
 | ||||
| 		table.boolean('showcased'); | ||||
| 		table.boolean('visible') | ||||
| 			.defaultTo(true); | ||||
| 
 | ||||
|  | @ -651,6 +652,8 @@ exports.up = (knex) => Promise.resolve() | |||
| 		table.integer('duration') | ||||
| 			.unsigned(); | ||||
| 
 | ||||
| 		table.specificType('qualities', 'text[]'); | ||||
| 
 | ||||
| 		table.boolean('deep'); | ||||
| 		table.text('deep_url', 1000); | ||||
| 
 | ||||
|  | @ -804,6 +807,8 @@ exports.up = (knex) => Promise.resolve() | |||
| 		table.text('original_tag'); | ||||
| 
 | ||||
| 		table.unique(['tag_id', 'release_id']); | ||||
| 		table.index('tag_id'); | ||||
| 		table.index('release_id'); | ||||
| 	})) | ||||
| 	.then(() => knex.schema.createTable('releases_search', (table) => { | ||||
| 		table.integer('release_id', 16) | ||||
|  | @ -873,6 +878,8 @@ exports.up = (knex) => Promise.resolve() | |||
| 
 | ||||
| 		table.datetime('created_at') | ||||
| 			.defaultTo(knex.fn.now()); | ||||
| 
 | ||||
| 		table.index('scene_id'); | ||||
| 	})) | ||||
| 	.then(() => knex.schema.createTable('movies_covers', (table) => { | ||||
| 		table.integer('movie_id', 16) | ||||
|  | @ -916,12 +923,151 @@ exports.up = (knex) => Promise.resolve() | |||
| 
 | ||||
| 		table.unique('movie_id'); | ||||
| 	})) | ||||
| 	.then(() => knex.schema.createTable('movies_photos', (table) => { | ||||
| 		table.integer('movie_id', 16) | ||||
| 			.notNullable() | ||||
| 			.references('id') | ||||
| 			.inTable('movies') | ||||
| 			.onDelete('cascade'); | ||||
| 
 | ||||
| 		table.text('media_id', 21) | ||||
| 			.notNullable() | ||||
| 			.references('id') | ||||
| 			.inTable('media'); | ||||
| 
 | ||||
| 		table.unique(['movie_id', 'media_id']); | ||||
| 	})) | ||||
| 	.then(() => knex.schema.createTable('movies_search', (table) => { | ||||
| 		table.integer('movie_id', 16) | ||||
| 			.references('id') | ||||
| 			.inTable('movies') | ||||
| 			.onDelete('cascade'); | ||||
| 	})) | ||||
| 	.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'); | ||||
| 	})) | ||||
| 	.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_photos', (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('chapters', (table) => { | ||||
| 		table.increments('id', 16); | ||||
| 
 | ||||
|  | @ -1062,6 +1208,8 @@ exports.up = (knex) => Promise.resolve() | |||
| 		table.datetime('created_at') | ||||
| 			.notNullable() | ||||
| 			.defaultTo(knex.fn.now()); | ||||
| 
 | ||||
| 		table.datetime('last_login'); | ||||
| 	})) | ||||
| 	.then(() => knex.schema.createTable('stashes', (table) => { | ||||
| 		table.increments('id'); | ||||
|  | @ -1088,7 +1236,12 @@ exports.up = (knex) => Promise.resolve() | |||
| 		table.datetime('created_at') | ||||
| 			.notNullable() | ||||
| 			.defaultTo(knex.fn.now()); | ||||
| 
 | ||||
| 		table.unique(['user_id', 'slug']); | ||||
| 	})) | ||||
| 	.then(() => knex.raw(` | ||||
| 		CREATE UNIQUE INDEX unique_primary ON stashes (user_id, "primary") WHERE ("primary" = TRUE); | ||||
| 	`))
 | ||||
| 	.then(() => knex.schema.createTable('stashes_scenes', (table) => { | ||||
| 		table.integer('stash_id') | ||||
| 			.notNullable() | ||||
|  | @ -1152,6 +1305,27 @@ exports.up = (knex) => Promise.resolve() | |||
| 			.notNullable() | ||||
| 			.defaultTo(knex.fn.now()); | ||||
| 	})) | ||||
| 	.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.schema.createTable('alerts', (table) => { | ||||
| 		table.increments('id'); | ||||
| 
 | ||||
|  | @ -1329,6 +1503,9 @@ exports.up = (knex) => Promise.resolve() | |||
| 			.notNullable() | ||||
| 			.defaultTo(knex.fn.now()); | ||||
| 	})) | ||||
| 	.then(() => knex.raw(` | ||||
| 		ALTER TABLE banners ADD COLUMN ratio numeric GENERATED ALWAYS AS (ROUND(width::decimal/ height::decimal, 2)) STORED; | ||||
| 	`))
 | ||||
| 	.then(() => knex.schema.createTable('banners_tags', (table) => { | ||||
| 		table.increments('id'); | ||||
| 
 | ||||
|  | @ -1372,12 +1549,32 @@ exports.up = (knex) => Promise.resolve() | |||
| 			.notNullable() | ||||
| 			.defaultTo(knex.fn.now()); | ||||
| 	})) | ||||
| 	.then(() => knex.schema.createTable('random_campaign', (table) => { | ||||
| 		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
 | ||||
| 	.then(() => { // eslint-disable-line arrow-body-style
 | ||||
| 		// allow vim fold
 | ||||
| 		return 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 | ||||
|  | @ -1401,6 +1598,8 @@ exports.up = (knex) => Promise.resolve() | |||
| 			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
 | ||||
|  | @ -1421,15 +1620,13 @@ exports.up = (knex) => Promise.resolve() | |||
| 			CREATE TABLE movies_search_results (movie_id integer, rank real, FOREIGN KEY (movie_id) REFERENCES movies (id)); | ||||
| 
 | ||||
| 			CREATE FUNCTION search_releases(query text) RETURNS SETOF releases_search_results AS $$ | ||||
| 				SELECT releases.id, ranks.rank FROM ( | ||||
| 					SELECT | ||||
| 						releases_search.release_id, | ||||
| 						ts_rank(releases_search.document, to_tsquery('english', array_to_string(array(SELECT * FROM regexp_matches(query, '[A-Za-zÀ-ÖØ-öø-ÿ0-9]+', 'g')), '|'))) AS rank | ||||
| 				SELECT results.release_id, ts_rank(results.document::tsvector, curate_search_query(query)) as rank | ||||
| 				FROM ( | ||||
| 					SELECT releases_search.release_id, document | ||||
| 					FROM releases_search | ||||
| 					) ranks | ||||
| 				LEFT JOIN releases ON releases.id = ranks.release_id | ||||
| 				WHERE ranks.rank > 0 | ||||
| 				ORDER BY ranks.rank DESC; | ||||
| 					WHERE document::tsvector @@ curate_search_query(query) | ||||
| 				) AS results | ||||
| 				ORDER BY rank DESC; | ||||
| 			$$ LANGUAGE SQL STABLE; | ||||
| 
 | ||||
| 			CREATE FUNCTION search_movies(query text) RETURNS SETOF movies_search_results AS $$ | ||||
|  | @ -1513,6 +1710,52 @@ exports.up = (knex) => Promise.resolve() | |||
| 				ORDER BY actors.name; | ||||
| 			$$ LANGUAGE SQL STABLE; | ||||
| 
 | ||||
| 			CREATE FUNCTION entities_scenes(entity entities) RETURNS SETOF releases AS $$ | ||||
| 				WITH RECURSIVE children AS ( | ||||
| 					SELECT entities.id | ||||
| 						FROM entities | ||||
| 						WHERE entities.id = entity.id | ||||
| 
 | ||||
| 						UNION ALL | ||||
| 
 | ||||
| 						SELECT entities.id | ||||
| 						FROM entities | ||||
| 						INNER JOIN children ON children.id = entities.parent_id | ||||
| 				) | ||||
| 
 | ||||
| 				SELECT releases FROM releases | ||||
| 				INNER JOIN children ON children.id = releases.entity_id | ||||
| 
 | ||||
| 				UNION | ||||
| 
 | ||||
| 				SELECT releases FROM releases | ||||
| 				INNER JOIN children ON children.id = releases.studio_id; | ||||
| 			$$ LANGUAGE SQL STABLE; | ||||
| 
 | ||||
| 			CREATE OR REPLACE FUNCTION entities_scene_total(entity entities) RETURNS bigint AS $$ | ||||
| 				SELECT COUNT(id) | ||||
| 				FROM releases | ||||
| 				WHERE releases.entity_id = entity.id; | ||||
| 			$$ LANGUAGE SQL STABLE; | ||||
| 
 | ||||
| 		CREATE FUNCTION entities_scene_tags(entity entities, selectable_tags text[]) RETURNS SETOF tags AS $$ | ||||
| 			SELECT tags.* | ||||
| 			FROM releases | ||||
| 			LEFT JOIN | ||||
| 				releases_tags ON releases_tags.release_id = releases.id | ||||
| 			LEFT JOIN | ||||
| 				tags ON tags.id = releases_tags.tag_id | ||||
| 			WHERE | ||||
| 				releases.entity_id = entity.id | ||||
| 			AND | ||||
| 				CASE WHEN array_length(selectable_tags, 1) IS NOT NULL | ||||
| 				THEN tags.slug = ANY(selectable_tags) | ||||
| 				ELSE true | ||||
| 				END | ||||
| 			GROUP BY tags.id | ||||
| 			ORDER BY tags.name; | ||||
| 		$$ LANGUAGE SQL STABLE; | ||||
| 
 | ||||
| 			/* GraphQL/Postgraphile 'every' applies to the data, will only include scenes for which every assigned tag is selected, | ||||
| 			   instead of what we want; scenes with every selected tag, but possibly also some others */ | ||||
| 			CREATE FUNCTION actors_scenes(actor actors, selected_tags text[], mode text DEFAULT 'all') RETURNS SETOF releases AS $$ | ||||
|  | @ -1589,7 +1832,7 @@ exports.up = (knex) => Promise.resolve() | |||
| 				ORDER BY tags.priority DESC | ||||
| 			$$ LANGUAGE SQL STABLE; | ||||
| 
 | ||||
| 			CREATE FUNCTION movies_photos(movie movies) RETURNS SETOF media AS $$ | ||||
| 			CREATE FUNCTION movies_scenes_photos(movie movies) RETURNS SETOF media AS $$ | ||||
| 				SELECT media.* | ||||
| 				FROM movies_scenes | ||||
| 				LEFT JOIN | ||||
|  | @ -1607,15 +1850,111 @@ exports.up = (knex) => Promise.resolve() | |||
| 				SELECT EXISTS(SELECT true WHERE (SELECT id FROM batches ORDER BY created_at DESC LIMIT 1) = release.created_batch_id); | ||||
| 			$$ LANGUAGE sql STABLE; | ||||
| 
 | ||||
| 			CREATE FUNCTION banners_ratio(banner banners) RETURNS numeric AS $$ | ||||
| 				SELECT ROUND(banner.width::decimal / banner.height::decimal, 2); | ||||
| 			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 get_random_campaign() RETURNS SETOF campaigns AS $$ | ||||
| 				SELECT * FROM campaigns | ||||
| 				ORDER BY random() | ||||
| 			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_scenes_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; | ||||
| 
 | ||||
| 			CREATE FUNCTION get_random_campaign(min_ratio decimal default 0, max_ratio decimal default 1000.0) RETURNS random_campaign AS $$ | ||||
| 				SELECT * FROM ( | ||||
| 					SELECT DISTINCT ON (CASE WHEN parent_id IS NOT NULL THEN parent_id ELSE entity_id END) | ||||
| 						banner_id, url, entity_id, affiliate_id, parent_id | ||||
| 					FROM ( | ||||
| 						SELECT | ||||
| 							campaigns.*, entities.parent_id as parent_id | ||||
| 						FROM campaigns | ||||
| 						LEFT JOIN entities ON entities.id = campaigns.entity_id | ||||
| 						LEFT JOIN banners ON banners.id = campaigns.banner_id | ||||
| 						WHERE banner_id IS NOT NULL | ||||
| 						AND ratio >= min_ratio | ||||
| 						AND ratio <= max_ratio | ||||
| 						ORDER BY RANDOM() | ||||
| 					) random_campaigns | ||||
| 				) random_banners | ||||
| 				ORDER BY RANDOM() | ||||
| 				LIMIT 1; | ||||
| 			$$ LANGUAGE sql STABLE; | ||||
| 			$$ LANGUAGE SQL STABLE; | ||||
| 		`);
 | ||||
| 	}) | ||||
| 	// VIEWS AND COMMENTS
 | ||||
| 	.then(() => { // eslint-disable-line arrow-body-style
 | ||||
| 		// allow vim fold
 | ||||
| 		return knex.raw(` | ||||
| 			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); | ||||
| 			COMMENT ON MATERIALIZED VIEW releases_not_showcased IS E'@foreignKey (release_id) references releases (id)'; | ||||
| 
 | ||||
| 			COMMENT ON COLUMN users.password IS E'@omit'; | ||||
| 			COMMENT ON COLUMN users.email IS E'@omit'; | ||||
| 			COMMENT ON COLUMN users.email_verified IS E'@omit'; | ||||
| 			COMMENT ON COLUMN users.abilities IS E'@omit'; | ||||
| 
 | ||||
| 			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'; | ||||
| 			COMMENT ON COLUMN actors.penis_length IS E'@omit read,update,create,delete,all,many'; | ||||
| 			COMMENT ON COLUMN actors.penis_girth IS E'@omit read,update,create,delete,all,many'; | ||||
| 
 | ||||
| 			COMMENT ON FUNCTION entities_scenes IS E'@sortable'; | ||||
| 
 | ||||
| 			COMMENT ON FUNCTION actors_tags IS E'@sortable'; | ||||
| 			COMMENT ON FUNCTION actors_channels IS E'@sortable'; | ||||
| 			COMMENT ON FUNCTION actors_actors IS E'@sortable'; | ||||
| 			COMMENT ON FUNCTION actors_scenes IS E'@sortable'; | ||||
| 			COMMENT ON FUNCTION tags_scenes IS E'@sortable'; | ||||
| 
 | ||||
| 			COMMENT ON FUNCTION search_releases IS E'@sortable'; | ||||
| 			COMMENT ON FUNCTION search_entities IS E'@sortable'; | ||||
| 			COMMENT ON FUNCTION search_actors IS E'@sortable'; | ||||
| 			COMMENT ON FUNCTION search_movies IS E'@sortable'; | ||||
| 			COMMENT ON FUNCTION search_tags IS E'@sortable'; | ||||
| 		`);
 | ||||
| 	}) | ||||
| 	// POLICIES
 | ||||
|  | @ -1632,6 +1971,7 @@ exports.up = (knex) => Promise.resolve() | |||
| 			ALTER TABLE stashes_scenes ENABLE ROW LEVEL SECURITY; | ||||
| 			ALTER TABLE stashes_movies ENABLE ROW LEVEL SECURITY; | ||||
| 			ALTER TABLE stashes_actors ENABLE ROW LEVEL SECURITY; | ||||
| 			ALTER TABLE stashes_series ENABLE ROW LEVEL SECURITY; | ||||
| 
 | ||||
| 			CREATE POLICY stashes_policy_select ON stashes FOR SELECT USING (stashes.public OR stashes.user_id = current_user_id()); | ||||
| 			CREATE POLICY stashes_policy_update ON stashes FOR UPDATE USING (stashes.public OR stashes.user_id = current_user_id()); | ||||
|  | @ -1662,6 +2002,14 @@ exports.up = (knex) => Promise.resolve() | |||
| 					AND (stashes.user_id = current_user_id() OR stashes.public) | ||||
| 				)); | ||||
| 
 | ||||
| 			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) | ||||
| 				)); | ||||
| 
 | ||||
| 			ALTER TABLE alerts ENABLE ROW LEVEL SECURITY; | ||||
| 			ALTER TABLE alerts_tags ENABLE ROW LEVEL SECURITY; | ||||
| 			ALTER TABLE alerts_scenes ENABLE ROW LEVEL SECURITY; | ||||
|  | @ -1729,33 +2077,6 @@ exports.up = (knex) => Promise.resolve() | |||
| 		`, {
 | ||||
| 			visitor: knex.raw(config.database.query.user), | ||||
| 		}); | ||||
| 	}) | ||||
| 	// VIEWS AND COMMENTS
 | ||||
| 	.then(() => { // eslint-disable-line arrow-body-style
 | ||||
| 		// allow vim fold
 | ||||
| 		return knex.raw(` | ||||
| 			COMMENT ON COLUMN users.password IS E'@omit'; | ||||
| 			COMMENT ON COLUMN users.email IS E'@omit'; | ||||
| 			COMMENT ON COLUMN users.email_verified IS E'@omit'; | ||||
| 			COMMENT ON COLUMN users.abilities IS E'@omit'; | ||||
| 
 | ||||
| 			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'; | ||||
| 			COMMENT ON COLUMN actors.penis_length IS E'@omit read,update,create,delete,all,many'; | ||||
| 			COMMENT ON COLUMN actors.penis_girth IS E'@omit read,update,create,delete,all,many'; | ||||
| 
 | ||||
| 			COMMENT ON FUNCTION actors_tags IS E'@sortable'; | ||||
| 			COMMENT ON FUNCTION actors_channels IS E'@sortable'; | ||||
| 			COMMENT ON FUNCTION actors_actors IS E'@sortable'; | ||||
| 			COMMENT ON FUNCTION actors_scenes IS E'@sortable'; | ||||
| 			COMMENT ON FUNCTION tags_scenes IS E'@sortable'; | ||||
| 
 | ||||
| 			COMMENT ON FUNCTION search_releases IS E'@sortable'; | ||||
| 			COMMENT ON FUNCTION search_entities IS E'@sortable'; | ||||
| 			COMMENT ON FUNCTION search_actors IS E'@sortable'; | ||||
| 			COMMENT ON FUNCTION search_movies IS E'@sortable'; | ||||
| 			COMMENT ON FUNCTION search_tags IS E'@sortable'; | ||||
| 		`);
 | ||||
| 	}); | ||||
| 
 | ||||
| exports.down = (knex) => { // eslint-disable-line arrow-body-style
 | ||||
|  | @ -1776,8 +2097,17 @@ exports.down = (knex) => { // eslint-disable-line arrow-body-style | |||
| 		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 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_photos CASCADE; | ||||
| 		DROP TABLE IF EXISTS series_search CASCADE; | ||||
| 
 | ||||
| 		DROP TABLE IF EXISTS clips_tags CASCADE; | ||||
| 		DROP TABLE IF EXISTS clips_posters CASCADE; | ||||
| 		DROP TABLE IF EXISTS clips_photos CASCADE; | ||||
|  | @ -1789,6 +2119,7 @@ exports.down = (knex) => { // eslint-disable-line arrow-body-style | |||
| 		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; | ||||
|  | @ -1812,6 +2143,7 @@ exports.down = (knex) => { // eslint-disable-line arrow-body-style | |||
| 		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; | ||||
|  | @ -1853,6 +2185,9 @@ exports.down = (knex) => { // eslint-disable-line arrow-body-style | |||
| 		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; | ||||
|  | @ -1860,7 +2195,11 @@ exports.down = (knex) => { // eslint-disable-line arrow-body-style | |||
| 
 | ||||
| 		DROP FUNCTION IF EXISTS movies_actors; | ||||
| 		DROP FUNCTION IF EXISTS movies_tags; | ||||
| 		DROP FUNCTION IF EXISTS movies_photos; | ||||
| 		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; | ||||
|  |  | |||
|  | @ -1,29 +0,0 @@ | |||
| exports.up = async (knex) => knex.raw(` | ||||
| 	CREATE FUNCTION entities_scenes(entity entities) RETURNS SETOF releases AS $$ | ||||
| 		WITH RECURSIVE children AS ( | ||||
| 			SELECT entities.id | ||||
| 				FROM entities | ||||
| 				WHERE entities.id = entity.id | ||||
| 
 | ||||
| 				UNION ALL | ||||
| 
 | ||||
| 				SELECT entities.id | ||||
| 				FROM entities | ||||
| 				INNER JOIN children ON children.id = entities.parent_id | ||||
| 		) | ||||
| 
 | ||||
| 		SELECT releases FROM releases | ||||
| 		INNER JOIN children ON children.id = releases.entity_id | ||||
| 
 | ||||
| 		UNION | ||||
| 
 | ||||
| 		SELECT releases FROM releases | ||||
| 		INNER JOIN children ON children.id = releases.studio_id; | ||||
| 	$$ LANGUAGE SQL STABLE; | ||||
| 
 | ||||
| 	COMMENT ON FUNCTION entities_scenes IS E'@sortable'; | ||||
| `);
 | ||||
| 
 | ||||
| exports.down = async (knex) => knex.raw(` | ||||
| 	DROP FUNCTION IF EXISTS entities_scenes; | ||||
| `);
 | ||||
|  | @ -1,15 +0,0 @@ | |||
| exports.up = async (knex) => Promise.resolve() | ||||
| 	.then(() => knex.schema.alterTable('releases_tags', (table) => { | ||||
| 		table.index('release_id'); | ||||
| 	})) | ||||
| 	.then(() => knex.schema.alterTable('movies_scenes', (table) => { | ||||
| 		table.index('scene_id'); | ||||
| 	})); | ||||
| 
 | ||||
| exports.down = async (knex) => Promise.resolve() | ||||
| 	.then(() => knex.schema.alterTable('releases_tags', (table) => { | ||||
| 		table.dropIndex('release_id'); | ||||
| 	})) | ||||
| 	.then(() => knex.schema.alterTable('movies_scenes', (table) => { | ||||
| 		table.dropIndex('scene_id'); | ||||
| 	})); | ||||
|  | @ -1,11 +0,0 @@ | |||
| exports.up = async (knex) => knex.raw(` | ||||
| 	CREATE OR REPLACE FUNCTION entities_scene_total(entity entities) RETURNS bigint AS $$ | ||||
| 		SELECT COUNT(id) | ||||
| 		FROM releases | ||||
| 		WHERE releases.entity_id = entity.id; | ||||
| 	$$ LANGUAGE SQL STABLE; | ||||
| `);
 | ||||
| 
 | ||||
| exports.down = async (knex) => knex.raw(` | ||||
| 	DROP FUNCTION IF EXISTS entities_scene_total; | ||||
| `);
 | ||||
|  | @ -1,23 +0,0 @@ | |||
| exports.up = async (knex) => knex.raw(` | ||||
| 	CREATE FUNCTION entities_scene_tags(entity entities, selectable_tags text[]) RETURNS SETOF tags AS $$ | ||||
| 		SELECT tags.* | ||||
| 		FROM releases | ||||
| 		LEFT JOIN | ||||
| 			releases_tags ON releases_tags.release_id = releases.id | ||||
| 		LEFT JOIN | ||||
| 			tags ON tags.id = releases_tags.tag_id | ||||
| 		WHERE | ||||
| 			releases.entity_id = entity.id | ||||
| 		AND | ||||
| 			CASE WHEN array_length(selectable_tags, 1) IS NOT NULL | ||||
| 			THEN tags.slug = ANY(selectable_tags) | ||||
| 			ELSE true | ||||
| 			END | ||||
| 		GROUP BY tags.id | ||||
| 		ORDER BY tags.name; | ||||
| 	$$ LANGUAGE SQL STABLE; | ||||
| `);
 | ||||
| 
 | ||||
| exports.down = async (knex) => knex.raw(` | ||||
| 	DROP FUNCTION IF EXISTS entities_scene_tags; | ||||
| `);
 | ||||
|  | @ -1,215 +0,0 @@ | |||
| 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'); | ||||
| 	})) | ||||
| 	.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() | ||||
| 	.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; | ||||
| 	`));
 | ||||
|  | @ -1,49 +0,0 @@ | |||
| const config = require('config'); | ||||
| 
 | ||||
| exports.up = async (knex) => Promise.resolve() | ||||
| 	.then(() => knex.raw(` | ||||
| 		ALTER FUNCTION movies_photos(movie movies) RENAME TO movies_scenes_photos; | ||||
| 		ALTER FUNCTION series_photos(serie series) RENAME TO series_scenes_photos; | ||||
| 	`))
 | ||||
| 	.then(() => knex.schema.createTable('movies_photos', (table) => { | ||||
| 		table.integer('movie_id', 16) | ||||
| 			.notNullable() | ||||
| 			.references('id') | ||||
| 			.inTable('movies') | ||||
| 			.onDelete('cascade'); | ||||
| 
 | ||||
| 		table.text('media_id', 21) | ||||
| 			.notNullable() | ||||
| 			.references('id') | ||||
| 			.inTable('media'); | ||||
| 
 | ||||
| 		table.unique(['movie_id', 'media_id']); | ||||
| 	})) | ||||
| 	.then(() => knex.schema.createTable('series_photos', (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.raw(` | ||||
| 		GRANT ALL ON ALL TABLES IN SCHEMA public TO :visitor; | ||||
| 		GRANT USAGE, SELECT ON ALL SEQUENCES IN SCHEMA public TO :visitor; | ||||
| 	`, {
 | ||||
| 		visitor: knex.raw(config.database.query.user), | ||||
| 	})); | ||||
| 
 | ||||
| exports.down = async (knex) => knex.raw(` | ||||
| 	DROP TABLE IF EXISTS movies_photos CASCADE; | ||||
| 	DROP TABLE IF EXISTS series_photos CASCADE; | ||||
| 
 | ||||
| 	ALTER FUNCTION movies_scenes_photos(movie movies) RENAME TO movies_photos; | ||||
| 	ALTER FUNCTION series_scenes_photos(serie series) RENAME TO series_photos; | ||||
| `);
 | ||||
|  | @ -1,7 +0,0 @@ | |||
| exports.up = async (knex) => knex.schema.alterTable('releases', (table) => { | ||||
| 	table.specificType('qualities', 'text[]'); | ||||
| }); | ||||
| 
 | ||||
| exports.down = async (knex) => knex.schema.alterTable('releases', (table) => { | ||||
| 	table.dropColumn('qualities'); | ||||
| }); | ||||
|  | @ -1,7 +0,0 @@ | |||
| exports.up = async (knex) => knex.schema.alterTable('users', (table) => { | ||||
| 	table.datetime('last_login'); | ||||
| }); | ||||
| 
 | ||||
| exports.down = async (knex) => knex.schema.alterTable('users', (table) => { | ||||
| 	table.dropColumn('last_login'); | ||||
| }); | ||||
|  | @ -1,58 +0,0 @@ | |||
| exports.up = async (knex) => Promise.resolve() | ||||
| 	.then(() => knex.schema.createTable('random_campaign', (table) => { | ||||
| 		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'); | ||||
| 	})) | ||||
| 	.then(() => knex.raw(` | ||||
| 		ALTER TABLE banners ADD COLUMN ratio numeric GENERATED ALWAYS AS (ROUND(width::decimal/ height::decimal, 2)) STORED; | ||||
| 	`))
 | ||||
| 	.then(() => knex.raw(` | ||||
| 		DROP FUNCTION IF EXISTS get_random_campaign; | ||||
| 		DROP FUNCTION IF EXISTS banners_ratio; | ||||
| 
 | ||||
| 		CREATE FUNCTION get_random_campaign(min_ratio decimal default 0, max_ratio decimal default 1000.0) RETURNS random_campaign AS $$ | ||||
| 			SELECT * FROM ( | ||||
| 				SELECT DISTINCT ON (CASE WHEN parent_id IS NOT NULL THEN parent_id ELSE entity_id END) | ||||
| 					banner_id, url, entity_id, affiliate_id, parent_id | ||||
| 				FROM ( | ||||
| 					SELECT | ||||
| 						campaigns.*, entities.parent_id as parent_id | ||||
| 					FROM campaigns | ||||
| 					LEFT JOIN entities ON entities.id = campaigns.entity_id | ||||
| 					LEFT JOIN banners ON banners.id = campaigns.banner_id | ||||
| 					WHERE banner_id IS NOT NULL | ||||
| 					AND ratio >= min_ratio | ||||
| 					AND ratio <= max_ratio | ||||
| 					ORDER BY RANDOM() | ||||
| 				) random_campaigns | ||||
| 			) random_banners | ||||
| 			ORDER BY RANDOM() | ||||
| 			LIMIT 1; | ||||
| 		$$ LANGUAGE SQL STABLE; | ||||
| 	`));
 | ||||
| 
 | ||||
| exports.down = async (knex) => knex.raw(` | ||||
| 	DROP FUNCTION IF EXISTS get_random_campaign; | ||||
| 	DROP TABLE IF EXISTS random_campaign; | ||||
| 
 | ||||
| 	ALTER TABLE banners DROP COLUMN ratio; | ||||
| 
 | ||||
| 	CREATE FUNCTION banners_ratio(banner banners) RETURNS numeric AS $$ | ||||
| 		SELECT ROUND(banner.width::decimal / banner.height::decimal, 2); | ||||
| 	$$ LANGUAGE SQL STABLE; | ||||
| `);
 | ||||
|  | @ -1,7 +0,0 @@ | |||
| exports.up = async (knex) => knex.schema.alterTable('entities', (table) => { | ||||
| 	table.boolean('showcased'); | ||||
| }); | ||||
| 
 | ||||
| exports.down = async (knex) => knex.schema.alterTable('entities', (table) => { | ||||
| 	table.dropColumn('showcased'); | ||||
| }); | ||||
|  | @ -1,22 +0,0 @@ | |||
| const config = require('config'); | ||||
| 
 | ||||
| exports.up = async (knex) => knex.raw(` | ||||
|     CREATE 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 = entities.parent_id | ||||
| 		WHERE (studios.showcased = false) | ||||
| 		OR (channel.showcased = false AND studios.showcased IS NOT true) | ||||
| 		OR (network.showcased = false AND channel.showcased IS NOT true AND studios.showcased IS NOT true) | ||||
|     ); | ||||
| 
 | ||||
|     COMMENT ON VIEW releases_not_showcased IS E'@foreignKey (release_id) references releases (id)'; | ||||
|     GRANT SELECT ON releases_not_showcased TO :visitor; | ||||
| `, {
 | ||||
| 	visitor: knex.raw(config.database.query.user), | ||||
| }); | ||||
| 
 | ||||
| exports.down = async (knex) => knex.raw(` | ||||
|     DROP VIEW IF EXISTS releases_not_showcased; | ||||
| `);
 | ||||
|  | @ -1,19 +0,0 @@ | |||
| exports.up = async (knex) => { | ||||
| 	await knex.schema.alterTable('stashes', (table) => { | ||||
| 		table.unique(['user_id', 'slug']); | ||||
| 	}); | ||||
| 
 | ||||
| 	await knex.raw(` | ||||
| 		CREATE UNIQUE INDEX unique_primary ON stashes (user_id, "primary") WHERE ("primary" = TRUE); | ||||
| 	`);
 | ||||
| }; | ||||
| 
 | ||||
| exports.down = async (knex) => { | ||||
| 	await knex.schema.alterTable('stashes', (table) => { | ||||
| 		table.dropUnique(['user_id', 'slug']); | ||||
| 	}); | ||||
| 
 | ||||
| 	await knex.raw(` | ||||
| 		DROP INDEX unique_primary; | ||||
| 	`);
 | ||||
| }; | ||||
|  | @ -1,7 +0,0 @@ | |||
| exports.up = async (knex) => { | ||||
| 	await knex.raw('CREATE INDEX releases_tag_index ON releases_tags(tag_id);'); | ||||
| }; | ||||
| 
 | ||||
| exports.down = async (knex) => { | ||||
| 	await knex.raw('DROP INDEX releases_tag_index;'); | ||||
| }; | ||||
|  | @ -1,38 +0,0 @@ | |||
| exports.up = async (knex) => { | ||||
| 	await knex.raw(` | ||||
| 		CREATE OR REPLACE FUNCTION curate_search_query(query text) RETURNS tsquery AS $$ | ||||
| 			SELECT to_tsquery('english', array_to_string(array(SELECT * FROM regexp_matches(query, '[A-Za-zÀ-ÖØ-öø-ÿ0-9]+', 'g')), '|')); | ||||
| 		$$ LANGUAGE SQL STABLE; | ||||
| 
 | ||||
| 		CREATE OR REPLACE FUNCTION search_releases(query text) RETURNS SETOF releases_search_results AS $$ | ||||
| 			SELECT results.release_id, ts_rank(results.document::tsvector, curate_search_query(query)) as rank | ||||
| 			FROM ( | ||||
| 				SELECT releases_search.release_id, document | ||||
| 				FROM releases_search | ||||
| 				WHERE document::tsvector @@ curate_search_query(query) | ||||
| 			) AS results | ||||
| 			ORDER BY rank DESC; | ||||
| 		$$ LANGUAGE SQL STABLE; | ||||
| 
 | ||||
| 		COMMENT ON FUNCTION search_releases IS E'@sortable'; | ||||
| 	`);
 | ||||
| }; | ||||
| 
 | ||||
| exports.down = async (knex) => { | ||||
| 	await knex.raw(` | ||||
| 		CREATE OR REPLACE FUNCTION search_releases(query text) RETURNS SETOF releases_search_results AS $$ | ||||
| 			SELECT releases.id, ranks.rank FROM ( | ||||
| 				SELECT | ||||
| 					releases_search.release_id, | ||||
| 					ts_rank(releases_search.document, to_tsquery('english', array_to_string(array(SELECT * FROM regexp_matches(query, '[A-Za-zÀ-ÖØ-öø-ÿ0-9]+', 'g')), '|'))) AS rank | ||||
| 				FROM releases_search | ||||
| 				) ranks | ||||
| 			LEFT JOIN releases ON releases.id = ranks.release_id | ||||
| 			WHERE ranks.rank > 0 | ||||
| 			ORDER BY ranks.rank DESC; | ||||
| 		$$ LANGUAGE SQL STABLE; | ||||
| 
 | ||||
| 		DROP FUNCTION curate_search_query; | ||||
| 		COMMENT ON FUNCTION search_releases IS E'@sortable'; | ||||
| 	`);
 | ||||
| }; | ||||
|  | @ -1,25 +0,0 @@ | |||
| exports.up = async (knex) => knex.raw(` | ||||
| 	CREATE MATERIALIZED VIEW entities_stats | ||||
| 	AS | ||||
| 		WITH RECURSIVE relations AS ( | ||||
| 			SELECT entities.id, entities.parent_id, count(releases.id) AS releases_count, count(releases.id) AS total_count | ||||
| 			FROM entities | ||||
| 			LEFT JOIN releases ON releases.entity_id = entities.id | ||||
| 			GROUP BY entities.id | ||||
| 
 | ||||
| 			UNION ALL | ||||
| 
 | ||||
| 			SELECT entities.id AS entity_id, count(releases.id) AS releases_count, count(releases.id) + relations.total_count AS total_count | ||||
| 			FROM entities | ||||
| 			INNER JOIN relations ON relations.id = entities.parent_id | ||||
| 			LEFT JOIN releases ON releases.entity_id = entities.id | ||||
| 			GROUP BY entities.id | ||||
| 		) | ||||
| 
 | ||||
| 		SELECT relations.id AS entity_id, relations.releases_count | ||||
| 		FROM relations; | ||||
| `);
 | ||||
| 
 | ||||
| exports.down = async (knex) => knex.raw(` | ||||
| 	DROP MATERIALIZED VIEW entities_stats; | ||||
| `);
 | ||||
										
											Binary file not shown.
										
									
								
							| After Width: | Height: | Size: 84 KiB | 
										
											Binary file not shown.
										
									
								
							| After Width: | Height: | Size: 1.4 MiB | 
										
											Binary file not shown.
										
									
								
							| After Width: | Height: | Size: 58 KiB | 
|  | @ -269,6 +269,8 @@ async function updateSceneSearch(releaseIds) { | |||
| 	if (documents.rows?.length > 0) { | ||||
| 		await bulkInsert('releases_search', documents.rows, ['release_id']); | ||||
| 	} | ||||
| 
 | ||||
| 	await knex.raw('REFRESH MATERIALIZED VIEW CONCURRENTLY releases_not_showcased;'); | ||||
| } | ||||
| 
 | ||||
| async function storeChapters(releases) { | ||||
|  |  | |||
		Loading…
	
		Reference in New Issue