JSON-based SQL query for node tree
This commit is contained in:
parent
f1f0f499dd
commit
0138f72b83
2 changed files with 92 additions and 65 deletions
150
node.go
150
node.go
|
|
@ -111,25 +111,98 @@ func GetNode(nodeID int) (node Node, err error) { // {{{
|
|||
return
|
||||
} // }}}
|
||||
|
||||
func GetNodeTree(startNodeID, maxDepth int) (topNode *Node, err error) { // {{{
|
||||
func GetNodeTree(startNodeID, maxDepth int, withData bool) (topNode *Node, err error) { // {{{
|
||||
nodes := make(map[int]*Node)
|
||||
var rows *sqlx.Rows
|
||||
rows, err = GetNodeRows(startNodeID, maxDepth)
|
||||
|
||||
var nodesFromRow []Node
|
||||
row := db.QueryRow(`
|
||||
SELECT json_agg(res) FROM (
|
||||
WITH RECURSIVE nodes AS (
|
||||
SELECT
|
||||
$1::int AS id,
|
||||
0 AS depth
|
||||
UNION
|
||||
|
||||
SELECT
|
||||
n.id,
|
||||
ns.depth+1 AS depth
|
||||
FROM node n
|
||||
INNER JOIN nodes ns ON ns.depth < $2 AND n.parent_id = ns.id
|
||||
)
|
||||
|
||||
SEARCH DEPTH FIRST BY id SET ordercol
|
||||
|
||||
SELECT
|
||||
COALESCE(n.parent_id, -1) AS ParentID,
|
||||
n.id,
|
||||
n.name,
|
||||
n.type_id AS TypeID,
|
||||
t.name AS TypeName,
|
||||
COALESCE(t.schema->>'icon', '') AS TypeIcon,
|
||||
n.updated,
|
||||
n.data AS data,
|
||||
COUNT(node_children.id) AS NumChildren,
|
||||
COALESCE(
|
||||
(
|
||||
SELECT jsonb_agg(res)
|
||||
FROM (
|
||||
SELECT
|
||||
nn.ID,
|
||||
COALESCE(nn.parent_id, -1) AS ParentID,
|
||||
nn.Name,
|
||||
nn.Updated,
|
||||
nn.data AS Data,
|
||||
|
||||
tt.id AS TypeID,
|
||||
tt.name AS TypeName,
|
||||
tt.schema AS TypeSchema,
|
||||
tt.schema->>'icon' AS TypeIcon,
|
||||
|
||||
c.id AS ConnectionID,
|
||||
c.data AS ConnectionData
|
||||
FROM connection c
|
||||
INNER JOIN public.node nn ON c.child_node_id = nn.id
|
||||
INNER JOIN public.type tt ON nn.type_id = tt.id
|
||||
WHERE
|
||||
c.parent_node_id = n.id
|
||||
) AS res
|
||||
)
|
||||
, '[]'::jsonb
|
||||
) AS ConnectedNodes
|
||||
FROM nodes ns
|
||||
INNER JOIN public.node n ON ns.id = n.id
|
||||
INNER JOIN public.type t ON n.type_id = t.id
|
||||
LEFT JOIN node node_children ON node_children.parent_id = n.id
|
||||
|
||||
GROUP BY
|
||||
ns.depth,
|
||||
n.parent_id,
|
||||
n.id,
|
||||
t.name,
|
||||
t.schema,
|
||||
ns.ordercol
|
||||
ORDER BY ordercol
|
||||
) AS res
|
||||
`,
|
||||
startNodeID,
|
||||
maxDepth,
|
||||
)
|
||||
|
||||
var body []byte
|
||||
err = row.Scan(&body)
|
||||
if err != nil {
|
||||
err = werr.Wrap(err)
|
||||
return
|
||||
}
|
||||
|
||||
err = json.Unmarshal(body, &nodesFromRow)
|
||||
if err != nil {
|
||||
err = werr.Wrap(err)
|
||||
return
|
||||
}
|
||||
defer rows.Close()
|
||||
|
||||
first := true
|
||||
for rows.Next() {
|
||||
var node Node
|
||||
err = rows.StructScan(&node)
|
||||
if err != nil {
|
||||
err = werr.Wrap(err)
|
||||
return
|
||||
}
|
||||
|
||||
for _, node := range nodesFromRow {
|
||||
if first {
|
||||
topNode = &node
|
||||
first = false
|
||||
|
|
@ -140,57 +213,6 @@ func GetNodeTree(startNodeID, maxDepth int) (topNode *Node, err error) { // {{{
|
|||
|
||||
return
|
||||
} // }}}
|
||||
func GetNodeRows(startNodeID, maxDepth int) (rows *sqlx.Rows, err error) { // {{{
|
||||
rows, err = db.Queryx(`
|
||||
WITH RECURSIVE nodes AS (
|
||||
SELECT
|
||||
$1::int AS id,
|
||||
0 AS depth
|
||||
UNION
|
||||
|
||||
SELECT
|
||||
n.id,
|
||||
ns.depth+1 AS depth
|
||||
FROM node n
|
||||
INNER JOIN nodes ns ON ns.depth < $2 AND n.parent_id = ns.id
|
||||
)
|
||||
|
||||
SEARCH DEPTH FIRST BY id SET ordercol
|
||||
|
||||
SELECT
|
||||
COALESCE(n.parent_id, -1) AS parent_id,
|
||||
n.id,
|
||||
n.name,
|
||||
n.type_id,
|
||||
t.name AS type_name,
|
||||
COALESCE(t.schema->>'icon', '') AS type_icon,
|
||||
n.updated,
|
||||
n.data AS data_raw,
|
||||
COUNT(node_children.id) AS num_children
|
||||
FROM nodes ns
|
||||
INNER JOIN public.node n ON ns.id = n.id
|
||||
INNER JOIN public.type t ON n.type_id = t.id
|
||||
LEFT JOIN node node_children ON node_children.parent_id = n.id
|
||||
|
||||
GROUP BY
|
||||
ns.depth,
|
||||
n.parent_id,
|
||||
n.id,
|
||||
t.name,
|
||||
t.schema,
|
||||
ns.ordercol
|
||||
ORDER BY ordercol
|
||||
`,
|
||||
startNodeID,
|
||||
maxDepth,
|
||||
)
|
||||
|
||||
if err != nil {
|
||||
err = werr.Wrap(err)
|
||||
}
|
||||
|
||||
return
|
||||
} // }}}
|
||||
func ComposeTree(nodes map[int]*Node, node *Node) { // {{{
|
||||
if node.Children == nil {
|
||||
node.Children = []*Node{}
|
||||
|
|
@ -321,7 +343,7 @@ func SearchNodes(typeID int, search string, maxResults int) (nodes []Node, err e
|
|||
|
||||
row := db.QueryRowx(`
|
||||
SELECT
|
||||
json_agg(res) AS node
|
||||
COALESCE(json_agg(res), '[]'::json) AS node
|
||||
FROM (
|
||||
SELECT
|
||||
n.id,
|
||||
|
|
|
|||
|
|
@ -105,7 +105,12 @@ func actionNodesTree(w http.ResponseWriter, r *http.Request) { // {{{
|
|||
maxDepth = 3
|
||||
}
|
||||
|
||||
topNode, err := GetNodeTree(startNode, maxDepth)
|
||||
var withData bool
|
||||
if r.URL.Query().Get("data") == "true" {
|
||||
withData = true
|
||||
}
|
||||
|
||||
topNode, err := GetNodeTree(startNode, maxDepth, withData)
|
||||
if err != nil {
|
||||
err = werr.Wrap(err)
|
||||
httpError(w, err)
|
||||
|
|
|
|||
Loading…
Add table
Add a link
Reference in a new issue