Upgrade to Pro — share decks privately, control downloads, hide ads and more …

Introduction to Tree Representations in RDB

Introduction to Tree Representations in RDB

RDBでのツリー表現入門

RDBでツリー構造を表現するための典型的なモデルについて学ぼう!
cf. 2024年版: https://speakerdeck.com/lagenorhynque/introduction-to-tree-representations-in-rdb-2024

Kent OHASHI

August 14, 2020
Tweet

More Decks by Kent OHASHI

Other Decks in Programming

Transcript

  1. lagénorhynque (defprofile lagénorhynque :id @lagenorhynque :reading "/laʒenɔʁɛ̃ k/" :aliases ["

    カマイルカ "] :languages [Clojure Haskell English français] :interests [programming language-learning law mathematics] :commits ["github.com/lagenorhynque/duct.module.pedestal" "github.com/lagenorhynque/duct.module.cambium"] :contributes ["github.com/japan-clojurians/clojure-site-ja"])
  2. ツリーの本体データ⽤テーブル department CREATE TABLE `department` ( `department_id` int(10) unsigned NOT

    NULL AUTO_INCREMENT, `name` varchar(100) NOT NULL, PRIMARY KEY (`department_id`) );
  3. ツリー管理⽤のテーブル parent_id: 親ノード 本体データ⽤テーブルに含めても良い CREATE TABLE `department_adjacency_list` ( `department_id` int(10)

    unsigned NOT NULL, `parent_id` int(10) unsigned DEFAULT NULL, PRIMARY KEY (`department_id`), FOREIGN KEY (`department_id`) REFERENCES `department` (`department_id`) ON DELETE CASCADE ON UPDATE RESTRICT, FOREIGN KEY (`parent_id`) REFERENCES `department` (`department_id`) ON DELETE CASCADE ON UPDATE RESTRICT );
  4. すべてのノードとその階層情報の取得 distance: ルートノードからの距離 cf. WITH RECURSIVE department_tree AS ( SELECT

    d.*, dal.parent_id, 0 distance FROM department d JOIN department_adjacency_list dal USING (department_id) WHERE dal.parent_id IS NULL UNION ALL SELECT d.*, dal.parent_id, dt.distance + 1 FROM department d JOIN department_adjacency_list dal USING (department_id) JOIN department_tree dt ON dal.parent_id = dt.department_id ) SELECT * FROM department_tree; WITH - MariaDB Knowledge Base
  5. 特定のノードからの⼦孫ノードの取得 distance: ノード 10 からの距離 WITH RECURSIVE department_tree AS (

    SELECT d.*, dal.parent_id, 0 distance FROM department d JOIN department_adjacency_list dal USING (department_id) WHERE d.department_id = 10 UNION ALL SELECT d.*, dal.parent_id, dt.distance + 1 FROM department d JOIN department_adjacency_list dal USING (department_id) JOIN department_tree dt ON dal.parent_id = dt.department_id ) SELECT * FROM department_tree;
  6. CONS 再帰CTE (recursive common table expressions) が使えないと任意階層に対するクエリが困難 削除操作が煩雑 parent_id で

    NULL が現れてしまう ルートノード管理⽤のテーブルを⽤意するこ とで回避可能
  7. ツリー管理⽤のテーブル path: 先祖からそのノードまでの経路( パス) 本体データ⽤テーブルに含めても良い CREATE TABLE `department_path_enumeration` ( `department_id`

    int(10) unsigned NOT NULL, `path` varchar(1000) NOT NULL, PRIMARY KEY (`department_id`), FOREIGN KEY (`department_id`) REFERENCES `department` (`department_id`) ON DELETE CASCADE ON UPDATE RESTRICT );
  8. 特定のノードからの⼦孫ノードの取得 depth: ルートノードからの距離 SELECT d.*, dpe.path, CHAR_LENGTH(dpe.path) - CHAR_LENGTH(REPLACE(dpe.path, '/',

    '')) - 1 depth FROM department d JOIN department_path_enumeration dpe USING (department_id) WHERE dpe.path LIKE CONCAT(( SELECT path FROM department_path_enumeration WHERE department_id = 10 ), '%');
  9. 特定のノードの⼦ノードの取得 SELECT d.* FROM department d JOIN department_path_enumeration dpe USING

    (department_id) WHERE dpe.path REGEXP CONCAT(( SELECT path FROM department_path_enumeration WHERE department_id = 10 ), '\\d+/$');
  10. 特定のノードの親ノードの取得 SELECT d.* FROM department d WHERE d.department_id = (

    SELECT CASE WHEN path = CONCAT(department_id, '/') THEN NULL ELSE REGEXP_REPLACE(path, '^(?:\\d+/)*(\\d+)/\\d+/$', '\\1') END FROM department_path_enumeration WHERE department_id = 10 );
  11. ツリー管理⽤のテーブル left, right: 数直線上の左右の点を表す depth: ルートノードからの距離( 必須ではない) 本体データ⽤テーブルに含めても良い CREATE TABLE

    `department_nested_sets` ( `department_id` int(10) unsigned NOT NULL, `left` int(11) NOT NULL, `right` int(11) NOT NULL, `depth` int(10) unsigned NOT NULL, PRIMARY KEY (`department_id`), FOREIGN KEY (`department_id`) REFERENCES `department` (`department_id`) ON DELETE CASCADE ON UPDATE RESTRICT );
  12. 特定のノードからの⼦孫ノードの取得 SELECT d.*, dns.left, dns.right, dns.depth FROM department d JOIN

    department_nested_sets dns USING (department_id) JOIN department_nested_sets dns2 ON dns.left BETWEEN dns2.left AND dns2.right WHERE dns2.department_id = 10;
  13. 特定のノードの⼦ノードの取得 SELECT d.* FROM department d JOIN department_nested_sets dns USING

    (department_id) JOIN department_nested_sets dns2 ON dns.left BETWEEN dns2.left AND dns2.right WHERE dns2.department_id = 10 AND dns.depth = ( SELECT depth FROM department_nested_sets WHERE department_id = 10 ) + 1;
  14. 特定のノードの親ノードの取得 SELECT d.* FROM department d JOIN department_nested_sets dns USING

    (department_id) JOIN department_nested_sets dns2 ON dns2.left BETWEEN dns.left AND dns.right WHERE dns2.department_id = 10 AND dns.depth + 1 = ( SELECT depth FROM department_nested_sets WHERE department_id = 10 );
  15. ツリー管理⽤のテーブル ancestor, descendant: 先祖/ ⼦孫関係にある ノードの組 path_length: ancestor から descendant

    ま での距離( 必須ではない) CREATE TABLE `department_closure_table` ( `ancestor` int(10) unsigned NOT NULL, `descendant` int(10) unsigned NOT NULL, `path_length` int(10) unsigned NOT NULL, PRIMARY KEY (`ancestor`, `descendant`), FOREIGN KEY (`ancestor`) REFERENCES `department` (`department_id`) ON DELETE CASCADE ON UPDATE RESTRICT, FOREIGN KEY (`descendant`) REFERENCES `department` (`department_id`) ON DELETE CASCADE ON UPDATE RESTRICT );
  16. すべてのノードとその階層情報の取得 depth: ルートノードからの距離 MAX(dct.path_length) でも求められる SELECT d.*, COUNT(*) - 1

    depth FROM department d JOIN department_closure_table dct ON d.department_id = dct.descendant GROUP BY dct.descendant;
  17. 特定のノードからの⼦孫ノードの取得 distance: ノード 10 からの距離 depth: ルートノードからの距離 SELECT d.*, dct.path_length

    distance, dct2.depth FROM department d JOIN department_closure_table dct ON d.department_id = dct.descendant JOIN ( SELECT descendant, COUNT(*) - 1 depth FROM department_closure_table GROUP BY descendant ) dct2 ON d.department_id = dct2.descendant WHERE dct.ancestor = 10;
  18. 特定のノードの⼦ノードの取得 SELECT d.* FROM department d JOIN department_closure_table dct ON

    d.department_id = dct.descendant WHERE dct.ancestor = 10 AND dct.path_length = 1;
  19. 特定のノードの親ノードの取得 SELECT d.* FROM department d JOIN department_closure_table dct ON

    d.department_id = dct.ancestor WHERE dct.descendant = 10 AND dct.path_length = 1;
  20. Further Reading 2 章 ナイーブツリー(素朴な⽊) 第10 章 グラフに⽴ち向かう 10.4 ツリー(⽊)

    第10 章 階層的なデータ構造 『SQL アンチパターン』 『理論から学ぶデータベース実践⼊⾨』 『E ective SQL 』
  21. 第9 章 ⼀歩進んだ論理設計 〜SQL で⽊構造 を扱う 『達⼈に学ぶDB 設計 徹底指南書』 『プログラマのためのSQL

    グラフ原論』 What are the options for storing hierarchical data in a relational database? - Stack Over ow