using System; using System.Collections.Generic; using System.IO; using System.Linq; using Dapper; using NzbDrone.Core.Datastore; using NzbDrone.Core.MediaFiles; using NzbDrone.Core.Messaging.Events; using NzbDrone.Core.Movies.AlternativeTitles; using NzbDrone.Core.Movies.Translations; using NzbDrone.Core.Profiles; using NzbDrone.Core.Qualities; namespace NzbDrone.Core.Movies { public interface IMovieRepository : IBasicRepository { bool MoviePathExists(string path); List FindByTitles(List titles); Movie FindByImdbId(string imdbid); Movie FindByTmdbId(int tmdbid); List FindByTmdbId(List tmdbids); List MoviesBetweenDates(DateTime start, DateTime end, bool includeUnmonitored); PagingSpec MoviesWithoutFiles(PagingSpec pagingSpec); List GetMoviesByFileId(int fileId); List GetMoviesByCollectionTmdbId(int collectionId); void SetFileId(int fileId, int movieId); PagingSpec MoviesWhereCutoffUnmet(PagingSpec pagingSpec, List qualitiesBelowCutoff); Movie FindByPath(string path); Dictionary AllMoviePaths(); List AllMovieTmdbIds(); Dictionary> AllMovieTags(); List GetRecommendations(); bool ExistsByMetadataId(int metadataId); } public class MovieRepository : BasicRepository, IMovieRepository { private readonly IProfileRepository _profileRepository; private readonly IAlternativeTitleRepository _alternativeTitleRepository; public MovieRepository(IMainDatabase database, IProfileRepository profileRepository, IAlternativeTitleRepository alternativeTitleRepository, IEventAggregator eventAggregator) : base(database, eventAggregator) { _profileRepository = profileRepository; _alternativeTitleRepository = alternativeTitleRepository; } protected override SqlBuilder Builder() => new SqlBuilder(_database.DatabaseType) .Join((m, p) => m.ProfileId == p.Id) .Join((m, p) => m.MovieMetadataId == p.Id) .LeftJoin((m, f) => m.Id == f.MovieId) .LeftJoin((mm, t) => mm.Id == t.MovieMetadataId); private Movie Map(Dictionary dict, Movie movie, Profile profile, MovieFile movieFile, AlternativeTitle altTitle = null, MovieTranslation translation = null) { Movie movieEntry; if (!dict.TryGetValue(movie.Id, out movieEntry)) { movieEntry = movie; movieEntry.Profile = profile; movieEntry.MovieFile = movieFile; dict.Add(movieEntry.Id, movieEntry); } if (altTitle != null) { movieEntry.MovieMetadata.Value.AlternativeTitles.Add(altTitle); } if (translation != null) { movieEntry.MovieMetadata.Value.Translations.Add(translation); } return movieEntry; } protected override List Query(SqlBuilder builder) { var movieDictionary = new Dictionary(); _ = _database.QueryJoined( builder, (movie, profile, file, altTitle) => Map(movieDictionary, movie, profile, file, altTitle)); return movieDictionary.Values.ToList(); } public override IEnumerable All() { // the skips the join on profile and alternative title and populates manually // to avoid repeatedly deserializing the same profile / movie var builder = new SqlBuilder(_database.DatabaseType) .LeftJoin((m, f) => m.MovieFileId == f.Id) .LeftJoin((m, f) => m.MovieMetadataId == f.Id); var profiles = _profileRepository.All().ToDictionary(x => x.Id); var titles = _alternativeTitleRepository.All() .GroupBy(x => x.MovieMetadataId) .ToDictionary(x => x.Key, y => y.ToList()); return _database.QueryJoined( builder, (movie, file, metadata) => { movie.MovieFile = file; movie.MovieMetadata = metadata; movie.Profile = profiles[movie.ProfileId]; if (titles.TryGetValue(movie.MovieMetadataId, out var altTitles)) { movie.MovieMetadata.Value.AlternativeTitles = altTitles; } return movie; }); } public bool MoviePathExists(string path) { return Query(x => x.Path == path).Any(); } public List FindByTitles(List titles) { var distinct = titles.Distinct().ToList(); var results = new List(); results.AddRange(FindByMovieTitles(distinct)); results.AddRange(FindByAltTitles(distinct)); results.AddRange(FindByTransTitles(distinct)); return results.DistinctBy(x => x.Id).ToList(); } // This is a bit of a hack, but if you try to combine / rationalise these then // SQLite makes a mess of the query plan and ends up doing a table scan private List FindByMovieTitles(List titles) { var movieDictionary = new Dictionary(); var builder = new SqlBuilder(_database.DatabaseType) .Join((m, p) => m.ProfileId == p.Id) .Join((m, p) => m.MovieMetadataId == p.Id) .LeftJoin((m, f) => m.Id == f.MovieId) .Where(x => titles.Contains(x.CleanTitle) || titles.Contains(x.CleanOriginalTitle)); _ = _database.QueryJoined( builder, (movie, profile, file) => Map(movieDictionary, movie, profile, file)); return movieDictionary.Values.ToList(); } private List FindByAltTitles(List titles) { var movieDictionary = new Dictionary(); var builder = new SqlBuilder(_database.DatabaseType) .Join((t, mm) => t.MovieMetadataId == mm.Id) .Join((mm, m) => mm.Id == m.MovieMetadataId) .Join((m, p) => m.ProfileId == p.Id) .LeftJoin((m, f) => m.Id == f.MovieId) .Where(x => titles.Contains(x.CleanTitle)); _ = _database.QueryJoined( builder, (altTitle, profile, movie, file) => { _ = Map(movieDictionary, movie, profile, file, altTitle); return null; }); return movieDictionary.Values.ToList(); } private List FindByTransTitles(List titles) { var movieDictionary = new Dictionary(); var builder = new SqlBuilder(_database.DatabaseType) .Join((t, mm) => t.MovieMetadataId == mm.Id) .Join((mm, m) => mm.Id == m.MovieMetadataId) .Join((m, p) => m.ProfileId == p.Id) .LeftJoin((m, f) => m.Id == f.MovieId) .Where(x => titles.Contains(x.CleanTitle)); _ = _database.QueryJoined( builder, (trans, profile, movie, file) => { _ = Map(movieDictionary, movie, profile, file, null, trans); return null; }); return movieDictionary.Values.ToList(); } public Movie FindByImdbId(string imdbid) { var imdbIdWithPrefix = Parser.Parser.NormalizeImdbId(imdbid); return imdbIdWithPrefix == null ? null : Query(x => x.MovieMetadata.Value.ImdbId == imdbIdWithPrefix).FirstOrDefault(); } public Movie FindByTmdbId(int tmdbid) { return Query(x => x.MovieMetadata.Value.TmdbId == tmdbid).FirstOrDefault(); } public List FindByTmdbId(List tmdbids) { return Query(x => tmdbids.Contains(x.TmdbId)); } public List GetMoviesByFileId(int fileId) { return Query(x => x.MovieFileId == fileId); } public List GetMoviesByCollectionTmdbId(int collectionId) { return Query(x => x.MovieMetadata.Value.CollectionTmdbId == collectionId); } public void SetFileId(int fileId, int movieId) { SetFields(new Movie { Id = movieId, MovieFileId = fileId }, movie => movie.MovieFileId); } public List MoviesBetweenDates(DateTime start, DateTime end, bool includeUnmonitored) { var builder = Builder() .Where(m => (m.MovieMetadata.Value.InCinemas >= start && m.MovieMetadata.Value.InCinemas <= end) || (m.MovieMetadata.Value.PhysicalRelease >= start && m.MovieMetadata.Value.PhysicalRelease <= end) || (m.MovieMetadata.Value.DigitalRelease >= start && m.MovieMetadata.Value.DigitalRelease <= end)); if (!includeUnmonitored) { builder.Where(x => x.Monitored == true); } return Query(builder); } public SqlBuilder MoviesWithoutFilesBuilder() => Builder() .Where(x => x.MovieFileId == 0); public PagingSpec MoviesWithoutFiles(PagingSpec pagingSpec) { pagingSpec.Records = GetPagedRecords(MoviesWithoutFilesBuilder(), pagingSpec, PagedQuery); pagingSpec.TotalRecords = GetPagedRecordCount(MoviesWithoutFilesBuilder().SelectCount(), pagingSpec); return pagingSpec; } public SqlBuilder MoviesWhereCutoffUnmetBuilder(List qualitiesBelowCutoff) => Builder() .Where(x => x.MovieFileId != 0) .Where(BuildQualityCutoffWhereClause(qualitiesBelowCutoff)); public PagingSpec MoviesWhereCutoffUnmet(PagingSpec pagingSpec, List qualitiesBelowCutoff) { pagingSpec.Records = GetPagedRecords(MoviesWhereCutoffUnmetBuilder(qualitiesBelowCutoff), pagingSpec, PagedQuery); pagingSpec.TotalRecords = GetPagedRecordCount(MoviesWhereCutoffUnmetBuilder(qualitiesBelowCutoff).SelectCount(), pagingSpec); return pagingSpec; } private string BuildQualityCutoffWhereClause(List qualitiesBelowCutoff) { var clauses = new List(); foreach (var profile in qualitiesBelowCutoff) { foreach (var belowCutoff in profile.QualityIds) { clauses.Add(string.Format($"(\"{_table}\".\"ProfileId\" = {profile.ProfileId} AND \"MovieFiles\".\"Quality\" LIKE '%_quality_: {belowCutoff},%')")); } } return string.Format("({0})", string.Join(" OR ", clauses)); } public Movie FindByPath(string path) { return Query(x => x.Path == path).FirstOrDefault(); } public Dictionary AllMoviePaths() { using (var conn = _database.OpenConnection()) { var strSql = "SELECT \"Id\" AS \"Key\", \"Path\" AS \"Value\" FROM \"Movies\""; return conn.Query>(strSql).ToDictionary(x => x.Key, x => x.Value); } } public List AllMovieTmdbIds() { using (var conn = _database.OpenConnection()) { return conn.Query("SELECT \"TmdbId\" FROM \"MovieMetadata\" JOIN \"Movies\" ON (\"Movies\".\"MovieMetadataId\" = \"MovieMetadata\".\"Id\")").ToList(); } } public Dictionary> AllMovieTags() { using (var conn = _database.OpenConnection()) { var strSql = "SELECT \"Id\" AS \"Key\", \"Tags\" AS \"Value\" FROM \"Movies\" WHERE \"Tags\" IS NOT NULL"; return conn.Query>>(strSql).ToDictionary(x => x.Key, x => x.Value); } } public List GetRecommendations() { var recommendations = new List(); if (_database.Version < new Version("3.9.0")) { return recommendations; } using (var conn = _database.OpenConnection()) { if (_database.DatabaseType == DatabaseType.PostgreSQL) { recommendations = conn.Query(@"SELECT DISTINCT ""Rec"" FROM ( SELECT DISTINCT ""Rec"" FROM ( SELECT DISTINCT CAST(""value"" AS INT) AS ""Rec"" FROM ""MovieMetadata"", json_array_elements_text((""MovieMetadata"".""Recommendations"")::json) WHERE CAST(""value"" AS INT) NOT IN (SELECT ""TmdbId"" FROM ""MovieMetadata"" union SELECT ""TmdbId"" from ""ImportExclusions"" as sub1) LIMIT 10 ) as sub2 UNION SELECT ""Rec"" FROM ( SELECT CAST(""value"" AS INT) AS ""Rec"" FROM ""MovieMetadata"", json_array_elements_text((""MovieMetadata"".""Recommendations"")::json) WHERE CAST(""value"" AS INT) NOT IN (SELECT ""TmdbId"" FROM ""MovieMetadata"" union SELECT ""TmdbId"" from ""ImportExclusions"" as sub2) GROUP BY ""Rec"" ORDER BY count(*) DESC LIMIT 120 ) as sub4 ) as sub5 LIMIT 100;").ToList(); } else { recommendations = conn.Query(@"SELECT DISTINCT ""Rec"" FROM ( SELECT DISTINCT ""Rec"" FROM ( SELECT DISTINCT CAST(""j"".""value"" AS INT) AS ""Rec"" FROM ""MovieMetadata"" CROSS JOIN json_each(""MovieMetadata"".""Recommendations"") AS ""j"" WHERE ""Rec"" NOT IN (SELECT ""TmdbId"" FROM ""MovieMetadata"" union SELECT ""TmdbId"" from ""ImportExclusions"") LIMIT 10 ) UNION SELECT ""Rec"" FROM ( SELECT CAST(""j"".""value"" AS INT) AS ""Rec"" FROM ""MovieMetadata"" CROSS JOIN json_each(""MovieMetadata"".""Recommendations"") AS ""j"" WHERE ""Rec"" NOT IN (SELECT ""TmdbId"" FROM ""MovieMetadata"" union SELECT ""TmdbId"" from ""ImportExclusions"") GROUP BY ""Rec"" ORDER BY count(*) DESC LIMIT 120 ) ) LIMIT 100;").ToList(); } } return recommendations; } public bool ExistsByMetadataId(int metadataId) { var movies = Query(x => x.MovieMetadataId == metadataId); return movies.Any(); } } }