summaryrefslogtreecommitdiff
path: root/initialize.sql
blob: 31f4b136008a640a8467019deab862fc4fa3bca5 (plain)
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
CREATE TABLE IF NOT EXISTS image(
	sha1     TEXT NOT NULL,  -- SHA-1 hash of file in lowercase hexadecimal
	thumbw   INTEGER,        -- cached thumbnail width, if known
	thumbh   INTEGER,        -- cached thumbnail height, if known
	dhash    INTEGER,        -- uint64 perceptual hash as a signed integer
	PRIMARY KEY (sha1)
) STRICT;

CREATE INDEX IF NOT EXISTS image__dhash ON image(dhash);

--

CREATE TABLE IF NOT EXISTS directory(
	id       INTEGER NOT NULL,                  -- unique ID
	name     TEXT NOT NULL,                     -- basename
	parent   INTEGER REFERENCES directory(id),  -- root if NULL
	PRIMARY KEY (id)
) STRICT;

CREATE UNIQUE INDEX IF NOT EXISTS directory__parent_name
ON directory(IFNULL(parent, 0), name);

-- FIXME: I want a nullable parent, but that can't be a primary key.
--  - Perhaps have an INTEGER for the PK of entry, and use a UNIQUE INDEX.
--  - Alternatively, create a directory record for the root.
CREATE TABLE IF NOT EXISTS entry(
	parent   INTEGER NOT NULL REFERENCES directory(id),
	name     TEXT NOT NULL,     -- last FS path component
	mtime    INTEGER NOT NULL,  -- Unix time of last modification in seconds
	sha1     TEXT NOT NULL REFERENCES image(sha1),
	PRIMARY KEY (parent, name)
) STRICT;

CREATE INDEX IF NOT EXISTS entry__sha1 ON entry(sha1);

/*
Automatic garbage collection, not sure if it actually makes any sense:

CREATE TRIGGER IF NOT EXISTS entry__parent__gc
AFTER DELETE ON entry FOR EACH ROW
BEGIN
	DELETE FROM directory WHERE id = OLD.parent
	AND id NOT IN (SELECT DISTINCT parent FROM entry)
	AND id NOT IN (SELECT DISTINCT parent FROM directory);
END;

CREATE TRIGGER IF NOT EXISTS directory__parent__gc
AFTER DELETE ON directory FOR EACH ROW
BEGIN
	DELETE FROM directory WHERE id = OLD.parent
	AND id NOT IN (SELECT DISTINCT parent FROM entry)
	AND id NOT IN (SELECT DISTINCT parent FROM directory);
END;
*/

--

CREATE TABLE IF NOT EXISTS tag_space(
	id          INTEGER NOT NULL,
	name        TEXT NOT NULL,
	description TEXT,
	PRIMARY KEY (id)
) STRICT;

CREATE UNIQUE INDEX IF NOT EXISTS tag_space__name ON tag_space(name);

-- To avoid having to deal with NULLs, always create this special tag space.
INSERT OR IGNORE INTO tag_space(id, name, description)
VALUES(0, '', 'User-defined tags');

CREATE TABLE IF NOT EXISTS tag(
	id       INTEGER NOT NULL,
	space    INTEGER NOT NULL REFERENCES tag_space(id),
	name     TEXT NOT NULL,
	PRIMARY KEY (id)
) STRICT;

CREATE UNIQUE INDEX IF NOT EXISTS tag__space_name ON tag(space, name);

CREATE TABLE IF NOT EXISTS tag_assignment(
	sha1     TEXT NOT NULL REFERENCES image(sha1),
	tag      INTEGER NOT NULL REFERENCES tag(id),
	weight   REAL NOT NULL,     -- 0..1 normalized weight assigned to tag
	PRIMARY KEY (sha1, tag)
) STRICT;

CREATE INDEX IF NOT EXISTS tag_assignment__tag ON tag_assignment(tag);