From 6ac969e2c52d7645389290c499c8c1810c4e4437 Mon Sep 17 00:00:00 2001 From: spl0k Date: Sat, 17 Mar 2018 23:25:26 +0100 Subject: [PATCH] Index folder and track path Speeds up scanning --- schema/migration/20180317.mysql.sql | 13 ++ schema/migration/20180317.postgresql.py | 34 +++++ schema/migration/20180317.sqlite.py | 31 +++++ schema/mysql.sql | 168 ++++++++++++------------ schema/postgresql.sql | 168 ++++++++++++------------ schema/sqlite.sql | 168 ++++++++++++------------ supysonic/db.py | 27 +++- tests/base/test_watcher.py | 2 + 8 files changed, 366 insertions(+), 245 deletions(-) create mode 100644 schema/migration/20180317.mysql.sql create mode 100644 schema/migration/20180317.postgresql.py create mode 100644 schema/migration/20180317.sqlite.py diff --git a/schema/migration/20180317.mysql.sql b/schema/migration/20180317.mysql.sql new file mode 100644 index 0000000..5d1a4f6 --- /dev/null +++ b/schema/migration/20180317.mysql.sql @@ -0,0 +1,13 @@ +START TRANSACTION; + +ALTER TABLE folder ADD COLUMN path_hash BINARY(20) NOT NULL AFTER path; +ALTER TABLE track ADD COLUMN path_hash BINARY(20) NOT NULL AFTER path; + +UPDATE folder SET path_hash=UNHEX(SHA1(path)); +UPDATE track SET path_hash=UNHEX(SHA1(path)); + +CREATE UNIQUE INDEX index_folder_path ON folder(path_hash); +CREATE UNIQUE INDEX index_track_path ON track(path_hash); + +COMMIT; + diff --git a/schema/migration/20180317.postgresql.py b/schema/migration/20180317.postgresql.py new file mode 100644 index 0000000..c17e369 --- /dev/null +++ b/schema/migration/20180317.postgresql.py @@ -0,0 +1,34 @@ +import argparse +import hashlib +import psycopg2 +import uuid + +try: + bytes = buffer +except: + pass + +parser = argparse.ArgumentParser() +parser.add_argument('username') +parser.add_argument('password') +parser.add_argument('database') +parser.add_argument('-H', '--host', default = 'localhost', help = 'default: localhost') +args = parser.parse_args() + +def process_table(connection, table): + c = connection.cursor() + + c.execute(r"ALTER TABLE {0} ADD COLUMN path_hash BYTEA NOT NULL DEFAULT E'\\0000'".format(table)) + + hashes = dict() + c.execute('SELECT path FROM {0}'.format(table)) + for row in c.fetchall(): + hashes[row[0]] = hashlib.sha1(row[0].encode('utf-8')).digest() + c.executemany('UPDATE {0} SET path_hash=%s WHERE path=%s'.format(table), [ (bytes(h), p) for p, h in hashes.items() ]) + + c.execute('CREATE UNIQUE INDEX index_{0}_path ON {0}(path_hash)'.format(table)) + +with psycopg2.connect(host = args.host, user = args.username, password = args.password, dbname = args.database) as conn: + process_table(conn, 'folder') + process_table(conn, 'track') + diff --git a/schema/migration/20180317.sqlite.py b/schema/migration/20180317.sqlite.py new file mode 100644 index 0000000..90ca091 --- /dev/null +++ b/schema/migration/20180317.sqlite.py @@ -0,0 +1,31 @@ +import argparse +import hashlib +import sqlite3 +import uuid + +try: + bytes = buffer +except: + pass + +parser = argparse.ArgumentParser() +parser.add_argument('dbfile', help = 'Path to the SQLite database file') +args = parser.parse_args() + +def process_table(connection, table): + c = connection.cursor() + + c.execute('ALTER TABLE {0} ADD COLUMN path_hash BLOB NOT NULL DEFAULT ROWID'.format(table)) + + hashes = dict() + for row in c.execute('SELECT path FROM {0}'.format(table)): + hashes[row[0]] = hashlib.sha1(row[0].encode('utf-8')).digest() + c.executemany('UPDATE {0} SET path_hash=? WHERE path=?'.format(table), [ (bytes(h), p) for p, h in hashes.items() ]) + + c.execute('CREATE UNIQUE INDEX index_{0}_path ON {0}(path_hash)'.format(table)) + +with sqlite3.connect(args.dbfile) as conn: + process_table(conn, 'folder') + process_table(conn, 'track') + conn.cursor().execute('VACUUM') + diff --git a/schema/mysql.sql b/schema/mysql.sql index b19f455..518c9c0 100644 --- a/schema/mysql.sql +++ b/schema/mysql.sql @@ -1,123 +1,129 @@ CREATE TABLE folder ( - id BINARY(16) PRIMARY KEY, - root BOOLEAN NOT NULL, - name VARCHAR(256) NOT NULL, - path VARCHAR(4096) NOT NULL, - created DATETIME NOT NULL, - has_cover_art BOOLEAN NOT NULL, - last_scan INTEGER NOT NULL, - parent_id BINARY(16) REFERENCES folder + id BINARY(16) PRIMARY KEY, + root BOOLEAN NOT NULL, + name VARCHAR(256) NOT NULL, + path VARCHAR(4096) NOT NULL, + path_hash BINARY(20) NOT NULL, + created DATETIME NOT NULL, + has_cover_art BOOLEAN NOT NULL, + last_scan INTEGER NOT NULL, + parent_id BINARY(16) REFERENCES folder ) DEFAULT CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci; +CREATE UNIQUE INDEX index_folder_path ON folder(path_hash); + CREATE TABLE artist ( - id BINARY(16) PRIMARY KEY, - name VARCHAR(256) NOT NULL + id BINARY(16) PRIMARY KEY, + name VARCHAR(256) NOT NULL ) DEFAULT CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci; CREATE TABLE album ( - id BINARY(16) PRIMARY KEY, - name VARCHAR(256) NOT NULL, - artist_id BINARY(16) NOT NULL REFERENCES artist + id BINARY(16) PRIMARY KEY, + name VARCHAR(256) NOT NULL, + artist_id BINARY(16) NOT NULL REFERENCES artist ) DEFAULT CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci; CREATE TABLE track ( - id BINARY(16) PRIMARY KEY, - disc INTEGER NOT NULL, - number INTEGER NOT NULL, - title VARCHAR(256) NOT NULL, - year INTEGER, - genre VARCHAR(256), - duration INTEGER NOT NULL, - album_id BINARY(16) NOT NULL REFERENCES album, - artist_id BINARY(16) NOT NULL REFERENCES artist, - bitrate INTEGER NOT NULL, - path VARCHAR(4096) NOT NULL, - content_type VARCHAR(32) NOT NULL, - created DATETIME NOT NULL, - last_modification INTEGER NOT NULL, - play_count INTEGER NOT NULL, - last_play DATETIME, - root_folder_id BINARY(16) NOT NULL REFERENCES folder, - folder_id BINARY(16) NOT NULL REFERENCES folder + id BINARY(16) PRIMARY KEY, + disc INTEGER NOT NULL, + number INTEGER NOT NULL, + title VARCHAR(256) NOT NULL, + year INTEGER, + genre VARCHAR(256), + duration INTEGER NOT NULL, + album_id BINARY(16) NOT NULL REFERENCES album, + artist_id BINARY(16) NOT NULL REFERENCES artist, + bitrate INTEGER NOT NULL, + path VARCHAR(4096) NOT NULL, + path_hash BINARY(20) NOT NULL, + content_type VARCHAR(32) NOT NULL, + created DATETIME NOT NULL, + last_modification INTEGER NOT NULL, + play_count INTEGER NOT NULL, + last_play DATETIME, + root_folder_id BINARY(16) NOT NULL REFERENCES folder, + folder_id BINARY(16) NOT NULL REFERENCES folder ) DEFAULT CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci; +CREATE UNIQUE INDEX index_track_path ON track(path_hash); + CREATE TABLE user ( - id BINARY(16) PRIMARY KEY, - name VARCHAR(64) NOT NULL, - mail VARCHAR(256), - password CHAR(40) NOT NULL, - salt CHAR(6) NOT NULL, - admin BOOLEAN NOT NULL, - lastfm_session CHAR(32), - lastfm_status BOOLEAN NOT NULL, - last_play_id BINARY(16) REFERENCES track, - last_play_date DATETIME + id BINARY(16) PRIMARY KEY, + name VARCHAR(64) NOT NULL, + mail VARCHAR(256), + password CHAR(40) NOT NULL, + salt CHAR(6) NOT NULL, + admin BOOLEAN NOT NULL, + lastfm_session CHAR(32), + lastfm_status BOOLEAN NOT NULL, + last_play_id BINARY(16) REFERENCES track, + last_play_date DATETIME ) DEFAULT CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci; CREATE TABLE client_prefs ( - user_id BINARY(16) NOT NULL, - client_name VARCHAR(32) NOT NULL, - format VARCHAR(8), - bitrate INTEGER, - PRIMARY KEY (user_id, client_name) + user_id BINARY(16) NOT NULL, + client_name VARCHAR(32) NOT NULL, + format VARCHAR(8), + bitrate INTEGER, + PRIMARY KEY (user_id, client_name) ) DEFAULT CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci; CREATE TABLE starred_folder ( - user_id BINARY(16) NOT NULL REFERENCES user, - starred_id BINARY(16) NOT NULL REFERENCES folder, - date DATETIME NOT NULL, - PRIMARY KEY (user_id, starred_id) + user_id BINARY(16) NOT NULL REFERENCES user, + starred_id BINARY(16) NOT NULL REFERENCES folder, + date DATETIME NOT NULL, + PRIMARY KEY (user_id, starred_id) ) DEFAULT CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci; CREATE TABLE starred_artist ( - user_id BINARY(16) NOT NULL REFERENCES user, - starred_id BINARY(16) NOT NULL REFERENCES artist, - date DATETIME NOT NULL, - PRIMARY KEY (user_id, starred_id) + user_id BINARY(16) NOT NULL REFERENCES user, + starred_id BINARY(16) NOT NULL REFERENCES artist, + date DATETIME NOT NULL, + PRIMARY KEY (user_id, starred_id) ) DEFAULT CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci; CREATE TABLE starred_album ( - user_id BINARY(16) NOT NULL REFERENCES user, - starred_id BINARY(16) NOT NULL REFERENCES album, - date DATETIME NOT NULL, - PRIMARY KEY (user_id, starred_id) + user_id BINARY(16) NOT NULL REFERENCES user, + starred_id BINARY(16) NOT NULL REFERENCES album, + date DATETIME NOT NULL, + PRIMARY KEY (user_id, starred_id) ) DEFAULT CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci; CREATE TABLE starred_track ( - user_id BINARY(16) NOT NULL REFERENCES user, - starred_id BINARY(16) NOT NULL REFERENCES track, - date DATETIME NOT NULL, - PRIMARY KEY (user_id, starred_id) + user_id BINARY(16) NOT NULL REFERENCES user, + starred_id BINARY(16) NOT NULL REFERENCES track, + date DATETIME NOT NULL, + PRIMARY KEY (user_id, starred_id) ) DEFAULT CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci; CREATE TABLE rating_folder ( - user_id BINARY(16) NOT NULL REFERENCES user, - rated_id BINARY(16) NOT NULL REFERENCES folder, - rating INTEGER NOT NULL CHECK(rating BETWEEN 1 AND 5), - PRIMARY KEY (user_id, rated_id) + user_id BINARY(16) NOT NULL REFERENCES user, + rated_id BINARY(16) NOT NULL REFERENCES folder, + rating INTEGER NOT NULL CHECK(rating BETWEEN 1 AND 5), + PRIMARY KEY (user_id, rated_id) ) DEFAULT CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci; CREATE TABLE rating_track ( - user_id BINARY(16) NOT NULL REFERENCES user, - rated_id BINARY(16) NOT NULL REFERENCES track, - rating INTEGER NOT NULL CHECK(rating BETWEEN 1 AND 5), - PRIMARY KEY (user_id, rated_id) + user_id BINARY(16) NOT NULL REFERENCES user, + rated_id BINARY(16) NOT NULL REFERENCES track, + rating INTEGER NOT NULL CHECK(rating BETWEEN 1 AND 5), + PRIMARY KEY (user_id, rated_id) ) DEFAULT CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci; CREATE TABLE chat_message ( - id BINARY(16) PRIMARY KEY, - user_id BINARY(16) NOT NULL REFERENCES user, - time INTEGER NOT NULL, - message VARCHAR(512) NOT NULL + id BINARY(16) PRIMARY KEY, + user_id BINARY(16) NOT NULL REFERENCES user, + time INTEGER NOT NULL, + message VARCHAR(512) NOT NULL ) DEFAULT CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci; CREATE TABLE playlist ( - id BINARY(16) PRIMARY KEY, - user_id BINARY(16) NOT NULL REFERENCES user, - name VARCHAR(256) NOT NULL, - comment VARCHAR(256), - public BOOLEAN NOT NULL, - created DATETIME NOT NULL, - tracks TEXT + id BINARY(16) PRIMARY KEY, + user_id BINARY(16) NOT NULL REFERENCES user, + name VARCHAR(256) NOT NULL, + comment VARCHAR(256), + public BOOLEAN NOT NULL, + created DATETIME NOT NULL, + tracks TEXT ) DEFAULT CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci; diff --git a/schema/postgresql.sql b/schema/postgresql.sql index 4aadbc2..e34a3e2 100644 --- a/schema/postgresql.sql +++ b/schema/postgresql.sql @@ -1,123 +1,129 @@ CREATE TABLE folder ( - id UUID PRIMARY KEY, - root BOOLEAN NOT NULL, - name CITEXT NOT NULL, - path VARCHAR(4096) NOT NULL, - created TIMESTAMP NOT NULL, - has_cover_art BOOLEAN NOT NULL, - last_scan INTEGER NOT NULL, - parent_id UUID REFERENCES folder + id UUID PRIMARY KEY, + root BOOLEAN NOT NULL, + name CITEXT NOT NULL, + path VARCHAR(4096) NOT NULL, + path_hash BYTEA NOT NULL, + created TIMESTAMP NOT NULL, + has_cover_art BOOLEAN NOT NULL, + last_scan INTEGER NOT NULL, + parent_id UUID REFERENCES folder ); +CREATE UNIQUE INDEX index_folder_path ON folder(path_hash); + CREATE TABLE artist ( - id UUID PRIMARY KEY, - name CITEXT NOT NULL + id UUID PRIMARY KEY, + name CITEXT NOT NULL ); CREATE TABLE album ( - id UUID PRIMARY KEY, - name CITEXT NOT NULL, - artist_id UUID NOT NULL REFERENCES artist + id UUID PRIMARY KEY, + name CITEXT NOT NULL, + artist_id UUID NOT NULL REFERENCES artist ); CREATE TABLE track ( - id UUID PRIMARY KEY, - disc INTEGER NOT NULL, - number INTEGER NOT NULL, - title CITEXT NOT NULL, - year INTEGER, - genre VARCHAR(256), - duration INTEGER NOT NULL, - album_id UUID NOT NULL REFERENCES album, - artist_id UUID NOT NULL REFERENCES artist, - bitrate INTEGER NOT NULL, - path VARCHAR(4096) NOT NULL, - content_type VARCHAR(32) NOT NULL, - created TIMESTAMP NOT NULL, - last_modification INTEGER NOT NULL, - play_count INTEGER NOT NULL, - last_play TIMESTAMP, - root_folder_id UUID NOT NULL REFERENCES folder, - folder_id UUID NOT NULL REFERENCES folder + id UUID PRIMARY KEY, + disc INTEGER NOT NULL, + number INTEGER NOT NULL, + title CITEXT NOT NULL, + year INTEGER, + genre VARCHAR(256), + duration INTEGER NOT NULL, + album_id UUID NOT NULL REFERENCES album, + artist_id UUID NOT NULL REFERENCES artist, + bitrate INTEGER NOT NULL, + path VARCHAR(4096) NOT NULL, + path_hash BYTEA NOT NULL, + content_type VARCHAR(32) NOT NULL, + created TIMESTAMP NOT NULL, + last_modification INTEGER NOT NULL, + play_count INTEGER NOT NULL, + last_play TIMESTAMP, + root_folder_id UUID NOT NULL REFERENCES folder, + folder_id UUID NOT NULL REFERENCES folder ); +CREATE UNIQUE INDEX index_track_path ON track(path_hash); + CREATE TABLE "user" ( - id UUID PRIMARY KEY, - name VARCHAR(64) NOT NULL, - mail VARCHAR(256), - password CHAR(40) NOT NULL, - salt CHAR(6) NOT NULL, - admin BOOLEAN NOT NULL, - lastfm_session CHAR(32), - lastfm_status BOOLEAN NOT NULL, - last_play_id UUID REFERENCES track, - last_play_date TIMESTAMP + id UUID PRIMARY KEY, + name VARCHAR(64) NOT NULL, + mail VARCHAR(256), + password CHAR(40) NOT NULL, + salt CHAR(6) NOT NULL, + admin BOOLEAN NOT NULL, + lastfm_session CHAR(32), + lastfm_status BOOLEAN NOT NULL, + last_play_id UUID REFERENCES track, + last_play_date TIMESTAMP ); CREATE TABLE client_prefs ( - user_id UUID NOT NULL, - client_name VARCHAR(32) NOT NULL, - format VARCHAR(8), - bitrate INTEGER, - PRIMARY KEY (user_id, client_name) + user_id UUID NOT NULL, + client_name VARCHAR(32) NOT NULL, + format VARCHAR(8), + bitrate INTEGER, + PRIMARY KEY (user_id, client_name) ); CREATE TABLE starred_folder ( - user_id UUID NOT NULL REFERENCES "user", - starred_id UUID NOT NULL REFERENCES folder, - date TIMESTAMP NOT NULL, - PRIMARY KEY (user_id, starred_id) + user_id UUID NOT NULL REFERENCES "user", + starred_id UUID NOT NULL REFERENCES folder, + date TIMESTAMP NOT NULL, + PRIMARY KEY (user_id, starred_id) ); CREATE TABLE starred_artist ( - user_id UUID NOT NULL REFERENCES "user", - starred_id UUID NOT NULL REFERENCES artist, - date TIMESTAMP NOT NULL, - PRIMARY KEY (user_id, starred_id) + user_id UUID NOT NULL REFERENCES "user", + starred_id UUID NOT NULL REFERENCES artist, + date TIMESTAMP NOT NULL, + PRIMARY KEY (user_id, starred_id) ); CREATE TABLE starred_album ( - user_id UUID NOT NULL REFERENCES "user", - starred_id UUID NOT NULL REFERENCES album, - date TIMESTAMP NOT NULL, - PRIMARY KEY (user_id, starred_id) + user_id UUID NOT NULL REFERENCES "user", + starred_id UUID NOT NULL REFERENCES album, + date TIMESTAMP NOT NULL, + PRIMARY KEY (user_id, starred_id) ); CREATE TABLE starred_track ( - user_id UUID NOT NULL REFERENCES "user", - starred_id UUID NOT NULL REFERENCES track, - date TIMESTAMP NOT NULL, - PRIMARY KEY (user_id, starred_id) + user_id UUID NOT NULL REFERENCES "user", + starred_id UUID NOT NULL REFERENCES track, + date TIMESTAMP NOT NULL, + PRIMARY KEY (user_id, starred_id) ); CREATE TABLE rating_folder ( - user_id UUID NOT NULL REFERENCES "user", - rated_id UUID NOT NULL REFERENCES folder, - rating INTEGER NOT NULL CHECK(rating BETWEEN 1 AND 5), - PRIMARY KEY (user_id, rated_id) + user_id UUID NOT NULL REFERENCES "user", + rated_id UUID NOT NULL REFERENCES folder, + rating INTEGER NOT NULL CHECK(rating BETWEEN 1 AND 5), + PRIMARY KEY (user_id, rated_id) ); CREATE TABLE rating_track ( - user_id UUID NOT NULL REFERENCES "user", - rated_id UUID NOT NULL REFERENCES track, - rating INTEGER NOT NULL CHECK(rating BETWEEN 1 AND 5), - PRIMARY KEY (user_id, rated_id) + user_id UUID NOT NULL REFERENCES "user", + rated_id UUID NOT NULL REFERENCES track, + rating INTEGER NOT NULL CHECK(rating BETWEEN 1 AND 5), + PRIMARY KEY (user_id, rated_id) ); CREATE TABLE chat_message ( - id UUID PRIMARY KEY, - user_id UUID NOT NULL REFERENCES "user", - time INTEGER NOT NULL, - message VARCHAR(512) NOT NULL + id UUID PRIMARY KEY, + user_id UUID NOT NULL REFERENCES "user", + time INTEGER NOT NULL, + message VARCHAR(512) NOT NULL ); CREATE TABLE playlist ( - id UUID PRIMARY KEY, - user_id UUID NOT NULL REFERENCES "user", - name VARCHAR(256) NOT NULL, - comment VARCHAR(256), - public BOOLEAN NOT NULL, - created TIMESTAMP NOT NULL, - tracks TEXT + id UUID PRIMARY KEY, + user_id UUID NOT NULL REFERENCES "user", + name VARCHAR(256) NOT NULL, + comment VARCHAR(256), + public BOOLEAN NOT NULL, + created TIMESTAMP NOT NULL, + tracks TEXT ); diff --git a/schema/sqlite.sql b/schema/sqlite.sql index 4d7872f..ac076d3 100644 --- a/schema/sqlite.sql +++ b/schema/sqlite.sql @@ -1,123 +1,129 @@ CREATE TABLE folder ( - id CHAR(36) PRIMARY KEY, - root BOOLEAN NOT NULL, - name VARCHAR(256) NOT NULL COLLATE NOCASE, - path VARCHAR(4096) NOT NULL, - created DATETIME NOT NULL, - has_cover_art BOOLEAN NOT NULL, - last_scan INTEGER NOT NULL, - parent_id CHAR(36) REFERENCES folder + id CHAR(36) PRIMARY KEY, + root BOOLEAN NOT NULL, + name VARCHAR(256) NOT NULL COLLATE NOCASE, + path VARCHAR(4096) NOT NULL, + path_hash BLOB NOT NULL, + created DATETIME NOT NULL, + has_cover_art BOOLEAN NOT NULL, + last_scan INTEGER NOT NULL, + parent_id CHAR(36) REFERENCES folder ); +CREATE UNIQUE INDEX index_folder_path ON folder(path_hash); + CREATE TABLE artist ( - id CHAR(36) PRIMARY KEY, - name VARCHAR(256) NOT NULL COLLATE NOCASE + id CHAR(36) PRIMARY KEY, + name VARCHAR(256) NOT NULL COLLATE NOCASE ); CREATE TABLE album ( - id CHAR(36) PRIMARY KEY, - name VARCHAR(256) NOT NULL COLLATE NOCASE, - artist_id CHAR(36) NOT NULL REFERENCES artist + id CHAR(36) PRIMARY KEY, + name VARCHAR(256) NOT NULL COLLATE NOCASE, + artist_id CHAR(36) NOT NULL REFERENCES artist ); CREATE TABLE track ( - id CHAR(36) PRIMARY KEY, - disc INTEGER NOT NULL, - number INTEGER NOT NULL, - title VARCHAR(256) NOT NULL COLLATE NOCASE, - year INTEGER, - genre VARCHAR(256), - duration INTEGER NOT NULL, - album_id CHAR(36) NOT NULL REFERENCES album, - artist_id CHAR(36) NOT NULL REFERENCES artist, - bitrate INTEGER NOT NULL, - path VARCHAR(4096) NOT NULL, - content_type VARCHAR(32) NOT NULL, - created DATETIME NOT NULL, - last_modification INTEGER NOT NULL, - play_count INTEGER NOT NULL, - last_play DATETIME, - root_folder_id CHAR(36) NOT NULL REFERENCES folder, - folder_id CHAR(36) NOT NULL REFERENCES folder + id CHAR(36) PRIMARY KEY, + disc INTEGER NOT NULL, + number INTEGER NOT NULL, + title VARCHAR(256) NOT NULL COLLATE NOCASE, + year INTEGER, + genre VARCHAR(256), + duration INTEGER NOT NULL, + album_id CHAR(36) NOT NULL REFERENCES album, + artist_id CHAR(36) NOT NULL REFERENCES artist, + bitrate INTEGER NOT NULL, + path VARCHAR(4096) NOT NULL, + path_hash BLOB NOT NULL, + content_type VARCHAR(32) NOT NULL, + created DATETIME NOT NULL, + last_modification INTEGER NOT NULL, + play_count INTEGER NOT NULL, + last_play DATETIME, + root_folder_id CHAR(36) NOT NULL REFERENCES folder, + folder_id CHAR(36) NOT NULL REFERENCES folder ); +CREATE UNIQUE INDEX index_track_path ON track(path_hash); + CREATE TABLE user ( - id CHAR(36) PRIMARY KEY, - name VARCHAR(64) NOT NULL, - mail VARCHAR(256), - password CHAR(40) NOT NULL, - salt CHAR(6) NOT NULL, - admin BOOLEAN NOT NULL, - lastfm_session CHAR(32), - lastfm_status BOOLEAN NOT NULL, - last_play_id CHAR(36) REFERENCES track, - last_play_date DATETIME + id CHAR(36) PRIMARY KEY, + name VARCHAR(64) NOT NULL, + mail VARCHAR(256), + password CHAR(40) NOT NULL, + salt CHAR(6) NOT NULL, + admin BOOLEAN NOT NULL, + lastfm_session CHAR(32), + lastfm_status BOOLEAN NOT NULL, + last_play_id CHAR(36) REFERENCES track, + last_play_date DATETIME ); CREATE TABLE client_prefs ( - user_id CHAR(36) NOT NULL, - client_name VARCHAR(32) NOT NULL, - format VARCHAR(8), - bitrate INTEGER, - PRIMARY KEY (user_id, client_name) + user_id CHAR(36) NOT NULL, + client_name VARCHAR(32) NOT NULL, + format VARCHAR(8), + bitrate INTEGER, + PRIMARY KEY (user_id, client_name) ); CREATE TABLE starred_folder ( - user_id CHAR(36) NOT NULL REFERENCES user, - starred_id CHAR(36) NOT NULL REFERENCES folder, - date DATETIME NOT NULL, - PRIMARY KEY (user_id, starred_id) + user_id CHAR(36) NOT NULL REFERENCES user, + starred_id CHAR(36) NOT NULL REFERENCES folder, + date DATETIME NOT NULL, + PRIMARY KEY (user_id, starred_id) ); CREATE TABLE starred_artist ( - user_id CHAR(36) NOT NULL REFERENCES user, - starred_id CHAR(36) NOT NULL REFERENCES artist, - date DATETIME NOT NULL, - PRIMARY KEY (user_id, starred_id) + user_id CHAR(36) NOT NULL REFERENCES user, + starred_id CHAR(36) NOT NULL REFERENCES artist, + date DATETIME NOT NULL, + PRIMARY KEY (user_id, starred_id) ); CREATE TABLE starred_album ( - user_id CHAR(36) NOT NULL REFERENCES user, - starred_id CHAR(36) NOT NULL REFERENCES album, - date DATETIME NOT NULL, - PRIMARY KEY (user_id, starred_id) + user_id CHAR(36) NOT NULL REFERENCES user, + starred_id CHAR(36) NOT NULL REFERENCES album, + date DATETIME NOT NULL, + PRIMARY KEY (user_id, starred_id) ); CREATE TABLE starred_track ( - user_id CHAR(36) NOT NULL REFERENCES user, - starred_id CHAR(36) NOT NULL REFERENCES track, - date DATETIME NOT NULL, - PRIMARY KEY (user_id, starred_id) + user_id CHAR(36) NOT NULL REFERENCES user, + starred_id CHAR(36) NOT NULL REFERENCES track, + date DATETIME NOT NULL, + PRIMARY KEY (user_id, starred_id) ); CREATE TABLE rating_folder ( - user_id CHAR(36) NOT NULL REFERENCES user, - rated_id CHAR(36) NOT NULL REFERENCES folder, - rating INTEGER NOT NULL CHECK(rating BETWEEN 1 AND 5), - PRIMARY KEY (user_id, rated_id) + user_id CHAR(36) NOT NULL REFERENCES user, + rated_id CHAR(36) NOT NULL REFERENCES folder, + rating INTEGER NOT NULL CHECK(rating BETWEEN 1 AND 5), + PRIMARY KEY (user_id, rated_id) ); CREATE TABLE rating_track ( - user_id CHAR(36) NOT NULL REFERENCES user, - rated_id CHAR(36) NOT NULL REFERENCES track, - rating INTEGER NOT NULL CHECK(rating BETWEEN 1 AND 5), - PRIMARY KEY (user_id, rated_id) + user_id CHAR(36) NOT NULL REFERENCES user, + rated_id CHAR(36) NOT NULL REFERENCES track, + rating INTEGER NOT NULL CHECK(rating BETWEEN 1 AND 5), + PRIMARY KEY (user_id, rated_id) ); CREATE TABLE chat_message ( - id CHAR(36) PRIMARY KEY, - user_id CHAR(36) NOT NULL REFERENCES user, - time INTEGER NOT NULL, - message VARCHAR(512) NOT NULL + id CHAR(36) PRIMARY KEY, + user_id CHAR(36) NOT NULL REFERENCES user, + time INTEGER NOT NULL, + message VARCHAR(512) NOT NULL ); CREATE TABLE playlist ( - id CHAR(36) PRIMARY KEY, - user_id CHAR(36) NOT NULL REFERENCES user, - name VARCHAR(256) NOT NULL COLLATE NOCASE, - comment VARCHAR(256), - public BOOLEAN NOT NULL, - created DATETIME NOT NULL, - tracks TEXT + id CHAR(36) PRIMARY KEY, + user_id CHAR(36) NOT NULL REFERENCES user, + name VARCHAR(256) NOT NULL COLLATE NOCASE, + comment VARCHAR(256), + public BOOLEAN NOT NULL, + created DATETIME NOT NULL, + tracks TEXT ); diff --git a/supysonic/db.py b/supysonic/db.py index a75ebe8..a716069 100644 --- a/supysonic/db.py +++ b/supysonic/db.py @@ -12,8 +12,10 @@ import mimetypes import os.path from datetime import datetime +from hashlib import sha1 from pony.orm import Database, Required, Optional, Set, PrimaryKey, LongStr from pony.orm import ObjectNotFound +from pony.orm import buffer from pony.orm import min, max, avg, sum, exists from uuid import UUID, uuid4 @@ -29,13 +31,33 @@ def now(): db = Database() -class Folder(db.Entity): +class PathMixin(object): + @classmethod + def get(cls, *args, **kwargs): + if kwargs: + path = kwargs.pop('path', None) + if path: + kwargs['_path_hash'] = sha1(path.encode('utf-8')).digest() + return db.Entity.get.__func__(cls, *args, **kwargs) + + def __init__(self, *args, **kwargs): + path = kwargs['path'] + kwargs['_path_hash'] = sha1(path.encode('utf-8')).digest() + db.Entity.__init__(self, *args, **kwargs) + + def __setattr__(self, attr, value): + db.Entity.__setattr__(self, attr, value) + if attr == 'path': + db.Entity.__setattr__(self, '_path_hash', sha1(value.encode('utf-8')).digest()) + +class Folder(PathMixin, db.Entity): _table_ = 'folder' id = PrimaryKey(UUID, default = uuid4) root = Required(bool, default = False) name = Required(str) path = Required(str, 4096) # unique + _path_hash = Required(buffer, column = 'path_hash') created = Required(datetime, precision = 0, default = now) has_cover_art = Required(bool, default = False) last_scan = Required(int, default = 0) @@ -160,7 +182,7 @@ class Album(db.Entity): def prune(cls): return cls.select(lambda self: not exists(t for t in Track if t.album == self)).delete(bulk = True) -class Track(db.Entity): +class Track(PathMixin, db.Entity): _table_ = 'track' id = PrimaryKey(UUID, default = uuid4) @@ -177,6 +199,7 @@ class Track(db.Entity): bitrate = Required(int) path = Required(str, 4096) # unique + _path_hash = Required(buffer, column = 'path_hash') content_type = Required(str) created = Required(datetime, precision = 0, default = now) last_modification = Required(int) diff --git a/tests/base/test_watcher.py b/tests/base/test_watcher.py index 96c0d75..2c19253 100644 --- a/tests/base/test_watcher.py +++ b/tests/base/test_watcher.py @@ -17,6 +17,7 @@ import time import unittest from contextlib import contextmanager +from hashlib import sha1 from pony.orm import db_session from threading import Thread @@ -171,6 +172,7 @@ class WatcherTestCase(WatcherTestBase): self.assertIsNotNone(track) self.assertNotEqual(track.path, path) self.assertEqual(track.path, newpath) + self.assertEqual(track._path_hash, memoryview(sha1(newpath.encode('utf-8')).digest())) self.assertEqual(track.id, trackid) def test_move_in(self):