notesmachine/server/nm-store/src/sql/select_note_collection_from...

92 lines
2.4 KiB
SQL

-- This is undoubtedly one of the more complex bits of code I've
-- written recently, and I do wish there had been macros because
-- there's a lot of hand-written, copy-pasted code here around the
-- basic content of a note; it would have been nice to be able to DRY
-- that out.
-- This expression creates a table, 'notetree', that contains all of
-- the notes nested under a page. Each entry in the table includes
-- the note's parent's internal and external ids so that applications
-- can build an actual tree out of a vec of these things.
-- TODO: Extensive testing to validate that the nodes are delivered
-- *in nesting order* to the client.
SELECT
id,
uuid,
parent_id,
parent_uuid,
content,
position,
notetype,
creation_date,
updated_date,
lastview_date,
deleted_date
FROM (
WITH RECURSIVE notetree (
id,
uuid,
parent_id,
parent_uuid,
content,
position,
notetype,
creation_date,
updated_date,
lastview_date,
deleted_date,
cycle
)
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"
-- 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
)
SELECT * from notetree);