diff --git a/src/main/sql/20151209054632-initial-schema-down.sql b/src/main/sql/20151209054632-initial-schema-down.sql new file mode 100644 index 0000000..f0a2fb3 --- /dev/null +++ b/src/main/sql/20151209054632-initial-schema-down.sql @@ -0,0 +1,14 @@ +DROP TABLE artists_albums; +DROP TABLE albums_images; +DROP TABLE artists_images; +DROP TABLE images; +DROP TABLE media_files_tags; +DROP TABLE bookmarks; +DROP TABLE playlists_media_files; +DROP TABLE playlists; +DROP TABLE tags; +DROP TABLE artists_media_files; +DROP TABLE albums_media_files; +DROP TABLE media_files; +DROP TABLE albums; +DROP TABLE artists; diff --git a/src/main/sql/20151209054632-initial-schema-up.sql b/src/main/sql/20151209054632-initial-schema-up.sql new file mode 100644 index 0000000..e48ca19 --- /dev/null +++ b/src/main/sql/20151209054632-initial-schema-up.sql @@ -0,0 +1,112 @@ +CREATE TABLE artists ( + id TEXT PRIMARY KEY, + name TEXT UNIQUE NOT NULL +); + +CREATE INDEX artists_name_idx ON artists(name); + +CREATE TABLE albums ( + id TEXT PRIMARY KEY, + name TEXT NOT NULL, + year INTEGER, + track_total INTEGER +); + +CREATE INDEX albums_name_idx ON albums(name); + +CREATE TABLE media_files ( + id TEXT PRIMARY KEY, + name TEXT NOT NULL, + disc_number INTEGER NOT NULL DEFAULT 1, + track_number INTEGER, + play_count INTEGER NOT NULL DEFAULT 0, + file_path TEXT NOT NULL, + file_hash TEXT NOT NULL, + meta_info_source TEXT NOT NULL, -- 'tag' or 'filesystem' + date_added TEXT NOT NULL DEFAULT strftime('%F %TZ', date()), + last_played TEXT, + present_locally INTEGER NOT NULL DEFAULT TRUE, + comment TEXT DEFAULT '' +); + +CREATE INDEX media_files_name_idx ON media_files(name); + +CREATE TABLE artists_media_files ( + artist_id TEXT NOT NULL REFERENCES artists(id) ON DELETE CASCADE ON UPDATE CASCADE, + media_file_id TEXT NOT NULL REFERENCES media_files(id) ON DELETE CASCADE ON UPDATE CASCADE, + PRIMARY KEY (artist_id, media_file_id) +); + +CREATE TABLE albums_media_files ( + album_id TEXT NOT NULL REFERENCES albums(id) ON DELETE CASCADE ON UPDATE CASCADE, + media_file_id TEXT NOT NULL REFERENCES media_files(id) ON DELETE CASCADE ON UPDATE CASCADE, + PRIMARY KEY (album_id, media_file_id) +); + +CREATE TABLE tags ( + id TEXT PRIMARY KEY, + name TEXT UNIQUE NOT NULL, + description TEXT NOT NULL DEFAULT '' +); + +CREATE TABLE playlists ( + id TEXT PRIMARY KEY, + user_created INTEGER NOT NULL DEFAULT FALSE, + name TEXT NOT NULL, + media_file_count INTEGER NOT NULL DEFAULT 0, + copied_from_id TEXT DEFAULT NULL, + created_at TEXT NOT NULL DEFAULT strftime('%F %TZ', date()), + last_used TEXT NOT NULL DEFAULT strftime('%F %TZ', date()) +); + +CREATE TABLE playlists_media_files ( + playlist_id TEXT NOT NULL REFERENCES playlists(id) ON DELETE CASCADE ON UPDATE CASCADE, + media_file_id TEXT NOT NULL REFERENCES media_files(id) ON DELETE CASCADE ON UPDATE CASCADE, + position INTEGER NOT NULL DEFAULT 0, + PRIMARY KEY (playlist_id, media_file_id, position), + UNIQUE (playlist_id, position) +); + +CREATE TABLE bookmarks ( + id TEXT PRIMARY KEY, + name TEXT, + user_created INTEGER NOT NULL DEFAULT FALSE, + playlist_id TEXT NOT NULL REFERENCES playlists(id) ON DELETE CASCADE ON UPDATE CASCADE, + media_file_id TEXT NOT NULL REFERENCES media_files(id) ON DELETE CASCADE ON UPDATE CASCADE, + play_index INTEGER NOT NULL, + play_time_ms INTEGER NOT NULL DEFAULT 0, + created_at TEXT NOT NULL DEFAULT strftime('%F %TZ', date()), + last_used TEXT NOT NULL DEFAULT strftime('%F %TZ', date()) +); + +CREATE INDEX bookmarks_playlist_id_idx ON bookmarks (playlist_id); +CREATE INDEX bookmarks_media_file_id_idx ON bookmarks (media_file_id); + +CREATE TABLE media_files_tags ( + media_file_id TEXT REFERENCES media_files(id) ON DELETE CASCADE ON UPDATE CASCADE, + tag_id TEXT REFERENCES tags(id) ON DELETE CASCADE ON UPDATE CASCADE, + PRIMARY KEY (media_file_id, tag_id) +); + +CREATE TABLE images ( + id TEXT PRIMARY KEY, + url TEXT +); + +CREATE TABLE artists_images ( + artist_id TEXT REFERENCES artists (id) ON DELETE CASCADE ON UPDATE CASCADE, + image_id TEXT REFERENCES images (id) ON DELETE CASCADE ON UPDATE CASCADE, + PRIMARY KEY (artist_id, image_id) +); + +CREATE TABLE albums_images ( + album_id TEXT REFERENCES albums (id) ON DELETE CASCADE ON UPDATE CASCADE, + image_id TEXT REFERENCES images (id) ON DELETE CASCADE ON UPDATE CASCADE, + PRIMARY KEY (album_id, image_id) +); + +CREATE TABLE artists_albums ( + artist_id TEXT NOT NULL REFERENCES artists (id) ON DELETE CASCADE ON UPDATE CASCADE, + album_id TEXT NOT NULL REFERENCES albums (id) ON DELETE CASCADE ON UPDATE CASCADE, + PRIMARY KEY (artist_id, album_id) +);