102 lines
2.8 KiB
MySQL
102 lines
2.8 KiB
MySQL
|
DROP TABLE IF EXISTS notes;
|
||
|
DROP TABLE IF EXISTS note_relationships;
|
||
|
DROP TABLE IF EXISTS pages;
|
||
|
DROP TABLE IF EXISTS page_relationships;
|
||
|
DROP TABLE IF EXISTS favorites;
|
||
|
|
||
|
CREATE TABLE notes (
|
||
|
id INTEGER PRIMARY KEY AUTOINCREMENT,
|
||
|
uuid TEXT NOT NULL UNIQUE,
|
||
|
notetype TEXT
|
||
|
);
|
||
|
|
||
|
CREATE TABLE pages (
|
||
|
id INTEGER PRIMARY KEY AUTOINCREMENT,
|
||
|
slug text NOT NULL UNIQUE,
|
||
|
note_id INTEGER,
|
||
|
FOREIGN KEY (note_id) REFERENCES notes (id) ON DELETE NO ACTION ON UPDATE NO ACTION
|
||
|
);
|
||
|
|
||
|
CREATE TABLE note_relationships (
|
||
|
note_id INTEGER NOT NULL,
|
||
|
parent_id INTEGER NOT NULL,
|
||
|
position INTEGER NOT NULL,
|
||
|
nature TEXT NOT NULL,
|
||
|
FOREIGN KEY (note_id) REFERENCES notes (id) ON DELETE NO ACTION ON UPDATE NO ACTION,
|
||
|
FOREIGN KEY (parent_id) REFERENCES notes (id) ON DELETE NO ACTION ON UPDATE NO ACTION
|
||
|
);
|
||
|
|
||
|
CREATE TABLE page_relationships (
|
||
|
note_id INTEGER NOT NULL,
|
||
|
page_id INTEGER NOT NULL,
|
||
|
FOREIGN KEY (note_id) references notes (id) ON DELETE NO ACTION ON UPDATE NO ACTION,
|
||
|
FOREIGN KEY (page_id) references pages (id) ON DELETE NO ACTION ON UPDATE NO ACTION
|
||
|
);
|
||
|
|
||
|
INSERT INTO notes (id, uuid, notetype) VALUES
|
||
|
(1, "U1", "root"),
|
||
|
(2, "U2", "note"),
|
||
|
(3, "U3", "note"),
|
||
|
(4, "U4", "note"),
|
||
|
(5, "U5", "note"),
|
||
|
(6, "U6", "note"),
|
||
|
(7, "U7", "note"),
|
||
|
(8, "U8", "note");
|
||
|
|
||
|
INSERT INTO note_relationships (note_id, parent_id, position, nature) VALUES
|
||
|
(2, 1, 1, "note"),
|
||
|
(3, 1, 2, "note"),
|
||
|
(4, 3, 1, "note"),
|
||
|
(5, 3, 2, "note"),
|
||
|
(6, 5, 1, "note"),
|
||
|
(7, 4, 1, "note"),
|
||
|
(8, 7, 1, "note");
|
||
|
|
||
|
|
||
|
SELECT id, uuid, parent_id, parent_uuid, notetype
|
||
|
FROM (
|
||
|
WITH RECURSIVE parents (
|
||
|
id, uuid, parent_id, parent_uuid, notetype, cycle
|
||
|
)
|
||
|
|
||
|
AS (
|
||
|
SELECT notes.id, notes.uuid,
|
||
|
note_parents.id,
|
||
|
note_parents.uuid,
|
||
|
notes.notetype,
|
||
|
','||notes.id||','
|
||
|
FROM notes
|
||
|
INNER JOIN note_relationships
|
||
|
ON notes.id = note_relationships.note_id
|
||
|
AND notes.notetype = 'note'
|
||
|
INNER JOIN notes as note_parents
|
||
|
ON note_parents.id = note_relationships.parent_id
|
||
|
WHERE notes.id = 4
|
||
|
|
||
|
UNION
|
||
|
SELECT DISTINCT notes.id,
|
||
|
notes.uuid,
|
||
|
next_parent.id,
|
||
|
next_parent.uuid,
|
||
|
notes.notetype,
|
||
|
parents.cycle||notes.id||','
|
||
|
FROM notes
|
||
|
INNER JOIN parents
|
||
|
ON parents.parent_id = notes.id
|
||
|
LEFT JOIN note_relationships
|
||
|
ON note_relationships.note_id = notes.id
|
||
|
LEFT JOIN notes as next_parent
|
||
|
ON next_parent.id = note_relationships.parent_id
|
||
|
WHERE parents.cycle NOT LIKE '%,'||notes.id||',%'
|
||
|
)
|
||
|
|
||
|
SELECT * FROM parents);
|
||
|
|
||
|
-- Possible outcomes epending on the 'WHERE notes.id' clause in the root SELECT (first value is passed in):
|
||
|
-- 8, 7, 4, 3, 1
|
||
|
-- 6, 5, 3, 1
|
||
|
-- 2, 1
|
||
|
-- 4, 3, 1
|
||
|
-- 1 should result in no return (root notes aren't returned by themselves; they exist only so that
|
||
|
-- valid note reversals can find their parent page objects.
|