|
| 1 | +--- |
| 2 | +layout: default |
| 3 | +title: SELECT Descendants |
| 4 | +nav_order: 3 |
| 5 | +parent: Materialized Paths |
| 6 | +permalink: /mat-paths/select-desc |
| 7 | +--- |
| 8 | + |
| 9 | +### Scope of provided selection queries for the MPs model |
| 10 | + |
| 11 | +This and the following sections provide a family of standard MPs queries for selecting a set of category tree nodes, their descendants, and ancestors. These queries return rows from the *categories* table for the following standard MPs node sets: |
| 12 | + |
| 13 | + - root nodes (just the nodes from the input) |
| 14 | + - all descendants, excluding the root nodes |
| 15 | + - subtrees, including root nodes and descendants |
| 16 | + - children, i.e., direct descendants only |
| 17 | + |
| 18 | +All provided selection queries have the [modular CTEs-based](../meta/db-derived-cte) structure and take a unified input in the form of a [JSON-array-formatted](../patterns/json-sql-input) string |
| 19 | + |
| 20 | +~~~json |
| 21 | +["tcl/compat/zlib1/", "BAZ/dev/git4win/x32/mingw32/share/"] |
| 22 | +~~~ |
| 23 | + |
| 24 | +with a list of category *path* values, identifying subtree root nodes. |
| 25 | + |
| 26 | +### Query structure and alternative category identifiers |
| 27 | + |
| 28 | +Each query starts with a prologue. Its function is to take the unified JSON array string of category identifiers (the *json_nodes* entry block) and its exit *tops* block produces a table containing the *path* column with one category path per row: |
| 29 | + |
| 30 | +#### Prologue input |
| 31 | + |
| 32 | +~~~json |
| 33 | +["tcl/compat/zlib1/", "BAZ/dev/git4win/x32/mingw32/share/"] |
| 34 | +~~~ |
| 35 | + |
| 36 | +#### Prologue |
| 37 | + |
| 38 | +~~~sql |
| 39 | +WITH |
| 40 | + json_nodes(ids) AS ( |
| 41 | + VALUES |
| 42 | + ('["tcl/compat/zlib1/", "BAZ/dev/git4win/x32/mingw32/share/"]') |
| 43 | + ), |
| 44 | + nodes AS ( |
| 45 | + SELECT node_ids.value AS node_id |
| 46 | + FROM json_nodes AS jn, json_each(jn.ids) AS node_ids |
| 47 | + ), |
| 48 | + tops AS (SELECT node_id AS path FROM nodes) |
| 49 | +SELECT * FROM tops ORDER BY path; |
| 50 | +~~~ |
| 51 | + |
| 52 | +#### Prologue output |
| 53 | + |
| 54 | +| path | |
| 55 | +|------------------------------------| |
| 56 | +| BAZ/dev/git4win/x32/mingw32/share/ | |
| 57 | +| tcl/compat/zlib1/ | |
| 58 | + |
| 59 | +--- |
| 60 | + |
| 61 | +Query prologue decouples the input format details from the query business logic. With query prologue and its output format defined, the input format and query business logic can be modified indepently. For example, switching from path-based to ascii_id-based identifies requires a localized change to a single block *tops*, identical for all queries in this family (immediate input in *json_nodes* is also adjusted; in production, a query parameter replaces this string input): |
| 62 | + |
| 63 | +#### Input |
| 64 | + |
| 65 | +~~~json |
| 66 | +["0FDAF2C8","65887f45"] |
| 67 | +~~~ |
| 68 | + |
| 69 | +#### Prologue |
| 70 | + |
| 71 | +~~~sql |
| 72 | +WITH |
| 73 | + json_nodes(ids) AS ( |
| 74 | + VALUES |
| 75 | + ('["0FDAF2C8", "65887f45"]') |
| 76 | + ), |
| 77 | + nodes AS ( |
| 78 | + SELECT node_ids.value AS node_id |
| 79 | + FROM json_nodes AS jn, json_each(jn.ids) AS node_ids |
| 80 | + ), |
| 81 | + tops AS ( |
| 82 | + SELECT cats.path |
| 83 | + FROM categories AS cats, nodes |
| 84 | + WHERE cats.ascii_id IN (nodes.node_id) |
| 85 | + ) |
| 86 | +SELECT * FROM tops ORDER BY path; |
| 87 | +~~~ |
| 88 | + |
| 89 | +--- |
| 90 | + |
| 91 | +### MPs queries |
| 92 | + |
| 93 | +Note that the four queries have alomst identical code, with the only difference in the WHERE clause (*records*). Here is a query template: |
| 94 | + |
| 95 | +~~~sql |
| 96 | +WITH |
| 97 | + json_nodes(ids) AS ( |
| 98 | + VALUES |
| 99 | + ('["tcl/compat/zlib1/", "BAZ/dev/git4win/x32/mingw32/share/"]') |
| 100 | + ), |
| 101 | + nodes AS ( |
| 102 | + SELECT node_ids.value AS node_id |
| 103 | + FROM json_nodes AS jn, json_each(jn.ids) AS node_ids |
| 104 | + ), |
| 105 | + tops AS (SELECT node_id AS path FROM nodes), |
| 106 | + records AS ( |
| 107 | + SELECT cats.* |
| 108 | + FROM categories AS cats, tops |
| 109 | + WHERE %SELECTOR% |
| 110 | + ) |
| 111 | +SELECT * FROM records ORDER BY path; |
| 112 | +~~~ |
| 113 | + |
| 114 | +in which %SELECTOR% should be replaced according to the following table |
| 115 | + |
| 116 | +| node set | %SELECTOR% | |
| 117 | +|-------------|-------------------------------------| |
| 118 | +| root nodes | `cats.path IN (tops.path)` | |
| 119 | +| descendants | `cats.prefix like tops.path || '%'` | |
| 120 | +| subtrees | `cats.path like tops.path || '%'` | |
| 121 | +| children | `cats.prefix = tops.path` | |
0 commit comments