emmental/emmental/db/emmental.sql

412 lines
11 KiB
SQL

/* Copyright 2022 (c) Anna Schumaker */
PRAGMA user_version = 1;
/**************************************
* *
* Application Settings *
* *
**************************************/
CREATE TABLE settings (
key TEXT PRIMARY KEY,
type TEXT NOT NULL,
value TEXT NOT NULL,
CHECK (type IN ("gint", "gdouble", "gboolean", "gchararray"))
);
/*************************************
* *
* Playlist Properties *
* *
*************************************/
CREATE TABLE playlist_properties (
propertyid INTEGER PRIMARY KEY,
active BOOLEAN NOT NULL DEFAULT FALSE
);
CREATE TRIGGER playlists_active_trigger
AFTER UPDATE OF active ON playlist_properties
FOR EACH ROW BEGIN
UPDATE playlist_properties
SET active = FALSE
WHERE propertyid != NEW.propertyid AND active == TRUE;
END;
/*******************************************
* *
* User and System Playlists *
* *
*******************************************/
CREATE TABLE playlists (
playlistid INTEGER PRIMARY KEY,
propertyid INTEGER REFERENCES playlist_properties(propertyid)
ON DELETE CASCADE
ON UPDATE CASCADE,
name TEXT NOT NULL UNIQUE COLLATE NOCASE,
image PATH
);
CREATE VIEW playlists_view AS
SELECT playlistid, propertyid, name, image, active
FROM playlists
JOIN playlist_properties USING (propertyid);
CREATE TRIGGER playlists_insert_trigger AFTER INSERT ON playlists
BEGIN
INSERT INTO playlist_properties (active)
VALUES (NEW.name == "Collection");
UPDATE playlists SET propertyid = last_insert_rowid()
WHERE playlistid = NEW.playlistid;
END;
CREATE TRIGGER playlists_delete_trigger AFTER DELETE ON playlists
BEGIN
DELETE FROM playlist_properties WHERE propertyid = OLD.propertyid;
END;
/*************************
* *
* Artists *
* *
*************************/
CREATE TABLE artists (
artistid INTEGER PRIMARY KEY,
propertyid INTEGER REFERENCES playlist_properties (propertyid)
ON DELETE CASCADE
ON UPDATE CASCADE,
name TEXT NOT NULL COLLATE NOCASE,
mbid TEXT NOT NULL DEFAULT "" COLLATE NOCASE,
UNIQUE (name, mbid)
);
CREATE VIEW artists_view AS
SELECT artistid, propertyid, name, mbid, active
FROM artists
JOIN playlist_properties USING (propertyid);
CREATE TRIGGER artists_insert_trigger AFTER INSERT ON artists
BEGIN
INSERT INTO playlist_properties (active) VALUES (False);
UPDATE artists SET propertyid = last_insert_rowid(),
mbid = LOWER(NEW.mbid)
WHERE artistid = NEW.artistid;
END;
CREATE TRIGGER artists_delete_trigger AFTER DELETE ON artists
BEGIN
DELETE FROM playlist_properties WHERE propertyid = OLD.propertyid;
END;
/************************
* *
* Albums *
* *
************************/
CREATE TABLE albums (
albumid INTEGER PRIMARY KEY,
propertyid INTEGER REFERENCES playlist_properties (propertyid)
ON DELETE CASCADE
ON UPDATE CASCADE,
name TEXT NOT NULL COLLATE NOCASE,
artist TEXT NOT NULL COLLATE NOCASE,
release TEXT NOT NULL,
mbid TEXT NOT NULL DEFAULT "" COLLATE NOCASE,
cover PATH,
UNIQUE (name, mbid, artist, release)
);
CREATE VIEW albums_view AS
SELECT albumid, propertyid, name, mbid, artist, release, cover, active
FROM albums
JOIN playlist_properties USING (propertyid);
CREATE TRIGGER albums_insert_trigger AFTER INSERT ON albums
BEGIN
INSERT INTO playlist_properties (active) VALUES (False);
UPDATE albums SET propertyid = last_insert_rowid(),
mbid = LOWER(NEW.mbid)
WHERE albumid = NEW.albumid;
END;
CREATE TRIGGER albums_delete_trigger AFTER DELETE ON albums
BEGIN
DELETE FROM playlist_properties WHERE propertyid = OLD.propertyid;
END;
/*************************
* *
* Mediums *
* *
*************************/
CREATE TABLE media (
mediumid INTEGER PRIMARY KEY,
propertyid INTEGER REFERENCES playlist_properties (propertyid)
ON DELETE CASCADE
ON UPDATE CASCADE,
albumid INTEGER NOT NULL REFERENCES albums (albumid)
ON DELETE CASCADE
ON UPDATE CASCADE,
number INTEGER NOT NULL,
name TEXT NOT NULL DEFAULT "" COLLATE NOCASE,
type TEXT NOT NULL DEFAULT "" COLLATE NOCASE,
UNIQUE (albumid, number, type)
);
CREATE VIEW media_view AS
SELECT mediumid, propertyid, albumid, number, name, type, active
FROM media
JOIN playlist_properties USING (propertyid);
CREATE TRIGGER media_insert_trigger AFTER INSERT ON media
BEGIN
INSERT INTO playlist_properties (active) VALUES (False);
UPDATE media SET propertyid = last_insert_rowid()
WHERE mediumid = NEW.mediumid;
END;
CREATE TRIGGER media_delete_trigger AFTER DELETE ON media
BEGIN
DELETE FROM playlist_properties WHERE propertyid = OLD.propertyid;
END;
/*******************************************************
* *
* Artist <--> Album <--> Medium Linking *
* *
*******************************************************/
CREATE TABLE album_artist_link (
artistid INTEGER NOT NULL REFERENCES artists (artistid)
ON DELETE CASCADE
ON UPDATE CASCADE,
albumid INTEGER NOT NULL REFERENCES albums (albumid)
ON DELETE CASCADE
ON UPDATE CASCADE,
UNIQUE (artistid, albumid)
);
CREATE VIEW album_artist_view AS
SELECT artistid, artists.name as artist,
albumid, COALESCE(albums.name, "") as album,
media.mediumid, COALESCE(media.name, "") as medium
FROM artists
LEFT JOIN album_artist_link USING (artistid)
LEFT JOIN albums USING (albumid)
LEFT JOIN media USING (albumid);
/************************
* *
* Genres *
* *
************************/
CREATE TABLE genres (
genreid INTEGER PRIMARY KEY,
propertyid INTEGER REFERENCES playlist_properties (propertyid)
ON DELETE CASCADE
ON UPDATE CASCADE,
name TEXT NOT NULL UNIQUE COLLATE NOCASE
);
CREATE VIEW genres_view AS
SELECT genreid, propertyid, name, active
FROM genres
JOIN playlist_properties USING (propertyid);
CREATE TRIGGER genres_insert_trigger AFTER INSERT ON genres
BEGIN
INSERT INTO playlist_properties (active) VALUES (False);
UPDATE genres SET propertyid = last_insert_rowid()
WHERE genreid = NEW.genreid;
END;
CREATE TRIGGER genres_delete_trigger AFTER DELETE ON genres
BEGIN
DELETE FROM playlist_properties WHERE propertyid = OLD.propertyid;
END;
/*************************
* *
* Decades *
* *
*************************/
CREATE TABLE decades (
decade INTEGER PRIMARY KEY,
propertyid INTEGER REFERENCES playlist_properties (propertyid)
ON DELETE CASCADE
ON UPDATE CASCADE
CHECK (decade % 10 = 0)
);
CREATE VIEW decades_view AS
SELECT decade, propertyid, FORMAT("The %ds", decade) as name, active
FROM decades
JOIN playlist_properties USING (propertyid);
CREATE TRIGGER decades_insert_trigger AFTER INSERT ON decades
BEGIN
INSERT INTO playlist_properties (active) VALUES (False);
UPDATE decades SET propertyid = last_insert_rowid()
WHERE decade = NEW.decade;
END;
CREATE TRIGGER decades_delete_trigger AFTER DELETE ON decades
BEGIN
DELETE FROM playlist_properties WHERE propertyid = OLD.propertyid;
END;
/***********************
* *
* Years *
* *
***********************/
CREATE TABLE years (
year INTEGER PRIMARY KEY,
propertyid INTEGER REFERENCES playlist_properties (propertyid)
ON DELETE CASCADE
ON UPDATE CASCADE
);
CREATE VIEW years_view AS
SELECT year, propertyid, FORMAT("%s", year) as name, active
FROM years
JOIN playlist_properties USING (propertyid);
CREATE TRIGGER years_insert_trigger AFTER INSERT ON years
BEGIN
INSERT INTO playlist_properties (active) VALUES (False);
UPDATE years SET propertyid = last_insert_rowid()
WHERE year = NEW.year;
END;
CREATE TRIGGER years_delete_trigger AFTER DELETE ON years
BEGIN
DELETE FROM playlist_properties WHERE propertyid = OLD.propertyid;
END;
/*******************************
* *
* Library Paths *
* *
*******************************/
CREATE TABLE libraries (
libraryid INTEGER PRIMARY KEY,
propertyid INTEGER REFERENCES playlist_properties (propertyid)
ON DELETE CASCADE
ON UPDATE CASCADE,
path PATH UNIQUE,
enabled BOOLEAN DEFAULT TRUE,
deleting BOOLEAN DEFAULT FALSE
);
CREATE VIEW libraries_view AS
SELECT libraryid, propertyid, path, path as name, enabled, active
FROM libraries
JOIN playlist_properties USING (propertyid);
CREATE TRIGGER libraries_insert_trigger AFTER INSERT ON libraries
BEGIN
INSERT INTO playlist_properties (active) VALUES (False);
UPDATE libraries SET propertyid = last_insert_rowid()
WHERE libraryid = NEW.libraryid;
END;
CREATE TRIGGER libraries_delete_trigger AFTER DELETE ON libraries
BEGIN
DELETE FROM playlist_properties WHERE propertyid = OLD.propertyid;
END;
/************************
* *
* Tracks *
* *
************************/
CREATE TABLE tracks (
trackid INTEGER PRIMARY KEY,
libraryid INTEGER REFERENCES libraries (libraryid)
ON DELETE CASCADE
ON UPDATE CASCADE,
mediumid INTEGER REFERENCES media (mediumid)
ON DELETE CASCADE
ON UPDATE CASCADE,
year INTEGER REFERENCES years (year)
ON DELETE CASCADE
ON UPDATE CASCADE,
path PATH NOT NULL,
mbid TEXT NOT NULL DEFAULT "" COLLATE NOCASE,
title TEXT NOT NULL,
number INTEGER NOT NULL,
length REAL NOT NULL,
artist TEXT NOT NULL,
mtime REAL NOT NULL,
active BOOLEAN NOT NULL DEFAULT FALSE,
favorite BOOLEAN NOT NULL DEFAULT FALSE,
playcount INTEGER NOT NULL DEFAULT 0,
added DATE DEFAULT CURRENT_DATE,
laststarted TIMESTAMP,
lastplayed TIMESTAMP,
UNIQUE (libraryid, path)
);
CREATE VIEW track_info_view AS
SELECT trackid, tracks.mediumid, tracks.number, length, playcount,
laststarted, lastplayed, title, tracks.artist,
tracks.path as filepath,
media.number as mediumno, COALESCE(media.name, "") as medium,
albums.albumid, COALESCE(albums.name, "") as album,
COALESCE(albums.release, "") as release,
COALESCE(albums.artist, "") as albumartist,
libraries.deleting
FROM tracks
LEFT JOIN media USING (mediumid)
LEFT JOIN albums USING (albumid)
LEFT JOIN libraries USING (libraryid);
CREATE TRIGGER tracks_active_trigger
AFTER UPDATE OF active ON tracks
FOR EACH ROW BEGIN
UPDATE tracks
SET active = FALSE
WHERE trackid != NEW.trackid and active == TRUE;
END;
/******************************************
* *
* Create Default Playlists *
* *
******************************************/
INSERT INTO playlists (name) VALUES
("Collection"),
("Favorite Tracks"),
("Most Played Tracks"),
("New Tracks"),
("Previous Tracks"),
("Queued Tracks"),
("Unplayed Tracks");