113 lines
3.6 KiB
SQL
113 lines
3.6 KiB
SQL
CREATE TABLE artists (
|
|
id UUID PRIMARY KEY,
|
|
name VARCHAR UNIQUE NOT NULL
|
|
);
|
|
|
|
CREATE INDEX artists_name_idx ON artists(name);
|
|
|
|
CREATE TABLE albums (
|
|
id UUID PRIMARY KEY,
|
|
name VARCHAR NOT NULL,
|
|
year INTEGER,
|
|
track_total INTEGER
|
|
);
|
|
|
|
CREATE INDEX albums_name_idx ON albums(name);
|
|
|
|
CREATE TABLE media_files (
|
|
id UUID PRIMARY KEY,
|
|
name VARCHAR NOT NULL,
|
|
disc_number VARCHAR NOT NULL DEFAULT '1',
|
|
track_number INTEGER,
|
|
play_count INTEGER NOT NULL DEFAULT 0,
|
|
file_path VARCHAR NOT NULL,
|
|
file_hash VARCHAR NOT NULL,
|
|
meta_info_source VARCHAR NOT NULL, -- 'tag' or 'filesystem'
|
|
date_added TIMESTAMP NOT NULL DEFAULT NOW(),
|
|
last_played TIMESTAMP,
|
|
present_locally BOOLEAN NOT NULL DEFAULT TRUE,
|
|
comment VARCHAR DEFAULT ''
|
|
);
|
|
|
|
CREATE INDEX media_files_name_idx ON media_files(name);
|
|
|
|
CREATE TABLE artists_media_files (
|
|
artist_id UUID NOT NULL REFERENCES artists(id) ON DELETE CASCADE ON UPDATE CASCADE,
|
|
media_file_id UUID 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 UUID NOT NULL REFERENCES albums(id) ON DELETE CASCADE ON UPDATE CASCADE,
|
|
media_file_id UUID NOT NULL REFERENCES media_files(id) ON DELETE CASCADE ON UPDATE CASCADE,
|
|
PRIMARY KEY (album_id, media_file_id)
|
|
);
|
|
|
|
CREATE TABLE tags (
|
|
id UUID PRIMARY KEY,
|
|
name VARCHAR UNIQUE NOT NULL,
|
|
description VARCHAR NOT NULL DEFAULT ''
|
|
);
|
|
|
|
CREATE TABLE playlists (
|
|
id UUID PRIMARY KEY,
|
|
user_created BOOLEAN NOT NULL DEFAULT FALSE,
|
|
name VARCHAR NOT NULL,
|
|
media_file_count INTEGER NOT NULL DEFAULT 0,
|
|
copied_from_id UUID DEFAULT NULL,
|
|
created_at TIMESTAMP NOT NULL DEFAULT NOW(),
|
|
last_used TIMESTAMP NOT NULL DEFAULT NOW()
|
|
);
|
|
|
|
CREATE TABLE playlists_media_files (
|
|
playlist_id UUID NOT NULL REFERENCES playlists(id) ON DELETE CASCADE ON UPDATE CASCADE,
|
|
media_file_id UUID 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 UUID PRIMARY KEY,
|
|
name VARCHAR,
|
|
user_created BOOLEAN NOT NULL DEFAULT FALSE,
|
|
playlist_id UUID NOT NULL REFERENCES playlists(id) ON DELETE CASCADE ON UPDATE CASCADE,
|
|
media_file_id UUID 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 TIMESTAMP NOT NULL DEFAULT NOW(),
|
|
last_used TIMESTAMP NOT NULL DEFAULT NOW()
|
|
);
|
|
|
|
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 UUID REFERENCES media_files(id) ON DELETE CASCADE ON UPDATE CASCADE,
|
|
tag_id UUID REFERENCES tags(id) ON DELETE CASCADE ON UPDATE CASCADE,
|
|
PRIMARY KEY (media_file_id, tag_id)
|
|
);
|
|
|
|
CREATE TABLE images (
|
|
id UUID PRIMARY KEY,
|
|
url VARCHAR
|
|
);
|
|
|
|
CREATE TABLE artists_images (
|
|
artist_id UUID REFERENCES artists (id) ON DELETE CASCADE ON UPDATE CASCADE,
|
|
image_id UUID REFERENCES images (id) ON DELETE CASCADE ON UPDATE CASCADE,
|
|
PRIMARY KEY (artist_id, image_id)
|
|
);
|
|
|
|
CREATE TABLE albums_images (
|
|
album_id UUID REFERENCES albums (id) ON DELETE CASCADE ON UPDATE CASCADE,
|
|
image_id UUID REFERENCES images (id) ON DELETE CASCADE ON UPDATE CASCADE,
|
|
PRIMARY KEY (album_id, image_id)
|
|
);
|
|
|
|
CREATE TABLE artists_albums (
|
|
artist_id UUID NOT NULL REFERENCES artists (id) ON DELETE CASCADE ON UPDATE CASCADE,
|
|
album_id UUID NOT NULL REFERENCES albums (id) ON DELETE CASCADE ON UPDATE CASCADE,
|
|
PRIMARY KEY (artist_id, album_id)
|
|
);
|