詳細(xì)聊一聊mysql的樹形結(jié)構(gòu)存儲(chǔ)以及查詢
序
本文主要研究一下mysql的樹形結(jié)構(gòu)存儲(chǔ)及查詢
存儲(chǔ)parent
這種方式就是每個(gè)節(jié)點(diǎn)存儲(chǔ)自己的parent_id信息
- 建表及數(shù)據(jù)準(zhǔn)備
CREATE TABLE `menu` ( `id` int(11) NOT NULL AUTO_INCREMENT, `name` varchar(50) NOT NULL, `parent_id` int(11) NOT NULL DEFAULT '0', PRIMARY KEY (`id`) ) ENGINE=InnoDB; INSERT INTO `menu` (`id`, `name`, `parent_id`) VALUES (1, 'level1a', 0), (2, 'level1b', 0), (3, 'level2a-1a',1), (4, 'level2b-1a',1), (5, 'level2a-1b', 2), (6, 'level2b-1b', 2), (7, 'level3-2a1a', 3), (8, 'level3-2b1a', 4), (9, 'level3-2a1b', 5), (10, 'level3-2b1b', 6);
- 查詢
-- 查詢跟節(jié)點(diǎn)下的所有節(jié)點(diǎn) SELECT t1.name AS lev1, t2.name as lev2, t3.name as lev3 FROM menu AS t1 LEFT JOIN menu AS t2 ON t2.parent_id = t1.id LEFT JOIN menu AS t3 ON t3.parent_id = t2.id WHERE t1.name = 'level1a'; +---------+------------+-------------+ | lev1 | lev2 | lev3 | +---------+------------+-------------+ | level1a | level2a-1a | level3-2a1a | | level1a | level2b-1a | level3-2b1a | +---------+------------+-------------+ -- 查詢?nèi)~子節(jié)點(diǎn) SELECT t1.name FROM menu AS t1 LEFT JOIN menu as t2 ON t1.id = t2.parent_id WHERE t2.id IS NULL; +-------------+ | name | +-------------+ | level3-2a1a | | level3-2b1a | | level3-2a1b | | level3-2b1b | +-------------+
存儲(chǔ)及修改上比較方便,就是要在sql里頭查詢樹比較費(fèi)勁,一般是加載到內(nèi)存由應(yīng)用自己構(gòu)造
存儲(chǔ)path
這種方式在存儲(chǔ)parent的基礎(chǔ)上,額外存儲(chǔ)path,即從根節(jié)點(diǎn)到該節(jié)點(diǎn)的路徑
- 建表及數(shù)據(jù)準(zhǔn)備
CREATE TABLE `menu_path` ( `id` int(11) NOT NULL AUTO_INCREMENT, `name` varchar(50) NOT NULL, `parent_id` int(11) NOT NULL DEFAULT '0', `path` varchar(255) NOT NULL DEFAULT '', PRIMARY KEY (`id`) ) ENGINE=InnoDB; INSERT INTO `menu_path` (`id`, `name`, `parent_id`, `path`) VALUES (1, 'level1a', 0, '1/'), (2, 'level1b', 0, '2/'), (3, 'level2a-1a',1, '1/3'), (4, 'level2b-1a',1, '1/4'), (5, 'level2a-1b', 2, '2/5'), (6, 'level2b-1b', 2, '2/6'), (7, 'level3-2a1a', 3, '1/3/7'), (8, 'level3-2b1a', 4, '1/4/8'), (9, 'level3-2a1b', 5, '2/5/9'), (10, 'level3-2b1b', 6, '2/6/10');
- 查詢
-- 查詢某個(gè)節(jié)點(diǎn)的所有子節(jié)點(diǎn) select * from menu_path where path like '1/%' +----+-------------+-----------+-------+ | id | name | parent_id | path | +----+-------------+-----------+-------+ | 1 | level1a | 0 | 1/ | | 3 | level2a-1a | 1 | 1/3 | | 4 | level2b-1a | 1 | 1/4 | | 7 | level3-2a1a | 3 | 1/3/7 | | 8 | level3-2b1a | 4 | 1/4/8 | +----+-------------+-----------+-------+
查找某個(gè)節(jié)點(diǎn)及其子節(jié)點(diǎn)比較方面,就是修改比較費(fèi)勁,特別是節(jié)點(diǎn)移動(dòng),所有子節(jié)點(diǎn)的path都得跟著修改
MPTT(Modified Preorder Tree Traversal)
不存儲(chǔ)parent_id,改為存儲(chǔ)lft,rgt,它們的值由樹的先序遍歷順序決定
- 建表及數(shù)據(jù)準(zhǔn)備
CREATE TABLE `menu_preorder` ( `id` int(11) NOT NULL, `name` varchar(50) NOT NULL, `lft` int(11) NOT NULL DEFAULT '0', `rgt` int(11) NOT NULL DEFAULT '0', PRIMARY KEY (`id`) ) ENGINE=InnoDB; 1(level1a)14 2(level2a)7 8(level2b)13 3(level3a-2a)4 5(level3b-2a)6 9(level3c-2b)10 11(level3d-2b)12 INSERT INTO `menu_preorder` (`id`, `name`, `lft`, `rgt`) VALUES (1, 'level1a', 1, 14), (2, 'level2a',2, 7), (3, 'level2b',8, 13), (4, 'level3a-2a', 3, 4), (5, 'level3b-2a', 5, 6), (6, 'level3c-2b', 9, 10), (7, 'level3d-2b', 11, 12); select * from menu_preorder +----+------------+-----+-----+ | id | name | lft | rgt | +----+------------+-----+-----+ | 1 | level1a | 1 | 14 | | 2 | level2a | 2 | 7 | | 3 | level2b | 8 | 13 | | 4 | level3a-2a | 3 | 4 | | 5 | level3b-2a | 5 | 6 | | 6 | level3c-2b | 9 | 10 | | 7 | level3d-2b | 11 | 12 | +----+------------+-----+-----+
- 查詢
-- 查詢某個(gè)節(jié)點(diǎn)及其子節(jié)點(diǎn),比如level2b select * from menu_preorder where lft between 8 and 13 +----+------------+-----+-----+ | id | name | lft | rgt | +----+------------+-----+-----+ | 3 | level2b | 8 | 13 | | 6 | level3c-2b | 9 | 10 | | 7 | level3d-2b | 11 | 12 | +----+------------+-----+-----+ -- 查詢所有葉子節(jié)點(diǎn) SELECT name FROM menu_preorder WHERE rgt = lft + 1; +------------+ | name | +------------+ | level3a-2a | | level3b-2a | | level3c-2b | | level3d-2b | +------------+ -- 查詢某個(gè)節(jié)點(diǎn)及其父節(jié)點(diǎn) SELECT parent.* FROM menu_preorder AS node, menu_preorder AS parent WHERE node.lft BETWEEN parent.lft AND parent.rgt AND node.name = 'level2b' ORDER BY parent.lft; +----+---------+-----+-----+ | id | name | lft | rgt | +----+---------+-----+-----+ | 1 | level1a | 1 | 14 | | 3 | level2b | 8 | 13 | +----+---------+-----+-----+ -- 樹形結(jié)構(gòu)展示 SELECT CONCAT( REPEAT(' ', COUNT(parent.name) - 1), node.name) AS name FROM menu_preorder AS node, menu_preorder AS parent WHERE node.lft BETWEEN parent.lft AND parent.rgt GROUP BY node.name ORDER BY node.lft; +--------------+ | name | +--------------+ | level1a | | level2a | | level3a-2a | | level3b-2a | | level2b | | level3c-2b | | level3d-2b | +--------------+
好處是通過lft進(jìn)行范圍(該節(jié)點(diǎn)的lft,rgt作為范圍)查找就可以,缺點(diǎn)就是增刪節(jié)點(diǎn)導(dǎo)致很多節(jié)點(diǎn)的lft及rgt都要修改
小結(jié)
- 存儲(chǔ)parent的方式最為場(chǎng)景,一般樹形結(jié)構(gòu)數(shù)據(jù)量不大的話,直接在應(yīng)用層內(nèi)存構(gòu)造樹形結(jié)構(gòu)和搜索
- 存儲(chǔ)path的好處是可以借助path來查找節(jié)點(diǎn)及其子節(jié)點(diǎn),缺點(diǎn)就是移動(dòng)node需要級(jí)聯(lián)所有子節(jié)點(diǎn)的path,比較費(fèi)勁
- MPTT的方式好處是通過lft進(jìn)行范圍(該節(jié)點(diǎn)的lft,rgt作為范圍)查找就可以,缺點(diǎn)就是增刪節(jié)點(diǎn)導(dǎo)致很多節(jié)點(diǎn)的lft及rgt都要修改
doc
- Managing Hierarchical Data in MySQL
- hierarchical-data-database
- hierarchical-data-database-2
- hierarchical-data-database-3
到此這篇關(guān)于mysql樹形結(jié)構(gòu)存儲(chǔ)以及查詢的文章就介紹到這了,更多相關(guān)mysql樹形結(jié)構(gòu)存儲(chǔ)及查詢內(nèi)容請(qǐng)搜索腳本之家以前的文章或繼續(xù)瀏覽下面的相關(guān)文章希望大家以后多多支持腳本之家!
相關(guān)文章
MySQL5綠色版windows下安裝總結(jié)(推薦)
這篇文章主要介紹了MySQL5綠色版windows下安裝總結(jié),需要的朋友可以參考下2017-03-03win2003服務(wù)器下配置 MySQL 群集(Cluster)的方法
MySQL 群集是 MySQL 適合于分布式計(jì)算環(huán)境的高可用、高冗余版本。它采用了 NDB Cluster 存儲(chǔ)引擎,允許在 1 個(gè)群集中運(yùn)行多個(gè) MySQL 服務(wù)器。2010-12-12SQL?Server攜程核心系統(tǒng)無感遷移到MySQL實(shí)戰(zhàn)
這篇文章主要介紹了SQL?Server攜程核心系統(tǒng)無感遷移到MySQL實(shí)戰(zhàn),文章通過基于數(shù)據(jù)庫部署架構(gòu)鏡像構(gòu)建了訂單緩存統(tǒng)一管理熱點(diǎn)數(shù)據(jù),解決各端差異,具體詳情需要的小伙伴可以參考下面文章詳細(xì)內(nèi)容2022-05-05MySQL中interactive_timeout和wait_timeout的區(qū)別
這篇文章主要介紹了MySQL中interactive_timeout和wait_timeout的區(qū)別,非常不錯(cuò)具有參考借鑒價(jià)值,需要的朋友可以參考下2016-10-10