[db] Improve speed of browse queries (issue #478)

Before, we returned either unordered (for RSP, meaning client had to
sort) or ordered by a client selected sort_clause[]. The latter are
multi-purpose and therefore not optimised for browse queries.

To speed up, we predefine the entire set of browse queries, including
order, with matching indices. The predefined queries are used except
if the client explicitly requests a non-default order or query.

As a special bonus, the commit also allows queries with I_SUB that
have an offset but no limit.
This commit is contained in:
ejurgensen 2018-01-21 00:22:21 +01:00
parent 121b812c30
commit ea6fd1476a
8 changed files with 129 additions and 109 deletions

133
src/db.c
View File

@ -77,10 +77,17 @@ struct col_type_map {
struct query_clause {
char *where;
const char *order;
char *group;
char *order;
char *index;
};
struct browse_clause {
char *select;
char *where;
char *group;
};
/* This list must be kept in sync with
* - the order of the columns in the files table
* - the type and name of the fields in struct media_file_info
@ -289,23 +296,41 @@ static const struct col_type_map wi_cols_map[] =
{ wi_offsetof(path), DB_TYPE_STRING },
};
/* Sort clauses */
/* Keep in sync with enum sort_type */
/* Sort clauses, used for ORDER BY */
/* Keep in sync with enum sort_type and indices */
static const char *sort_clause[] =
{
"",
"ORDER BY f.title_sort ASC",
"ORDER BY f.album_sort ASC, f.disc ASC, f.track ASC",
"ORDER BY f.album_artist_sort ASC, f.album_sort ASC, f.disc ASC, f.track ASC",
"ORDER BY f.type ASC, f.parent_id ASC, f.special_id ASC, f.title ASC",
"ORDER BY f.year ASC",
"ORDER BY f.genre ASC",
"ORDER BY f.composer_sort ASC",
"ORDER BY f.disc ASC",
"ORDER BY f.track ASC",
"ORDER BY f.virtual_path ASC",
"ORDER BY pos ASC",
"ORDER BY shuffle_pos ASC",
"f.title_sort",
"f.album_sort, f.disc, f.track",
"f.album_artist_sort, f.album_sort, f.disc, f.track",
"f.type, f.parent_id, f.special_id, f.title",
"f.year",
"f.genre",
"f.composer_sort",
"f.disc",
"f.track",
"f.virtual_path",
"pos",
"shuffle_pos",
};
/* Browse clauses, used for SELECT, WHERE, GROUP BY and for default ORDER BY
* Keep in sync with enum query_type and indices
* Col 1: for SELECT, Col 2: for WHERE, Col 3: for GROUP BY/ORDER BY
*/
static const struct browse_clause browse_clause[] =
{
{ "", "", "" },
{ "f.album_artist, f.album_artist_sort", "f.album_artist", "f.album_artist_sort, f.album_artist" },
{ "f.album, f.album_sort", "f.album", "f.album_sort, f.album" },
{ "f.genre, f.genre", "f.genre", "f.genre" },
{ "f.composer, f.composer_sort", "f.composer", "f.composer_sort, f.composer" },
{ "f.year, f.year", "f.year", "f.year" },
{ "f.disc, f.disc", "f.disc", "f.disc" },
{ "f.track, f.track", "f.track", "f.track" },
{ "f.virtual_path, f.virtual_path", "f.virtual_path", "f.virtual_path" },
{ "f.path, f.path", "f.path", "f.path" },
};
/* Shuffle RNG state */
@ -995,6 +1020,8 @@ db_free_query_clause(struct query_clause *qc)
return;
sqlite3_free(qc->where);
sqlite3_free(qc->group);
sqlite3_free(qc->order);
sqlite3_free(qc->index);
free(qc);
}
@ -1008,15 +1035,20 @@ db_build_query_clause(struct query_params *qp)
if (!qc)
goto error;
if (qp->type & Q_F_BROWSE)
qc->group = sqlite3_mprintf("GROUP BY %s", browse_clause[qp->type & ~Q_F_BROWSE].group);
if (qp->filter)
qc->where = sqlite3_mprintf("WHERE f.disabled = 0 AND %s", qp->filter);
else
qc->where = sqlite3_mprintf("WHERE f.disabled = 0");
if (qp->sort)
qc->order = sort_clause[qp->sort];
qc->order = sqlite3_mprintf("ORDER BY %s", sort_clause[qp->sort]);
else if (qp->type & Q_F_BROWSE)
qc->order = sqlite3_mprintf("ORDER BY %s", browse_clause[qp->type & ~Q_F_BROWSE].group);
else
qc->order = "";
qc->order = sqlite3_mprintf("");
switch (qp->idx_type)
{
@ -1029,7 +1061,10 @@ db_build_query_clause(struct query_params *qp)
break;
case I_SUB:
if (qp->limit)
qc->index = sqlite3_mprintf("LIMIT %d OFFSET %d", qp->limit, qp->offset);
else
qc->index = sqlite3_mprintf("LIMIT -1 OFFSET %d", qp->offset);
break;
case I_NONE:
@ -1329,9 +1364,11 @@ db_build_query_group_dirs(struct query_params *qp)
}
static char *
db_build_query_browse(struct query_params *qp, const char *field, const char *group_field)
db_build_query_browse(struct query_params *qp)
{
struct query_clause *qc;
const char *where;
const char *select;
char *count;
char *query;
@ -1339,8 +1376,11 @@ db_build_query_browse(struct query_params *qp, const char *field, const char *gr
if (!qc)
return NULL;
count = sqlite3_mprintf("SELECT COUNT(DISTINCT f.%s) FROM files f %s AND f.%s != '';", field, qc->where, field);
query = sqlite3_mprintf("SELECT f.%s, f.%s FROM files f %s AND f.%s != '' GROUP BY f.%s %s %s;", field, group_field, qc->where, field, group_field, qc->order, qc->index);
select = browse_clause[qp->type & ~Q_F_BROWSE].select;
where = browse_clause[qp->type & ~Q_F_BROWSE].where;
count = sqlite3_mprintf("SELECT COUNT(*) FROM files f %s AND %s != '' %s;", qc->where, where, qc->group);
query = sqlite3_mprintf("SELECT %s FROM files f %s AND %s != '' %s %s %s;", select, qc->where, where, qc->group, qc->order, qc->index);
db_free_query_clause(qc);
@ -1412,53 +1452,22 @@ db_query_start(struct query_params *qp)
query = db_build_query_group_dirs(qp);
break;
case Q_BROWSE_ALBUMS:
query = db_build_query_browse(qp, "album", "album_sort");
break;
case Q_BROWSE_ARTISTS:
query = db_build_query_browse(qp, "album_artist", "album_artist_sort");
break;
case Q_BROWSE_GENRES:
query = db_build_query_browse(qp, "genre", "genre");
break;
case Q_BROWSE_COMPOSERS:
query = db_build_query_browse(qp, "composer", "composer_sort");
break;
case Q_BROWSE_YEARS:
query = db_build_query_browse(qp, "year", "year");
break;
case Q_BROWSE_DISCS:
query = db_build_query_browse(qp, "disc", "disc");
break;
case Q_BROWSE_TRACKS:
query = db_build_query_browse(qp, "track", "track");
break;
case Q_BROWSE_VPATH:
query = db_build_query_browse(qp, "virtual_path", "virtual_path");
break;
case Q_BROWSE_PATH:
query = db_build_query_browse(qp, "path", "path");
break;
case Q_COUNT_ITEMS:
query = db_build_query_count_items(qp);
break;
default:
DPRINTF(E_LOG, L_DB, "Unknown query type\n");
return -1;
if (qp->type & Q_F_BROWSE)
query = db_build_query_browse(qp);
else
query = NULL;
}
if (!query)
{
DPRINTF(E_LOG, L_DB, "Could not create query, unknown type %d\n", qp->type);
return -1;
}
DPRINTF(E_DBG, L_DB, "Starting query '%s'\n", query);
@ -1812,12 +1821,6 @@ db_query_fetch_string(struct query_params *qp, char **string)
return -1;
}
if (!(qp->type & Q_F_BROWSE))
{
DPRINTF(E_LOG, L_DB, "Not a browse query!\n");
return -1;
}
ret = db_blocking_step(qp->stmt);
if (ret == SQLITE_DONE)
{
@ -4460,7 +4463,7 @@ db_queue_add_item(struct db_queue_item *queue_item, char reshuffle, uint32_t ite
static int
queue_enum_start(struct query_params *qp)
{
#define Q_TMPL "SELECT * FROM queue f WHERE %s %s;"
#define Q_TMPL "SELECT * FROM queue f WHERE %s ORDER BY %s;"
sqlite3_stmt *stmt;
char *query;
const char *orderby;

View File

@ -15,6 +15,7 @@ enum index_type {
I_SUB
};
// Keep in sync with sort_clause[]
enum sort_type {
S_NONE = 0,
S_NAME,
@ -41,17 +42,19 @@ enum query_type {
Q_GROUP_ALBUMS = 5,
Q_GROUP_ARTISTS = 6,
Q_GROUP_ITEMS = 7,
Q_COUNT_ITEMS = 8,
Q_GROUP_DIRS = 8,
Q_COUNT_ITEMS = 9,
// Keep in sync with browse_clause[]
Q_BROWSE_ARTISTS = Q_F_BROWSE | 1,
Q_BROWSE_ALBUMS = Q_F_BROWSE | 2,
Q_BROWSE_GENRES = Q_F_BROWSE | 3,
Q_BROWSE_COMPOSERS = Q_F_BROWSE | 4,
Q_GROUP_DIRS = Q_F_BROWSE | 5,
Q_BROWSE_YEARS = Q_F_BROWSE | 6,
Q_BROWSE_DISCS = Q_F_BROWSE | 7,
Q_BROWSE_TRACKS = Q_F_BROWSE | 8,
Q_BROWSE_VPATH = Q_F_BROWSE | 9,
Q_BROWSE_PATH = Q_F_BROWSE | 10,
Q_BROWSE_YEARS = Q_F_BROWSE | 5,
Q_BROWSE_DISCS = Q_F_BROWSE | 6,
Q_BROWSE_TRACKS = Q_F_BROWSE | 7,
Q_BROWSE_VPATH = Q_F_BROWSE | 8,
Q_BROWSE_PATH = Q_F_BROWSE | 9,
};
#define ARTWORK_UNKNOWN 0

View File

@ -311,26 +311,25 @@ static const struct db_init_query db_init_table_queries[] =
#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);"
/* Used by Q_BROWSE_ALBUM */
#define I_ALBUM \
"CREATE INDEX IF NOT EXISTS idx_album ON files(disabled, album_sort, album, media_kind);"
/* Used by Q_BROWSE_ARTIST */
#define I_ALBUMARTIST \
"CREATE INDEX IF NOT EXISTS idx_albumartist ON files(album_artist, album_artist_sort);"
"CREATE INDEX IF NOT EXISTS idx_albumartist ON files(disabled, album_artist_sort, album_artist, media_kind);"
/* Used by Q_BROWSE_COMPOSERS */
#define I_COMPOSER \
"CREATE INDEX IF NOT EXISTS idx_composer ON files(disabled, media_kind, composer_sort);"
"CREATE INDEX IF NOT EXISTS idx_composer ON files(disabled, composer_sort, composer, media_kind);"
/* Used by Q_BROWSE_GENRES */
#define I_GENRE \
"CREATE INDEX IF NOT EXISTS idx_genre ON files(disabled, media_kind, genre);"
"CREATE INDEX IF NOT EXISTS idx_genre ON files(disabled, genre, media_kind);"
/* Used by Q_PLITEMS for smart playlists */
#define I_TITLE \
"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);"
"CREATE INDEX IF NOT EXISTS idx_title ON files(disabled, title_sort, media_kind);"
#define I_FILELIST \
"CREATE INDEX IF NOT EXISTS idx_filelist ON files(disabled, virtual_path, time_modified);"
@ -380,7 +379,6 @@ static const struct db_init_query db_init_index_queries[] =
{ I_STATEMKINDSARI, "create state/mkind/sari index" },
{ I_STATEMKINDSALI, "create state/mkind/sali index" },
{ I_ARTIST, "create artist index" },
{ I_ALBUMARTIST, "create album_artist index" },
{ I_COMPOSER, "create composer index" },
{ I_GENRE, "create genre index" },

View File

@ -26,7 +26,7 @@
* is a major upgrade. In other words minor version upgrades permit downgrading
* forked-daapd after the database was upgraded. */
#define SCHEMA_VERSION_MAJOR 19
#define SCHEMA_VERSION_MINOR 06
#define SCHEMA_VERSION_MINOR 07
int
db_init_indices(sqlite3 *hdl);

View File

@ -1574,8 +1574,6 @@ static const struct db_upgrade_query db_upgrade_v1905_queries[] =
};
/* Upgrade from schema v19.05 to v20.00 */
#define U_V1906_DROP_TABLE_QUEUE \
"DROP TABLE queue;"
@ -1626,6 +1624,16 @@ static const struct db_upgrade_query db_upgrade_V1906_queries[] =
};
#define U_V1907_SCVER_MINOR \
"UPDATE admin SET value = '07' WHERE key = 'schema_version_minor';"
// Purpose of this upgrade is to reset the indeces
static const struct db_upgrade_query db_upgrade_V1907_queries[] =
{
{ U_V1907_SCVER_MINOR, "set schema_version_minor to 07" },
};
int
db_upgrade(sqlite3 *hdl, int db_ver)
{
@ -1778,6 +1786,13 @@ db_upgrade(sqlite3 *hdl, int db_ver)
if (ret < 0)
return -1;
/* FALLTHROUGH */
case 1906:
ret = db_generic_upgrade(hdl, db_upgrade_V1907_queries, sizeof(db_upgrade_V1907_queries) / sizeof(db_upgrade_V1907_queries[0]));
if (ret < 0)
return -1;
break;
default:

View File

@ -566,9 +566,9 @@ query_params_set(struct query_params *qp, int *sort_headers, struct httpd_reques
{
if (strcmp(param, "name") == 0)
qp->sort = S_NAME;
else if (strcmp(param, "album") == 0)
else if (strcmp(param, "album") == 0 && (type != Q_BROWSE_ALBUMS)) // Only set if non-default sort requested
qp->sort = S_ALBUM;
else if (strcmp(param, "artist") == 0)
else if (strcmp(param, "artist") == 0 && (type != Q_BROWSE_ARTISTS)) // Only set if non-default sort requested
qp->sort = S_ARTIST;
else if (strcmp(param, "releasedate") == 0)
qp->sort = S_NAME;
@ -603,7 +603,7 @@ query_params_set(struct query_params *qp, int *sort_headers, struct httpd_reques
DPRINTF(E_LOG, L_DAAP, "Ignoring improper DAAP query: %s\n", param);
/* iTunes seems to default to this when there is a query (which there is for audiobooks, but not for normal playlists) */
if (qp->sort == S_NONE)
if (!qp->sort && !(type & Q_F_BROWSE))
qp->sort = S_ALBUM;
}
@ -1829,25 +1829,21 @@ daap_reply_browse(struct httpd_request *hreq)
{
tag = "abar";
query_params_set(&qp, &sort_headers, hreq, Q_BROWSE_ARTISTS);
qp.sort = S_ARTIST;
}
else if (strcmp(hreq->uri_parsed->path_parts[3], "albums") == 0)
{
tag = "abal";
query_params_set(&qp, &sort_headers, hreq, Q_BROWSE_ALBUMS);
qp.sort = S_ALBUM;
}
else if (strcmp(hreq->uri_parsed->path_parts[3], "genres") == 0)
{
tag = "abgn";
query_params_set(&qp, &sort_headers, hreq, Q_BROWSE_GENRES);
qp.sort = S_GENRE;
}
else if (strcmp(hreq->uri_parsed->path_parts[3], "composers") == 0)
{
tag = "abcp";
query_params_set(&qp, &sort_headers, hreq, Q_BROWSE_COMPOSERS);
qp.sort = S_COMPOSER;
}
else
{

View File

@ -238,8 +238,6 @@ query_params_set(struct query_params *qp, struct httpd_request *hreq)
else
qp->idx_type = I_NONE;
qp->sort = S_NONE;
param = evhttp_find_header(hreq->query, "query");
if (param)
{
@ -492,6 +490,8 @@ rsp_reply_playlist(struct httpd_request *hreq)
else
qp.type = Q_PLITEMS;
qp.sort = S_NAME;
mode = F_FULL;
param = evhttp_find_header(hreq->query, "type");
if (param)
@ -526,9 +526,10 @@ rsp_reply_playlist(struct httpd_request *hreq)
if (qp.offset > qp.results)
records = 0;
else if (qp.limit > (qp.results - qp.offset))
records = qp.results - qp.offset;
else
records = qp.results - qp.offset;
if (qp.limit && (records > qp.limit))
records = qp.limit;
/* We'd use mxmlNewXML(), but then we can't put any attributes
@ -661,13 +662,21 @@ rsp_reply_browse(struct httpd_request *hreq)
memset(&qp, 0, sizeof(struct query_params));
if (strcmp(hreq->uri_parsed->path_parts[3], "artist") == 0)
{
qp.type = Q_BROWSE_ARTISTS;
}
else if (strcmp(hreq->uri_parsed->path_parts[3], "genre") == 0)
{
qp.type = Q_BROWSE_GENRES;
}
else if (strcmp(hreq->uri_parsed->path_parts[3], "album") == 0)
{
qp.type = Q_BROWSE_ALBUMS;
}
else if (strcmp(hreq->uri_parsed->path_parts[3], "composer") == 0)
{
qp.type = Q_BROWSE_COMPOSERS;
}
else
{
DPRINTF(E_LOG, L_RSP, "Unsupported browse type '%s'\n", hreq->uri_parsed->path_parts[3]);
@ -701,9 +710,10 @@ rsp_reply_browse(struct httpd_request *hreq)
if (qp.offset > qp.results)
records = 0;
else if (qp.limit > (qp.results - qp.offset))
records = qp.results - qp.offset;
else
records = qp.results - qp.offset;
if (qp.limit && (records > qp.limit))
records = qp.limit;
/* We'd use mxmlNewXML(), but then we can't put any attributes

View File

@ -2753,31 +2753,26 @@ mpd_command_list(struct evbuffer *evbuf, int argc, char **argv, char **errmsg, s
else if (0 == strcasecmp(argv[1], "date"))
{
qp.type = Q_BROWSE_YEARS;
qp.sort = S_YEAR;
type = "Date: ";
}
else if (0 == strcasecmp(argv[1], "genre"))
{
qp.type = Q_BROWSE_GENRES;
qp.sort = S_GENRE;
type = "Genre: ";
}
else if (0 == strcasecmp(argv[1], "disc"))
{
qp.type = Q_BROWSE_DISCS;
qp.sort = S_DISC;
type = "Disc: ";
}
else if (0 == strcasecmp(argv[1], "track"))
{
qp.type = Q_BROWSE_TRACKS;
qp.sort = S_TRACK;
type = "Track: ";
}
else if (0 == strcasecmp(argv[1], "file"))
{
qp.type = Q_BROWSE_VPATH;
qp.sort = S_VPATH;
type = "file: ";
}
else