Reverse reference SQL written.
This is pretty hairy, because we're relying on the LEFT JOIN feature to give us the root node when we need it. That's kinda ugly, but it seems to work just fine. It also gives us the list in the *correct* order, so the only thing we need to do is go to the last item in the returned vector, make sure it's a root node, then go fetch the page so we can decorate the list with the *right* root. We'll pass this as a JSON object { [notes-in-reverse], page }.
This commit is contained in:
parent
dd61f8c0c2
commit
da44610098
|
@ -0,0 +1,36 @@
|
|||
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
|
||||
);
|
||||
|
||||
|
|
@ -0,0 +1,101 @@
|
|||
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.
|
|
@ -0,0 +1,88 @@
|
|||
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, position, notetype
|
||||
FROM (
|
||||
WITH RECURSIVE notetree (
|
||||
id, uuid, parent_id, parent_uuid, position, notetype, cycle
|
||||
)
|
||||
|
||||
AS (
|
||||
SELECT notes.id, notes.uuid,
|
||||
notes.id AS parent_id,
|
||||
notes.uuid AS parent_uuid,
|
||||
0, notes.notetype, ','||notes.id||','
|
||||
FROM notes
|
||||
WHERE notes.id = 1 AND notes.notetype = "root"
|
||||
|
||||
UNION
|
||||
SELECT notes.id, notes.uuid,
|
||||
notetree.id AS parent_id,
|
||||
notetree.uuid AS parent_uuid,
|
||||
note_relationships.position,
|
||||
notes.notetype,
|
||||
notetree.cycle||notes.id||','
|
||||
FROM notes
|
||||
INNER JOIN note_relationships
|
||||
ON notes.id = note_relationships.note_id
|
||||
INNER JOIN notetree
|
||||
ON note_relationships.parent_id = notetree.id
|
||||
WHERE notetree.cycle NOT LIKE '%,'||notes.id||',%'
|
||||
ORDER BY note_relationships.position
|
||||
)
|
||||
|
||||
SELECT * from notetree);
|
||||
|
||||
|
||||
|
|
@ -0,0 +1,72 @@
|
|||
SELECT
|
||||
id,
|
||||
uuid,
|
||||
parent_id,
|
||||
parent_uuid,
|
||||
content,
|
||||
notetype,
|
||||
creation_date,
|
||||
updated_date,
|
||||
lastview_date,
|
||||
deleted_date
|
||||
|
||||
FROM (
|
||||
|
||||
WITH RECURSIVE parents (
|
||||
id,
|
||||
uuid,
|
||||
parent_id,
|
||||
parent_uuid,
|
||||
content,
|
||||
notetype,
|
||||
creation_date,
|
||||
updated_date,
|
||||
lastview_date,
|
||||
deleted_date,
|
||||
cycle
|
||||
)
|
||||
|
||||
AS (
|
||||
|
||||
SELECT
|
||||
notes.id,
|
||||
notes.uuid,
|
||||
note_parents.id,
|
||||
note_parents.uuid,
|
||||
notes.content,
|
||||
notes.notetype,
|
||||
notes.creation_date,
|
||||
notes.updated_date,
|
||||
notes.lastview_date,
|
||||
notes.deleted_date,
|
||||
','||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 = ? -- IMPORTANT: THIS IS THE PARAMETER
|
||||
|
||||
UNION
|
||||
SELECT DISTINCT
|
||||
notes.id,
|
||||
notes.uuid,
|
||||
next_parent.id,
|
||||
next_parent.uuid,
|
||||
notes.content,
|
||||
notes.creation_date,
|
||||
notes.updated_date,
|
||||
notes.lastview_date,
|
||||
notes.deleted_date,
|
||||
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);
|
|
@ -27,7 +27,7 @@ SELECT
|
|||
|
||||
FROM (
|
||||
|
||||
WITH RECURSIVE notetree(
|
||||
WITH RECURSIVE notetree (
|
||||
id,
|
||||
uuid,
|
||||
parent_id,
|
||||
|
@ -39,48 +39,53 @@ FROM (
|
|||
updated_date,
|
||||
lastview_date,
|
||||
deleted_date,
|
||||
cycle) AS
|
||||
cycle
|
||||
)
|
||||
|
||||
-- ROOT expression
|
||||
(SELECT
|
||||
notes.id,
|
||||
notes.uuid,
|
||||
notes.id AS parent_id,
|
||||
notes.uuid AS parent_uuid,
|
||||
notes.content,
|
||||
0, -- Root notes are always in position 0
|
||||
notes.notetype,
|
||||
notes.creation_date,
|
||||
notes.updated_date,
|
||||
notes.lastview_date,
|
||||
notes.deleted_date,
|
||||
','||notes.id||',' -- Cycle monitor
|
||||
AS (
|
||||
|
||||
SELECT
|
||||
notes.id,
|
||||
notes.uuid,
|
||||
notes.id AS parent_id,
|
||||
notes.uuid AS parent_uuid,
|
||||
notes.content,
|
||||
0, -- Root notes are always in position 0
|
||||
notes.notetype,
|
||||
notes.creation_date,
|
||||
notes.updated_date,
|
||||
notes.lastview_date,
|
||||
notes.deleted_date,
|
||||
','||notes.id||',' -- Cycle monitor
|
||||
FROM notes
|
||||
WHERE notes.id = ? AND notes.notetype = "root"
|
||||
WHERE notes.id = ? AND notes.notetype = "root"
|
||||
|
||||
-- RECURSIVE expression
|
||||
UNION SELECT
|
||||
notes.id,
|
||||
notes.uuid,
|
||||
notetree.id AS parent_id,
|
||||
notetree.uuid AS parent_uuid,
|
||||
notes.content,
|
||||
note_relationships.position,
|
||||
notes.notetype,
|
||||
notes.creation_date,
|
||||
notes.updated_date,
|
||||
notes.lastview_date,
|
||||
notes.deleted_date,
|
||||
notetree.cycle||notes.id||','
|
||||
FROM notes
|
||||
INNER JOIN note_relationships ON notes.id = note_relationships.note_id
|
||||
-- For a given ID in the level of notetree in *this* recursion,
|
||||
-- we want each note's branches one level down.
|
||||
INNER JOIN notetree ON note_relationships.parent_id = notetree.id
|
||||
-- And we want to make sure there are no cycles. There shouldn't
|
||||
-- be; we're supposed to prevent those. But you never know.
|
||||
WHERE
|
||||
notetree.cycle NOT LIKE '%,'||notes.id||',%'
|
||||
ORDER BY note_relationships.position)
|
||||
UNION SELECT
|
||||
notes.id,
|
||||
notes.uuid,
|
||||
notetree.id AS parent_id,
|
||||
notetree.uuid AS parent_uuid,
|
||||
notes.content,
|
||||
note_relationships.position,
|
||||
notes.notetype,
|
||||
notes.creation_date,
|
||||
notes.updated_date,
|
||||
notes.lastview_date,
|
||||
notes.deleted_date,
|
||||
notetree.cycle||notes.id||','
|
||||
FROM notes
|
||||
INNER JOIN note_relationships
|
||||
ON notes.id = note_relationships.note_id
|
||||
-- For a given ID in the level of notetree in *this* recursion,
|
||||
-- we want each note's branches one level down.
|
||||
INNER JOIN notetree
|
||||
ON note_relationships.parent_id = notetree.id
|
||||
-- And we want to make sure there are no cycles. There shouldn't
|
||||
-- be; we're supposed to prevent those. But you never know.
|
||||
WHERE notetree.cycle NOT LIKE '%,'||notes.id||',%'
|
||||
ORDER BY note_relationships.position
|
||||
)
|
||||
|
||||
SELECT * from notetree);
|
||||
|
||||
|
|
Loading…
Reference in New Issue