From 31870fe046f37fcde45ed2a77de6a850b69d8a40 Mon Sep 17 00:00:00 2001 From: chme Date: Sun, 21 Dec 2014 20:41:44 +0100 Subject: [PATCH 01/17] improve selects for files table by removing the join to the groups table --- src/artwork.c | 11 +- src/db.c | 311 +++++++++++++++++++++++++++++++--------------- src/db.h | 7 -- src/filescanner.c | 15 --- 4 files changed, 215 insertions(+), 129 deletions(-) diff --git a/src/artwork.c b/src/artwork.c index 2f87f122..bf10079b 100644 --- a/src/artwork.c +++ b/src/artwork.c @@ -1153,19 +1153,10 @@ artwork_get_group(int id, int max_w, int max_h, struct evbuffer *evbuf) DPRINTF(E_DBG, L_ART, "Artwork request for group %d\n", id); - /* - * Get the persistent id for the given group id - */ - ret = db_group_persistentid_byid(id, &persistentid); - if (ret < 0) { - DPRINTF(E_LOG, L_ART, "Error fetching persistent id for group id %d\n", id); - return -1; - } - /* * Load artwork image for the persistent id */ - ret = artwork_get_group_persistentid(persistentid, max_w, max_h, evbuf); + ret = artwork_get_group_persistentid(id, max_w, max_h, evbuf); if (ret < 0) DPRINTF(E_DBG, L_ART, "No artwork found for group id %d\n", id); diff --git a/src/db.c b/src/db.c index 75815d19..12fe8d16 100644 --- a/src/db.c +++ b/src/db.c @@ -742,12 +742,14 @@ db_purge_cruft(time_t ref) char *errmsg; int i; int ret; - char *queries[3] = { NULL, NULL, NULL }; - char *queries_tmpl[3] = + char *queries[5] = { NULL, NULL, NULL, NULL, NULL }; + char *queries_tmpl[5] = { "DELETE FROM playlistitems WHERE playlistid IN (SELECT id FROM playlists p WHERE p.type <> 1 AND p.db_timestamp < %" PRIi64 ");", "DELETE FROM playlists WHERE type <> 1 AND db_timestamp < %" PRIi64 ";", - "DELETE FROM files WHERE db_timestamp < %" PRIi64 ";" + "DELETE FROM files WHERE db_timestamp < %" PRIi64 ";", + "DELETE FROM groups WHERE type = 1 AND id NOT IN (SELECT songalbumid FROM files);", + "DELETE FROM groups WHERE type = 2 AND id NOT IN (SELECT songartistid FROM files);" }; if (sizeof(queries) != sizeof(queries_tmpl)) @@ -758,7 +760,11 @@ db_purge_cruft(time_t ref) for (i = 0; i < (sizeof(queries_tmpl) / sizeof(queries_tmpl[0])); i++) { - queries[i] = sqlite3_mprintf(queries_tmpl[i], (int64_t)ref); + if (i < 3) + queries[i] = sqlite3_mprintf(queries_tmpl[i], (int64_t)ref); + else + queries[i] = sqlite3_mprintf(queries_tmpl[i]); + if (!queries[i]) { DPRINTF(E_LOG, L_DB, "Out of memory for query string\n"); @@ -1197,13 +1203,13 @@ db_build_query_group_albums(struct query_params *qp, char **q) sort = sort_clause[qp->sort]; if (idx && qp->filter) - query = sqlite3_mprintf("SELECT g.id, g.persistentid, f.album, f.album_sort, COUNT(f.id), 1, f.album_artist, f.songartistid FROM files f, groups g WHERE f.songalbumid = g.persistentid AND g.type = %d AND f.disabled = 0 AND %s GROUP BY f.album, g.name %s %s;", G_ALBUMS, qp->filter, sort, idx); + query = sqlite3_mprintf("SELECT f.songalbumid, f.songalbumid, f.album, f.album_sort, COUNT(f.id), 1, f.album_artist, f.songartistid FROM files f WHERE f.disabled = 0 AND %s GROUP BY f.songalbumid %s %s;", qp->filter, sort, idx); else if (idx) - query = sqlite3_mprintf("SELECT g.id, g.persistentid, f.album, f.album_sort, COUNT(f.id), 1, f.album_artist, f.songartistid FROM files f, groups g WHERE f.songalbumid = g.persistentid AND g.type = %d AND f.disabled = 0 GROUP BY f.album, g.name %s %s;", G_ALBUMS, sort, idx); + query = sqlite3_mprintf("SELECT f.songalbumid, f.songalbumid, f.album, f.album_sort, COUNT(f.id), 1, f.album_artist, f.songartistid FROM files f WHERE f.disabled = 0 GROUP BY f.songalbumid %s %s;", sort, idx); else if (qp->filter) - query = sqlite3_mprintf("SELECT g.id, g.persistentid, f.album, f.album_sort, COUNT(f.id), 1, f.album_artist, f.songartistid FROM files f, groups g WHERE f.songalbumid = g.persistentid AND g.type = %d AND f.disabled = 0 AND %s GROUP BY f.album, g.name %s;", G_ALBUMS, qp->filter, sort); + query = sqlite3_mprintf("SELECT f.songalbumid, f.songalbumid, f.album, f.album_sort, COUNT(f.id), 1, f.album_artist, f.songartistid FROM files f WHERE f.disabled = 0 AND %s GROUP BY f.songalbumid %s;", qp->filter, sort); else - query = sqlite3_mprintf("SELECT g.id, g.persistentid, f.album, f.album_sort, COUNT(f.id), 1, f.album_artist, f.songartistid FROM files f, groups g WHERE f.songalbumid = g.persistentid AND g.type = %d AND f.disabled = 0 GROUP BY f.album, g.name %s;", G_ALBUMS, sort); + query = sqlite3_mprintf("SELECT f.songalbumid, f.songalbumid, f.album, f.album_sort, COUNT(f.id), 1, f.album_artist, f.songartistid FROM files f WHERE f.disabled = 0 GROUP BY f.songalbumid %s;", sort); if (!query) { @@ -1236,13 +1242,13 @@ db_build_query_group_artists(struct query_params *qp, char **q) sort = sort_clause[qp->sort]; if (idx && qp->filter) - query = sqlite3_mprintf("SELECT g.id, g.persistentid, f.album_artist, f.album_artist_sort, COUNT(f.id), COUNT(DISTINCT f.songalbumid), f.album_artist, f.songartistid FROM files f, groups g WHERE f.songartistid = g.persistentid AND g.type = %d AND f.disabled = 0 AND %s GROUP BY f.album_artist, g.name %s %s;", G_ARTISTS, qp->filter, sort, idx); + query = sqlite3_mprintf("SELECT f.songartistid, f.songartistid, f.album_artist, f.album_artist_sort, COUNT(f.id), COUNT(DISTINCT f.songalbumid), f.album_artist, f.songartistid FROM files f WHERE f.disabled = 0 AND %s GROUP BY f.songartistid %s %s;", qp->filter, sort, idx); else if (idx) - query = sqlite3_mprintf("SELECT g.id, g.persistentid, f.album_artist, f.album_artist_sort, COUNT(f.id), COUNT(DISTINCT f.songalbumid), f.album_artist, f.songartistid FROM files f, groups g WHERE f.songartistid = g.persistentid AND g.type = %d AND f.disabled = 0 GROUP BY f.album_artist, g.name %s %s;", G_ARTISTS, sort, idx); + query = sqlite3_mprintf("SELECT f.songartistid, f.songartistid, f.album_artist, f.album_artist_sort, COUNT(f.id), COUNT(DISTINCT f.songalbumid), f.album_artist, f.songartistid FROM files f WHERE f.disabled = 0 GROUP BY f.songartistid %s %s;", sort, idx); else if (qp->filter) - query = sqlite3_mprintf("SELECT g.id, g.persistentid, f.album_artist, f.album_artist_sort, COUNT(f.id), COUNT(DISTINCT f.songalbumid), f.album_artist, f.songartistid FROM files f, groups g WHERE f.songartistid = g.persistentid AND g.type = %d AND f.disabled = 0 AND %s GROUP BY f.album_artist, g.name %s;", G_ARTISTS, qp->filter, sort); + query = sqlite3_mprintf("SELECT f.songartistid, f.songartistid, f.album_artist, f.album_artist_sort, COUNT(f.id), COUNT(DISTINCT f.songalbumid), f.album_artist, f.songartistid FROM files f WHERE f.disabled = 0 AND %s GROUP BY f.songartistid %s;", qp->filter, sort); else - query = sqlite3_mprintf("SELECT g.id, g.persistentid, f.album_artist, f.album_artist_sort, COUNT(f.id), COUNT(DISTINCT f.songalbumid), f.album_artist, f.songartistid FROM files f, groups g WHERE f.songartistid = g.persistentid AND g.type = %d AND f.disabled = 0 GROUP BY f.album_artist, g.name %s;", G_ARTISTS, sort); + query = sqlite3_mprintf("SELECT f.songartistid, f.songartistid, f.album_artist, f.album_artist_sort, COUNT(f.id), COUNT(DISTINCT f.songalbumid), f.album_artist, f.songartistid FROM files f WHERE f.disabled = 0 GROUP BY f.songartistid %s;", sort); if (!query) { @@ -2359,6 +2365,101 @@ db_file_fetch_byid(int id) #undef Q_TMPL } +static int +db_group_get_id(enum group_type type, const char *artist, const char *album, uint32_t *id) +{ +#define Q_TMPL "SELECT id FROM groups WHERE type = %d AND name = LOWER(TRIM(%Q)) || '==' || LOWER(TRIM(%Q));" + + sqlite3_stmt *stmt; + char *query; + int ret; + + // Select artist and album from groups + query = sqlite3_mprintf(Q_TMPL, type, artist, (album ? album : "")); + if (!query) + { + DPRINTF(E_LOG, L_DB, "Out of memory for query string\n"); + return -1; + } + + DPRINTF(E_DBG, L_DB, "Running query '%s'\n", query); + + ret = db_blocking_prepare_v2(query, strlen(query) + 1, &stmt, NULL); + if (ret != SQLITE_OK) + { + DPRINTF(E_LOG, L_DB, "Could not prepare statement: %s\n", sqlite3_errmsg(hdl)); + + sqlite3_free(query); + return -1; + } + + ret = db_blocking_step(stmt); + + if (ret == SQLITE_DONE) + { + DPRINTF(E_DBG, L_DB, "No results\n"); + sqlite3_finalize(stmt); + sqlite3_free(query); + + *id = 0; + return 0; + } + else if (ret == SQLITE_ROW) + { + *id = sqlite3_column_int(stmt, 0); + + sqlite3_finalize(stmt); + sqlite3_free(query); + return 0; + } + + DPRINTF(E_LOG, L_DB, "Could not step: %s\n", sqlite3_errmsg(hdl)); + sqlite3_finalize(stmt); + sqlite3_free(query); + return -1; + +#undef Q_TMPL +} + +static int +db_group_add(enum group_type type, const char *artist, const char *album, uint32_t *id) +{ +#define Q_TMPL "INSERT OR REPLACE INTO groups (type, name) VALUES (%d, LOWER(TRIM(%Q)) || '==' || LOWER(TRIM(%Q)));" + + char *query; + char *errmsg; + int ret; + + // Select artist and album from groups + query = sqlite3_mprintf(Q_TMPL, type, artist, (album ? album : "")); + if (!query) + { + DPRINTF(E_LOG, L_DB, "Out of memory for query string\n"); + return -1; + } + + DPRINTF(E_DBG, L_DB, "Running query '%s'\n", query); + + ret = db_exec(query, &errmsg); + if (ret != SQLITE_OK) + { + DPRINTF(E_LOG, L_DB, "Error '%s' while runnning '%s'\n", errmsg, query); + sqlite3_free(errmsg); + sqlite3_free(query); + *id = 0; + return -1; + } + + sqlite3_free(errmsg); + sqlite3_free(query); + + *id = sqlite3_last_insert_rowid(hdl); + + return 0; + +#undef Q_TMPL +} + int db_file_add(struct media_file_info *mfi) { @@ -2377,11 +2478,13 @@ db_file_add(struct media_file_info *mfi) " %Q, %" PRIi64 ", %" PRIi64 ", %" PRIi64 ", %" PRIi64 ", %d, %" PRIi64 "," \ " %Q, %d, %d, %d, %d, TRIM(%Q)," \ " %d, TRIM(%Q), TRIM(%Q), TRIM(%Q), %d, %d," \ - " daap_songalbumid(LOWER(TRIM(%Q)), ''), daap_songalbumid(LOWER(TRIM(%Q)), LOWER(TRIM(%Q))), " \ + " %" PRIi64 ", %" PRIi64 ", " \ " TRIM(%Q), TRIM(%Q), TRIM(%Q), TRIM(%Q), TRIM(%Q));" char *query; char *errmsg; + uint32_t albumid; + uint32_t artistid; int ret; @@ -2391,6 +2494,43 @@ db_file_add(struct media_file_info *mfi) return -1; } + // Select artist and album from groups + ret = db_group_get_id(G_ALBUMS, mfi->album_artist, mfi->album, &albumid); + if (ret < 0) + { + DPRINTF(E_LOG, L_DB, "Could not get albumid for artist '%s' album '%s'\n", mfi->album_artist, mfi->album); + return -1; + } + + if (albumid == 0) + { + ret = db_group_add(G_ALBUMS, mfi->album_artist, mfi->album, &albumid); + if (ret < 0) + { + DPRINTF(E_LOG, L_DB, "Could not add artist '%s' album '%s'\n", mfi->album_artist, mfi->album); + return -1; + } + } + + ret = db_group_get_id(G_ARTISTS, mfi->album_artist, NULL, &artistid); + if (ret < 0) + { + DPRINTF(E_LOG, L_DB, "Could not get artistid for artist '%s'\n", mfi->album_artist); + return -1; + } + + if (artistid == 0) + { + ret = db_group_add(G_ARTISTS, mfi->album_artist, NULL, &artistid); + if (ret < 0) + { + DPRINTF(E_LOG, L_DB, "Could not add artist '%s'\n", mfi->album_artist); + return -1; + } + } + + mfi->songalbumid = albumid; + mfi->songartistid = artistid; mfi->db_timestamp = (uint64_t)time(NULL); mfi->time_added = mfi->db_timestamp; @@ -2410,7 +2550,8 @@ db_file_add(struct media_file_info *mfi) mfi->contentrating, mfi->bits_per_sample, mfi->album_artist, mfi->media_kind, mfi->tv_series_name, mfi->tv_episode_num_str, mfi->tv_network_name, mfi->tv_episode_sort, mfi->tv_season_num, - mfi->album_artist, mfi->album_artist, mfi->album, mfi->title_sort, mfi->artist_sort, mfi->album_sort, + mfi->songartistid, mfi->songalbumid, + mfi->title_sort, mfi->artist_sort, mfi->album_sort, mfi->composer_sort, mfi->album_artist_sort); if (!query) @@ -2454,11 +2595,15 @@ db_file_update(struct media_file_info *mfi) " bits_per_sample = %d, album_artist = TRIM(%Q)," \ " media_kind = %d, tv_series_name = TRIM(%Q), tv_episode_num_str = TRIM(%Q)," \ " tv_network_name = TRIM(%Q), tv_episode_sort = %d, tv_season_num = %d," \ - " songartistid = daap_songalbumid(LOWER(TRIM(%Q)), ''), songalbumid = daap_songalbumid(LOWER(TRIM(%Q)), LOWER(TRIM(%Q)))," \ + " songartistid = %" PRIi64 ", songalbumid = %" PRIi64 "," \ " title_sort = TRIM(%Q), artist_sort = TRIM(%Q), album_sort = TRIM(%Q), composer_sort = TRIM(%Q), album_artist_sort = TRIM(%Q)" \ " WHERE id = %d;" + +// struct media_file_info *oldmfi; char *query; char *errmsg; + uint32_t albumid; + uint32_t artistid; int ret; if (mfi->id == 0) @@ -2467,6 +2612,56 @@ db_file_update(struct media_file_info *mfi) return -1; } + /* + oldmfi = db_file_fetch_byid(mfi->id); + + if (!oldmfi) + { + DPRINTF(E_WARN, L_DB, "File with id '%d' does not exist\n", mfi->id); + return -1; + } + + free_mfi(oldmfi, 0); + */ + + //TODO insert/update/delete groups + ret = db_group_get_id(G_ALBUMS, mfi->album_artist, mfi->album, &albumid); + if (ret < 0) + { + DPRINTF(E_LOG, L_DB, "Could not get albumid for artist '%s' album '%s'\n", mfi->album_artist, mfi->album); + return -1; + } + + if (albumid == 0) + { + ret = db_group_add(G_ALBUMS, mfi->album_artist, mfi->album, &albumid); + if (ret < 0) + { + DPRINTF(E_LOG, L_DB, "Could not add artist '%s' album '%s'\n", mfi->album_artist, mfi->album); + return -1; + } + } + + ret = db_group_get_id(G_ARTISTS, mfi->album_artist, NULL, &artistid); + if (ret < 0) + { + DPRINTF(E_LOG, L_DB, "Could not get artistid for artist '%s'\n", mfi->album_artist); + return -1; + } + + if (artistid == 0) + { + ret = db_group_add(G_ARTISTS, mfi->album_artist, NULL, &artistid); + if (ret < 0) + { + DPRINTF(E_LOG, L_DB, "Could not add artist '%s'\n", mfi->album_artist); + return -1; + } + } + + mfi->songalbumid = albumid; + mfi->songartistid = artistid; + mfi->db_timestamp = (uint64_t)time(NULL); if (mfi->time_modified == 0) @@ -2484,7 +2679,7 @@ db_file_update(struct media_file_info *mfi) mfi->bits_per_sample, mfi->album_artist, mfi->media_kind, mfi->tv_series_name, mfi->tv_episode_num_str, mfi->tv_network_name, mfi->tv_episode_sort, mfi->tv_season_num, - mfi->album_artist, mfi->album_artist, mfi->album, + mfi->songartistid, mfi->songalbumid, mfi->title_sort, mfi->artist_sort, mfi->album_sort, mfi->composer_sort, mfi->album_artist_sort, mfi->id); @@ -3109,16 +3304,11 @@ db_pl_enable_bycookie(uint32_t cookie, char *path) /* Groups */ -int -db_groups_clear(void) -{ - return db_query_run("DELETE FROM groups;", 0, 1); -} static enum group_type db_group_type_bypersistentid(int64_t persistentid) { -#define Q_TMPL "SELECT g.type FROM groups g WHERE g.persistentid = %" PRIi64 ";" +#define Q_TMPL "SELECT g.type FROM groups g WHERE g.id = %" PRIi64 ";" char *query; sqlite3_stmt *stmt; int ret; @@ -3170,61 +3360,6 @@ db_group_type_bypersistentid(int64_t persistentid) #undef Q_TMPL } -int -db_group_persistentid_byid(int id, int64_t *persistentid) -{ -#define Q_TMPL "SELECT g.persistentid FROM groups g WHERE g.id = %d;" - char *query; - sqlite3_stmt *stmt; - int ret; - - query = sqlite3_mprintf(Q_TMPL, id); - if (!query) - { - DPRINTF(E_LOG, L_DB, "Out of memory for query string\n"); - - return -1; - } - - DPRINTF(E_DBG, L_DB, "Running query '%s'\n", query); - - ret = db_blocking_prepare_v2(query, -1, &stmt, NULL); - if (ret != SQLITE_OK) - { - DPRINTF(E_LOG, L_DB, "Could not prepare statement: %s\n", sqlite3_errmsg(hdl)); - - sqlite3_free(query); - return -1; - } - - ret = db_blocking_step(stmt); - if (ret != SQLITE_ROW) - { - if (ret == SQLITE_DONE) - DPRINTF(E_DBG, L_DB, "No results\n"); - else - DPRINTF(E_LOG, L_DB, "Could not step: %s\n", sqlite3_errmsg(hdl)); - - sqlite3_finalize(stmt); - sqlite3_free(query); - return -1; - } - - *persistentid = sqlite3_column_int64(stmt, 0); - -#ifdef DB_PROFILE - while (db_blocking_step(stmt) == SQLITE_ROW) - ; /* EMPTY */ -#endif - - sqlite3_finalize(stmt); - sqlite3_free(query); - - return 0; - -#undef Q_TMPL -} - /* Remotes */ static int @@ -4303,8 +4438,7 @@ db_perthread_deinit(void) " id INTEGER PRIMARY KEY NOT NULL," \ " type INTEGER NOT NULL," \ " name VARCHAR(1024) NOT NULL COLLATE DAAP," \ - " persistentid INTEGER NOT NULL," \ - "CONSTRAINT groups_type_unique_persistentid UNIQUE (type, persistentid)" \ + "CONSTRAINT groups_type_unique_name UNIQUE (type, name)" \ ");" #define T_PAIRINGS \ @@ -4371,26 +4505,12 @@ db_perthread_deinit(void) "CREATE INDEX IF NOT EXISTS idx_playlistid ON playlistitems(playlistid, filepath);" #define I_GRP_TYPE_PERSIST \ - "CREATE INDEX IF NOT EXISTS idx_grp_type_persist ON groups(type, persistentid);" + "CREATE INDEX IF NOT EXISTS idx_grp_type_persist ON groups(type, name);" #define I_PAIRING \ "CREATE INDEX IF NOT EXISTS idx_pairingguid ON pairings(guid);" -#define TRG_GROUPS_INSERT_FILES \ - "CREATE TRIGGER update_groups_new_file AFTER INSERT ON files FOR EACH ROW" \ - " BEGIN" \ - " INSERT OR IGNORE INTO groups (type, name, persistentid) VALUES (1, NEW.album, NEW.songalbumid);" \ - " INSERT OR IGNORE INTO groups (type, name, persistentid) VALUES (2, NEW.album_artist, NEW.songartistid);" \ - " END;" - -#define TRG_GROUPS_UPDATE_FILES \ - "CREATE TRIGGER update_groups_update_file AFTER UPDATE OF songalbumid ON files FOR EACH ROW" \ - " BEGIN" \ - " INSERT OR IGNORE INTO groups (type, name, persistentid) VALUES (1, NEW.album, NEW.songalbumid);" \ - " INSERT OR IGNORE INTO groups (type, name, persistentid) VALUES (2, NEW.album_artist, NEW.songartistid);" \ - " END;" - #define Q_PL1 \ "INSERT INTO playlists (id, title, type, query, db_timestamp, path, idx, special_id)" \ " VALUES(1, 'Library', 1, '1 = 1', 0, '', 0, 0);" @@ -4463,9 +4583,6 @@ static const struct db_init_query db_init_queries[] = { I_PAIRING, "create pairing guid index" }, - { TRG_GROUPS_INSERT_FILES, "create trigger update_groups_new_file" }, - { TRG_GROUPS_UPDATE_FILES, "create trigger update_groups_update_file" }, - { Q_PL1, "create default playlist" }, { Q_PL2, "create default smart playlist 'Music'" }, { Q_PL3, "create default smart playlist 'Movies'" }, diff --git a/src/db.h b/src/db.h index a7d72bf4..499792e9 100644 --- a/src/db.h +++ b/src/db.h @@ -458,13 +458,6 @@ db_pl_disable_bymatch(char *path, char *strip, uint32_t cookie); int db_pl_enable_bycookie(uint32_t cookie, char *path); -/* Groups */ -int -db_groups_clear(void); - -int -db_group_persistentid_byid(int id, int64_t *persistentid); - /* Remotes */ int db_pairing_add(struct pairing_info *pi); diff --git a/src/filescanner.c b/src/filescanner.c index 439a2331..d0495fc7 100644 --- a/src/filescanner.c +++ b/src/filescanner.c @@ -1125,21 +1125,6 @@ filescanner(void *arg) pthread_exit(NULL); } - ret = db_groups_clear(); - if (ret < 0) - { - DPRINTF(E_LOG, L_SCAN, "Error: could not clear old groups from DB\n"); - - pthread_exit(NULL); - } - - /* Recompute all songartistids and songalbumids, in case the SQLite DB got transferred - * to a different host; the hash is not portable. - * It will also rebuild the groups we just cleared. - */ - db_files_update_songartistid(); - db_files_update_songalbumid(); - if (cfg_getbool(cfg_getsec(cfg, "library"), "filescan_disable")) bulk_scan(F_SCAN_BULK | F_SCAN_FAST); else From e321e5137f39bb47b5770c30398916ed41a6dff0 Mon Sep 17 00:00:00 2001 From: chme Date: Mon, 22 Dec 2014 06:04:13 +0100 Subject: [PATCH 02/17] db update v16 and cache update v2 --- src/cache.c | 2 +- src/db.c | 176 ++++++++++++++++++++++++++++++++++++++++++++++++++-- 2 files changed, 171 insertions(+), 7 deletions(-) diff --git a/src/cache.c b/src/cache.c index 9da5bad9..5b6cbb2a 100644 --- a/src/cache.c +++ b/src/cache.c @@ -38,7 +38,7 @@ #include "cache.h" -#define CACHE_VERSION 1 +#define CACHE_VERSION 2 /* The DAAP cache will cache raw daap replies for queries added with * cache_add(). Only some query types are supported. diff --git a/src/db.c b/src/db.c index 12fe8d16..9c3e6d75 100644 --- a/src/db.c +++ b/src/db.c @@ -2624,7 +2624,6 @@ db_file_update(struct media_file_info *mfi) free_mfi(oldmfi, 0); */ - //TODO insert/update/delete groups ret = db_group_get_id(G_ALBUMS, mfi->album_artist, mfi->album, &albumid); if (ret < 0) { @@ -4504,8 +4503,8 @@ db_perthread_deinit(void) #define I_PLITEMID \ "CREATE INDEX IF NOT EXISTS idx_playlistid ON playlistitems(playlistid, filepath);" -#define I_GRP_TYPE_PERSIST \ - "CREATE INDEX IF NOT EXISTS idx_grp_type_persist ON groups(type, name);" +#define I_GRP_TYPE_NAME \ + "CREATE INDEX IF NOT EXISTS idx_grp_type_name ON groups(type, name);" #define I_PAIRING \ "CREATE INDEX IF NOT EXISTS idx_pairingguid ON pairings(guid);" @@ -4541,9 +4540,9 @@ db_perthread_deinit(void) " VALUES(8, 'Purchased', 0, 'media_kind = 1024', 0, '', 0, 8);" */ -#define SCHEMA_VERSION 15 +#define SCHEMA_VERSION 16 #define Q_SCVER \ - "INSERT INTO admin (key, value) VALUES ('schema_version', '15');" + "INSERT INTO admin (key, value) VALUES ('schema_version', '16');" struct db_init_query { char *query; @@ -4579,7 +4578,7 @@ static const struct db_init_query db_init_queries[] = { I_FILEPATH, "create file path index" }, { I_PLITEMID, "create playlist id index" }, - { I_GRP_TYPE_PERSIST, "create groups type/persistentid index" }, + { I_GRP_TYPE_NAME, "create groups type/name index" }, { I_PAIRING, "create pairing guid index" }, @@ -5585,6 +5584,162 @@ db_upgrade_v15(void) #undef Q_DUMP } + +/* Upgrade from schema v15 to v16 */ + +#define U_V16_DROP_IDX \ + "DROP INDEX idx_grp_type_persist;" + +#define U_V16_DROP_TRG_NEW \ + "DROP TRIGGER update_groups_new_file;" + +#define U_V16_DROP_TRG_UPDATE \ + "DROP TRIGGER update_groups_update_file;" + +#define U_V16_DROP_TBL_GROUPS \ + "DROP TABLE groups;" + +#define U_V16_CREATE_TBL_GROUPS \ + "CREATE TABLE IF NOT EXISTS groups (" \ + " id INTEGER PRIMARY KEY NOT NULL," \ + " type INTEGER NOT NULL," \ + " name VARCHAR(1024) NOT NULL COLLATE DAAP," \ + "CONSTRAINT groups_type_unique_name UNIQUE (type, name)" \ + ");" + +#define U_V16_CREATE_IDX \ + "CREATE INDEX IF NOT EXISTS idx_grp_type_name ON groups(type, name);" + +#define U_V16_SCVER \ + "UPDATE admin SET value = '16' WHERE key = 'schema_version';" + +static const struct db_init_query db_upgrade_v16_queries[] = + { + { U_V16_DROP_IDX, "drop index type/persistentid" }, + { U_V16_DROP_TRG_NEW, "drop trigger new files" }, + { U_V16_DROP_TRG_UPDATE, "drop trigger update files" }, + { U_V16_DROP_TBL_GROUPS, "drop table groups" }, + { U_V16_CREATE_TBL_GROUPS, "create table groups" }, + { U_V16_CREATE_IDX, "create index type/name" }, + { U_V16_SCVER, "set schema_version to 16" }, + }; + +static int +db_upgrade_v16_persistentid(enum group_type type, char *artist, char *album) +{ + sqlite3_stmt *stmt; + char *query; + char *errmsg; + int id; + int ret; + + id = 0; + + query = sqlite3_mprintf("SELECT id FROM groups WHERE type = %d AND name = LOWER(TRIM(%Q)) || '==' || LOWER(TRIM(%Q));", type, (artist ? artist : ""), (album ? album : "")); + + ret = sqlite3_prepare_v2(hdl, query, -1, &stmt, NULL); + if (ret != SQLITE_OK) + { + DPRINTF(E_LOG, L_DB, "Could not prepare statement: %s\n", sqlite3_errmsg(hdl)); + return -1; + } + + ret = sqlite3_step(stmt); + if (ret == SQLITE_ROW) + { + id = sqlite3_column_int(stmt, 0); + } + else + { + if (ret != SQLITE_DONE) + { + DPRINTF(E_LOG, L_DB, "Could not step: %s\n", sqlite3_errmsg(hdl)); + } + id = 0; + } + + sqlite3_finalize(stmt); + sqlite3_free(query); + + if (id > 0) + return id; + + query = sqlite3_mprintf("INSERT INTO groups (type, name) VALUES (%d, LOWER(TRIM(%Q)) || '==' || LOWER(TRIM(%Q)));", type, (artist ? artist : ""), (album ? album : "")); + ret = sqlite3_exec(hdl, query, NULL, NULL, &errmsg); + if (ret == SQLITE_OK) + { + id = sqlite3_last_insert_rowid(hdl); + } + else + { + DPRINTF(E_LOG, L_DB, "Error adding group: %s\n", errmsg); + return -1; + } + + sqlite3_free(query); + sqlite3_free(errmsg); + + return id; +} + +static int +db_upgrade_v16(void) +{ + sqlite3_stmt *stmt; + char *query; + char *uquery; + char *errmsg; + char *artist; + char *album; + int id; + int artistid; + int albumid; + int ret; + + query = "SELECT id, album_artist, album FROM files;"; + + DPRINTF(E_DBG, L_DB, "Running query '%s'\n", query); + + ret = sqlite3_prepare_v2(hdl, query, -1, &stmt, NULL); + if (ret != SQLITE_OK) + { + DPRINTF(E_LOG, L_DB, "Could not prepare statement: %s\n", sqlite3_errmsg(hdl)); + return -1; + } + + while ((ret = sqlite3_step(stmt)) == SQLITE_ROW) + { + id = sqlite3_column_int(stmt, 0); + artist = (char *)sqlite3_column_text(stmt, 1); + album = (char *)sqlite3_column_text(stmt, 2); + + artistid = db_upgrade_v16_persistentid(G_ARTISTS, artist, NULL); + albumid = db_upgrade_v16_persistentid(G_ALBUMS, artist, album); + + if (artistid <= 0) + { + + } + if (albumid <= 0) + { + + } + uquery = sqlite3_mprintf("UPDATE files SET songartistid = %d, songalbumid = %d WHERE id = %d;", artistid, albumid, id); + ret = sqlite3_exec(hdl, uquery, NULL, NULL, &errmsg); + if (ret != SQLITE_OK) + { + DPRINTF(E_LOG, L_DB, "Error updating files: %s\n", errmsg); + } + + sqlite3_free(uquery); + sqlite3_free(errmsg); + } + + sqlite3_finalize(stmt); + + return 0; +} + static int db_check_version(void) { @@ -5678,6 +5833,15 @@ db_check_version(void) if (ret < 0) return -1; + case 15: + ret = db_generic_upgrade(db_upgrade_v16_queries, sizeof(db_upgrade_v16_queries) / sizeof(db_upgrade_v16_queries[0])); + if (ret < 0) + return -1; + + ret = db_upgrade_v16(); + if (ret < 0) + return -1; + break; default: From fedf571d34ff977cd517a77598e8d73d8a2a8f46 Mon Sep 17 00:00:00 2001 From: chme Date: Sat, 27 Dec 2014 14:02:32 +0100 Subject: [PATCH 03/17] Improve selects for files table by removing the (f.album <> '' AND f.album IS NOT NULL) from the where clause for album and artist. These are unnecessary because forked-daapd makes sure that an artist or album name exists. --- src/DAAP2SQL.g | 11 +++++++++++ 1 file changed, 11 insertions(+) diff --git a/src/DAAP2SQL.g b/src/DAAP2SQL.g index 1fcbf12f..5d03491f 100644 --- a/src/DAAP2SQL.g +++ b/src/DAAP2SQL.g @@ -194,6 +194,17 @@ expr returns [ pANTLR3_STRING result, int valid ] goto STR_result_valid_0; /* ABORT */ } + /* No need to exclude empty artist and album, as forked-daapd makes sure there always exists an artist/album. */ + if (neg_op && op == ':' + && (strcmp((char *)field, "daap.songalbumartist") == 0 + || strcmp((char *)field, "daap.songartist") == 0 + || strcmp((char *)field, "daap.songalbum") == 0)) + { + DPRINTF(E_DBG, L_DAAP, "Ignoring clause '\%s\%s\%c'\n", field, (neg_op) ? "!" : "", op); + $result->append8($result, "1 = 1"); + goto STR_out; + } + /* Need to check against NULL too */ if (op == ':') $result->append8($result, "("); From 12b46ad94d676e70266b43a94733b1186336b839 Mon Sep 17 00:00:00 2001 From: chme Date: Sat, 27 Dec 2014 21:20:09 +0100 Subject: [PATCH 04/17] Improve select for files table by removing f.media_kind = 32 from the queries (forked_daapd has no media_kind = 32). --- src/DAAP2SQL.g | 58 ++++++++++++++++++++++++++++++++++++++------------ 1 file changed, 44 insertions(+), 14 deletions(-) diff --git a/src/DAAP2SQL.g b/src/DAAP2SQL.g index 5d03491f..ac23a6e6 100644 --- a/src/DAAP2SQL.g +++ b/src/DAAP2SQL.g @@ -69,11 +69,7 @@ expr returns [ pANTLR3_STRING result, int valid ] @init { $result = NULL; $valid = 1; } : ^(OPAND a = expr b = expr) { - if (!$a.valid || !$b.valid) - { - $valid = 0; - } - else + if ($a.valid && $b.valid) { $result = $a.result->factory->newRaw($a.result->factory); $result->append8($result, "("); @@ -82,14 +78,24 @@ expr returns [ pANTLR3_STRING result, int valid ] $result->appendS($result, $b.result); $result->append8($result, ")"); } - } - | ^(OPOR a = expr b = expr) - { - if (!$a.valid || !$b.valid) + else if ($a.valid) + { + $result = $a.result->factory->newRaw($a.result->factory); + $result->appendS($result, $a.result); + } + else if ($b.valid) + { + $result = $b.result->factory->newRaw($b.result->factory); + $result->appendS($result, $b.result); + } + else { $valid = 0; } - else + } + | ^(OPOR a = expr b = expr) + { + if ($a.valid && $b.valid) { $result = $a.result->factory->newRaw($a.result->factory); $result->append8($result, "("); @@ -98,6 +104,20 @@ expr returns [ pANTLR3_STRING result, int valid ] $result->appendS($result, $b.result); $result->append8($result, ")"); } + else if ($a.valid) + { + $result = $a.result->factory->newRaw($a.result->factory); + $result->appendS($result, $a.result); + } + else if ($b.valid) + { + $result = $b.result->factory->newRaw($b.result->factory); + $result->appendS($result, $b.result); + } + else + { + $valid = 0; + } } | STR { @@ -201,8 +221,8 @@ expr returns [ pANTLR3_STRING result, int valid ] || strcmp((char *)field, "daap.songalbum") == 0)) { DPRINTF(E_DBG, L_DAAP, "Ignoring clause '\%s\%s\%c'\n", field, (neg_op) ? "!" : "", op); - $result->append8($result, "1 = 1"); - goto STR_out; + $valid = 0; + goto STR_result_valid_0; } /* Need to check against NULL too */ @@ -210,8 +230,6 @@ expr returns [ pANTLR3_STRING result, int valid ] $result->append8($result, "("); } - $result->append8($result, dqfm->db_col); - /* Int field: check integer conversion */ if (dqfm->as_int) { @@ -236,6 +254,16 @@ expr returns [ pANTLR3_STRING result, int valid ] } *end = '\0'; /* Cut out potential garbage - we're being kind */ + + /* forked-daapd only has media_kind = 1 for music - so remove media_kind = 32 to imporve select query performance. */ + if (llval == 32 + && (strcmp((char *)field, "com.apple.itunes.mediakind") == 0 + || strcmp((char *)field, "com.apple.itunes.extended-media-kind") == 0)) + { + DPRINTF(E_DBG, L_DAAP, "Ignoring clause '\%s\%s\%c\%s'\n", field, (neg_op) ? "!" : "", op, val); + $valid = 0; + goto STR_result_valid_0; + } } /* String field: escape string, check for '*' */ else @@ -269,6 +297,8 @@ expr returns [ pANTLR3_STRING result, int valid ] val[strlen((char *)val) - 1] = '\%'; } } + + $result->append8($result, dqfm->db_col); switch(op) { From 5cb06980e30551124c58e6a9f423709257245d62 Mon Sep 17 00:00:00 2001 From: chme Date: Sat, 27 Dec 2014 21:20:36 +0100 Subject: [PATCH 05/17] Optimize the indexes on the files table to speed up select queries --- src/db.c | 50 +++++++++++++++++++++++++++++++++++++++++--------- 1 file changed, 41 insertions(+), 9 deletions(-) diff --git a/src/db.c b/src/db.c index 9c3e6d75..0cba9fb0 100644 --- a/src/db.c +++ b/src/db.c @@ -4468,7 +4468,7 @@ db_perthread_deinit(void) "CREATE INDEX IF NOT EXISTS idx_sari ON files(songartistid);" #define I_SONGALBUMID \ - "CREATE INDEX IF NOT EXISTS idx_sali ON files(songalbumid);" + "CREATE INDEX IF NOT EXISTS idx_sali ON files(songalbumid, disabled, media_kind, album_sort, disc, track);" #define I_STATEMKINDSARI \ "CREATE INDEX IF NOT EXISTS idx_state_mkind_sari ON files(disabled, media_kind, songartistid);" @@ -4486,7 +4486,7 @@ db_perthread_deinit(void) "CREATE INDEX IF NOT EXISTS idx_composer ON files(composer, composer_sort);" #define I_TITLE \ - "CREATE INDEX IF NOT EXISTS idx_title ON files(title, title_sort);" + "CREATE INDEX IF NOT EXISTS idx_title ON files(disabled, media_kind, title_sort, data_kind);" #define I_ALBUM \ "CREATE INDEX IF NOT EXISTS idx_album ON files(album, album_sort);" @@ -5610,18 +5610,34 @@ db_upgrade_v15(void) #define U_V16_CREATE_IDX \ "CREATE INDEX IF NOT EXISTS idx_grp_type_name ON groups(type, name);" +#define U_V16_DROP_IDX_TITLE \ + "DROP INDEX idx_title;" + +#define U_V16_CREATE_IDX_TITLE \ + "CREATE INDEX IF NOT EXISTS idx_title ON files(disabled, media_kind, title_sort, data_kind);" + +#define U_V16_DROP_IDX_SONGALBUMID \ + "DROP INDEX idx_sali;" + +#define U_V16_CREATE_IDX_SONGALBUMID \ + "CREATE INDEX IF NOT EXISTS idx_sali ON files(songalbumid, disabled, media_kind, album_sort, disc, track);" + #define U_V16_SCVER \ "UPDATE admin SET value = '16' WHERE key = 'schema_version';" static const struct db_init_query db_upgrade_v16_queries[] = { - { U_V16_DROP_IDX, "drop index type/persistentid" }, - { U_V16_DROP_TRG_NEW, "drop trigger new files" }, - { U_V16_DROP_TRG_UPDATE, "drop trigger update files" }, - { U_V16_DROP_TBL_GROUPS, "drop table groups" }, - { U_V16_CREATE_TBL_GROUPS, "create table groups" }, - { U_V16_CREATE_IDX, "create index type/name" }, - { U_V16_SCVER, "set schema_version to 16" }, + { U_V16_DROP_IDX, "drop index type/persistentid" }, + { U_V16_DROP_TRG_NEW, "drop trigger new files" }, + { U_V16_DROP_TRG_UPDATE, "drop trigger update files" }, + { U_V16_DROP_TBL_GROUPS, "drop table groups" }, + { U_V16_CREATE_TBL_GROUPS, "create table groups" }, + { U_V16_CREATE_IDX, "create index type/name" }, + { U_V16_DROP_IDX_TITLE, "drop index title on files" }, + { U_V16_CREATE_IDX_TITLE, "create index title on files" }, + { U_V16_DROP_IDX_SONGALBUMID, "drop index songalbumid on files" }, + { U_V16_CREATE_IDX_SONGALBUMID, "create index songalbumid on files" }, + { U_V16_SCVER, "set schema_version to 16" }, }; static int @@ -5782,6 +5798,14 @@ db_check_version(void) { DPRINTF(E_LOG, L_DB, "Database schema outdated, schema upgrade needed v%d -> v%d\n", cur_ver, SCHEMA_VERSION); + ret = sqlite3_exec(hdl, "BEGIN TRANSACTION;", NULL, NULL, &errmsg); + if (ret != SQLITE_OK) + { + DPRINTF(E_LOG, L_DB, "Error starting transaction: %s\n", errmsg); + sqlite3_free(errmsg); + return -1; + } + switch (cur_ver) { case 10: @@ -5849,6 +5873,14 @@ db_check_version(void) return -1; } + ret = sqlite3_exec(hdl, "END TRANSACTION;", NULL, NULL, &errmsg); + if (ret != SQLITE_OK) + { + DPRINTF(E_LOG, L_DB, "Error ending transaction: %s\n", errmsg); + sqlite3_free(errmsg); + return -1; + } + /* What about some housekeeping work, eh? */ DPRINTF(E_INFO, L_DB, "Now vacuuming database, this may take some time...\n"); From ec47c6e730106d511ea5054102233411d4980878 Mon Sep 17 00:00:00 2001 From: chme Date: Sun, 28 Dec 2014 10:10:40 +0100 Subject: [PATCH 06/17] optimize queries and indexes for composer/genre --- src/db.c | 42 +++++++++++++++++++++++++++++------------- 1 file changed, 29 insertions(+), 13 deletions(-) diff --git a/src/db.c b/src/db.c index 0cba9fb0..8876058c 100644 --- a/src/db.c +++ b/src/db.c @@ -1450,17 +1450,17 @@ db_build_query_browse(struct query_params *qp, char *field, char *sort_field, ch } if (idx && qp->filter) - query = sqlite3_mprintf("SELECT DISTINCT f.%s, f.%s FROM files f WHERE f.disabled = 0 AND f.%s != ''" - " AND %s %s %s;", field, sort_field, field, qp->filter, sort, idx); + query = sqlite3_mprintf("SELECT f.%s, f.%s FROM files f WHERE f.disabled = 0 AND f.%s != ''" + " AND %s GROUP BY f.%s %s %s;", field, sort_field, field, qp->filter, field, sort, idx); else if (idx) - query = sqlite3_mprintf("SELECT DISTINCT f.%s, f.%s FROM files f WHERE f.disabled = 0 AND f.%s != ''" - " %s %s;", field, sort_field, field, sort, idx); + query = sqlite3_mprintf("SELECT f.%s, f.%s FROM files f WHERE f.disabled = 0 AND f.%s != ''" + " GROUP BY f.%s %s %s;", field, sort_field, field, field, sort, idx); else if (qp->filter) - query = sqlite3_mprintf("SELECT DISTINCT f.%s, f.%s FROM files f WHERE f.disabled = 0 AND f.%s != ''" - " AND %s %s;", field, sort_field, field, qp->filter, sort); + query = sqlite3_mprintf("SELECT f.%s, f.%s FROM files f WHERE f.disabled = 0 AND f.%s != ''" + " AND %s GROUP BY f.%s %s;", field, sort_field, field, qp->filter, field, sort); else - query = sqlite3_mprintf("SELECT DISTINCT f.%s, f.%s FROM files f WHERE f.disabled = 0 AND f.%s != '' %s", - field, sort_field, field, sort); + query = sqlite3_mprintf("SELECT f.%s, f.%s FROM files f WHERE f.disabled = 0 AND f.%s != '' GROUP BY f.%s %s", + field, sort_field, field, field, sort); free(sort); @@ -4483,7 +4483,10 @@ db_perthread_deinit(void) "CREATE INDEX IF NOT EXISTS idx_albumartist ON files(album_artist, album_artist_sort);" #define I_COMPOSER \ - "CREATE INDEX IF NOT EXISTS idx_composer ON files(composer, composer_sort);" + "CREATE INDEX IF NOT EXISTS idx_composer ON files(disabled, media_kind, composer, data_kind);" + +#define I_GENRE \ + "CREATE INDEX IF NOT EXISTS idx_genre ON files(disabled, media_kind, genre, data_kind);" #define I_TITLE \ "CREATE INDEX IF NOT EXISTS idx_title ON files(disabled, media_kind, title_sort, data_kind);" @@ -4566,11 +4569,12 @@ static const struct db_init_query db_init_queries[] = { I_STATEMKINDSARI, "create state/mkind/sari index" }, { I_STATEMKINDSALI, "create state/mkind/sali index" }, - { I_ARTIST, "create artist index" }, + { I_ARTIST, "create artist index" }, { I_ALBUMARTIST, "create album_artist index" }, - { I_COMPOSER, "create composer index" }, - { I_TITLE, "create title index" }, - { I_ALBUM, "create album index" }, + { I_COMPOSER, "create composer index" }, + { I_GENRE, "create genre index" }, + { I_TITLE, "create title index" }, + { I_ALBUM, "create album index" }, { I_PL_PATH, "create playlist path index" }, { I_PL_DISABLED, "create playlist state index" }, @@ -5622,6 +5626,15 @@ db_upgrade_v15(void) #define U_V16_CREATE_IDX_SONGALBUMID \ "CREATE INDEX IF NOT EXISTS idx_sali ON files(songalbumid, disabled, media_kind, album_sort, disc, track);" +#define U_V16_CREATE_IDX_GENRE \ + "CREATE INDEX IF NOT EXISTS idx_genre ON files(disabled, media_kind, genre, data_kind);" + +#define U_V16_DROP_IDX_COMPOSER \ + "DROP INDEX idx_composer;" + +#define U_V16_CREATE_IDX_COMPOSER \ + "CREATE INDEX IF NOT EXISTS idx_composer ON files(disabled, media_kind, composer, data_kind);" + #define U_V16_SCVER \ "UPDATE admin SET value = '16' WHERE key = 'schema_version';" @@ -5637,6 +5650,9 @@ static const struct db_init_query db_upgrade_v16_queries[] = { U_V16_CREATE_IDX_TITLE, "create index title on files" }, { U_V16_DROP_IDX_SONGALBUMID, "drop index songalbumid on files" }, { U_V16_CREATE_IDX_SONGALBUMID, "create index songalbumid on files" }, + { U_V16_CREATE_IDX_GENRE, "create index genre on files" }, + { U_V16_DROP_IDX_COMPOSER, "drop index composer on files" }, + { U_V16_CREATE_IDX_COMPOSER, "create index composer on files" }, { U_V16_SCVER, "set schema_version to 16" }, }; From ad48ccb8040ac0e317c47717e9537347ffd9fdd4 Mon Sep 17 00:00:00 2001 From: ejurgensen Date: Thu, 8 Jan 2015 22:40:47 +0100 Subject: [PATCH 07/17] Revert "Merge branch 'db' of git://github.com/chme/forked-daapd into chme-db" This reverts commit b8d5e32160eb360c7f381a46ae696a1f78e91f52, reversing changes made to 5a02f926e3629e9d8fb9b25cb1d90b25d9f89057. --- src/DAAP2SQL.g | 65 +----- src/artwork.c | 10 +- src/db.c | 561 ++++++++++------------------------------------ src/db.h | 7 + src/filescanner.c | 15 ++ 5 files changed, 159 insertions(+), 499 deletions(-) diff --git a/src/DAAP2SQL.g b/src/DAAP2SQL.g index ac23a6e6..1fcbf12f 100644 --- a/src/DAAP2SQL.g +++ b/src/DAAP2SQL.g @@ -69,7 +69,11 @@ expr returns [ pANTLR3_STRING result, int valid ] @init { $result = NULL; $valid = 1; } : ^(OPAND a = expr b = expr) { - if ($a.valid && $b.valid) + if (!$a.valid || !$b.valid) + { + $valid = 0; + } + else { $result = $a.result->factory->newRaw($a.result->factory); $result->append8($result, "("); @@ -78,24 +82,14 @@ expr returns [ pANTLR3_STRING result, int valid ] $result->appendS($result, $b.result); $result->append8($result, ")"); } - else if ($a.valid) - { - $result = $a.result->factory->newRaw($a.result->factory); - $result->appendS($result, $a.result); - } - else if ($b.valid) - { - $result = $b.result->factory->newRaw($b.result->factory); - $result->appendS($result, $b.result); - } - else - { - $valid = 0; - } } | ^(OPOR a = expr b = expr) { - if ($a.valid && $b.valid) + if (!$a.valid || !$b.valid) + { + $valid = 0; + } + else { $result = $a.result->factory->newRaw($a.result->factory); $result->append8($result, "("); @@ -104,20 +98,6 @@ expr returns [ pANTLR3_STRING result, int valid ] $result->appendS($result, $b.result); $result->append8($result, ")"); } - else if ($a.valid) - { - $result = $a.result->factory->newRaw($a.result->factory); - $result->appendS($result, $a.result); - } - else if ($b.valid) - { - $result = $b.result->factory->newRaw($b.result->factory); - $result->appendS($result, $b.result); - } - else - { - $valid = 0; - } } | STR { @@ -214,22 +194,13 @@ expr returns [ pANTLR3_STRING result, int valid ] goto STR_result_valid_0; /* ABORT */ } - /* No need to exclude empty artist and album, as forked-daapd makes sure there always exists an artist/album. */ - if (neg_op && op == ':' - && (strcmp((char *)field, "daap.songalbumartist") == 0 - || strcmp((char *)field, "daap.songartist") == 0 - || strcmp((char *)field, "daap.songalbum") == 0)) - { - DPRINTF(E_DBG, L_DAAP, "Ignoring clause '\%s\%s\%c'\n", field, (neg_op) ? "!" : "", op); - $valid = 0; - goto STR_result_valid_0; - } - /* Need to check against NULL too */ if (op == ':') $result->append8($result, "("); } + $result->append8($result, dqfm->db_col); + /* Int field: check integer conversion */ if (dqfm->as_int) { @@ -254,16 +225,6 @@ expr returns [ pANTLR3_STRING result, int valid ] } *end = '\0'; /* Cut out potential garbage - we're being kind */ - - /* forked-daapd only has media_kind = 1 for music - so remove media_kind = 32 to imporve select query performance. */ - if (llval == 32 - && (strcmp((char *)field, "com.apple.itunes.mediakind") == 0 - || strcmp((char *)field, "com.apple.itunes.extended-media-kind") == 0)) - { - DPRINTF(E_DBG, L_DAAP, "Ignoring clause '\%s\%s\%c\%s'\n", field, (neg_op) ? "!" : "", op, val); - $valid = 0; - goto STR_result_valid_0; - } } /* String field: escape string, check for '*' */ else @@ -297,8 +258,6 @@ expr returns [ pANTLR3_STRING result, int valid ] val[strlen((char *)val) - 1] = '\%'; } } - - $result->append8($result, dqfm->db_col); switch(op) { diff --git a/src/artwork.c b/src/artwork.c index 49134a3f..de8b4110 100644 --- a/src/artwork.c +++ b/src/artwork.c @@ -1303,12 +1303,20 @@ artwork_get_item(int id, int max_w, int max_h, struct evbuffer *evbuf) int artwork_get_group(int id, int max_w, int max_h, struct evbuffer *evbuf) { + int64_t persistentid; int format; DPRINTF(E_DBG, L_ART, "Artwork request for group %d\n", id); + /* Get the persistent id for the given group id */ + if (db_group_persistentid_byid(id, &persistentid) < 0) + { + DPRINTF(E_LOG, L_ART, "Error fetching persistent id for group id %d\n", id); + return -1; + } + /* Load artwork image for the persistent id */ - format = artwork_get_group_persistentid(id, max_w, max_h, evbuf); + format = artwork_get_group_persistentid(persistentid, max_w, max_h, evbuf); if (format <= 0) { DPRINTF(E_DBG, L_ART, "No artwork found for group %d\n", id); diff --git a/src/db.c b/src/db.c index 8876058c..75815d19 100644 --- a/src/db.c +++ b/src/db.c @@ -742,14 +742,12 @@ db_purge_cruft(time_t ref) char *errmsg; int i; int ret; - char *queries[5] = { NULL, NULL, NULL, NULL, NULL }; - char *queries_tmpl[5] = + char *queries[3] = { NULL, NULL, NULL }; + char *queries_tmpl[3] = { "DELETE FROM playlistitems WHERE playlistid IN (SELECT id FROM playlists p WHERE p.type <> 1 AND p.db_timestamp < %" PRIi64 ");", "DELETE FROM playlists WHERE type <> 1 AND db_timestamp < %" PRIi64 ";", - "DELETE FROM files WHERE db_timestamp < %" PRIi64 ";", - "DELETE FROM groups WHERE type = 1 AND id NOT IN (SELECT songalbumid FROM files);", - "DELETE FROM groups WHERE type = 2 AND id NOT IN (SELECT songartistid FROM files);" + "DELETE FROM files WHERE db_timestamp < %" PRIi64 ";" }; if (sizeof(queries) != sizeof(queries_tmpl)) @@ -760,11 +758,7 @@ db_purge_cruft(time_t ref) for (i = 0; i < (sizeof(queries_tmpl) / sizeof(queries_tmpl[0])); i++) { - if (i < 3) - queries[i] = sqlite3_mprintf(queries_tmpl[i], (int64_t)ref); - else - queries[i] = sqlite3_mprintf(queries_tmpl[i]); - + queries[i] = sqlite3_mprintf(queries_tmpl[i], (int64_t)ref); if (!queries[i]) { DPRINTF(E_LOG, L_DB, "Out of memory for query string\n"); @@ -1203,13 +1197,13 @@ db_build_query_group_albums(struct query_params *qp, char **q) sort = sort_clause[qp->sort]; if (idx && qp->filter) - query = sqlite3_mprintf("SELECT f.songalbumid, f.songalbumid, f.album, f.album_sort, COUNT(f.id), 1, f.album_artist, f.songartistid FROM files f WHERE f.disabled = 0 AND %s GROUP BY f.songalbumid %s %s;", qp->filter, sort, idx); + query = sqlite3_mprintf("SELECT g.id, g.persistentid, f.album, f.album_sort, COUNT(f.id), 1, f.album_artist, f.songartistid FROM files f, groups g WHERE f.songalbumid = g.persistentid AND g.type = %d AND f.disabled = 0 AND %s GROUP BY f.album, g.name %s %s;", G_ALBUMS, qp->filter, sort, idx); else if (idx) - query = sqlite3_mprintf("SELECT f.songalbumid, f.songalbumid, f.album, f.album_sort, COUNT(f.id), 1, f.album_artist, f.songartistid FROM files f WHERE f.disabled = 0 GROUP BY f.songalbumid %s %s;", sort, idx); + query = sqlite3_mprintf("SELECT g.id, g.persistentid, f.album, f.album_sort, COUNT(f.id), 1, f.album_artist, f.songartistid FROM files f, groups g WHERE f.songalbumid = g.persistentid AND g.type = %d AND f.disabled = 0 GROUP BY f.album, g.name %s %s;", G_ALBUMS, sort, idx); else if (qp->filter) - query = sqlite3_mprintf("SELECT f.songalbumid, f.songalbumid, f.album, f.album_sort, COUNT(f.id), 1, f.album_artist, f.songartistid FROM files f WHERE f.disabled = 0 AND %s GROUP BY f.songalbumid %s;", qp->filter, sort); + query = sqlite3_mprintf("SELECT g.id, g.persistentid, f.album, f.album_sort, COUNT(f.id), 1, f.album_artist, f.songartistid FROM files f, groups g WHERE f.songalbumid = g.persistentid AND g.type = %d AND f.disabled = 0 AND %s GROUP BY f.album, g.name %s;", G_ALBUMS, qp->filter, sort); else - query = sqlite3_mprintf("SELECT f.songalbumid, f.songalbumid, f.album, f.album_sort, COUNT(f.id), 1, f.album_artist, f.songartistid FROM files f WHERE f.disabled = 0 GROUP BY f.songalbumid %s;", sort); + query = sqlite3_mprintf("SELECT g.id, g.persistentid, f.album, f.album_sort, COUNT(f.id), 1, f.album_artist, f.songartistid FROM files f, groups g WHERE f.songalbumid = g.persistentid AND g.type = %d AND f.disabled = 0 GROUP BY f.album, g.name %s;", G_ALBUMS, sort); if (!query) { @@ -1242,13 +1236,13 @@ db_build_query_group_artists(struct query_params *qp, char **q) sort = sort_clause[qp->sort]; if (idx && qp->filter) - query = sqlite3_mprintf("SELECT f.songartistid, f.songartistid, f.album_artist, f.album_artist_sort, COUNT(f.id), COUNT(DISTINCT f.songalbumid), f.album_artist, f.songartistid FROM files f WHERE f.disabled = 0 AND %s GROUP BY f.songartistid %s %s;", qp->filter, sort, idx); + query = sqlite3_mprintf("SELECT g.id, g.persistentid, f.album_artist, f.album_artist_sort, COUNT(f.id), COUNT(DISTINCT f.songalbumid), f.album_artist, f.songartistid FROM files f, groups g WHERE f.songartistid = g.persistentid AND g.type = %d AND f.disabled = 0 AND %s GROUP BY f.album_artist, g.name %s %s;", G_ARTISTS, qp->filter, sort, idx); else if (idx) - query = sqlite3_mprintf("SELECT f.songartistid, f.songartistid, f.album_artist, f.album_artist_sort, COUNT(f.id), COUNT(DISTINCT f.songalbumid), f.album_artist, f.songartistid FROM files f WHERE f.disabled = 0 GROUP BY f.songartistid %s %s;", sort, idx); + query = sqlite3_mprintf("SELECT g.id, g.persistentid, f.album_artist, f.album_artist_sort, COUNT(f.id), COUNT(DISTINCT f.songalbumid), f.album_artist, f.songartistid FROM files f, groups g WHERE f.songartistid = g.persistentid AND g.type = %d AND f.disabled = 0 GROUP BY f.album_artist, g.name %s %s;", G_ARTISTS, sort, idx); else if (qp->filter) - query = sqlite3_mprintf("SELECT f.songartistid, f.songartistid, f.album_artist, f.album_artist_sort, COUNT(f.id), COUNT(DISTINCT f.songalbumid), f.album_artist, f.songartistid FROM files f WHERE f.disabled = 0 AND %s GROUP BY f.songartistid %s;", qp->filter, sort); + query = sqlite3_mprintf("SELECT g.id, g.persistentid, f.album_artist, f.album_artist_sort, COUNT(f.id), COUNT(DISTINCT f.songalbumid), f.album_artist, f.songartistid FROM files f, groups g WHERE f.songartistid = g.persistentid AND g.type = %d AND f.disabled = 0 AND %s GROUP BY f.album_artist, g.name %s;", G_ARTISTS, qp->filter, sort); else - query = sqlite3_mprintf("SELECT f.songartistid, f.songartistid, f.album_artist, f.album_artist_sort, COUNT(f.id), COUNT(DISTINCT f.songalbumid), f.album_artist, f.songartistid FROM files f WHERE f.disabled = 0 GROUP BY f.songartistid %s;", sort); + query = sqlite3_mprintf("SELECT g.id, g.persistentid, f.album_artist, f.album_artist_sort, COUNT(f.id), COUNT(DISTINCT f.songalbumid), f.album_artist, f.songartistid FROM files f, groups g WHERE f.songartistid = g.persistentid AND g.type = %d AND f.disabled = 0 GROUP BY f.album_artist, g.name %s;", G_ARTISTS, sort); if (!query) { @@ -1450,17 +1444,17 @@ db_build_query_browse(struct query_params *qp, char *field, char *sort_field, ch } if (idx && qp->filter) - query = sqlite3_mprintf("SELECT f.%s, f.%s FROM files f WHERE f.disabled = 0 AND f.%s != ''" - " AND %s GROUP BY f.%s %s %s;", field, sort_field, field, qp->filter, field, sort, idx); + query = sqlite3_mprintf("SELECT DISTINCT f.%s, f.%s FROM files f WHERE f.disabled = 0 AND f.%s != ''" + " AND %s %s %s;", field, sort_field, field, qp->filter, sort, idx); else if (idx) - query = sqlite3_mprintf("SELECT f.%s, f.%s FROM files f WHERE f.disabled = 0 AND f.%s != ''" - " GROUP BY f.%s %s %s;", field, sort_field, field, field, sort, idx); + query = sqlite3_mprintf("SELECT DISTINCT f.%s, f.%s FROM files f WHERE f.disabled = 0 AND f.%s != ''" + " %s %s;", field, sort_field, field, sort, idx); else if (qp->filter) - query = sqlite3_mprintf("SELECT f.%s, f.%s FROM files f WHERE f.disabled = 0 AND f.%s != ''" - " AND %s GROUP BY f.%s %s;", field, sort_field, field, qp->filter, field, sort); + query = sqlite3_mprintf("SELECT DISTINCT f.%s, f.%s FROM files f WHERE f.disabled = 0 AND f.%s != ''" + " AND %s %s;", field, sort_field, field, qp->filter, sort); else - query = sqlite3_mprintf("SELECT f.%s, f.%s FROM files f WHERE f.disabled = 0 AND f.%s != '' GROUP BY f.%s %s", - field, sort_field, field, field, sort); + query = sqlite3_mprintf("SELECT DISTINCT f.%s, f.%s FROM files f WHERE f.disabled = 0 AND f.%s != '' %s", + field, sort_field, field, sort); free(sort); @@ -2365,101 +2359,6 @@ db_file_fetch_byid(int id) #undef Q_TMPL } -static int -db_group_get_id(enum group_type type, const char *artist, const char *album, uint32_t *id) -{ -#define Q_TMPL "SELECT id FROM groups WHERE type = %d AND name = LOWER(TRIM(%Q)) || '==' || LOWER(TRIM(%Q));" - - sqlite3_stmt *stmt; - char *query; - int ret; - - // Select artist and album from groups - query = sqlite3_mprintf(Q_TMPL, type, artist, (album ? album : "")); - if (!query) - { - DPRINTF(E_LOG, L_DB, "Out of memory for query string\n"); - return -1; - } - - DPRINTF(E_DBG, L_DB, "Running query '%s'\n", query); - - ret = db_blocking_prepare_v2(query, strlen(query) + 1, &stmt, NULL); - if (ret != SQLITE_OK) - { - DPRINTF(E_LOG, L_DB, "Could not prepare statement: %s\n", sqlite3_errmsg(hdl)); - - sqlite3_free(query); - return -1; - } - - ret = db_blocking_step(stmt); - - if (ret == SQLITE_DONE) - { - DPRINTF(E_DBG, L_DB, "No results\n"); - sqlite3_finalize(stmt); - sqlite3_free(query); - - *id = 0; - return 0; - } - else if (ret == SQLITE_ROW) - { - *id = sqlite3_column_int(stmt, 0); - - sqlite3_finalize(stmt); - sqlite3_free(query); - return 0; - } - - DPRINTF(E_LOG, L_DB, "Could not step: %s\n", sqlite3_errmsg(hdl)); - sqlite3_finalize(stmt); - sqlite3_free(query); - return -1; - -#undef Q_TMPL -} - -static int -db_group_add(enum group_type type, const char *artist, const char *album, uint32_t *id) -{ -#define Q_TMPL "INSERT OR REPLACE INTO groups (type, name) VALUES (%d, LOWER(TRIM(%Q)) || '==' || LOWER(TRIM(%Q)));" - - char *query; - char *errmsg; - int ret; - - // Select artist and album from groups - query = sqlite3_mprintf(Q_TMPL, type, artist, (album ? album : "")); - if (!query) - { - DPRINTF(E_LOG, L_DB, "Out of memory for query string\n"); - return -1; - } - - DPRINTF(E_DBG, L_DB, "Running query '%s'\n", query); - - ret = db_exec(query, &errmsg); - if (ret != SQLITE_OK) - { - DPRINTF(E_LOG, L_DB, "Error '%s' while runnning '%s'\n", errmsg, query); - sqlite3_free(errmsg); - sqlite3_free(query); - *id = 0; - return -1; - } - - sqlite3_free(errmsg); - sqlite3_free(query); - - *id = sqlite3_last_insert_rowid(hdl); - - return 0; - -#undef Q_TMPL -} - int db_file_add(struct media_file_info *mfi) { @@ -2478,13 +2377,11 @@ db_file_add(struct media_file_info *mfi) " %Q, %" PRIi64 ", %" PRIi64 ", %" PRIi64 ", %" PRIi64 ", %d, %" PRIi64 "," \ " %Q, %d, %d, %d, %d, TRIM(%Q)," \ " %d, TRIM(%Q), TRIM(%Q), TRIM(%Q), %d, %d," \ - " %" PRIi64 ", %" PRIi64 ", " \ + " daap_songalbumid(LOWER(TRIM(%Q)), ''), daap_songalbumid(LOWER(TRIM(%Q)), LOWER(TRIM(%Q))), " \ " TRIM(%Q), TRIM(%Q), TRIM(%Q), TRIM(%Q), TRIM(%Q));" char *query; char *errmsg; - uint32_t albumid; - uint32_t artistid; int ret; @@ -2494,43 +2391,6 @@ db_file_add(struct media_file_info *mfi) return -1; } - // Select artist and album from groups - ret = db_group_get_id(G_ALBUMS, mfi->album_artist, mfi->album, &albumid); - if (ret < 0) - { - DPRINTF(E_LOG, L_DB, "Could not get albumid for artist '%s' album '%s'\n", mfi->album_artist, mfi->album); - return -1; - } - - if (albumid == 0) - { - ret = db_group_add(G_ALBUMS, mfi->album_artist, mfi->album, &albumid); - if (ret < 0) - { - DPRINTF(E_LOG, L_DB, "Could not add artist '%s' album '%s'\n", mfi->album_artist, mfi->album); - return -1; - } - } - - ret = db_group_get_id(G_ARTISTS, mfi->album_artist, NULL, &artistid); - if (ret < 0) - { - DPRINTF(E_LOG, L_DB, "Could not get artistid for artist '%s'\n", mfi->album_artist); - return -1; - } - - if (artistid == 0) - { - ret = db_group_add(G_ARTISTS, mfi->album_artist, NULL, &artistid); - if (ret < 0) - { - DPRINTF(E_LOG, L_DB, "Could not add artist '%s'\n", mfi->album_artist); - return -1; - } - } - - mfi->songalbumid = albumid; - mfi->songartistid = artistid; mfi->db_timestamp = (uint64_t)time(NULL); mfi->time_added = mfi->db_timestamp; @@ -2550,8 +2410,7 @@ db_file_add(struct media_file_info *mfi) mfi->contentrating, mfi->bits_per_sample, mfi->album_artist, mfi->media_kind, mfi->tv_series_name, mfi->tv_episode_num_str, mfi->tv_network_name, mfi->tv_episode_sort, mfi->tv_season_num, - mfi->songartistid, mfi->songalbumid, - mfi->title_sort, mfi->artist_sort, mfi->album_sort, + mfi->album_artist, mfi->album_artist, mfi->album, mfi->title_sort, mfi->artist_sort, mfi->album_sort, mfi->composer_sort, mfi->album_artist_sort); if (!query) @@ -2595,15 +2454,11 @@ db_file_update(struct media_file_info *mfi) " bits_per_sample = %d, album_artist = TRIM(%Q)," \ " media_kind = %d, tv_series_name = TRIM(%Q), tv_episode_num_str = TRIM(%Q)," \ " tv_network_name = TRIM(%Q), tv_episode_sort = %d, tv_season_num = %d," \ - " songartistid = %" PRIi64 ", songalbumid = %" PRIi64 "," \ + " songartistid = daap_songalbumid(LOWER(TRIM(%Q)), ''), songalbumid = daap_songalbumid(LOWER(TRIM(%Q)), LOWER(TRIM(%Q)))," \ " title_sort = TRIM(%Q), artist_sort = TRIM(%Q), album_sort = TRIM(%Q), composer_sort = TRIM(%Q), album_artist_sort = TRIM(%Q)" \ " WHERE id = %d;" - -// struct media_file_info *oldmfi; char *query; char *errmsg; - uint32_t albumid; - uint32_t artistid; int ret; if (mfi->id == 0) @@ -2612,55 +2467,6 @@ db_file_update(struct media_file_info *mfi) return -1; } - /* - oldmfi = db_file_fetch_byid(mfi->id); - - if (!oldmfi) - { - DPRINTF(E_WARN, L_DB, "File with id '%d' does not exist\n", mfi->id); - return -1; - } - - free_mfi(oldmfi, 0); - */ - - ret = db_group_get_id(G_ALBUMS, mfi->album_artist, mfi->album, &albumid); - if (ret < 0) - { - DPRINTF(E_LOG, L_DB, "Could not get albumid for artist '%s' album '%s'\n", mfi->album_artist, mfi->album); - return -1; - } - - if (albumid == 0) - { - ret = db_group_add(G_ALBUMS, mfi->album_artist, mfi->album, &albumid); - if (ret < 0) - { - DPRINTF(E_LOG, L_DB, "Could not add artist '%s' album '%s'\n", mfi->album_artist, mfi->album); - return -1; - } - } - - ret = db_group_get_id(G_ARTISTS, mfi->album_artist, NULL, &artistid); - if (ret < 0) - { - DPRINTF(E_LOG, L_DB, "Could not get artistid for artist '%s'\n", mfi->album_artist); - return -1; - } - - if (artistid == 0) - { - ret = db_group_add(G_ARTISTS, mfi->album_artist, NULL, &artistid); - if (ret < 0) - { - DPRINTF(E_LOG, L_DB, "Could not add artist '%s'\n", mfi->album_artist); - return -1; - } - } - - mfi->songalbumid = albumid; - mfi->songartistid = artistid; - mfi->db_timestamp = (uint64_t)time(NULL); if (mfi->time_modified == 0) @@ -2678,7 +2484,7 @@ db_file_update(struct media_file_info *mfi) mfi->bits_per_sample, mfi->album_artist, mfi->media_kind, mfi->tv_series_name, mfi->tv_episode_num_str, mfi->tv_network_name, mfi->tv_episode_sort, mfi->tv_season_num, - mfi->songartistid, mfi->songalbumid, + mfi->album_artist, mfi->album_artist, mfi->album, mfi->title_sort, mfi->artist_sort, mfi->album_sort, mfi->composer_sort, mfi->album_artist_sort, mfi->id); @@ -3303,11 +3109,16 @@ db_pl_enable_bycookie(uint32_t cookie, char *path) /* Groups */ +int +db_groups_clear(void) +{ + return db_query_run("DELETE FROM groups;", 0, 1); +} static enum group_type db_group_type_bypersistentid(int64_t persistentid) { -#define Q_TMPL "SELECT g.type FROM groups g WHERE g.id = %" PRIi64 ";" +#define Q_TMPL "SELECT g.type FROM groups g WHERE g.persistentid = %" PRIi64 ";" char *query; sqlite3_stmt *stmt; int ret; @@ -3359,6 +3170,61 @@ db_group_type_bypersistentid(int64_t persistentid) #undef Q_TMPL } +int +db_group_persistentid_byid(int id, int64_t *persistentid) +{ +#define Q_TMPL "SELECT g.persistentid FROM groups g WHERE g.id = %d;" + char *query; + sqlite3_stmt *stmt; + int ret; + + query = sqlite3_mprintf(Q_TMPL, id); + if (!query) + { + DPRINTF(E_LOG, L_DB, "Out of memory for query string\n"); + + return -1; + } + + DPRINTF(E_DBG, L_DB, "Running query '%s'\n", query); + + ret = db_blocking_prepare_v2(query, -1, &stmt, NULL); + if (ret != SQLITE_OK) + { + DPRINTF(E_LOG, L_DB, "Could not prepare statement: %s\n", sqlite3_errmsg(hdl)); + + sqlite3_free(query); + return -1; + } + + ret = db_blocking_step(stmt); + if (ret != SQLITE_ROW) + { + if (ret == SQLITE_DONE) + DPRINTF(E_DBG, L_DB, "No results\n"); + else + DPRINTF(E_LOG, L_DB, "Could not step: %s\n", sqlite3_errmsg(hdl)); + + sqlite3_finalize(stmt); + sqlite3_free(query); + return -1; + } + + *persistentid = sqlite3_column_int64(stmt, 0); + +#ifdef DB_PROFILE + while (db_blocking_step(stmt) == SQLITE_ROW) + ; /* EMPTY */ +#endif + + sqlite3_finalize(stmt); + sqlite3_free(query); + + return 0; + +#undef Q_TMPL +} + /* Remotes */ static int @@ -4437,7 +4303,8 @@ db_perthread_deinit(void) " id INTEGER PRIMARY KEY NOT NULL," \ " type INTEGER NOT NULL," \ " name VARCHAR(1024) NOT NULL COLLATE DAAP," \ - "CONSTRAINT groups_type_unique_name UNIQUE (type, name)" \ + " persistentid INTEGER NOT NULL," \ + "CONSTRAINT groups_type_unique_persistentid UNIQUE (type, persistentid)" \ ");" #define T_PAIRINGS \ @@ -4468,7 +4335,7 @@ db_perthread_deinit(void) "CREATE INDEX IF NOT EXISTS idx_sari ON files(songartistid);" #define I_SONGALBUMID \ - "CREATE INDEX IF NOT EXISTS idx_sali ON files(songalbumid, disabled, media_kind, album_sort, disc, track);" + "CREATE INDEX IF NOT EXISTS idx_sali ON files(songalbumid);" #define I_STATEMKINDSARI \ "CREATE INDEX IF NOT EXISTS idx_state_mkind_sari ON files(disabled, media_kind, songartistid);" @@ -4483,13 +4350,10 @@ db_perthread_deinit(void) "CREATE INDEX IF NOT EXISTS idx_albumartist ON files(album_artist, album_artist_sort);" #define I_COMPOSER \ - "CREATE INDEX IF NOT EXISTS idx_composer ON files(disabled, media_kind, composer, data_kind);" - -#define I_GENRE \ - "CREATE INDEX IF NOT EXISTS idx_genre ON files(disabled, media_kind, genre, data_kind);" + "CREATE INDEX IF NOT EXISTS idx_composer ON files(composer, composer_sort);" #define I_TITLE \ - "CREATE INDEX IF NOT EXISTS idx_title ON files(disabled, media_kind, title_sort, data_kind);" + "CREATE INDEX IF NOT EXISTS idx_title ON files(title, title_sort);" #define I_ALBUM \ "CREATE INDEX IF NOT EXISTS idx_album ON files(album, album_sort);" @@ -4506,13 +4370,27 @@ db_perthread_deinit(void) #define I_PLITEMID \ "CREATE INDEX IF NOT EXISTS idx_playlistid ON playlistitems(playlistid, filepath);" -#define I_GRP_TYPE_NAME \ - "CREATE INDEX IF NOT EXISTS idx_grp_type_name ON groups(type, name);" +#define I_GRP_TYPE_PERSIST \ + "CREATE INDEX IF NOT EXISTS idx_grp_type_persist ON groups(type, persistentid);" #define I_PAIRING \ "CREATE INDEX IF NOT EXISTS idx_pairingguid ON pairings(guid);" +#define TRG_GROUPS_INSERT_FILES \ + "CREATE TRIGGER update_groups_new_file AFTER INSERT ON files FOR EACH ROW" \ + " BEGIN" \ + " INSERT OR IGNORE INTO groups (type, name, persistentid) VALUES (1, NEW.album, NEW.songalbumid);" \ + " INSERT OR IGNORE INTO groups (type, name, persistentid) VALUES (2, NEW.album_artist, NEW.songartistid);" \ + " END;" + +#define TRG_GROUPS_UPDATE_FILES \ + "CREATE TRIGGER update_groups_update_file AFTER UPDATE OF songalbumid ON files FOR EACH ROW" \ + " BEGIN" \ + " INSERT OR IGNORE INTO groups (type, name, persistentid) VALUES (1, NEW.album, NEW.songalbumid);" \ + " INSERT OR IGNORE INTO groups (type, name, persistentid) VALUES (2, NEW.album_artist, NEW.songartistid);" \ + " END;" + #define Q_PL1 \ "INSERT INTO playlists (id, title, type, query, db_timestamp, path, idx, special_id)" \ " VALUES(1, 'Library', 1, '1 = 1', 0, '', 0, 0);" @@ -4543,9 +4421,9 @@ db_perthread_deinit(void) " VALUES(8, 'Purchased', 0, 'media_kind = 1024', 0, '', 0, 8);" */ -#define SCHEMA_VERSION 16 +#define SCHEMA_VERSION 15 #define Q_SCVER \ - "INSERT INTO admin (key, value) VALUES ('schema_version', '16');" + "INSERT INTO admin (key, value) VALUES ('schema_version', '15');" struct db_init_query { char *query; @@ -4569,12 +4447,11 @@ static const struct db_init_query db_init_queries[] = { I_STATEMKINDSARI, "create state/mkind/sari index" }, { I_STATEMKINDSALI, "create state/mkind/sali index" }, - { I_ARTIST, "create artist index" }, + { I_ARTIST, "create artist index" }, { I_ALBUMARTIST, "create album_artist index" }, - { I_COMPOSER, "create composer index" }, - { I_GENRE, "create genre index" }, - { I_TITLE, "create title index" }, - { I_ALBUM, "create album index" }, + { I_COMPOSER, "create composer index" }, + { I_TITLE, "create title index" }, + { I_ALBUM, "create album index" }, { I_PL_PATH, "create playlist path index" }, { I_PL_DISABLED, "create playlist state index" }, @@ -4582,10 +4459,13 @@ static const struct db_init_query db_init_queries[] = { I_FILEPATH, "create file path index" }, { I_PLITEMID, "create playlist id index" }, - { I_GRP_TYPE_NAME, "create groups type/name index" }, + { I_GRP_TYPE_PERSIST, "create groups type/persistentid index" }, { I_PAIRING, "create pairing guid index" }, + { TRG_GROUPS_INSERT_FILES, "create trigger update_groups_new_file" }, + { TRG_GROUPS_UPDATE_FILES, "create trigger update_groups_update_file" }, + { Q_PL1, "create default playlist" }, { Q_PL2, "create default smart playlist 'Music'" }, { Q_PL3, "create default smart playlist 'Movies'" }, @@ -5588,190 +5468,6 @@ db_upgrade_v15(void) #undef Q_DUMP } - -/* Upgrade from schema v15 to v16 */ - -#define U_V16_DROP_IDX \ - "DROP INDEX idx_grp_type_persist;" - -#define U_V16_DROP_TRG_NEW \ - "DROP TRIGGER update_groups_new_file;" - -#define U_V16_DROP_TRG_UPDATE \ - "DROP TRIGGER update_groups_update_file;" - -#define U_V16_DROP_TBL_GROUPS \ - "DROP TABLE groups;" - -#define U_V16_CREATE_TBL_GROUPS \ - "CREATE TABLE IF NOT EXISTS groups (" \ - " id INTEGER PRIMARY KEY NOT NULL," \ - " type INTEGER NOT NULL," \ - " name VARCHAR(1024) NOT NULL COLLATE DAAP," \ - "CONSTRAINT groups_type_unique_name UNIQUE (type, name)" \ - ");" - -#define U_V16_CREATE_IDX \ - "CREATE INDEX IF NOT EXISTS idx_grp_type_name ON groups(type, name);" - -#define U_V16_DROP_IDX_TITLE \ - "DROP INDEX idx_title;" - -#define U_V16_CREATE_IDX_TITLE \ - "CREATE INDEX IF NOT EXISTS idx_title ON files(disabled, media_kind, title_sort, data_kind);" - -#define U_V16_DROP_IDX_SONGALBUMID \ - "DROP INDEX idx_sali;" - -#define U_V16_CREATE_IDX_SONGALBUMID \ - "CREATE INDEX IF NOT EXISTS idx_sali ON files(songalbumid, disabled, media_kind, album_sort, disc, track);" - -#define U_V16_CREATE_IDX_GENRE \ - "CREATE INDEX IF NOT EXISTS idx_genre ON files(disabled, media_kind, genre, data_kind);" - -#define U_V16_DROP_IDX_COMPOSER \ - "DROP INDEX idx_composer;" - -#define U_V16_CREATE_IDX_COMPOSER \ - "CREATE INDEX IF NOT EXISTS idx_composer ON files(disabled, media_kind, composer, data_kind);" - -#define U_V16_SCVER \ - "UPDATE admin SET value = '16' WHERE key = 'schema_version';" - -static const struct db_init_query db_upgrade_v16_queries[] = - { - { U_V16_DROP_IDX, "drop index type/persistentid" }, - { U_V16_DROP_TRG_NEW, "drop trigger new files" }, - { U_V16_DROP_TRG_UPDATE, "drop trigger update files" }, - { U_V16_DROP_TBL_GROUPS, "drop table groups" }, - { U_V16_CREATE_TBL_GROUPS, "create table groups" }, - { U_V16_CREATE_IDX, "create index type/name" }, - { U_V16_DROP_IDX_TITLE, "drop index title on files" }, - { U_V16_CREATE_IDX_TITLE, "create index title on files" }, - { U_V16_DROP_IDX_SONGALBUMID, "drop index songalbumid on files" }, - { U_V16_CREATE_IDX_SONGALBUMID, "create index songalbumid on files" }, - { U_V16_CREATE_IDX_GENRE, "create index genre on files" }, - { U_V16_DROP_IDX_COMPOSER, "drop index composer on files" }, - { U_V16_CREATE_IDX_COMPOSER, "create index composer on files" }, - { U_V16_SCVER, "set schema_version to 16" }, - }; - -static int -db_upgrade_v16_persistentid(enum group_type type, char *artist, char *album) -{ - sqlite3_stmt *stmt; - char *query; - char *errmsg; - int id; - int ret; - - id = 0; - - query = sqlite3_mprintf("SELECT id FROM groups WHERE type = %d AND name = LOWER(TRIM(%Q)) || '==' || LOWER(TRIM(%Q));", type, (artist ? artist : ""), (album ? album : "")); - - ret = sqlite3_prepare_v2(hdl, query, -1, &stmt, NULL); - if (ret != SQLITE_OK) - { - DPRINTF(E_LOG, L_DB, "Could not prepare statement: %s\n", sqlite3_errmsg(hdl)); - return -1; - } - - ret = sqlite3_step(stmt); - if (ret == SQLITE_ROW) - { - id = sqlite3_column_int(stmt, 0); - } - else - { - if (ret != SQLITE_DONE) - { - DPRINTF(E_LOG, L_DB, "Could not step: %s\n", sqlite3_errmsg(hdl)); - } - id = 0; - } - - sqlite3_finalize(stmt); - sqlite3_free(query); - - if (id > 0) - return id; - - query = sqlite3_mprintf("INSERT INTO groups (type, name) VALUES (%d, LOWER(TRIM(%Q)) || '==' || LOWER(TRIM(%Q)));", type, (artist ? artist : ""), (album ? album : "")); - ret = sqlite3_exec(hdl, query, NULL, NULL, &errmsg); - if (ret == SQLITE_OK) - { - id = sqlite3_last_insert_rowid(hdl); - } - else - { - DPRINTF(E_LOG, L_DB, "Error adding group: %s\n", errmsg); - return -1; - } - - sqlite3_free(query); - sqlite3_free(errmsg); - - return id; -} - -static int -db_upgrade_v16(void) -{ - sqlite3_stmt *stmt; - char *query; - char *uquery; - char *errmsg; - char *artist; - char *album; - int id; - int artistid; - int albumid; - int ret; - - query = "SELECT id, album_artist, album FROM files;"; - - DPRINTF(E_DBG, L_DB, "Running query '%s'\n", query); - - ret = sqlite3_prepare_v2(hdl, query, -1, &stmt, NULL); - if (ret != SQLITE_OK) - { - DPRINTF(E_LOG, L_DB, "Could not prepare statement: %s\n", sqlite3_errmsg(hdl)); - return -1; - } - - while ((ret = sqlite3_step(stmt)) == SQLITE_ROW) - { - id = sqlite3_column_int(stmt, 0); - artist = (char *)sqlite3_column_text(stmt, 1); - album = (char *)sqlite3_column_text(stmt, 2); - - artistid = db_upgrade_v16_persistentid(G_ARTISTS, artist, NULL); - albumid = db_upgrade_v16_persistentid(G_ALBUMS, artist, album); - - if (artistid <= 0) - { - - } - if (albumid <= 0) - { - - } - uquery = sqlite3_mprintf("UPDATE files SET songartistid = %d, songalbumid = %d WHERE id = %d;", artistid, albumid, id); - ret = sqlite3_exec(hdl, uquery, NULL, NULL, &errmsg); - if (ret != SQLITE_OK) - { - DPRINTF(E_LOG, L_DB, "Error updating files: %s\n", errmsg); - } - - sqlite3_free(uquery); - sqlite3_free(errmsg); - } - - sqlite3_finalize(stmt); - - return 0; -} - static int db_check_version(void) { @@ -5814,14 +5510,6 @@ db_check_version(void) { DPRINTF(E_LOG, L_DB, "Database schema outdated, schema upgrade needed v%d -> v%d\n", cur_ver, SCHEMA_VERSION); - ret = sqlite3_exec(hdl, "BEGIN TRANSACTION;", NULL, NULL, &errmsg); - if (ret != SQLITE_OK) - { - DPRINTF(E_LOG, L_DB, "Error starting transaction: %s\n", errmsg); - sqlite3_free(errmsg); - return -1; - } - switch (cur_ver) { case 10: @@ -5873,15 +5561,6 @@ db_check_version(void) if (ret < 0) return -1; - case 15: - ret = db_generic_upgrade(db_upgrade_v16_queries, sizeof(db_upgrade_v16_queries) / sizeof(db_upgrade_v16_queries[0])); - if (ret < 0) - return -1; - - ret = db_upgrade_v16(); - if (ret < 0) - return -1; - break; default: @@ -5889,14 +5568,6 @@ db_check_version(void) return -1; } - ret = sqlite3_exec(hdl, "END TRANSACTION;", NULL, NULL, &errmsg); - if (ret != SQLITE_OK) - { - DPRINTF(E_LOG, L_DB, "Error ending transaction: %s\n", errmsg); - sqlite3_free(errmsg); - return -1; - } - /* What about some housekeeping work, eh? */ DPRINTF(E_INFO, L_DB, "Now vacuuming database, this may take some time...\n"); diff --git a/src/db.h b/src/db.h index 499792e9..a7d72bf4 100644 --- a/src/db.h +++ b/src/db.h @@ -458,6 +458,13 @@ db_pl_disable_bymatch(char *path, char *strip, uint32_t cookie); int db_pl_enable_bycookie(uint32_t cookie, char *path); +/* Groups */ +int +db_groups_clear(void); + +int +db_group_persistentid_byid(int id, int64_t *persistentid); + /* Remotes */ int db_pairing_add(struct pairing_info *pi); diff --git a/src/filescanner.c b/src/filescanner.c index d0495fc7..439a2331 100644 --- a/src/filescanner.c +++ b/src/filescanner.c @@ -1125,6 +1125,21 @@ filescanner(void *arg) pthread_exit(NULL); } + ret = db_groups_clear(); + if (ret < 0) + { + DPRINTF(E_LOG, L_SCAN, "Error: could not clear old groups from DB\n"); + + pthread_exit(NULL); + } + + /* Recompute all songartistids and songalbumids, in case the SQLite DB got transferred + * to a different host; the hash is not portable. + * It will also rebuild the groups we just cleared. + */ + db_files_update_songartistid(); + db_files_update_songalbumid(); + if (cfg_getbool(cfg_getsec(cfg, "library"), "filescan_disable")) bulk_scan(F_SCAN_BULK | F_SCAN_FAST); else From 46f770b52d4bfed8b37dc82586aa389208a2f41b Mon Sep 17 00:00:00 2001 From: chme Date: Sat, 27 Dec 2014 14:02:32 +0100 Subject: [PATCH 08/17] Improve selects for files table by removing the (f.album <> '' AND f.album IS NOT NULL) from the where clause for album and artist. These are unnecessary because forked-daapd makes sure that an artist or album name exists. --- src/DAAP2SQL.g | 11 +++++++++++ 1 file changed, 11 insertions(+) diff --git a/src/DAAP2SQL.g b/src/DAAP2SQL.g index 1fcbf12f..5d03491f 100644 --- a/src/DAAP2SQL.g +++ b/src/DAAP2SQL.g @@ -194,6 +194,17 @@ expr returns [ pANTLR3_STRING result, int valid ] goto STR_result_valid_0; /* ABORT */ } + /* No need to exclude empty artist and album, as forked-daapd makes sure there always exists an artist/album. */ + if (neg_op && op == ':' + && (strcmp((char *)field, "daap.songalbumartist") == 0 + || strcmp((char *)field, "daap.songartist") == 0 + || strcmp((char *)field, "daap.songalbum") == 0)) + { + DPRINTF(E_DBG, L_DAAP, "Ignoring clause '\%s\%s\%c'\n", field, (neg_op) ? "!" : "", op); + $result->append8($result, "1 = 1"); + goto STR_out; + } + /* Need to check against NULL too */ if (op == ':') $result->append8($result, "("); From 1981237638b4adf7fc9fdbe4e852a9c725a61adc Mon Sep 17 00:00:00 2001 From: chme Date: Sat, 27 Dec 2014 21:20:09 +0100 Subject: [PATCH 09/17] Improve select for files table by removing f.media_kind = 32 from the queries (forked_daapd has no media_kind = 32). --- src/DAAP2SQL.g | 58 ++++++++++++++++++++++++++++++++++++++------------ 1 file changed, 44 insertions(+), 14 deletions(-) diff --git a/src/DAAP2SQL.g b/src/DAAP2SQL.g index 5d03491f..ac23a6e6 100644 --- a/src/DAAP2SQL.g +++ b/src/DAAP2SQL.g @@ -69,11 +69,7 @@ expr returns [ pANTLR3_STRING result, int valid ] @init { $result = NULL; $valid = 1; } : ^(OPAND a = expr b = expr) { - if (!$a.valid || !$b.valid) - { - $valid = 0; - } - else + if ($a.valid && $b.valid) { $result = $a.result->factory->newRaw($a.result->factory); $result->append8($result, "("); @@ -82,14 +78,24 @@ expr returns [ pANTLR3_STRING result, int valid ] $result->appendS($result, $b.result); $result->append8($result, ")"); } - } - | ^(OPOR a = expr b = expr) - { - if (!$a.valid || !$b.valid) + else if ($a.valid) + { + $result = $a.result->factory->newRaw($a.result->factory); + $result->appendS($result, $a.result); + } + else if ($b.valid) + { + $result = $b.result->factory->newRaw($b.result->factory); + $result->appendS($result, $b.result); + } + else { $valid = 0; } - else + } + | ^(OPOR a = expr b = expr) + { + if ($a.valid && $b.valid) { $result = $a.result->factory->newRaw($a.result->factory); $result->append8($result, "("); @@ -98,6 +104,20 @@ expr returns [ pANTLR3_STRING result, int valid ] $result->appendS($result, $b.result); $result->append8($result, ")"); } + else if ($a.valid) + { + $result = $a.result->factory->newRaw($a.result->factory); + $result->appendS($result, $a.result); + } + else if ($b.valid) + { + $result = $b.result->factory->newRaw($b.result->factory); + $result->appendS($result, $b.result); + } + else + { + $valid = 0; + } } | STR { @@ -201,8 +221,8 @@ expr returns [ pANTLR3_STRING result, int valid ] || strcmp((char *)field, "daap.songalbum") == 0)) { DPRINTF(E_DBG, L_DAAP, "Ignoring clause '\%s\%s\%c'\n", field, (neg_op) ? "!" : "", op); - $result->append8($result, "1 = 1"); - goto STR_out; + $valid = 0; + goto STR_result_valid_0; } /* Need to check against NULL too */ @@ -210,8 +230,6 @@ expr returns [ pANTLR3_STRING result, int valid ] $result->append8($result, "("); } - $result->append8($result, dqfm->db_col); - /* Int field: check integer conversion */ if (dqfm->as_int) { @@ -236,6 +254,16 @@ expr returns [ pANTLR3_STRING result, int valid ] } *end = '\0'; /* Cut out potential garbage - we're being kind */ + + /* forked-daapd only has media_kind = 1 for music - so remove media_kind = 32 to imporve select query performance. */ + if (llval == 32 + && (strcmp((char *)field, "com.apple.itunes.mediakind") == 0 + || strcmp((char *)field, "com.apple.itunes.extended-media-kind") == 0)) + { + DPRINTF(E_DBG, L_DAAP, "Ignoring clause '\%s\%s\%c\%s'\n", field, (neg_op) ? "!" : "", op, val); + $valid = 0; + goto STR_result_valid_0; + } } /* String field: escape string, check for '*' */ else @@ -269,6 +297,8 @@ expr returns [ pANTLR3_STRING result, int valid ] val[strlen((char *)val) - 1] = '\%'; } } + + $result->append8($result, dqfm->db_col); switch(op) { From ea598bfeaf552fc7dc99efa11c78127cefdffecc Mon Sep 17 00:00:00 2001 From: ejurgensen Date: Fri, 9 Jan 2015 00:28:06 +0100 Subject: [PATCH 10/17] Remove upgrade paths for indices (since they don't have any data anyway), and instead implement db_create_indices and db_drop_indices to reduce redundancy --- src/db.c | 397 +++++++++++++++++++++++-------------------------------- 1 file changed, 166 insertions(+), 231 deletions(-) diff --git a/src/db.c b/src/db.c index 75815d19..bdab170f 100644 --- a/src/db.c +++ b/src/db.c @@ -4328,55 +4328,6 @@ db_perthread_deinit(void) " path VARCHAR(4096) NOT NULL" \ ");" -#define I_RESCAN \ - "CREATE INDEX IF NOT EXISTS idx_rescan ON files(path, db_timestamp);" - -#define I_SONGARTISTID \ - "CREATE INDEX IF NOT EXISTS idx_sari ON files(songartistid);" - -#define I_SONGALBUMID \ - "CREATE INDEX IF NOT EXISTS idx_sali ON files(songalbumid);" - -#define I_STATEMKINDSARI \ - "CREATE INDEX IF NOT EXISTS idx_state_mkind_sari ON files(disabled, media_kind, songartistid);" - -#define I_STATEMKINDSALI \ - "CREATE INDEX IF NOT EXISTS idx_state_mkind_sali ON files(disabled, media_kind, songalbumid);" - -#define I_ARTIST \ - "CREATE INDEX IF NOT EXISTS idx_artist ON files(artist, artist_sort);" - -#define I_ALBUMARTIST \ - "CREATE INDEX IF NOT EXISTS idx_albumartist ON files(album_artist, album_artist_sort);" - -#define I_COMPOSER \ - "CREATE INDEX IF NOT EXISTS idx_composer ON files(composer, composer_sort);" - -#define I_TITLE \ - "CREATE INDEX IF NOT EXISTS idx_title ON files(title, title_sort);" - -#define I_ALBUM \ - "CREATE INDEX IF NOT EXISTS idx_album ON files(album, album_sort);" - -#define I_PL_PATH \ - "CREATE INDEX IF NOT EXISTS idx_pl_path ON playlists(path);" - -#define I_PL_DISABLED \ - "CREATE INDEX IF NOT EXISTS idx_pl_disabled ON playlists(disabled);" - -#define I_FILEPATH \ - "CREATE INDEX IF NOT EXISTS idx_filepath ON playlistitems(filepath ASC);" - -#define I_PLITEMID \ - "CREATE INDEX IF NOT EXISTS idx_playlistid ON playlistitems(playlistid, filepath);" - -#define I_GRP_TYPE_PERSIST \ - "CREATE INDEX IF NOT EXISTS idx_grp_type_persist ON groups(type, persistentid);" - -#define I_PAIRING \ - "CREATE INDEX IF NOT EXISTS idx_pairingguid ON pairings(guid);" - - #define TRG_GROUPS_INSERT_FILES \ "CREATE TRIGGER update_groups_new_file AFTER INSERT ON files FOR EACH ROW" \ " BEGIN" \ @@ -4430,7 +4381,7 @@ struct db_init_query { char *desc; }; -static const struct db_init_query db_init_queries[] = +static const struct db_init_query db_init_table_queries[] = { { T_ADMIN, "create table admin" }, { T_FILES, "create table files" }, @@ -4441,6 +4392,70 @@ static const struct db_init_query db_init_queries[] = { T_SPEAKERS, "create table speakers" }, { T_INOTIFY, "create table inotify" }, + { TRG_GROUPS_INSERT_FILES, "create trigger update_groups_new_file" }, + { TRG_GROUPS_UPDATE_FILES, "create trigger update_groups_update_file" }, + + { Q_PL1, "create default playlist" }, + { Q_PL2, "create default smart playlist 'Music'" }, + { Q_PL3, "create default smart playlist 'Movies'" }, + { Q_PL4, "create default smart playlist 'TV Shows'" }, + { Q_PL5, "create default smart playlist 'Podcasts'" }, + { Q_PL6, "create default smart playlist 'Audiobooks'" }, + + { Q_SCVER, "set schema version" }, + }; + + +#define I_RESCAN \ + "CREATE INDEX IF NOT EXISTS idx_rescan ON files(path, db_timestamp);" + +#define I_SONGARTISTID \ + "CREATE INDEX IF NOT EXISTS idx_sari ON files(songartistid);" + +#define I_SONGALBUMID \ + "CREATE INDEX IF NOT EXISTS idx_sali ON files(songalbumid);" + +#define I_STATEMKINDSARI \ + "CREATE INDEX IF NOT EXISTS idx_state_mkind_sari ON files(disabled, media_kind, songartistid);" + +#define I_STATEMKINDSALI \ + "CREATE INDEX IF NOT EXISTS idx_state_mkind_sali ON files(disabled, media_kind, songalbumid);" + +#define I_ARTIST \ + "CREATE INDEX IF NOT EXISTS idx_artist ON files(artist, artist_sort);" + +#define I_ALBUMARTIST \ + "CREATE INDEX IF NOT EXISTS idx_albumartist ON files(album_artist, album_artist_sort);" + +#define I_COMPOSER \ + "CREATE INDEX IF NOT EXISTS idx_composer ON files(composer, composer_sort);" + +#define I_TITLE \ + "CREATE INDEX IF NOT EXISTS idx_title ON files(title, title_sort);" + +#define I_ALBUM \ + "CREATE INDEX IF NOT EXISTS idx_album ON files(album, album_sort);" + +#define I_PL_PATH \ + "CREATE INDEX IF NOT EXISTS idx_pl_path ON playlists(path);" + +#define I_PL_DISABLED \ + "CREATE INDEX IF NOT EXISTS idx_pl_disabled ON playlists(disabled);" + +#define I_FILEPATH \ + "CREATE INDEX IF NOT EXISTS idx_filepath ON playlistitems(filepath ASC);" + +#define I_PLITEMID \ + "CREATE INDEX IF NOT EXISTS idx_playlistid ON playlistitems(playlistid, filepath);" + +#define I_GRP_TYPE_PERSIST \ + "CREATE INDEX IF NOT EXISTS idx_grp_type_persist ON groups(type, persistentid);" + +#define I_PAIRING \ + "CREATE INDEX IF NOT EXISTS idx_pairingguid ON pairings(guid);" + +static const struct db_init_query db_init_index_queries[] = + { { I_RESCAN, "create rescan index" }, { I_SONGARTISTID, "create songartistid index" }, { I_SONGALBUMID, "create songalbumid index" }, @@ -4462,32 +4477,20 @@ static const struct db_init_query db_init_queries[] = { I_GRP_TYPE_PERSIST, "create groups type/persistentid index" }, { I_PAIRING, "create pairing guid index" }, - - { TRG_GROUPS_INSERT_FILES, "create trigger update_groups_new_file" }, - { TRG_GROUPS_UPDATE_FILES, "create trigger update_groups_update_file" }, - - { Q_PL1, "create default playlist" }, - { Q_PL2, "create default smart playlist 'Music'" }, - { Q_PL3, "create default smart playlist 'Movies'" }, - { Q_PL4, "create default smart playlist 'TV Shows'" }, - { Q_PL5, "create default smart playlist 'Podcasts'" }, - { Q_PL6, "create default smart playlist 'Audiobooks'" }, - - { Q_SCVER, "set schema version" }, }; static int -db_create_tables(void) +db_create_indices(void) { char *errmsg; int i; int ret; - for (i = 0; i < (sizeof(db_init_queries) / sizeof(db_init_queries[0])); i++) + for (i = 0; i < (sizeof(db_init_index_queries) / sizeof(db_init_index_queries[0])); i++) { - DPRINTF(E_DBG, L_DB, "DB init query: %s\n", db_init_queries[i].desc); + DPRINTF(E_DBG, L_DB, "DB init index query: %s\n", db_init_index_queries[i].desc); - ret = sqlite3_exec(hdl, db_init_queries[i].query, NULL, NULL, &errmsg); + ret = sqlite3_exec(hdl, db_init_index_queries[i].query, NULL, NULL, &errmsg); if (ret != SQLITE_OK) { DPRINTF(E_FATAL, L_DB, "DB init error: %s\n", errmsg); @@ -4500,6 +4503,95 @@ db_create_tables(void) return 0; } +static int +db_drop_indices(void) +{ +#define Q_INDEX "SELECT name FROM sqlite_master WHERE type == 'index' AND name LIKE 'idx_%';" +#define Q_TMPL "DROP INDEX %q;" + sqlite3_stmt *stmt; + char *errmsg; + char *query; + char *index[256]; + int ret; + int i; + int n; + + DPRINTF(E_DBG, L_DB, "Running query '%s'\n", Q_INDEX); + + ret = sqlite3_prepare_v2(hdl, Q_INDEX, strlen(Q_INDEX) + 1, &stmt, NULL); + if (ret != SQLITE_OK) + { + DPRINTF(E_LOG, L_DB, "Could not prepare statement: %s\n", sqlite3_errmsg(hdl)); + return -1; + } + + n = 0; + while ((ret = sqlite3_step(stmt)) == SQLITE_ROW) + { + index[n] = strdup((char *)sqlite3_column_text(stmt, 0)); + n++; + } + + if (ret != SQLITE_DONE) + { + DPRINTF(E_LOG, L_DB, "Could not step: %s\n", sqlite3_errmsg(hdl)); + + sqlite3_finalize(stmt); + return -1; + } + + sqlite3_finalize(stmt); + + for (i = 0; i < n; i++) + { + query = sqlite3_mprintf(Q_TMPL, index[i]); + free(index[i]); + + DPRINTF(E_DBG, L_DB, "Running query '%s'\n", query); + + ret = sqlite3_exec(hdl, query, NULL, NULL, &errmsg); + if (ret != SQLITE_OK) + { + DPRINTF(E_LOG, L_DB, "DB error while running '%s': %s\n", query, errmsg); + + sqlite3_free(errmsg); + return -1; + } + + sqlite3_free(query); + } + + return 0; +#undef Q_TMPL +#undef Q_INDEX +} + +static int +db_create_tables(void) +{ + char *errmsg; + int i; + int ret; + + for (i = 0; i < (sizeof(db_init_table_queries) / sizeof(db_init_table_queries[0])); i++) + { + DPRINTF(E_DBG, L_DB, "DB init table query: %s\n", db_init_table_queries[i].desc); + + ret = sqlite3_exec(hdl, db_init_table_queries[i].query, NULL, NULL, &errmsg); + if (ret != SQLITE_OK) + { + DPRINTF(E_FATAL, L_DB, "DB init error: %s\n", errmsg); + + sqlite3_free(errmsg); + return -1; + } + } + + ret = db_create_indices(); + + return ret; +} + static int db_generic_upgrade(const struct db_init_query *queries, int nqueries) { @@ -4954,18 +5046,6 @@ db_upgrade_v11(void) " album_artist_sort VARCHAR(1024) DEFAULT NULL COLLATE DAAP" \ ");" -#define U_V12_IDX_PATH \ - "CREATE INDEX IF NOT EXISTS idx_path ON files(path, idx);" - -#define U_V12_IDX_TS \ - "CREATE INDEX IF NOT EXISTS idx_titlesort ON files(title_sort);" - -#define U_V12_IDX_AS \ - "CREATE INDEX IF NOT EXISTS idx_artistsort ON files(artist_sort);" - -#define U_V12_IDX_BS \ - "CREATE INDEX IF NOT EXISTS idx_albumsort ON files(album_sort);" - #define U_V12_TRG1 \ "CREATE TRIGGER update_groups_new_file AFTER INSERT ON files FOR EACH ROW" \ " BEGIN" \ @@ -4983,11 +5063,6 @@ db_upgrade_v11(void) static const struct db_init_query db_upgrade_v12_queries[] = { - { U_V12_IDX_PATH, "create index path table files" }, - { U_V12_IDX_TS, "create index titlesort table files" }, - { U_V12_IDX_AS, "create index artistsort table files" }, - { U_V12_IDX_BS, "create index albumsort table files" }, - { U_V12_TRG1, "create trigger update_groups_new_file" }, { U_V12_TRG2, "create trigger update_groups_update_file" }, @@ -5028,51 +5103,6 @@ db_upgrade_v12(void) /* Upgrade from schema v12 to v13 */ -#define U_V13_DROP_IDX_PATH \ - "DROP INDEX idx_path;" - -#define U_V13_DROP_IDX_TS \ - "DROP INDEX idx_titlesort;" - -#define U_V13_DROP_IDX_AS \ - "DROP INDEX idx_artistsort;" - -#define U_V13_DROP_IDX_BS \ - "DROP INDEX idx_albumsort;" - -#define U_V13_IDX_RESCAN \ - "CREATE INDEX IF NOT EXISTS idx_rescan ON files(path, db_timestamp);" - -#define U_V13_IDX_SONGALBUMID \ - "CREATE INDEX IF NOT EXISTS idx_sai ON files(songalbumid);" - -#define U_V13_IDX_STATEMKINDSAI \ - "CREATE INDEX IF NOT EXISTS idx_state_mkind_sai ON files(disabled, media_kind, songalbumid);" - -#define U_V13_IDX_ARTIST \ - "CREATE INDEX IF NOT EXISTS idx_artist ON files(artist, artist_sort);" - -#define U_V13_IDX_ALBUMARTIST \ - "CREATE INDEX IF NOT EXISTS idx_albumartist ON files(album_artist, album_artist_sort);" - -#define U_V13_IDX_COMPOSER \ - "CREATE INDEX IF NOT EXISTS idx_composer ON files(composer, composer_sort);" - -#define U_V13_IDX_TITLE \ - "CREATE INDEX IF NOT EXISTS idx_title ON files(title, title_sort);" - -#define U_V13_IDX_ALBUM \ - "CREATE INDEX IF NOT EXISTS idx_album ON files(album, album_sort);" - -#define U_V13_IDX_GRP_TYPE_PERSIST \ - "CREATE INDEX IF NOT EXISTS idx_grp_type_persist ON groups(type, persistentid);" - -#define U_V13_IDX_PL_PATH \ - "CREATE INDEX IF NOT EXISTS idx_pl_path ON playlists(path);" - -#define U_V13_IDX_PL_DISABLED \ - "CREATE INDEX IF NOT EXISTS idx_pl_disabled ON playlists(disabled);" - #define U_V13_PL2 \ "UPDATE playlists SET query = 'f.media_kind = 1' where id = 2;" @@ -5087,25 +5117,6 @@ db_upgrade_v12(void) static const struct db_init_query db_upgrade_v13_queries[] = { - { U_V13_DROP_IDX_PATH, "drop index path table files" }, - { U_V13_DROP_IDX_TS, "drop index titlesort table files" }, - { U_V13_DROP_IDX_AS, "drop index artistsort table files" }, - { U_V13_DROP_IDX_BS, "drop index albumsort table files" }, - - { U_V13_IDX_RESCAN, "create rescan index" }, - { U_V13_IDX_SONGALBUMID, "create songalbumid index" }, - { U_V13_IDX_STATEMKINDSAI, "create state/mkind/sai index" }, - { U_V13_IDX_ARTIST, "create artist index" }, - { U_V13_IDX_ALBUMARTIST, "create album_artist index" }, - { U_V13_IDX_COMPOSER, "create composer index" }, - { U_V13_IDX_TITLE, "create title index" }, - { U_V13_IDX_ALBUM, "create album index" }, - - { U_V13_IDX_GRP_TYPE_PERSIST, "create groups type/persistentid index" }, - - { U_V13_IDX_PL_PATH, "create playlist path index" }, - { U_V13_IDX_PL_DISABLED, "create playlist state index" }, - { U_V13_PL2, "update default smart playlist 'Music'" }, { U_V13_PL3, "update default smart playlist 'Movies'" }, { U_V13_PL4, "update default smart playlist 'TV Shows'" }, @@ -5188,36 +5199,6 @@ static const struct db_init_query db_upgrade_v13_queries[] = #define U_V14_DELETE_PL6_2 \ "DELETE FROM playlistitems WHERE playlistid=6;" -#define U_V14_IDX_RESCAN \ - "CREATE INDEX IF NOT EXISTS idx_rescan ON files(path, db_timestamp);" - -#define U_V14_IDX_SONGARTISTID \ - "CREATE INDEX IF NOT EXISTS idx_sari ON files(songartistid);" - -#define U_V14_IDX_SONGALBUMID \ - "CREATE INDEX IF NOT EXISTS idx_sali ON files(songalbumid);" - -#define U_V14_IDX_STATEMKINDSARI \ - "CREATE INDEX IF NOT EXISTS idx_state_mkind_sari ON files(disabled, media_kind, songartistid);" - -#define U_V14_IDX_STATEMKINDSALI \ - "CREATE INDEX IF NOT EXISTS idx_state_mkind_sali ON files(disabled, media_kind, songalbumid);" - -#define U_V14_IDX_ARTIST \ - "CREATE INDEX IF NOT EXISTS idx_artist ON files(artist, artist_sort);" - -#define U_V14_IDX_ALBUMARTIST \ - "CREATE INDEX IF NOT EXISTS idx_albumartist ON files(album_artist, album_artist_sort);" - -#define U_V14_IDX_COMPOSER \ - "CREATE INDEX IF NOT EXISTS idx_composer ON files(composer, composer_sort);" - -#define U_V14_IDX_TITLE \ - "CREATE INDEX IF NOT EXISTS idx_title ON files(title, title_sort);" - -#define U_V14_IDX_ALBUM \ - "CREATE INDEX IF NOT EXISTS idx_album ON files(album, album_sort);" - #define U_V14_TRG1 \ "CREATE TRIGGER update_groups_new_file AFTER INSERT ON files FOR EACH ROW" \ " BEGIN" \ @@ -5250,18 +5231,6 @@ static const struct db_init_query db_upgrade_v14_queries[] = { U_V14_DELETE_PL6_1, "delete playlist id 6 table playlists" }, { U_V14_DELETE_PL6_2, "delete playlist id 6 table playlistitems" }, - { U_V14_IDX_RESCAN, "create rescan index table files" }, - { U_V14_IDX_SONGARTISTID, "create songartistid index table files" }, - { U_V14_IDX_SONGALBUMID, "create songalbumid index table files" }, - { U_V14_IDX_STATEMKINDSARI, "create state/mkind/sari index table files" }, - { U_V14_IDX_STATEMKINDSALI, "create state/mkind/sali index table files" }, - - { U_V14_IDX_ARTIST, "create artist index table files" }, - { U_V14_IDX_ALBUMARTIST, "create album_artist index table files" }, - { U_V14_IDX_COMPOSER, "create composer index table files" }, - { U_V14_IDX_TITLE, "create title index table files" }, - { U_V14_IDX_ALBUM, "create album index table files" }, - { U_V14_TRG1, "create trigger update_groups_new_file" }, { U_V14_TRG2, "create trigger update_groups_update_file" }, @@ -5368,36 +5337,6 @@ db_upgrade_v14(void) " album_artist_sort VARCHAR(1024) DEFAULT NULL COLLATE DAAP" \ ");" -#define U_V15_IDX_RESCAN \ - "CREATE INDEX IF NOT EXISTS idx_rescan ON files(path, db_timestamp);" - -#define U_V15_IDX_SONGARTISTID \ - "CREATE INDEX IF NOT EXISTS idx_sari ON files(songartistid);" - -#define U_V15_IDX_SONGALBUMID \ - "CREATE INDEX IF NOT EXISTS idx_sali ON files(songalbumid);" - -#define U_V15_IDX_STATEMKINDSARI \ - "CREATE INDEX IF NOT EXISTS idx_state_mkind_sari ON files(disabled, media_kind, songartistid);" - -#define U_V15_IDX_STATEMKINDSALI \ - "CREATE INDEX IF NOT EXISTS idx_state_mkind_sali ON files(disabled, media_kind, songalbumid);" - -#define U_V15_IDX_ARTIST \ - "CREATE INDEX IF NOT EXISTS idx_artist ON files(artist, artist_sort);" - -#define U_V15_IDX_ALBUMARTIST \ - "CREATE INDEX IF NOT EXISTS idx_albumartist ON files(album_artist, album_artist_sort);" - -#define U_V15_IDX_COMPOSER \ - "CREATE INDEX IF NOT EXISTS idx_composer ON files(composer, composer_sort);" - -#define U_V15_IDX_TITLE \ - "CREATE INDEX IF NOT EXISTS idx_title ON files(title, title_sort);" - -#define U_V15_IDX_ALBUM \ - "CREATE INDEX IF NOT EXISTS idx_album ON files(album, album_sort);" - #define U_V15_TRG1 \ "CREATE TRIGGER update_groups_new_file AFTER INSERT ON files FOR EACH ROW" \ " BEGIN" \ @@ -5417,18 +5356,6 @@ db_upgrade_v14(void) static const struct db_init_query db_upgrade_v15_queries[] = { - { U_V15_IDX_RESCAN, "create rescan index table files" }, - { U_V15_IDX_SONGARTISTID, "create songartistid index table files" }, - { U_V15_IDX_SONGALBUMID, "create songalbumid index table files" }, - { U_V15_IDX_STATEMKINDSARI, "create state/mkind/sari index table files" }, - { U_V15_IDX_STATEMKINDSALI, "create state/mkind/sali index table files" }, - - { U_V15_IDX_ARTIST, "create artist index table files" }, - { U_V15_IDX_ALBUMARTIST, "create album_artist index table files" }, - { U_V15_IDX_COMPOSER, "create composer index table files" }, - { U_V15_IDX_TITLE, "create title index table files" }, - { U_V15_IDX_ALBUM, "create album index table files" }, - { U_V15_TRG1, "create trigger update_groups_new_file" }, { U_V15_TRG2, "create trigger update_groups_update_file" }, @@ -5510,6 +5437,10 @@ db_check_version(void) { DPRINTF(E_LOG, L_DB, "Database schema outdated, schema upgrade needed v%d -> v%d\n", cur_ver, SCHEMA_VERSION); + ret = db_drop_indices(); + if (ret < 0) + return -1; + switch (cur_ver) { case 10: @@ -5568,6 +5499,10 @@ db_check_version(void) return -1; } + ret = db_create_indices(); + if (ret < 0) + return -1; + /* What about some housekeeping work, eh? */ DPRINTF(E_INFO, L_DB, "Now vacuuming database, this may take some time...\n"); From 27a2fabb564a1dde35f12c8b2d6865225d4e8ef0 Mon Sep 17 00:00:00 2001 From: ejurgensen Date: Fri, 9 Jan 2015 23:04:50 +0100 Subject: [PATCH 11/17] Modify groups queries and improve index --- src/db.c | 28 ++++++++++++++++------------ 1 file changed, 16 insertions(+), 12 deletions(-) diff --git a/src/db.c b/src/db.c index bdab170f..3a28d89f 100644 --- a/src/db.c +++ b/src/db.c @@ -1197,13 +1197,13 @@ db_build_query_group_albums(struct query_params *qp, char **q) sort = sort_clause[qp->sort]; if (idx && qp->filter) - query = sqlite3_mprintf("SELECT g.id, g.persistentid, f.album, f.album_sort, COUNT(f.id), 1, f.album_artist, f.songartistid FROM files f, groups g WHERE f.songalbumid = g.persistentid AND g.type = %d AND f.disabled = 0 AND %s GROUP BY f.album, g.name %s %s;", G_ALBUMS, qp->filter, sort, idx); + query = sqlite3_mprintf("SELECT g.id, g.persistentid, f.album, f.album_sort, COUNT(f.id), 1, f.album_artist, f.songartistid FROM files f JOIN groups g ON f.songalbumid = g.persistentid WHERE f.disabled = 0 AND %s GROUP BY f.songalbumid %s %s;", qp->filter, sort, idx); else if (idx) - query = sqlite3_mprintf("SELECT g.id, g.persistentid, f.album, f.album_sort, COUNT(f.id), 1, f.album_artist, f.songartistid FROM files f, groups g WHERE f.songalbumid = g.persistentid AND g.type = %d AND f.disabled = 0 GROUP BY f.album, g.name %s %s;", G_ALBUMS, sort, idx); + query = sqlite3_mprintf("SELECT g.id, g.persistentid, f.album, f.album_sort, COUNT(f.id), 1, f.album_artist, f.songartistid FROM files f JOIN groups g ON f.songalbumid = g.persistentid WHERE f.disabled = 0 GROUP BY f.songalbumid %s %s;", sort, idx); else if (qp->filter) - query = sqlite3_mprintf("SELECT g.id, g.persistentid, f.album, f.album_sort, COUNT(f.id), 1, f.album_artist, f.songartistid FROM files f, groups g WHERE f.songalbumid = g.persistentid AND g.type = %d AND f.disabled = 0 AND %s GROUP BY f.album, g.name %s;", G_ALBUMS, qp->filter, sort); + query = sqlite3_mprintf("SELECT g.id, g.persistentid, f.album, f.album_sort, COUNT(f.id), 1, f.album_artist, f.songartistid FROM files f JOIN groups g ON f.songalbumid = g.persistentid WHERE f.disabled = 0 AND %s GROUP BY f.songalbumid %s;", qp->filter, sort); else - query = sqlite3_mprintf("SELECT g.id, g.persistentid, f.album, f.album_sort, COUNT(f.id), 1, f.album_artist, f.songartistid FROM files f, groups g WHERE f.songalbumid = g.persistentid AND g.type = %d AND f.disabled = 0 GROUP BY f.album, g.name %s;", G_ALBUMS, sort); + query = sqlite3_mprintf("SELECT g.id, g.persistentid, f.album, f.album_sort, COUNT(f.id), 1, f.album_artist, f.songartistid FROM files f JOIN groups g ON f.songalbumid = g.persistentid WHERE f.disabled = 0 GROUP BY f.songalbumid %s;", sort); if (!query) { @@ -1236,13 +1236,13 @@ db_build_query_group_artists(struct query_params *qp, char **q) sort = sort_clause[qp->sort]; if (idx && qp->filter) - query = sqlite3_mprintf("SELECT g.id, g.persistentid, f.album_artist, f.album_artist_sort, COUNT(f.id), COUNT(DISTINCT f.songalbumid), f.album_artist, f.songartistid FROM files f, groups g WHERE f.songartistid = g.persistentid AND g.type = %d AND f.disabled = 0 AND %s GROUP BY f.album_artist, g.name %s %s;", G_ARTISTS, qp->filter, sort, idx); + query = sqlite3_mprintf("SELECT g.id, g.persistentid, f.album_artist, f.album_artist_sort, COUNT(f.id), COUNT(DISTINCT f.songalbumid), f.album_artist, f.songartistid FROM files f JOIN groups g ON f.songartistid = g.persistentid WHERE f.disabled = 0 AND %s GROUP BY f.songartistid %s %s;", qp->filter, sort, idx); else if (idx) - query = sqlite3_mprintf("SELECT g.id, g.persistentid, f.album_artist, f.album_artist_sort, COUNT(f.id), COUNT(DISTINCT f.songalbumid), f.album_artist, f.songartistid FROM files f, groups g WHERE f.songartistid = g.persistentid AND g.type = %d AND f.disabled = 0 GROUP BY f.album_artist, g.name %s %s;", G_ARTISTS, sort, idx); + query = sqlite3_mprintf("SELECT g.id, g.persistentid, f.album_artist, f.album_artist_sort, COUNT(f.id), COUNT(DISTINCT f.songalbumid), f.album_artist, f.songartistid FROM files f JOIN groups g ON f.songartistid = g.persistentid WHERE f.disabled = 0 GROUP BY f.songartistid %s %s;", sort, idx); else if (qp->filter) - query = sqlite3_mprintf("SELECT g.id, g.persistentid, f.album_artist, f.album_artist_sort, COUNT(f.id), COUNT(DISTINCT f.songalbumid), f.album_artist, f.songartistid FROM files f, groups g WHERE f.songartistid = g.persistentid AND g.type = %d AND f.disabled = 0 AND %s GROUP BY f.album_artist, g.name %s;", G_ARTISTS, qp->filter, sort); + query = sqlite3_mprintf("SELECT g.id, g.persistentid, f.album_artist, f.album_artist_sort, COUNT(f.id), COUNT(DISTINCT f.songalbumid), f.album_artist, f.songartistid FROM files f JOIN groups g ON f.songartistid = g.persistentid WHERE f.disabled = 0 AND %s GROUP BY f.songartistid %s;", qp->filter, sort); else - query = sqlite3_mprintf("SELECT g.id, g.persistentid, f.album_artist, f.album_artist_sort, COUNT(f.id), COUNT(DISTINCT f.songalbumid), f.album_artist, f.songartistid FROM files f, groups g WHERE f.songartistid = g.persistentid AND g.type = %d AND f.disabled = 0 GROUP BY f.album_artist, g.name %s;", G_ARTISTS, sort); + query = sqlite3_mprintf("SELECT g.id, g.persistentid, f.album_artist, f.album_artist_sort, COUNT(f.id), COUNT(DISTINCT f.songalbumid), f.album_artist, f.songartistid FROM files f JOIN groups g ON f.songartistid = g.persistentid WHERE f.disabled = 0 GROUP BY f.songartistid %s;", sort); if (!query) { @@ -4406,15 +4406,19 @@ static const struct db_init_query db_init_table_queries[] = }; +/* Indexes must be prefixed with idx_ for db_drop_indices() to id them */ + #define I_RESCAN \ "CREATE INDEX IF NOT EXISTS idx_rescan ON files(path, db_timestamp);" #define I_SONGARTISTID \ "CREATE INDEX IF NOT EXISTS idx_sari ON files(songartistid);" +/* Used by Q_GROUP_ALBUMS */ #define I_SONGALBUMID \ - "CREATE INDEX IF NOT EXISTS idx_sali ON files(songalbumid);" + "CREATE INDEX IF NOT EXISTS idx_sali ON files(songalbumid, disabled, media_kind, album_sort, disc, track);" +/* Used by Q_GROUP_ARTISTS */ #define I_STATEMKINDSARI \ "CREATE INDEX IF NOT EXISTS idx_state_mkind_sari ON files(disabled, media_kind, songartistid);" @@ -4448,8 +4452,8 @@ static const struct db_init_query db_init_table_queries[] = #define I_PLITEMID \ "CREATE INDEX IF NOT EXISTS idx_playlistid ON playlistitems(playlistid, filepath);" -#define I_GRP_TYPE_PERSIST \ - "CREATE INDEX IF NOT EXISTS idx_grp_type_persist ON groups(type, persistentid);" +#define I_GRP_PERSIST \ + "CREATE INDEX IF NOT EXISTS idx_grp_persist ON groups(persistentid);" #define I_PAIRING \ "CREATE INDEX IF NOT EXISTS idx_pairingguid ON pairings(guid);" @@ -4474,7 +4478,7 @@ static const struct db_init_query db_init_index_queries[] = { I_FILEPATH, "create file path index" }, { I_PLITEMID, "create playlist id index" }, - { I_GRP_TYPE_PERSIST, "create groups type/persistentid index" }, + { I_GRP_PERSIST, "create groups persistentid index" }, { I_PAIRING, "create pairing guid index" }, }; From 2208c021aa526b7ec6d9d13f9f233f8ce681208b Mon Sep 17 00:00:00 2001 From: ejurgensen Date: Fri, 9 Jan 2015 23:58:27 +0100 Subject: [PATCH 12/17] Improve browse queries (credit @chme) Adjusted re-commit of commit ec47c6e730106d511ea5054102233411d4980878 --- src/db.c | 30 ++++++++++++++++++------------ 1 file changed, 18 insertions(+), 12 deletions(-) diff --git a/src/db.c b/src/db.c index 3a28d89f..f0874fb8 100644 --- a/src/db.c +++ b/src/db.c @@ -1433,28 +1433,28 @@ db_build_query_browse(struct query_params *qp, char *field, char *sort_field, ch } else { - size = strlen("ORDER BY f.") + strlen(field) + 1; + size = strlen("ORDER BY f.") + strlen(sort_field) + 1; sort = malloc(size); if (!sort) { DPRINTF(E_LOG, L_DB, "Out of memory for sort string\n"); return -1; } - snprintf(sort, size, "ORDER BY f.%s", field); + snprintf(sort, size, "ORDER BY f.%s", sort_field); } if (idx && qp->filter) - query = sqlite3_mprintf("SELECT DISTINCT f.%s, f.%s FROM files f WHERE f.disabled = 0 AND f.%s != ''" - " AND %s %s %s;", field, sort_field, field, qp->filter, sort, idx); + query = sqlite3_mprintf("SELECT f.%s, f.%s FROM files f WHERE f.disabled = 0 AND f.%s != ''" + " AND %s GROUP BY f.%s %s %s;", field, sort_field, field, qp->filter, field, sort, idx); else if (idx) - query = sqlite3_mprintf("SELECT DISTINCT f.%s, f.%s FROM files f WHERE f.disabled = 0 AND f.%s != ''" - " %s %s;", field, sort_field, field, sort, idx); + query = sqlite3_mprintf("SELECT f.%s, f.%s FROM files f WHERE f.disabled = 0 AND f.%s != ''" + " GROUP BY f.%s %s %s;", field, sort_field, field, field, sort, idx); else if (qp->filter) - query = sqlite3_mprintf("SELECT DISTINCT f.%s, f.%s FROM files f WHERE f.disabled = 0 AND f.%s != ''" - " AND %s %s;", field, sort_field, field, qp->filter, sort); + query = sqlite3_mprintf("SELECT f.%s, f.%s FROM files f WHERE f.disabled = 0 AND f.%s != ''" + " AND %s GROUP BY f.%s %s;", field, sort_field, field, qp->filter, field, sort); else - query = sqlite3_mprintf("SELECT DISTINCT f.%s, f.%s FROM files f WHERE f.disabled = 0 AND f.%s != '' %s", - field, sort_field, field, sort); + query = sqlite3_mprintf("SELECT f.%s, f.%s FROM files f WHERE f.disabled = 0 AND f.%s != ''" + " GROUP BY f.%s %s", field, sort_field, field, field, sort); free(sort); @@ -4431,11 +4431,17 @@ static const struct db_init_query db_init_table_queries[] = #define I_ALBUMARTIST \ "CREATE INDEX IF NOT EXISTS idx_albumartist ON files(album_artist, album_artist_sort);" +/* Used by Q_BROWSE_COMPOSERS */ #define I_COMPOSER \ - "CREATE INDEX IF NOT EXISTS idx_composer ON files(composer, composer_sort);" + "CREATE INDEX IF NOT EXISTS idx_composer ON files(disabled, media_kind, composer_sort);" +/* Used by Q_BROWSE_GENRES */ +#define I_GENRE \ + "CREATE INDEX IF NOT EXISTS idx_genre ON files(disabled, media_kind, genre);" + +/* Used by Q_PLITEMS for smart playlists */ #define I_TITLE \ - "CREATE INDEX IF NOT EXISTS idx_title ON files(title, title_sort);" + "CREATE INDEX IF NOT EXISTS idx_title ON files(disabled, media_kind, title_sort);" #define I_ALBUM \ "CREATE INDEX IF NOT EXISTS idx_album ON files(album, album_sort);" From bfa9f4d5cf322fff480d4795d79533f840f9c975 Mon Sep 17 00:00:00 2001 From: ejurgensen Date: Sat, 10 Jan 2015 00:08:50 +0100 Subject: [PATCH 13/17] Upgrade db schema to v16 --- src/db.c | 19 +++++++++++++++++-- 1 file changed, 17 insertions(+), 2 deletions(-) diff --git a/src/db.c b/src/db.c index f0874fb8..22537b4f 100644 --- a/src/db.c +++ b/src/db.c @@ -4372,9 +4372,9 @@ db_perthread_deinit(void) " VALUES(8, 'Purchased', 0, 'media_kind = 1024', 0, '', 0, 8);" */ -#define SCHEMA_VERSION 15 +#define SCHEMA_VERSION 16 #define Q_SCVER \ - "INSERT INTO admin (key, value) VALUES ('schema_version', '15');" + "INSERT INTO admin (key, value) VALUES ('schema_version', '16');" struct db_init_query { char *query; @@ -5405,6 +5405,14 @@ db_upgrade_v15(void) #undef Q_DUMP } +#define U_V16_SCVER \ + "UPDATE admin SET value = '16' WHERE key = 'schema_version';" + +static const struct db_init_query db_upgrade_v16_queries[] = + { + { U_V16_SCVER, "set schema_version to 16" }, + }; + static int db_check_version(void) { @@ -5502,6 +5510,13 @@ db_check_version(void) if (ret < 0) return -1; + /* FALLTHROUGH */ + + case 15: + ret = db_generic_upgrade(db_upgrade_v16_queries, sizeof(db_upgrade_v16_queries) / sizeof(db_upgrade_v16_queries[0])); + if (ret < 0) + return -1; + break; default: From a96af67a30e687cc8f73d3045f6bceffffb2d003 Mon Sep 17 00:00:00 2001 From: ejurgensen Date: Sat, 10 Jan 2015 00:45:19 +0100 Subject: [PATCH 14/17] Some fixing up of prev commit --- src/db.c | 9 +++++---- 1 file changed, 5 insertions(+), 4 deletions(-) diff --git a/src/db.c b/src/db.c index 22537b4f..225cc004 100644 --- a/src/db.c +++ b/src/db.c @@ -1445,16 +1445,16 @@ db_build_query_browse(struct query_params *qp, char *field, char *sort_field, ch if (idx && qp->filter) query = sqlite3_mprintf("SELECT f.%s, f.%s FROM files f WHERE f.disabled = 0 AND f.%s != ''" - " AND %s GROUP BY f.%s %s %s;", field, sort_field, field, qp->filter, field, sort, idx); + " AND %s GROUP BY f.%s %s %s;", field, sort_field, field, qp->filter, sort_field, sort, idx); else if (idx) query = sqlite3_mprintf("SELECT f.%s, f.%s FROM files f WHERE f.disabled = 0 AND f.%s != ''" - " GROUP BY f.%s %s %s;", field, sort_field, field, field, sort, idx); + " GROUP BY f.%s %s %s;", field, sort_field, field, sort_field, sort, idx); else if (qp->filter) query = sqlite3_mprintf("SELECT f.%s, f.%s FROM files f WHERE f.disabled = 0 AND f.%s != ''" - " AND %s GROUP BY f.%s %s;", field, sort_field, field, qp->filter, field, sort); + " AND %s GROUP BY f.%s %s;", field, sort_field, field, qp->filter, sort_field, sort); else query = sqlite3_mprintf("SELECT f.%s, f.%s FROM files f WHERE f.disabled = 0 AND f.%s != ''" - " GROUP BY f.%s %s", field, sort_field, field, field, sort); + " GROUP BY f.%s %s", field, sort_field, field, sort_field, sort); free(sort); @@ -4475,6 +4475,7 @@ static const struct db_init_query db_init_index_queries[] = { I_ARTIST, "create artist index" }, { I_ALBUMARTIST, "create album_artist index" }, { I_COMPOSER, "create composer index" }, + { I_GENRE, "create genre index" }, { I_TITLE, "create title index" }, { I_ALBUM, "create album index" }, From b605dc2fc36c60a9c41bf342cbba8797b5ede844 Mon Sep 17 00:00:00 2001 From: ejurgensen Date: Sat, 10 Jan 2015 19:19:45 +0100 Subject: [PATCH 15/17] Spelling mistake --- src/db.c | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/src/db.c b/src/db.c index 225cc004..f6feac01 100644 --- a/src/db.c +++ b/src/db.c @@ -4406,7 +4406,7 @@ static const struct db_init_query db_init_table_queries[] = }; -/* Indexes must be prefixed with idx_ for db_drop_indices() to id them */ +/* Indices must be prefixed with idx_ for db_drop_indices() to id them */ #define I_RESCAN \ "CREATE INDEX IF NOT EXISTS idx_rescan ON files(path, db_timestamp);" From 1f81b5ce7ec912e42c0e447dc3e59be1d76b054a Mon Sep 17 00:00:00 2001 From: ejurgensen Date: Sat, 10 Jan 2015 20:31:13 +0100 Subject: [PATCH 16/17] Revert "Upgrade db schema to v16" This reverts commit bfa9f4d5cf322fff480d4795d79533f840f9c975. --- src/db.c | 19 ++----------------- 1 file changed, 2 insertions(+), 17 deletions(-) diff --git a/src/db.c b/src/db.c index f6feac01..028602fc 100644 --- a/src/db.c +++ b/src/db.c @@ -4372,9 +4372,9 @@ db_perthread_deinit(void) " VALUES(8, 'Purchased', 0, 'media_kind = 1024', 0, '', 0, 8);" */ -#define SCHEMA_VERSION 16 +#define SCHEMA_VERSION 15 #define Q_SCVER \ - "INSERT INTO admin (key, value) VALUES ('schema_version', '16');" + "INSERT INTO admin (key, value) VALUES ('schema_version', '15');" struct db_init_query { char *query; @@ -5406,14 +5406,6 @@ db_upgrade_v15(void) #undef Q_DUMP } -#define U_V16_SCVER \ - "UPDATE admin SET value = '16' WHERE key = 'schema_version';" - -static const struct db_init_query db_upgrade_v16_queries[] = - { - { U_V16_SCVER, "set schema_version to 16" }, - }; - static int db_check_version(void) { @@ -5511,13 +5503,6 @@ db_check_version(void) if (ret < 0) return -1; - /* FALLTHROUGH */ - - case 15: - ret = db_generic_upgrade(db_upgrade_v16_queries, sizeof(db_upgrade_v16_queries) / sizeof(db_upgrade_v16_queries[0])); - if (ret < 0) - return -1; - break; default: From 829619be5d91fcc9417194ca8c5f8cee08738a9c Mon Sep 17 00:00:00 2001 From: ejurgensen Date: Sat, 10 Jan 2015 22:44:26 +0100 Subject: [PATCH 17/17] Vacuum on startup and also make index changes possible without schema updates --- src/db.c | 42 +++++++++++++++++++++--------------------- 1 file changed, 21 insertions(+), 21 deletions(-) diff --git a/src/db.c b/src/db.c index 028602fc..de589016 100644 --- a/src/db.c +++ b/src/db.c @@ -5448,10 +5448,6 @@ db_check_version(void) { DPRINTF(E_LOG, L_DB, "Database schema outdated, schema upgrade needed v%d -> v%d\n", cur_ver, SCHEMA_VERSION); - ret = db_drop_indices(); - if (ret < 0) - return -1; - switch (cur_ver) { case 10: @@ -5509,29 +5505,33 @@ db_check_version(void) DPRINTF(E_LOG, L_DB, "No upgrade path from DB schema v%d to v%d\n", cur_ver, SCHEMA_VERSION); return -1; } - - ret = db_create_indices(); - if (ret < 0) - return -1; - - /* What about some housekeeping work, eh? */ - DPRINTF(E_INFO, L_DB, "Now vacuuming database, this may take some time...\n"); - - ret = sqlite3_exec(hdl, Q_VACUUM, NULL, NULL, &errmsg); - if (ret != SQLITE_OK) - { - DPRINTF(E_LOG, L_DB, "Could not VACUUM database: %s\n", errmsg); - - sqlite3_free(errmsg); - return -1; - } } else if (cur_ver > SCHEMA_VERSION) { - DPRINTF(E_LOG, L_DB, "Database schema is newer than the supported version\n"); + DPRINTF(E_FATAL, L_DB, "Database schema is newer than the supported version\n"); return -1; } + /* Drop and create indices on startup so that change of a index can be done without a schema update */ + ret = db_drop_indices(); + if (ret < 0) + return -1; + + DPRINTF(E_INFO, L_DB, "Now vacuuming database, this may take some time...\n"); + + ret = sqlite3_exec(hdl, Q_VACUUM, NULL, NULL, &errmsg); + if (ret != SQLITE_OK) + { + DPRINTF(E_LOG, L_DB, "Could not VACUUM database: %s\n", errmsg); + + sqlite3_free(errmsg); + return -1; + } + + ret = db_create_indices(); + if (ret < 0) + return -1; + return 0; #undef Q_VER