109 lines
2.8 KiB
SQL
109 lines
2.8 KiB
SQL
BEGIN TRANSACTION;
|
|
CREATE TABLE source_files (
|
|
id INTEGER PRIMARY KEY,
|
|
filename TEXT UNIQUE NOT NULL,
|
|
size INTEGER NOT NULL,
|
|
hash TEXT,
|
|
mime_type INTEGER,
|
|
last_change INTEGER NOT NULL DEFAULT (strftime('%s','now')),
|
|
last_seen INTEGER NOT NULL DEFAULT (strftime('%s','now')),
|
|
FOREIGN KEY (mime_type) REFERENCES mime_types(id)
|
|
ON DELETE SET NULL
|
|
);
|
|
CREATE TABLE destinations (
|
|
id INTEGER PRIMARY KEY,
|
|
name TEXT UNIQUE NOT NULL
|
|
);
|
|
CREATE TABLE destination_files (
|
|
id INTEGER PRIMARY KEY,
|
|
filename TEXT,
|
|
last_change INTEGER NOT NULL DEFAULT 0,
|
|
source_file_id INTEGER,
|
|
destination_id INTEGER,
|
|
FOREIGN KEY (source_file_id) REFERENCES source_files(id)
|
|
ON DELETE SET NULL,
|
|
FOREIGN KEY (destination_id) REFERENCES destinations(id)
|
|
ON DELETE CASCADE
|
|
);
|
|
CREATE TABLE mime_types (
|
|
id INTEGER PRIMARY KEY,
|
|
mime_text TEXT UNIQUE NOT NULL
|
|
);
|
|
CREATE TABLE mime_actions (
|
|
id INTEGER PRIMARY KEY,
|
|
mime_type INTEGER,
|
|
destination_id INTEGER,
|
|
action INTEGER DEFAULT 1,
|
|
FOREIGN KEY (mime_type) REFERENCES mime_types(id),
|
|
FOREIGN KEY (destination_id) REFERENCES destinations(id)
|
|
ON DELETE CASCADE
|
|
);
|
|
CREATE TABLE tags (
|
|
source_file INTEGER PRIMARY KEY,
|
|
genre TEXT,
|
|
albumartist TEXT,
|
|
year TEXT,
|
|
album TEXT,
|
|
disc TEXT,
|
|
artist TEXT,
|
|
track TEXT,
|
|
title TEXT,
|
|
composer TEXT,
|
|
performer TEXT,
|
|
rate INTEGER,
|
|
channels INTEGER,
|
|
last_change INTEGER,
|
|
FOREIGN KEY (source_file) REFERENCES source_files(id)
|
|
ON DELETE CASCADE
|
|
);
|
|
|
|
CREATE VIEW mime_type_actions AS
|
|
SELECT
|
|
mime_types.id,mime_types.mime_text,
|
|
mime_actions.destination_id,mime_actions.action
|
|
FROM mime_types INNER JOIN mime_actions
|
|
ON mime_actions.mime_type = mime_types.id;
|
|
CREATE TRIGGER update_mime_actions INSTEAD OF UPDATE OF action ON mime_type_actions
|
|
BEGIN
|
|
UPDATE mime_actions
|
|
SET action=new.action
|
|
WHERE mime_type=old.id
|
|
AND destination_id=old.destination_id;
|
|
END;
|
|
|
|
CREATE TRIGGER create_dest_files_and_mime_actions AFTER INSERT ON destinations
|
|
BEGIN
|
|
INSERT INTO mime_actions
|
|
(mime_type,destination_id)
|
|
SELECT id,new.id
|
|
FROM mime_types;
|
|
INSERT INTO destination_files
|
|
(source_file_id,destination_id)
|
|
SELECT id,new.id
|
|
FROM source_files;
|
|
END;
|
|
|
|
CREATE TRIGGER create_mime_actions AFTER INSERT ON mime_types
|
|
BEGIN
|
|
INSERT INTO mime_actions (mime_type,destination_id)
|
|
SELECT mime_types.id,destinations.id
|
|
FROM mime_types INNER JOIN destinations
|
|
WHERE mime_types.id=new.id;
|
|
END;
|
|
|
|
CREATE INDEX sourcefiles_by_name ON source_files (filename,id);
|
|
|
|
CREATE TRIGGER create_destinations AFTER INSERT ON source_files
|
|
BEGIN
|
|
INSERT INTO destination_files (source_file_id,destination_id)
|
|
SELECT source_files.id,destinations.id FROM source_files
|
|
INNER JOIN destinations
|
|
WHERE source_files.id=new.id;
|
|
END;
|
|
CREATE TRIGGER create_tags AFTER INSERT ON source_files
|
|
BEGIN
|
|
INSERT INTO tags (source_file,last_change) VALUES (new.id,0);
|
|
END;
|
|
|
|
COMMIT;
|