├── LICENSE.md
├── .gitignore
├── assets
├── closure-table-paths.png
└── call p_prefix_nodes_get_subtree_by_node_id.png
├── mysql
├── triggers
│ ├── trigger_add_node.sql
│ └── trigger_move_node.sql
├── procedures
│ ├── p_node_hide.sql
│ ├── p_node_add.sql
│ ├── p_get_tree.sql
│ └── p_node_move.sql
├── data
│ └── sample_data.sql
├── create_table_structure.sql
└── all-in-one.sql
├── postgres
├── README.md
├── procedures
│ ├── delete_subtree.sql
│ ├── get_child_nodes.sql
│ ├── add_node.sql
│ ├── move_subtree.sql
│ ├── get_subtree.sql
│ └── json_output.sql
├── create_table_structure.sql
├── triggers
│ └── add_new_paths_for_insert.sql
├── data
│ └── sample_data.sql
└── all-in-one.sql
└── README.md
/LICENSE.md:
--------------------------------------------------------------------------------
1 |
--------------------------------------------------------------------------------
/.gitignore:
--------------------------------------------------------------------------------
1 | .test
2 |
--------------------------------------------------------------------------------
/assets/closure-table-paths.png:
--------------------------------------------------------------------------------
https://raw.githubusercontent.com/developerworks/hierarchy-data-closure-table/HEAD/assets/closure-table-paths.png
--------------------------------------------------------------------------------
/assets/call p_prefix_nodes_get_subtree_by_node_id.png:
--------------------------------------------------------------------------------
https://raw.githubusercontent.com/developerworks/hierarchy-data-closure-table/HEAD/assets/call p_prefix_nodes_get_subtree_by_node_id.png
--------------------------------------------------------------------------------
/mysql/triggers/trigger_add_node.sql:
--------------------------------------------------------------------------------
1 | DELIMITER $$
2 |
3 | USE `hierarchy_data`$$
4 |
5 | DROP TRIGGER IF EXISTS `trigger_add_node`$$
6 |
7 | CREATE
8 | TRIGGER `trigger_add_node` AFTER INSERT ON `prefix_nodes`
9 | FOR EACH ROW BEGIN
10 | CALL p_node_add(NEW.`id`, NEW.`parent_id`);
11 | END;
12 | $$
13 |
14 | DELIMITER ;
15 |
--------------------------------------------------------------------------------
/postgres/README.md:
--------------------------------------------------------------------------------
1 | ## Description
2 |
3 | Directory structure:
4 |
5 | - `data`: Insert some test data.
6 | - `procedures`: Operations functions of clusure table in postgres dbms.
7 | - `triggers`: Just one trigger used to chanage parent/child relationship of nodes when add/move nodes in the tree.
8 | - `all-in-one.sql`: All codes of procedures and triggers
9 | - `create_table_structure.sql`: Create postgres database tables.
10 |
11 | ## References
12 |
13 |
14 | [Building a nested hierarchy of JSON in a relational DB](https://lakshminp.com/building-nested-hierarchy-json-relational-db)
15 |
--------------------------------------------------------------------------------
/postgres/procedures/delete_subtree.sql:
--------------------------------------------------------------------------------
1 | --------------------------------------------
2 | -- Delete a leaf
3 | --------------------------------------------
4 |
5 |
6 |
7 | --------------------------------------------
8 | -- Delete a subtree
9 | --------------------------------------------
10 |
11 | DROP FUNCTION IF EXISTS delete_subtree(INTEGER);
12 |
13 | CREATE FUNCTION delete_subtree(INTEGER)
14 | RETURNS VOID
15 | AS $$
16 | DELETE FROM prefix_nodes_paths
17 | WHERE descendant_id IN (
18 | SELECT descendant_id FROM prefix_nodes_paths WHERE ancestor_id = $1
19 | );
20 | $$ LANGUAGE sql
21 |
--------------------------------------------------------------------------------
/mysql/procedures/p_node_hide.sql:
--------------------------------------------------------------------------------
1 | DELIMITER $$
2 |
3 | USE `hierarchy_data`$$
4 |
5 | DROP PROCEDURE IF EXISTS `p_node_hide`$$
6 |
7 | CREATE PROCEDURE `p_node_hide` (
8 | `node_id` INT UNSIGNED,
9 | `deleted` INT UNSIGNED
10 | ) COMMENT 'Delete a node and its descendant nodes(update is_deleted = 1)'
11 | BEGIN
12 | UPDATE
13 | `prefix_nodes` AS d
14 | JOIN `prefix_nodes_paths` AS p
15 | ON d.`id` = p.`descendant_id`
16 | JOIN `prefix_nodes_paths` AS crumbs
17 | ON crumbs.`descendant_id` = p.`descendant_id` SET d.`is_deleted` = deleted
18 | WHERE p.`ancestor_id` = node_id;
19 | END $$
20 |
21 | DELIMITER ;
22 |
--------------------------------------------------------------------------------
/mysql/triggers/trigger_move_node.sql:
--------------------------------------------------------------------------------
1 | DELIMITER $$
2 |
3 | USE `hierarchy_data`$$
4 |
5 | DROP TRIGGER IF EXISTS `trigger_move_node`$$
6 |
7 | CREATE TRIGGER `trigger_move_node` AFTER UPDATE ON `prefix_nodes`
8 | FOR EACH ROW BEGIN
9 | IF NOT OLD.`parent_id` <=> NEW.`parent_id` THEN
10 | -- http://www.mysqlperformanceblog.com/2011/02/14/moving-subtrees-in-closure-table/
11 | -- in the example, when change node D's parent to B.
12 | -- its sql has only D & B. so I think it should currentNode.id& newParent.id
13 | CALL p_node_move(NEW.`id`, NEW.`parent_id`);
14 | END IF;
15 |
16 | IF OLD.`is_deleted` != NEW.`is_deleted` THEN
17 | CALL p_node_hide(NEW.`parent_id`, NEW.`is_deleted`);
18 | END IF;
19 | END;
20 | $$
21 |
22 | DELIMITER ;
23 |
--------------------------------------------------------------------------------
/mysql/procedures/p_node_add.sql:
--------------------------------------------------------------------------------
1 | DELIMITER $$
2 |
3 | USE `hierarchy_data`$$
4 |
5 | DROP PROCEDURE IF EXISTS `p_node_add`$$
6 |
7 | CREATE PROCEDURE `p_node_add`(
8 | param_node_new_id INT UNSIGNED,
9 | param_node_parent_id INT UNSIGNED
10 | )
11 | COMMENT 'Adding new paths prefix_nodes_paths table'
12 | BEGIN
13 | -- Update paths information
14 | INSERT INTO `prefix_nodes_paths` (
15 | `ancestor_id`,
16 | `descendant_id`,
17 | `path_length`
18 | )
19 | SELECT
20 | `ancestor_id`,
21 | `param_node_new_id`,
22 | `path_length` + 1
23 | FROM
24 | `prefix_nodes_paths`
25 | WHERE `descendant_id` = `param_node_parent_id`
26 | UNION
27 | ALL
28 | SELECT
29 | `param_node_new_id`,
30 | `param_node_new_id`,
31 | 0 ;
32 | END$$
33 |
34 | DELIMITER ;
35 |
--------------------------------------------------------------------------------
/postgres/procedures/get_child_nodes.sql:
--------------------------------------------------------------------------------
1 | ----------------
2 | -- Get child nodes
3 | ----------------
4 |
5 | DROP FUNCTION IF EXISTS get_child_nodes(INTEGER);
6 |
7 | -- Create function
8 | CREATE FUNCTION get_child_nodes(INTEGER)
9 | RETURNS SETOF RECORD
10 | LANGUAGE SQL
11 | AS $$
12 | SELECT d.id,
13 | d.is_deleted,
14 | d.parent_id,
15 | concat(repeat('-', p.depth), d.name) AS tree,
16 | p.depth,
17 | array_to_string(array_agg(crumbs.ancestor_id::CHARACTER VARYING ORDER BY crumbs.ancestor_id),',','*') breadcrumbs
18 | FROM prefix_nodes AS d
19 | JOIN prefix_nodes_paths AS p ON d.id = p.descendant_id
20 | JOIN prefix_nodes_paths AS crumbs ON crumbs.descendant_id = p.descendant_id
21 | WHERE p.ancestor_id = $1 AND d.is_deleted = false
22 | GROUP BY d.id, p.depth
23 | ORDER BY d.id ASC
24 | ;
25 | $$
26 |
27 |
--------------------------------------------------------------------------------
/mysql/procedures/p_get_tree.sql:
--------------------------------------------------------------------------------
1 | DELIMITER $$
2 |
3 | USE `hierarchy_data`$$
4 |
5 | DROP PROCEDURE IF EXISTS `p_get_tree`$$
6 |
7 | CREATE PROCEDURE `p_get_tree`(
8 | node_id INT UNSIGNED
9 | ) COMMENT 'Query all descendants nodes by a node id, return as a result set'
10 | BEGIN
11 | SELECT
12 | node.`id`,
13 | node.`is_deleted`,
14 | node.`parent_id`,
15 | CONCAT(
16 | REPEAT('-', path.`path_length`),
17 | node.`name`
18 | ) AS name,
19 | path.`path_length`,
20 | GROUP_CONCAT(
21 | crumbs.`ancestor_id` SEPARATOR ','
22 | ) AS breadcrumbs
23 | FROM
24 | `prefix_nodes` AS node
25 | JOIN `prefix_nodes_paths` AS path
26 | ON node.`id` = path.`descendant_id`
27 | JOIN `prefix_nodes_paths` AS crumbs
28 | ON crumbs.`descendant_id` = path.`descendant_id`
29 | WHERE path.`ancestor_id` = `node_id`
30 | AND node.`is_deleted` = 0
31 | GROUP BY node.`id`
32 | ORDER BY breadcrumbs ;
33 | END$$
34 |
35 | DELIMITER ;
36 |
--------------------------------------------------------------------------------
/mysql/data/sample_data.sql:
--------------------------------------------------------------------------------
1 | INSERT INTO `prefix_nodes` VALUES(1, NULL, NULL, 'HOME',DEFAULT);
2 | INSERT INTO `prefix_nodes` VALUES(2, 1, 1, 'PRODUCT',DEFAULT);
3 | INSERT INTO `prefix_nodes` VALUES(3, 1, 2, 'CONTACT',DEFAULT);
4 | INSERT INTO `prefix_nodes` VALUES(4, 1, 3, 'DOCUMENTATION',DEFAULT);
5 | INSERT INTO `prefix_nodes` VALUES(5, 2, 2, 'SOFTWARE',DEFAULT);
6 | INSERT INTO `prefix_nodes` VALUES(6, 2, 1, 'HARDWARE',DEFAULT);
7 | INSERT INTO `prefix_nodes` VALUES(7, 1, 3, 'DEMO',DEFAULT);
8 | INSERT INTO `prefix_nodes` VALUES(8, 4, 1, 'JAVA',DEFAULT);
9 | INSERT INTO `prefix_nodes` VALUES(9, 4, 2, 'PHP',DEFAULT);
10 | INSERT INTO `prefix_nodes` VALUES(10, NULL, NULL, 'Asia',DEFAULT);
11 | INSERT INTO `prefix_nodes` VALUES(11, 10, 1, 'China',DEFAULT);
12 | INSERT INTO `prefix_nodes` VALUES(12, 10, 2, 'Korea',DEFAULT);
13 | INSERT INTO `prefix_nodes` VALUES(13, 10, 3, 'Japan',DEFAULT);
14 | INSERT INTO `prefix_nodes` VALUES(14, 6, 3, 'CPU',DEFAULT);
15 | INSERT INTO `prefix_nodes` VALUES(15, 6, 4, 'HARD DISK',DEFAULT);
16 | INSERT INTO `prefix_nodes` VALUES(16, 15, 1, 'SSD',DEFAULT);
17 | INSERT INTO `prefix_nodes` VALUES(17, 15, 2, 'HDD',DEFAULT);
18 |
--------------------------------------------------------------------------------
/postgres/procedures/add_node.sql:
--------------------------------------------------------------------------------
1 | -----------------------------------------------
2 | -- Add a new node to existing parent node.
3 | --
4 | -- If you want modify the `after_change_node` function,
5 | -- you must delete the trigger from `prefix_nodes` table
6 | -- first, and re-create it.
7 | --
8 | -----------------------------------------------
9 |
10 | -- Drop trigger on a table
11 | DROP TRIGGER IF EXISTS after_change_node ON prefix_nodes;
12 |
13 | -- Drop trigger function
14 | DROP FUNCTION IF EXISTS after_change_node();
15 |
16 | -- Step 1: Create a function used to update paths
17 | CREATE OR REPLACE FUNCTION after_change_node() RETURNS TRIGGER LANGUAGE PLPGSQL AS $$
18 | BEGIN
19 | IF (TG_OP = 'INSERT') THEN
20 | INSERT INTO prefix_nodes_paths(ancestor_id,descendant_id,depth)
21 | SELECT ancestor_id, NEW.id, depth + 1
22 | FROM prefix_nodes_paths WHERE descendant_id = NEW.parent_id
23 | UNION ALL SELECT NEW.id, NEW.id, 0;
24 | END IF;
25 | RETURN NULL;
26 | END;
27 | $$;
28 |
29 | -- Add trigger function on prefix_nodes table
30 | CREATE TRIGGER after_change_node AFTER INSERT OR UPDATE
31 | ON prefix_nodes FOR EACH ROW EXECUTE PROCEDURE after_change_node();
32 |
33 |
34 |
35 |
--------------------------------------------------------------------------------
/mysql/create_table_structure.sql:
--------------------------------------------------------------------------------
1 | DROP TABLE IF EXISTS `prefix_nodes_paths`;
2 | DROP TABLE IF EXISTS `prefix_nodes`;
3 |
4 | CREATE TABLE `prefix_nodes` (
5 | `id` int(11) NOT NULL AUTO_INCREMENT,
6 | `parent_id` int(11) DEFAULT NULL,
7 | `order` int(11) DEFAULT NULL,
8 | `name` varchar(128) NOT NULL,
9 | `is_deleted` tinyint(1) DEFAULT '0',
10 | `user_id` int(11) NOT NULL,
11 | `user_type` int(11) NOT NULL,
12 | PRIMARY KEY (`id`),
13 | KEY `parent_id` (`parent_id`),
14 | KEY `name` (`name`),
15 | CONSTRAINT `prefix_nodes_ibfk1` FOREIGN KEY (`parent_id`) REFERENCES `prefix_nodes` (`id`) ON DELETE CASCADE
16 | ) ENGINE=InnoDB DEFAULT CHARSET=utf8;
17 |
18 |
19 | CREATE TABLE `prefix_nodes_paths` (
20 | `ancestor_id` int(11) NOT NULL,
21 | `descendant_id` int(11) NOT NULL,
22 | `path_length` int(11) NOT NULL,
23 | PRIMARY KEY (`ancestor_id`,`descendant_id`),
24 | KEY `descendant_id` (`descendant_id`),
25 | CONSTRAINT `prefix_nodes_paths_ibfk_1` FOREIGN KEY (`ancestor_id`) REFERENCES `prefix_nodes` (`id`) ON DELETE CASCADE,
26 | CONSTRAINT `prefix_nodes_paths_ibfk_2` FOREIGN KEY (`descendant_id`) REFERENCES `prefix_nodes` (`id`) ON DELETE CASCADE
27 | ) ENGINE=InnoDB DEFAULT CHARSET=utf8;
28 |
--------------------------------------------------------------------------------
/postgres/procedures/move_subtree.sql:
--------------------------------------------------------------------------------
1 | DROP FUNCTION IF EXISTS move(UUID, UUID);
2 |
3 | CREATE FUNCTION move(
4 | UUID,
5 | UUID
6 | ) RETURNS VOID
7 | AS $$
8 | --------------------------------------------
9 | -- Step 1: Update parent node id
10 | --------------------------------------------
11 | UPDATE prefix_nodes SET parent_id = $2 WHERE id = $1;
12 |
13 | --------------------------------------------
14 | -- Step 2: Disconnect from current ancestors
15 | -- Delete all paths that end at descendants in the subtree
16 | --------------------------------------------
17 | DELETE FROM prefix_nodes_paths
18 | WHERE descendant_id IN (SELECT descendant_id FROM prefix_nodes_paths WHERE ancestor_id = $1)
19 | AND ancestor_id IN (SELECT ancestor_id FROM prefix_nodes_paths WHERE descendant_id = $1 AND ancestor_id != descendant_id);
20 |
21 | --------------------------------------------
22 | -- Step 2: Mount subtree to new ancestors
23 | -- Insert rows matching ancestors of insertion point and descendants of subtree
24 | --------------------------------------------
25 | INSERT INTO prefix_nodes_paths (ancestor_id, descendant_id, depth)
26 | SELECT supertree.ancestor_id, subtree.descendant_id, supertree.depth + subtree.depth + 1
27 | FROM prefix_nodes_paths AS supertree
28 | CROSS JOIN prefix_nodes_paths AS subtree
29 | WHERE supertree.descendant_id = $2
30 | AND subtree.ancestor_id = $1;
31 | $$ LANGUAGE SQL;
32 |
--------------------------------------------------------------------------------
/postgres/procedures/get_subtree.sql:
--------------------------------------------------------------------------------
1 | -----------------------------------------------------------------------
2 | -- Get child nodes
3 | -----------------------------------------------------------------------
4 |
5 |
6 | DROP FUNCTION IF EXISTS get_child_nodes(UUID);
7 |
8 | -- Create function
9 | CREATE FUNCTION get_child_nodes(UUID)
10 | RETURNS SETOF RECORD
11 | AS $$
12 | SELECT d.id,
13 | d.is_deleted,
14 | d.parent_id,
15 | concat(repeat('-', p.depth), d.name) AS name,
16 | p.depth,
17 | array_to_string(array_agg(crumbs.ancestor_id::CHARACTER VARYING),',','*') breadcrumbs
18 | FROM prefix_nodes AS d
19 | JOIN prefix_nodes_paths AS p ON d.id = p.descendant_id
20 | JOIN prefix_nodes_paths AS crumbs ON crumbs.descendant_id = p.descendant_id
21 | WHERE p.ancestor_id = $1 AND d.is_deleted = false
22 | GROUP BY d.id, p.depth
23 | ORDER BY d.id ASC
24 | ;
25 | $$ LANGUAGE SQL;
26 |
27 |
28 |
29 | -----------------------------------------------------------------------
30 | -- Get subtree(Depend on `get_child_nodes` user defined function above)
31 | -- (include node itself, such as following statement, node #2)
32 | -- TODO
33 | -- 1. Add a switch(boolean value) if include node itself
34 | -----------------------------------------------------------------------
35 |
36 |
37 | SELECT * FROM get_child_nodes('29f9d3a1-068f-4132-bf5e-4792add8489b')
38 | AS (id UUID,is_deleted BOOLEAN,parent_id UUID,name VARCHAR(255),depth INTEGER,breadcrumbs VARCHAR(255))
39 | ORDER BY breadcrumbs;
40 |
41 |
--------------------------------------------------------------------------------
/mysql/procedures/p_node_move.sql:
--------------------------------------------------------------------------------
1 | DELIMITER $$
2 |
3 | USE `hierarchy_data`$$
4 |
5 | DROP PROCEDURE IF EXISTS `p_node_move`$$
6 |
7 | CREATE PROCEDURE `p_node_move` (
8 | `node_old_parent_id` INT UNSIGNED,
9 | `node_new_parent_id` INT UNSIGNED
10 | ) COMMENT 'Update paths when parent_id column changed'
11 | BEGIN
12 | -- References:
13 | -- http://www.mysqlperformanceblog.com/2011/02/14/moving-subtrees-in-closure-table/
14 | -- The store procedure is used to update paths informations when the value of parent_id columns is changed (when move a node to a new parent)
15 | -- If parent_id has chanaged
16 | -- 1. Delete the paths between moved node and old ancestors
17 | -- 2. Add the paths between moved node and new ancestors
18 | DELETE
19 | a
20 | FROM
21 | `prefix_nodes_paths` AS a
22 | JOIN `prefix_nodes_paths` AS d
23 | ON a.`descendant_id` = d.`descendant_id`
24 | LEFT JOIN `prefix_nodes_paths` AS x
25 | ON x.`ancestor_id` = d.`ancestor_id`
26 | AND x.`descendant_id` = a.`ancestor_id`
27 | WHERE d.`ancestor_id` = `node_old_parent_id`
28 | AND x.`ancestor_id` IS NULL ;
29 |
30 | -- Add the node to its new parent
31 | INSERT `prefix_nodes_paths` (
32 | `ancestor_id`,
33 | `descendant_id`,
34 | `path_length`
35 | )
36 | SELECT
37 | supertree.`ancestor_id`,
38 | subtree.`descendant_id`,
39 | supertree.`path_length` + subtree.`path_length` + 1
40 | FROM
41 | `prefix_nodes_paths` AS supertree
42 | JOIN `prefix_nodes_paths` AS subtree
43 | WHERE subtree.`ancestor_id` = `node_old_parent_id`
44 | AND supertree.`descendant_id` = `node_new_parent_id` ;
45 | END$$
46 |
47 | DELIMITER ;
48 |
--------------------------------------------------------------------------------
/postgres/procedures/json_output.sql:
--------------------------------------------------------------------------------
1 | ------------------------------------------
2 | -- Get tree
3 | ------------------------------------------
4 |
5 | DROP FUNCTION IF EXISTS get_tree(data json);
6 |
7 | CREATE OR REPLACE FUNCTION get_tree(data json)
8 | RETURNS json
9 | AS $$
10 | var root = [];
11 | for(var i in data) {
12 | build_tree(data[i]['id'], data[i]['name'], data[i]['children']);
13 | }
14 | function build_tree(id, name, children) {
15 | var exists = getObject(root, id);
16 | if(exists) {
17 | exists['children'] = children;
18 | }
19 | else {
20 | root.push({'id': id, 'name': name, 'children': children, 'toggled': true});
21 | }
22 | }
23 | function getObject(theObject, id) {
24 | var result = null;
25 | if(theObject instanceof Array) {
26 | for(var i = 0; i < theObject.length; i++) {
27 | result = getObject(theObject[i], id);
28 | if (result) {
29 | break;
30 | }
31 | }
32 | }
33 | else
34 | {
35 | theObject['toggled'] = true;
36 | for(var prop in theObject) {
37 | if(prop == 'id') {
38 | if(theObject[prop] === id) {
39 | return theObject;
40 | }
41 | }
42 | if(theObject[prop] instanceof Object || theObject[prop] instanceof Array) {
43 | result = getObject(theObject[prop], id);
44 | if (result) {
45 | break;
46 | }
47 | }
48 | }
49 | }
50 | return result;
51 | }
52 | return JSON.stringify(root);
53 | $$ LANGUAGE plv8 IMMUTABLE STRICT;
54 |
55 | ------------------------------------------
56 | -- Format to JSON Object(The Whole Trees)
57 | ------------------------------------------
58 |
59 | WITH data AS(
60 | SELECT array_to_json(array_agg(row_to_json(t))) AS data
61 | FROM (
62 | SELECT id, name, COALESCE(get_children_by_uuid(id), '[]') AS children, 'true' FROM prefix_nodes
63 | ) t
64 | ) SELECT get_tree(data) FROM data;
65 |
--------------------------------------------------------------------------------
/postgres/create_table_structure.sql:
--------------------------------------------------------------------------------
1 | -- Table: public.prefix_nodes
2 |
3 | -- DROP TABLE public.prefix_nodes;
4 |
5 | CREATE TABLE public.prefix_nodes
6 | (
7 | id integer NOT NULL DEFAULT nextval('prefix_nodes_id_seq'::regclass),
8 | parent_id integer,
9 | name character varying(255),
10 | "order" integer,
11 | is_deleted boolean NOT NULL DEFAULT false,
12 | CONSTRAINT prefix_nodes_pkey1 PRIMARY KEY (id),
13 | CONSTRAINT prefix_nodes_parent_id_fkey FOREIGN KEY (parent_id)
14 | REFERENCES public.prefix_nodes (id) MATCH SIMPLE
15 | ON UPDATE NO ACTION ON DELETE CASCADE
16 | )
17 | WITH (
18 | OIDS=FALSE
19 | );
20 | ALTER TABLE public.prefix_nodes
21 | OWNER TO postgres;
22 |
23 | -- Index: public.prefix_nodes_parent_id_index
24 |
25 | -- DROP INDEX public.prefix_nodes_parent_id_index;
26 |
27 | CREATE INDEX prefix_nodes_parent_id_index
28 | ON public.prefix_nodes
29 | USING btree
30 | (parent_id);
31 |
32 |
33 | -- Table: public.prefix_nodes_paths
34 |
35 | -- DROP TABLE public.prefix_nodes_paths;
36 |
37 | CREATE TABLE public.prefix_nodes_paths
38 | (
39 | id integer NOT NULL DEFAULT nextval('prefix_nodes_paths_id_seq'::regclass),
40 | ancestor_id integer,
41 | descendant_id integer,
42 | depth integer,
43 | CONSTRAINT prefix_nodes_paths_pkey PRIMARY KEY (id),
44 | CONSTRAINT prefix_nodes_paths_ancestor_id_fkey FOREIGN KEY (ancestor_id)
45 | REFERENCES public.prefix_nodes (id) MATCH SIMPLE
46 | ON UPDATE NO ACTION ON DELETE CASCADE,
47 | CONSTRAINT prefix_nodes_paths_descendant_id_fkey FOREIGN KEY (descendant_id)
48 | REFERENCES public.prefix_nodes (id) MATCH SIMPLE
49 | ON UPDATE NO ACTION ON DELETE CASCADE
50 | )
51 | WITH (
52 | OIDS=FALSE
53 | );
54 | ALTER TABLE public.prefix_nodes_paths
55 | OWNER TO postgres;
56 |
57 | -- Index: public.prefix_nodes_paths_ancestor_id_index
58 |
59 | -- DROP INDEX public.prefix_nodes_paths_ancestor_id_index;
60 |
61 | CREATE INDEX prefix_nodes_paths_ancestor_id_index
62 | ON public.prefix_nodes_paths
63 | USING btree
64 | (ancestor_id);
65 |
66 | -- Index: public.prefix_nodes_paths_descendant_id_index
67 |
68 | -- DROP INDEX public.prefix_nodes_paths_descendant_id_index;
69 |
70 | CREATE INDEX prefix_nodes_paths_descendant_id_index
71 | ON public.prefix_nodes_paths
72 | USING btree
73 | (descendant_id);
74 |
75 |
76 |
--------------------------------------------------------------------------------
/README.md:
--------------------------------------------------------------------------------
1 | # Update: 2023
2 |
3 | Consider use graph to process this type of problems.
4 |
5 | # Closure Table
6 |
7 |
8 | This is a mysql store procedure and trigger implementation of closure table in
9 | RDBMS about hierarchy data model.
10 |
11 |
Closure Table Node Paths
12 |
13 | 
14 |
15 | Query the subtree nodes
16 |
17 | 
18 |
19 | ## Features
20 |
21 |
22 | * Automatically add new paths when you insert a new node
23 |
24 | * Automatically update(`DELETE` old paths and `INSERT` new paths) paths when you
25 | update `parent_id` of a node. (This means move a node/subtree to a new parent)
26 |
27 | * A store procedure that is used to select a whole subtree by a `node_id`
28 | (if the `node_id` has descendant)
29 |
30 |
31 | ## Triggers
32 |
33 |
34 | * `trigger_add_paths`
35 |
36 | The trigger is execute when insert a node into `prefix_nodes` table, and call `p_node_add` to add update paths.
37 |
38 | * `prefix_node_move`:
39 |
40 | The trigger is execute when update the `parent_id` column of `prefix_nodes`
41 | table only if `OLD.parent_id != NEW.parent_id`
42 |
43 | ## Store Procedures
44 |
45 |
46 | * `p_node_add(param_node_new_id INT UNSIGNED,param_node_parent_id INT UNSIGNED)`
47 |
48 | Add new paths when insert a node to `prefix_nodes` table
49 |
50 | * `p_get_tree(node_id INT UNSIGNED)`
51 |
52 | Get subtree by a node id
53 |
54 | * `p_node_move(node_old_parent_id INT UNSIGNED,node_new_parent_id INT UNSIGNED)`
55 |
56 | Update paths when move a node to a new parent node
57 |
58 | * `p_node_hide(node_id INT UNSIGNED, is_deleted INT UNSIGNED)`
59 |
60 | Hide or show nodes from subtree, explains as following:
61 |
62 | - Step 1. `call p_get_tree(6)` get the `HARDWARE` subtree,
63 | - Step 2. `call p_node_hide(6, 0)` to hide a subtree,
64 | - Step 3. `call p_get_tree(6)` get the `HARDWARE` subtree, when you get a subtree, it is not show in the result.
65 | - Step 4. `call p_node_hide(6, 1)` show `HARDWARE` subtree
66 |
67 | ## MySQL Files
68 |
69 | * `./mysql/tables.sql`
70 |
71 | Create tables.
72 |
73 | * `./mysql/sample_data.sql`
74 |
75 | Some insert statements for testing
76 |
77 | ## Postgresql Files
78 |
79 | TODO::
80 |
--------------------------------------------------------------------------------
/postgres/triggers/add_new_paths_for_insert.sql:
--------------------------------------------------------------------------------
1 | -----------------------------------------------
2 | -- This function is used to update paths when
3 | -- inserted a new node to a exist parent node.
4 | -----------------------------------------------
5 |
6 | -- Drop function
7 | DROP FUNCTION IF EXISTS after_change_node();
8 |
9 | -- Step 1: Create a function used to update paths
10 | CREATE OR REPLACE FUNCTION after_change_node() RETURNS TRIGGER LANGUAGE PLPGSQL AS $$
11 | BEGIN
12 | IF (TG_OP = 'INSERT') THEN
13 | INSERT INTO prefix_nodes_paths(ancestor_id,descendant_id,depth)
14 | SELECT ancestor_id, NEW.id, depth + 1
15 | FROM prefix_nodes_paths WHERE descendant_id = NEW.parent_id
16 | UNION ALL SELECT NEW.id, NEW.id, 0;
17 | ELSE IF (TG_OP = 'UPDATE') THEN
18 | -- Move Subtree
19 | -- References:
20 | -- https://codegists.com/snippet/sql/closure_treesql_x2002uwh_sql
21 | IF OLD.parent_id != NEW.parent_id THEN
22 | -- Step 1: Disconnect from current ancestors
23 | DELETE FROM prefix_nodes_paths
24 | WHERE descendant_id IN (SELECT descendant_id FROM prefix_nodes_paths WHERE ancestor_id = OLD.parent_id)
25 | AND ancestor_id IN (SELECT ancestor_id FROM prefix_nodes_paths WHERE descendant_id = OLD.parent_id AND ancestor_id != descendant_id);
26 |
27 | -- Step 2: Insert rows matching ancestors of insertion point and descendants of subtree
28 | INSERT INTO prefix_nodes_paths (ancestor, descendant)
29 | SELECT supertree.ancestor, subtree.descendant
30 | FROM prefix_nodes_paths AS supertree
31 | CROSS JOIN prefix_nodes_paths AS subtree
32 | WHERE supertree.descendant = 3
33 | AND subtree.ancestor = 6;
34 |
35 |
36 | -- Add new paths
37 | INSERT prefix_nodes_paths (ancestor_id, descendant_id, depth)
38 | SELECT supertree.ancestor_id, subtree.descendant_id, supertree.path_length + subtree.path_length + 1
39 | FROM prefix_nodes_paths AS supertree
40 | JOIN prefix_nodes_paths AS subtree
41 | WHERE subtree.ancestor_id = OLD.parent_id
42 | AND supertree.descendant_id = NEW.parent_id ;
43 |
44 | END IF;
45 | END IF;
46 | RETURN NULL;
47 | END;
48 | $$;
49 |
50 |
51 | -- Add trigger function on prefix_nodes table
52 | CREATE TRIGGER after_change_node AFTER INSERT OR UPDATE
53 | ON prefix_nodes FOR EACH ROW EXECUTE PROCEDURE after_change_node();
54 |
55 | --
56 | -- If you want modify the `after_change_node` function,
57 | -- you must delete the trigger from `prefix_nodes` table
58 | -- first, and re-create it.
59 | --
60 |
61 | -- Drop trigger function on a table
62 | DROP TRIGGER IF EXISTS after_change_node ON prefix_nodes;
63 |
64 |
65 |
66 |
--------------------------------------------------------------------------------
/postgres/data/sample_data.sql:
--------------------------------------------------------------------------------
1 | -- Hardware category
2 |
3 | INSERT INTO prefix_nodes("order", name, is_deleted, parent_id) VALUES(0, 'HOME', false, NULL);
4 | INSERT INTO prefix_nodes("order", name, is_deleted, parent_id) VALUES(0, 'PRODUCT', false, 1);
5 | INSERT INTO prefix_nodes("order", name, is_deleted, parent_id) VALUES(0, 'CONTACT', false, 1);
6 | INSERT INTO prefix_nodes("order", name, is_deleted, parent_id) VALUES(0, 'DOCUMENTATION', false, 1);
7 | INSERT INTO prefix_nodes("order", name, is_deleted, parent_id) VALUES(0, 'SOFTWARE', false, 2);
8 | INSERT INTO prefix_nodes("order", name, is_deleted, parent_id) VALUES(0, 'HARDWARE', false, 2);
9 | INSERT INTO prefix_nodes("order", name, is_deleted, parent_id) VALUES(0, 'DEMO', false, 1);
10 | INSERT INTO prefix_nodes("order", name, is_deleted, parent_id) VALUES(0, 'JAVA', false, 4);
11 | INSERT INTO prefix_nodes("order", name, is_deleted, parent_id) VALUES(0, 'PHP', false, 4);
12 | INSERT INTO prefix_nodes("order", name, is_deleted, parent_id) VALUES(0, 'Asia', false, NULL);
13 |
14 | INSERT INTO prefix_nodes("order", name, is_deleted, parent_id) VALUES(0, 'China', false, 10);
15 | INSERT INTO prefix_nodes("order", name, is_deleted, parent_id) VALUES(0, 'Korea', false, 10);
16 | INSERT INTO prefix_nodes("order", name, is_deleted, parent_id) VALUES(0, 'Japan', false, 10);
17 | INSERT INTO prefix_nodes("order", name, is_deleted, parent_id) VALUES(0, 'CPU', false, 6);
18 | INSERT INTO prefix_nodes("order", name, is_deleted, parent_id) VALUES(0, 'HARD DISK', false, 6);
19 | INSERT INTO prefix_nodes("order", name, is_deleted, parent_id) VALUES(0, 'SSD', false, 15);
20 | INSERT INTO prefix_nodes("order", name, is_deleted, parent_id) VALUES(0, 'HDD', false, 15);
21 |
22 |
23 | -- Goods category
24 |
25 | INSERT INTO prefix_nodes(id, "order", name, is_deleted, parent_id) VALUES('29f9d3a1-068f-4132-bf5e-4792add8489b', 0, 'Subtree Test', false, NULL);
26 |
27 | INSERT INTO prefix_nodes("order", name, is_deleted, parent_id) VALUES(0, 'Child Node 1', false, '29f9d3a1-068f-4132-bf5e-4792add8489b');
28 | INSERT INTO prefix_nodes("order", name, is_deleted, parent_id) VALUES(0, 'Child Node 2', false, '29f9d3a1-068f-4132-bf5e-4792add8489b');
29 | INSERT INTO prefix_nodes("order", name, is_deleted, parent_id) VALUES(0, 'Child Node 3', false, '29f9d3a1-068f-4132-bf5e-4792add8489b');
30 |
31 | INSERT INTO prefix_nodes("order", name, is_deleted, parent_id) VALUES(0, 'Child Node 3 - Child', false, '72850f82-7dab-45d9-8560-dc183abf3817');
32 | INSERT INTO prefix_nodes("order", name, is_deleted, parent_id) VALUES(0, 'Child Node 3 - Child', false, '5efc1e96-6931-4310-ac09-ad791f22d7e3');
33 |
34 |
35 | INSERT INTO prefix_nodes("order", name, is_deleted, parent_id) VALUES(0, '春季焕新', false, 'e632b593-8b1b-4966-8427-3273f2d43f4c');
36 | INSERT INTO prefix_nodes("order", name, is_deleted, parent_id) VALUES(0, '商场同款', false, 'e632b593-8b1b-4966-8427-3273f2d43f4c');
37 | INSERT INTO prefix_nodes("order", name, is_deleted, parent_id) VALUES(0, '修身夹克', false, 'e632b593-8b1b-4966-8427-3273f2d43f4c');
38 | INSERT INTO prefix_nodes("order", name, is_deleted, parent_id) VALUES(0, '牛仔夹克', false, 'e632b593-8b1b-4966-8427-3273f2d43f4c');
39 | INSERT INTO prefix_nodes("order", name, is_deleted, parent_id) VALUES(0, '潮流卫衣', false, 'e632b593-8b1b-4966-8427-3273f2d43f4c');
40 | INSERT INTO prefix_nodes("order", name, is_deleted, parent_id) VALUES(0, '长袖衬衫', false, 'e632b593-8b1b-4966-8427-3273f2d43f4c');
41 | INSERT INTO prefix_nodes("order", name, is_deleted, parent_id) VALUES(0, '长袖T恤', false, 'e632b593-8b1b-4966-8427-3273f2d43f4c');
42 | INSERT INTO prefix_nodes("order", name, is_deleted, parent_id) VALUES(0, '针织开衫', false, 'e632b593-8b1b-4966-8427-3273f2d43f4c');
43 | INSERT INTO prefix_nodes("order", name, is_deleted, parent_id) VALUES(0, '单西', false, 'e632b593-8b1b-4966-8427-3273f2d43f4c');
44 | INSERT INTO prefix_nodes("order", name, is_deleted, parent_id) VALUES(0, '束脚裤', false, 'e632b593-8b1b-4966-8427-3273f2d43f4c');
45 | INSERT INTO prefix_nodes("order", name, is_deleted, parent_id) VALUES(0, '水洗牛仔裤', false, 'e632b593-8b1b-4966-8427-3273f2d43f4c');
46 |
47 |
48 |
49 | INSERT INTO prefix_nodes("order", name, is_deleted, parent_id) VALUES(0, '精选上装', false, 'a498140e-be81-494f-926f-b907614ac3fe');
50 |
51 | INSERT INTO prefix_nodes("order", name, is_deleted, parent_id) VALUES(0, '羽绒服', false, 'e462c5b8-3674-4a06-9abb-047e9cb4a0d8');
52 | INSERT INTO prefix_nodes("order", name, is_deleted, parent_id) VALUES(0, '毛呢外套', false, 'e462c5b8-3674-4a06-9abb-047e9cb4a0d8');
53 | INSERT INTO prefix_nodes("order", name, is_deleted, parent_id) VALUES(0, '毛衣', false, 'e462c5b8-3674-4a06-9abb-047e9cb4a0d8');
54 | INSERT INTO prefix_nodes("order", name, is_deleted, parent_id) VALUES(0, '针织衫', false, 'e462c5b8-3674-4a06-9abb-047e9cb4a0d8');
55 | INSERT INTO prefix_nodes("order", name, is_deleted, parent_id) VALUES(0, '衬衫', false, 'e462c5b8-3674-4a06-9abb-047e9cb4a0d8');
56 | INSERT INTO prefix_nodes("order", name, is_deleted, parent_id) VALUES(0, '风衣', false, 'e462c5b8-3674-4a06-9abb-047e9cb4a0d8');
57 | INSERT INTO prefix_nodes("order", name, is_deleted, parent_id) VALUES(0, '短外套', false, 'e462c5b8-3674-4a06-9abb-047e9cb4a0d8');
58 | INSERT INTO prefix_nodes("order", name, is_deleted, parent_id) VALUES(0, '卫衣', false, 'e462c5b8-3674-4a06-9abb-047e9cb4a0d8');
59 | INSERT INTO prefix_nodes("order", name, is_deleted, parent_id) VALUES(0, '小西装', false, 'e462c5b8-3674-4a06-9abb-047e9cb4a0d8');
60 |
61 |
62 |
63 |
64 |
--------------------------------------------------------------------------------
/mysql/all-in-one.sql:
--------------------------------------------------------------------------------
1 | DROP TABLE IF EXISTS `prefix_nodes_paths`;
2 | DROP TABLE IF EXISTS `prefix_nodes`;
3 |
4 | CREATE TABLE `prefix_nodes` (
5 | `id` int(11) NOT NULL AUTO_INCREMENT,
6 | `parent_id` int(11) DEFAULT NULL,
7 | `order` int(11) DEFAULT NULL,
8 | `name` varchar(128) NOT NULL,
9 | `is_deleted` tinyint(1) DEFAULT '0',
10 | `user_id` int(11) NOT NULL,
11 | `user_type` int(11) NOT NULL,
12 | PRIMARY KEY (`id`),
13 | KEY `parent_id` (`parent_id`),
14 | KEY `name` (`name`),
15 | CONSTRAINT `prefix_nodes_ibfk1` FOREIGN KEY (`parent_id`) REFERENCES `prefix_nodes` (`id`) ON DELETE CASCADE
16 | ) ENGINE=InnoDB DEFAULT CHARSET=utf8;
17 |
18 | CREATE TABLE `prefix_nodes_paths` (
19 | `ancestor_id` int(11) NOT NULL,
20 | `descendant_id` int(11) NOT NULL,
21 | `path_length` int(11) NOT NULL,
22 | PRIMARY KEY (`ancestor_id`,`descendant_id`),
23 | KEY `descendant_id` (`descendant_id`),
24 | CONSTRAINT `prefix_nodes_paths_ibfk_1` FOREIGN KEY (`ancestor_id`) REFERENCES `prefix_nodes` (`id`) ON DELETE CASCADE,
25 | CONSTRAINT `prefix_nodes_paths_ibfk_2` FOREIGN KEY (`descendant_id`) REFERENCES `prefix_nodes` (`id`) ON DELETE CASCADE
26 | ) ENGINE=InnoDB DEFAULT CHARSET=utf8;
27 |
28 |
29 | DELIMITER $$
30 |
31 | USE `hierarchy_data`$$
32 |
33 | DROP TRIGGER IF EXISTS `trigger_add_node`$$
34 |
35 | CREATE
36 | TRIGGER `trigger_add_node` AFTER INSERT ON `prefix_nodes`
37 | FOR EACH ROW BEGIN
38 | CALL p_node_add(NEW.`id`, NEW.`parent_id`);
39 | END;
40 | $$
41 |
42 | DELIMITER ;
43 |
44 |
45 | DELIMITER $$
46 |
47 | USE `hierarchy_data`$$
48 |
49 | DROP TRIGGER IF EXISTS `trigger_move_node`$$
50 |
51 | CREATE TRIGGER `trigger_move_node` AFTER UPDATE ON `prefix_nodes`
52 | FOR EACH ROW BEGIN
53 | IF NOT OLD.`parent_id` <=> NEW.`parent_id` THEN
54 | -- http://www.mysqlperformanceblog.com/2011/02/14/moving-subtrees-in-closure-table/
55 | -- in the example, when change node D's parent to B.
56 | -- its sql has only D & B. so I think it should currentNode.id& newParent.id
57 | CALL p_node_move(NEW.`id`, NEW.`parent_id`);
58 | END IF;
59 |
60 | IF OLD.`is_deleted` != NEW.`is_deleted` THEN
61 | CALL p_node_hide(NEW.`parent_id`, NEW.`is_deleted`);
62 | END IF;
63 | END;
64 | $$
65 |
66 | DELIMITER ;
67 |
68 |
69 | DELIMITER $$
70 |
71 | USE `hierarchy_data`$$
72 |
73 | DROP PROCEDURE IF EXISTS `p_get_tree`$$
74 |
75 | CREATE PROCEDURE `p_get_tree`(
76 | node_id INT UNSIGNED
77 | ) COMMENT 'Query all descendants nodes by a node id, return as a result set'
78 | BEGIN
79 | SELECT
80 | node.`id`,
81 | node.`is_deleted`,
82 | node.`parent_id`,
83 | CONCAT(
84 | REPEAT('-', path.`path_length`),
85 | node.`name`
86 | ) AS name,
87 | path.`path_length`,
88 | GROUP_CONCAT(
89 | crumbs.`ancestor_id` SEPARATOR ','
90 | ) AS breadcrumbs
91 | FROM
92 | `prefix_nodes` AS node
93 | JOIN `prefix_nodes_paths` AS path
94 | ON node.`id` = path.`descendant_id`
95 | JOIN `prefix_nodes_paths` AS crumbs
96 | ON crumbs.`descendant_id` = path.`descendant_id`
97 | WHERE path.`ancestor_id` = `node_id`
98 | AND node.`is_deleted` = 0
99 | GROUP BY node.`id`
100 | ORDER BY breadcrumbs ;
101 | END$$
102 |
103 | DELIMITER ;
104 |
105 |
106 | DELIMITER $$
107 |
108 | USE `hierarchy_data`$$
109 |
110 | DROP PROCEDURE IF EXISTS `p_node_add`$$
111 |
112 | CREATE PROCEDURE `p_node_add`(
113 | param_node_new_id INT UNSIGNED,
114 | param_node_parent_id INT UNSIGNED
115 | )
116 | COMMENT 'Adding new paths prefix_nodes_paths table'
117 | BEGIN
118 | -- Update paths information
119 | INSERT INTO `prefix_nodes_paths` (
120 | `ancestor_id`,
121 | `descendant_id`,
122 | `path_length`
123 | )
124 | SELECT
125 | `ancestor_id`,
126 | `param_node_new_id`,
127 | `path_length` + 1
128 | FROM
129 | `prefix_nodes_paths`
130 | WHERE `descendant_id` = `param_node_parent_id`
131 | UNION
132 | ALL
133 | SELECT
134 | `param_node_new_id`,
135 | `param_node_new_id`,
136 | 0 ;
137 | END$$
138 |
139 | DELIMITER ;
140 |
141 |
142 | DELIMITER $$
143 |
144 | USE `hierarchy_data`$$
145 |
146 | DROP PROCEDURE IF EXISTS `p_node_hide`$$
147 |
148 | CREATE PROCEDURE `p_node_hide` (
149 | `node_id` INT UNSIGNED,
150 | `deleted` INT UNSIGNED
151 | ) COMMENT 'Delete a node and its descendant nodes(update is_deleted = 1)'
152 | BEGIN
153 | UPDATE
154 | `prefix_nodes` AS d
155 | JOIN `prefix_nodes_paths` AS p
156 | ON d.`id` = p.`descendant_id`
157 | JOIN `prefix_nodes_paths` AS crumbs
158 | ON crumbs.`descendant_id` = p.`descendant_id` SET d.`is_deleted` = deleted
159 | WHERE p.`ancestor_id` = node_id;
160 | END $$
161 |
162 | DELIMITER ;
163 |
164 |
165 | DELIMITER $$
166 |
167 | USE `hierarchy_data`$$
168 |
169 | DROP PROCEDURE IF EXISTS `p_node_move`$$
170 |
171 | CREATE PROCEDURE `p_node_move` (
172 | `node_old_parent_id` INT UNSIGNED,
173 | `node_new_parent_id` INT UNSIGNED
174 | ) COMMENT 'Update paths when parent_id column changed'
175 | BEGIN
176 | -- References:
177 | -- http://www.mysqlperformanceblog.com/2011/02/14/moving-subtrees-in-closure-table/
178 | -- The store procedure is used to update paths informations when the value of parent_id columns is changed (when move a node to a new parent)
179 | -- If parent_id has chanaged
180 | -- 1. Delete the paths between moved node and old ancestors
181 | -- 2. Add the paths between moved node and new ancestors
182 | DELETE
183 | a
184 | FROM
185 | `prefix_nodes_paths` AS a
186 | JOIN `prefix_nodes_paths` AS d
187 | ON a.`descendant_id` = d.`descendant_id`
188 | LEFT JOIN `prefix_nodes_paths` AS x
189 | ON x.`ancestor_id` = d.`ancestor_id`
190 | AND x.`descendant_id` = a.`ancestor_id`
191 | WHERE d.`ancestor_id` = `node_old_parent_id`
192 | AND x.`ancestor_id` IS NULL ;
193 |
194 | -- Add the node to its new parent
195 | INSERT `prefix_nodes_paths` (
196 | `ancestor_id`,
197 | `descendant_id`,
198 | `path_length`
199 | )
200 | SELECT
201 | supertree.`ancestor_id`,
202 | subtree.`descendant_id`,
203 | supertree.`path_length` + subtree.`path_length` + 1
204 | FROM
205 | `prefix_nodes_paths` AS supertree
206 | JOIN `prefix_nodes_paths` AS subtree
207 | WHERE subtree.`ancestor_id` = `node_old_parent_id`
208 | AND supertree.`descendant_id` = `node_new_parent_id` ;
209 | END$$
210 |
211 | DELIMITER ;
212 |
213 |
214 | INSERT INTO `prefix_nodes` VALUES(1, NULL, NULL, 'ROOT',DEFAULT, 0, 0);
215 | INSERT INTO `prefix_nodes` VALUES(2, 1, NULL, 'C0',DEFAULT, 0, 3);
216 | INSERT INTO `prefix_nodes` VALUES(3, 1, NULL, 'B0',DEFAULT, 0, 2);
217 |
218 |
219 |
220 |
221 | INSERT INTO `prefix_nodes` VALUES(NULL, 3, NULL, 'A1',DEFAULT, 0, 1);
222 | INSERT INTO `prefix_nodes` VALUES(NULL, 3, NULL, 'A2',DEFAULT, 0, 1);
223 | INSERT INTO `prefix_nodes` VALUES(NULL, 3, NULL, 'A3',DEFAULT, 0, 1);
224 | INSERT INTO `prefix_nodes` VALUES(NULL, 3, NULL, 'A4',DEFAULT, 0, 1);
225 | INSERT INTO `prefix_nodes` VALUES(NULL, 3, NULL, 'A5',DEFAULT, 0, 1);
226 | INSERT INTO `prefix_nodes` VALUES(NULL, 3, NULL, 'A6',DEFAULT, 0, 1);
227 | INSERT INTO `prefix_nodes` VALUES(NULL, 3, NULL, 'A7',DEFAULT, 0, 1);
228 | INSERT INTO `prefix_nodes` VALUES(NULL, 3, NULL, 'A8',DEFAULT, 0, 1);
229 | INSERT INTO `prefix_nodes` VALUES(NULL, 3, NULL, 'A9',DEFAULT, 0, 1);
230 |
231 |
--------------------------------------------------------------------------------
/postgres/all-in-one.sql:
--------------------------------------------------------------------------------
1 | -- Table: public.prefix_nodes
2 |
3 | -- DROP TABLE public.prefix_nodes;
4 |
5 | CREATE TABLE public.prefix_nodes
6 | (
7 | id uuid NOT NULL DEFAULT gen_random_uuid(),
8 | "order" integer,
9 | name character varying(255),
10 | is_deleted boolean NOT NULL DEFAULT false,
11 | parent_id uuid,
12 | CONSTRAINT prefix_nodes_pkey PRIMARY KEY (id),
13 | CONSTRAINT prefix_nodes_parent_id_fkey FOREIGN KEY (parent_id)
14 | REFERENCES public.prefix_nodes (id) MATCH SIMPLE
15 | ON UPDATE NO ACTION ON DELETE CASCADE
16 | )
17 | WITH (
18 | OIDS=FALSE
19 | );
20 | ALTER TABLE public.prefix_nodes
21 | OWNER TO postgres;
22 |
23 | -- Index: public.prefix_nodes_parent_id_index
24 |
25 | -- DROP INDEX public.prefix_nodes_parent_id_index;
26 |
27 | CREATE INDEX prefix_nodes_parent_id_index
28 | ON public.prefix_nodes
29 | USING btree
30 | (parent_id);
31 |
32 |
33 | -- Trigger: after_change_node on public.prefix_nodes
34 |
35 | -- DROP TRIGGER after_change_node ON public.prefix_nodes;
36 |
37 | CREATE TRIGGER after_change_node
38 | AFTER INSERT OR UPDATE
39 | ON public.prefix_nodes
40 | FOR EACH ROW
41 | EXECUTE PROCEDURE public.after_change_node();
42 |
43 | ------------------------------------------------------------------------------------------------------
44 |
45 | -- Table: public.prefix_nodes_paths
46 |
47 | -- DROP TABLE public.prefix_nodes_paths;
48 |
49 | CREATE TABLE public.prefix_nodes_paths
50 | (
51 | ancestor_id uuid NOT NULL,
52 | descendant_id uuid NOT NULL,
53 | depth integer,
54 | CONSTRAINT prefix_nodes_paths_pkey PRIMARY KEY (ancestor_id, descendant_id),
55 | CONSTRAINT prefix_nodes_paths_ancestor_id_fkey FOREIGN KEY (ancestor_id)
56 | REFERENCES public.prefix_nodes (id) MATCH SIMPLE
57 | ON UPDATE NO ACTION ON DELETE CASCADE,
58 | CONSTRAINT prefix_nodes_paths_descendant_id_fkey FOREIGN KEY (descendant_id)
59 | REFERENCES public.prefix_nodes (id) MATCH SIMPLE
60 | ON UPDATE NO ACTION ON DELETE CASCADE
61 | )
62 | WITH (
63 | OIDS=FALSE
64 | );
65 | ALTER TABLE public.prefix_nodes_paths
66 | OWNER TO postgres;
67 |
68 | -- Index: public.prefix_nodes_paths_ancestor_id_index
69 |
70 | -- DROP INDEX public.prefix_nodes_paths_ancestor_id_index;
71 |
72 | CREATE INDEX prefix_nodes_paths_ancestor_id_index
73 | ON public.prefix_nodes_paths
74 | USING btree
75 | (ancestor_id);
76 |
77 | -- Index: public.prefix_nodes_paths_descendant_id_index
78 |
79 | -- DROP INDEX public.prefix_nodes_paths_descendant_id_index;
80 |
81 | CREATE INDEX prefix_nodes_paths_descendant_id_index
82 | ON public.prefix_nodes_paths
83 | USING btree
84 | (descendant_id);
85 |
86 |
87 | ------------------------------------------------------------------------------------------------------
88 |
89 |
90 | -- Function: public.get_child_nodes(uuid)
91 |
92 | -- DROP FUNCTION public.get_child_nodes(uuid);
93 |
94 | CREATE OR REPLACE FUNCTION public.get_child_nodes(uuid)
95 | RETURNS SETOF record AS
96 | $BODY$
97 | SELECT d.id,
98 | d.is_deleted,
99 | d.parent_id,
100 | concat(repeat('-', p.depth), d.name) AS name,
101 | p.depth,
102 | array_to_string(array_agg(crumbs.ancestor_id::CHARACTER VARYING),',','*') breadcrumbs
103 | FROM prefix_nodes AS d
104 | JOIN prefix_nodes_paths AS p ON d.id = p.descendant_id
105 | JOIN prefix_nodes_paths AS crumbs ON crumbs.descendant_id = p.descendant_id
106 | WHERE p.ancestor_id = $1 AND d.is_deleted = false
107 | GROUP BY d.id, p.depth
108 | ORDER BY d.id ASC
109 | ;
110 | $BODY$
111 | LANGUAGE sql VOLATILE
112 | COST 100
113 | ROWS 1000;
114 | ALTER FUNCTION public.get_child_nodes(uuid)
115 | OWNER TO postgres;
116 |
117 |
118 | ------------------------------------------------------------------------------------------------------
119 |
120 |
121 | -- Function: public.get_children_by_uuid(uuid)
122 |
123 | -- DROP FUNCTION public.get_children_by_uuid(uuid);
124 |
125 | CREATE OR REPLACE FUNCTION public.get_children_by_uuid(uuid)
126 | RETURNS json AS
127 | $BODY$
128 | DECLARE
129 | result json;
130 | BEGIN
131 | SELECT array_to_json(array_agg(row_to_json(t))) INTO result -- inject output into result variable
132 | FROM ( -- same CTE as above
133 | WITH RECURSIVE genres_materialized_path AS (
134 | SELECT id, name, ARRAY[]::UUID[] AS path
135 | FROM prefix_nodes WHERE parent_id IS NULL
136 |
137 | UNION ALL
138 |
139 | SELECT prefix_nodes.id, prefix_nodes.name, genres_materialized_path.path || prefix_nodes.parent_id::UUID
140 | FROM prefix_nodes, genres_materialized_path
141 | WHERE prefix_nodes.parent_id = genres_materialized_path.id
142 | ) SELECT id, name, ARRAY[]::UUID[] AS children
143 | FROM genres_materialized_path WHERE $1 = genres_materialized_path.path[array_upper(genres_materialized_path.path,1)] -- some column polish for a cleaner JSON
144 | ) t;
145 | RETURN result;
146 | END;
147 | $BODY$
148 | LANGUAGE plpgsql VOLATILE
149 | COST 100;
150 | ALTER FUNCTION public.get_children_by_uuid(uuid)
151 | OWNER TO postgres;
152 |
153 |
154 |
155 | ------------------------------------------------------------------------------------------------------
156 |
157 |
158 |
159 | -- Function: public.get_tree(json)
160 |
161 | -- DROP FUNCTION public.get_tree(json);
162 |
163 | CREATE OR REPLACE FUNCTION public.get_tree(data json)
164 | RETURNS json AS
165 | $BODY$
166 | var root = [];
167 | for(var i in data) {
168 | build_tree(data[i]['id'], data[i]['name'], data[i]['children']);
169 | }
170 | function build_tree(id, name, children) {
171 | var exists = getObject(root, id);
172 | if(exists) {
173 | exists['children'] = children;
174 | }
175 | else {
176 | root.push({'id': id, 'name': name, 'children': children});
177 | }
178 | }
179 | function getObject(theObject, id) {
180 | var result = null;
181 | if(theObject instanceof Array) {
182 | for(var i = 0; i < theObject.length; i++) {
183 | result = getObject(theObject[i], id);
184 | if (result) {
185 | break;
186 | }
187 | }
188 | }
189 | else
190 | {
191 | for(var prop in theObject) {
192 | if(prop == 'id') {
193 | if(theObject[prop] === id) {
194 | return theObject;
195 | }
196 | }
197 | if(theObject[prop] instanceof Object || theObject[prop] instanceof Array) {
198 | result = getObject(theObject[prop], id);
199 | if (result) {
200 | break;
201 | }
202 | }
203 | }
204 | }
205 | return result;
206 | }
207 | return JSON.stringify(root);
208 | $BODY$
209 | LANGUAGE plv8 IMMUTABLE STRICT
210 | COST 100;
211 | ALTER FUNCTION public.get_tree(json)
212 | OWNER TO postgres;
213 |
214 |
215 | ------------------------------------------------------------------------------------------------------
216 |
217 |
218 |
219 | -- Function: public.move(uuid, uuid)
220 |
221 | -- DROP FUNCTION public.move(uuid, uuid);
222 |
223 | CREATE OR REPLACE FUNCTION public.move(
224 | uuid,
225 | uuid)
226 | RETURNS void AS
227 | $BODY$
228 | UPDATE prefix_nodes SET parent_id = $2 WHERE id = $1;
229 |
230 | DELETE FROM prefix_nodes_paths
231 | WHERE descendant_id IN (SELECT descendant_id FROM prefix_nodes_paths WHERE ancestor_id = $1)
232 | AND ancestor_id IN (SELECT ancestor_id FROM prefix_nodes_paths WHERE descendant_id = $1 AND ancestor_id != descendant_id);
233 |
234 | INSERT INTO prefix_nodes_paths (ancestor_id, descendant_id, depth)
235 | SELECT supertree.ancestor_id, subtree.descendant_id, supertree.depth + subtree.depth + 1
236 | FROM prefix_nodes_paths AS supertree
237 | CROSS JOIN prefix_nodes_paths AS subtree
238 | WHERE supertree.descendant_id = $2
239 | AND subtree.ancestor_id = $1;
240 | $BODY$
241 | LANGUAGE sql VOLATILE
242 | COST 100;
243 | ALTER FUNCTION public.move(uuid, uuid)
244 | OWNER TO postgres;
245 |
--------------------------------------------------------------------------------