emmental/emmental/db/emmental.sql
Anna Schumaker d3bdaaa063 db: Add an Artist Table
This table allows us to work with Artist playlists that have a name and
(optional) mbid. Note that we can insert multiple artists with the same
name into the database as long as they have different mbids.

Signed-off-by: Anna Schumaker <Anna@NoWheyCreamery.com>
2023-04-12 10:44:34 -04:00

124 lines
3.2 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;
/******************************************
* *
* Create Default Playlists *
* *
******************************************/
INSERT INTO playlists (name) VALUES
("Collection"),
("Favorite Tracks"),
("Most Played Tracks"),
("New Tracks"),
("Previous Tracks"),
("Queued Tracks"),
("Unplayed Tracks");