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

99 lines
2.8 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.
-- Search in here for the term QUERYPARAMETER. That string will be
-- substituted with the correct parameter (id or title) depending on
-- the use case, by the level 1 client (the private parts of
-- store.rs).
SELECT
id,
parent_id,
content,
location,
kind,
creation_date,
updated_date,
lastview_date,
deleted_date
FROM (
WITH RECURSIVE notestree (
id,
parent_id,
content,
location,
kind,
creation_date,
updated_date,
lastview_date,
deleted_date,
cycle
)
AS (
-- The seed query. Finds the root node of any tree of notes,
-- which by definition has a location of zero and a type of
-- 'page'.
SELECT
notes.id,
NULL as parent_id,
notes.content,
0, -- All boxes are at position zero. They are the root of the tree.
notes.kind,
notes.creation_date,
notes.updated_date,
notes.lastview_date,
notes.deleted_date,
','||notes.id||',' -- Cycle monitor
FROM notes
WHERE notes.kind = "box"
AND QUERYPARAMETER = ? -- The Query Parameter
-- RECURSIVE expression
--
-- Here, for each recursion down the tree, we collect the child
-- nodes for a given node, eliding any cycles.
--
-- TODO: Figure out what to do when a cycle DOES occur.
UNION SELECT
notes.id,
notestree.id AS parent_id,
notes.content,
note_relationships.location,
notes.kind,
notes.creation_date,
notes.updated_date,
notes.lastview_date,
notes.deleted_date,
notestree.cycle||notes.id||','
FROM notes
INNER JOIN note_relationships
ON notes.id = note_relationships.note_id
-- For a given ID in the level of notestree in *this* recursion,
-- we want each note's branches one level down.
INNER JOIN notestree
ON note_relationships.parent_id = notestree.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 notestree.cycle NOT LIKE '%,'||notes.id||',%'
ORDER BY note_relationships.location
)
SELECT * from notestree);