Yu-Gi-Oh! Deck Building and Card Inventory Management web interface written in Common Lisp, utilizing HTMX.
Ви не можете вибрати більше 25 тем Теми мають розпочинатися з літери або цифри, можуть містити дефіси (-) і не повинні перевищувати 35 символів.

878 рядки
31KB

  1. #|
  2. src/models/category.lisp
  3. TODO All of this needs a serious rewrite.
  4. |#
  5. (in-package #:cl-deck-builder2.models.category)
  6. ;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;
  7. (defclass category ()
  8. ((name :accessor name-of
  9. :col-type (:varchar 64)
  10. :initarg :name)
  11. (left :accessor category-left-of
  12. :col-type :integer
  13. :initarg :left)
  14. (right :accessor category-right-of
  15. :col-type :integer
  16. :initarg :right))
  17. (:metaclass registered-table-class)
  18. (:unique-key name)
  19. (:documentation "Category implementation based on Joe Celko's Nested Set Hierarchy from one of his books."))
  20. (defun create-category (name left right)
  21. (create-dao 'category :name name
  22. :left left
  23. :right right))
  24. ;; (defmacro category (&body body)
  25. ;; `(select-dao 'category ,@body))
  26. ;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;
  27. (defmethod category-rename ((category category) new-name)
  28. (setf (category-name-of category) new-name)
  29. (update-dao category))
  30. ;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;
  31. ;;;; Joe Celko Nested Set Hierarchy
  32. ;;;;
  33. ;;;; <https://mikehillyer.com/articles/managing-hierarchical-data-in-mysql/>
  34. ;;;;
  35. ;;;; * The Nested Set Model
  36. ;;;;
  37. ;;;; #+BEGIN_SRC sql
  38. ;;;; CREATE TABLE nested_category (
  39. ;;;; category_id INT AUTO_INCREMENT PRIMARY KEY,
  40. ;;;; name VARCHAR(20) NOT NULL,
  41. ;;;; lft INT NOT NULL,
  42. ;;;; rgt INT NOT NULL
  43. ;;;; );
  44. ;;;;
  45. ;;;; INSERT INTO nested_category VALUES
  46. ;;;; (1,'ELECTRONICS',1,20),
  47. ;;;; (2,'TELEVISIONS',2,9),
  48. ;;;; (3,'TUBE',3,4),
  49. ;;;; (4,'LCD',5,6),
  50. ;;;; (5,'PLASMA',7,8),
  51. ;;;; (6,'PORTABLE ELECTRONICS',10,19),
  52. ;;;; (7,'MP3 PLAYERS',11,14),
  53. ;;;; (8,'FLASH',12,13),
  54. ;;;; (9,'CD PLAYERS',15,16),
  55. ;;;; (10,'2 WAY RADIOS',17,18);
  56. ;;;;
  57. ;;;; SELECT * FROM nested_category ORDER BY category_id;
  58. ;;;; #+END_SRC
  59. ;;;;
  60. ;;;; #+BEGIN_SRC lisp
  61. (defun category-insert-fake-data ()
  62. "Insert Fake Data. These LEFT-IDs will mess with your stuff...
  63. TODO Figure out how to fix that."
  64. (with-connection (db)
  65. (with-transaction
  66. (mapcar (lambda (values-list)
  67. (destructuring-bind (name left right)
  68. values-list
  69. (mito:create-dao 'category
  70. :name name
  71. :left left
  72. :right right)))
  73. '(("ELECTRONICS" 1 20)
  74. ("TELEVISIONS" 2 9)
  75. ("TUBE" 3 4)
  76. ("LCD" 5 6)
  77. ("PLASMA" 7 8)
  78. ("PORTABLE ELECTRONICS" 10 19)
  79. ("MP3 PLAYERS" 11 14)
  80. ("FLASH" 12 13)
  81. ("CD PLAYERS" 15 16)
  82. ("2 WAY RADIOS" 17 18))))))
  83. ;;;; #+END_SRC
  84. ;;;;
  85. ;;;;
  86. ;;;; +-------------+----------------------+-----+-----+
  87. ;;;; | category_id | name | lft | rgt |
  88. ;;;; +-------------+----------------------+-----+-----+
  89. ;;;; | 1 | ELECTRONICS | 1 | 20 |
  90. ;;;; | 2 | TELEVISIONS | 2 | 9 |
  91. ;;;; | 3 | TUBE | 3 | 4 |
  92. ;;;; | 4 | LCD | 5 | 6 |
  93. ;;;; | 5 | PLASMA | 7 | 8 |
  94. ;;;; | 6 | PORTABLE ELECTRONICS | 10 | 19 |
  95. ;;;; | 7 | MP3 PLAYERS | 11 | 14 |
  96. ;;;; | 8 | FLASH | 12 | 13 |
  97. ;;;; | 9 | CD PLAYERS | 15 | 16 |
  98. ;;;; | 10 | 2 WAY RADIOS | 17 | 18 |
  99. ;;;; +-------------+----------------------+-----+-----+
  100. ;;;;
  101. ;;;; * Retrieving a Full Tree
  102. ;;;;
  103. ;;;; We can retrieve the full tree through the use of a self-join that
  104. ;;;; links parents with nodes on the basis that a node’s lft value will
  105. ;;;; always appear between its parent’s lft and rgt values:
  106. ;;;;
  107. ;;;; #+BEGIN_SRC sql
  108. ;;;; SELECT node.name
  109. ;;;; FROM nested_category AS node,
  110. ;;;; nested_category AS parent
  111. ;;;; WHERE node.lft BETWEEN parent.lft AND parent.rgt
  112. ;;;; AND parent.name = 'ELECTRONICS'
  113. ;;;; ORDER BY node.lft;
  114. ;;;; #+END_SRC
  115. ;;;;
  116. ;;;; #+BEGIN_SRC lisp
  117. (defun category-full-tree (fields name)
  118. (retrieve-by-sql
  119. (sxql:select fields
  120. (sxql:from (:as :category :node)
  121. (:as :category :parent))
  122. (sxql:where (:and (sxql:make-op :raw "node.left between parent.left and parent.right")
  123. (:= :parent.name name)))
  124. (sxql:order-by :node.left))))
  125. ;;;; #+END_SRC
  126. ;;;;
  127. ;;;; +----------------------+
  128. ;;;; | name |
  129. ;;;; +----------------------+
  130. ;;;; | ELECTRONICS |
  131. ;;;; | TELEVISIONS |
  132. ;;;; | TUBE |
  133. ;;;; | LCD |
  134. ;;;; | PLASMA |
  135. ;;;; | PORTABLE ELECTRONICS |
  136. ;;;; | MP3 PLAYERS |
  137. ;;;; | FLASH |
  138. ;;;; | CD PLAYERS |
  139. ;;;; | 2 WAY RADIOS |
  140. ;;;; +----------------------+
  141. ;;;;
  142. ;;;; * Finding all the Leaf Nodes
  143. ;;;;
  144. ;;;; Finding all leaf nodes in the nested set model even simpler than the
  145. ;;;; LEFT JOIN method used in the adjacency list model. If you look at the
  146. ;;;; nested_category table, you may notice that the lft and rgt values for
  147. ;;;; leaf nodes are consecutive numbers. To find the leaf nodes, we look
  148. ;;;; for nodes where rgt = lft + 1:
  149. ;;;;
  150. ;;;; #+BEGIN_SRC sql
  151. ;;;; SELECT name
  152. ;;;; FROM nested_category
  153. ;;;; WHERE rgt = lft + 1;
  154. ;;;; #+END_SRC
  155. ;;;;
  156. ;;;; #+BEGIN_SRC lisp
  157. (defun category-leaf-nodes ()
  158. "Finding all the Leaf Nodes"
  159. (select-dao 'category
  160. (sxql:where (:= :right (sxql:make-op :+ :left 1)))))
  161. ;;;; #+END_SRC
  162. ;;;;
  163. ;;;; +--------------+
  164. ;;;; | name |
  165. ;;;; +--------------+
  166. ;;;; | TUBE |
  167. ;;;; | LCD |
  168. ;;;; | PLASMA |
  169. ;;;; | FLASH |
  170. ;;;; | CD PLAYERS |
  171. ;;;; | 2 WAY RADIOS |
  172. ;;;; +--------------+
  173. ;;;;
  174. ;;;; * Retrieving a Single Path
  175. ;;;;
  176. ;;;; With the nested set model, we can retrieve a single path without
  177. ;;;; having multiple self-joins:
  178. ;;;;
  179. ;;;; #+BEGIN_SRC sql
  180. ;;;; SELECT parent.name
  181. ;;;; FROM nested_category AS node,
  182. ;;;; nested_category AS parent
  183. ;;;; WHERE node.lft BETWEEN parent.lft AND parent.rgt
  184. ;;;; AND node.name = 'FLASH'
  185. ;;;; ORDER BY parent.lft;
  186. ;;;; #+END_SRC
  187. ;;;;
  188. ;;;; #+BEGIN_SRC lisp
  189. (defun category-path-of (name)
  190. (retrieve-by-sql
  191. (sxql:select :parent.name
  192. (sxql:from (:as :category :node)
  193. (:as :category :parent))
  194. (sxql:where (:and (sxql:make-op :raw "node.left between parent.left and parent.right")
  195. (:= :node.name name)))
  196. (sxql:order-by :parent.left))))
  197. ;;;; #+END_SRC
  198. ;;;;
  199. ;;;; +----------------------+
  200. ;;;; | name |
  201. ;;;; +----------------------+
  202. ;;;; | ELECTRONICS |
  203. ;;;; | PORTABLE ELECTRONICS |
  204. ;;;; | MP3 PLAYERS |
  205. ;;;; | FLASH |
  206. ;;;; +----------------------+
  207. ;;;;
  208. ;;;; * Finding the Depth of the Nodes
  209. ;;;;
  210. ;;;; We have already looked at how to show the entire tree, but what if we
  211. ;;;; want to also show the depth of each node in the tree, to better
  212. ;;;; identify how each node fits in the hierarchy? This can be done by
  213. ;;;; adding a COUNT function and a GROUP BY clause to our existing query
  214. ;;;; for showing the entire tree:
  215. ;;;;
  216. ;;;; #+BEGIN_SRC sql
  217. ;;;; SELECT node.name, (COUNT(parent.name) - 1) AS depth
  218. ;;;; FROM nested_category AS node,
  219. ;;;; nested_category AS parent
  220. ;;;; WHERE node.lft BETWEEN parent.lft AND parent.rgt
  221. ;;;; GROUP BY node.name
  222. ;;;; ORDER BY node.lft;
  223. ;;;; #+END_SRC
  224. ;;;;
  225. ;;;; #+BEGIN_SRC lisp
  226. (defun category-node-depth (name)
  227. "Find the depth of a specific CATEGORY node named NAME."
  228. (retrieve-by-sql
  229. (sxql:select
  230. (:node.name (:as (:- (:count :parent.name) 1) :depth))
  231. (sxql:from (:as :category :node)
  232. (:as :category :parent))
  233. (sxql:where (:and (sxql:make-op :raw "node.left between parent.left and parent.right")
  234. (:= :node.name name)))
  235. (sxql:group-by :node.name)
  236. (sxql:order-by :node.left))))
  237. (defun category-tree-depth ()
  238. "Show the depths of all nodes in the CATEGORY tree."
  239. (retrieve-by-sql
  240. (sxql:select
  241. (:node.name (:as (:- (:count :parent.name) 1) :depth))
  242. (sxql:from (:as :category :node)
  243. (:as :category :parent))
  244. (sxql:where (sxql:make-op :raw "node.left between parent.left and parent.right"))
  245. (sxql:group-by :node.name)
  246. (sxql:order-by :node.left))))
  247. ;;;; #+END_SRC
  248. ;;;;
  249. ;;;; +----------------------+-------+
  250. ;;;; | name | depth |
  251. ;;;; +----------------------+-------+
  252. ;;;; | ELECTRONICS | 0 |
  253. ;;;; | TELEVISIONS | 1 |
  254. ;;;; | TUBE | 2 |
  255. ;;;; | LCD | 2 |
  256. ;;;; | PLASMA | 2 |
  257. ;;;; | PORTABLE ELECTRONICS | 1 |
  258. ;;;; | MP3 PLAYERS | 2 |
  259. ;;;; | FLASH | 3 |
  260. ;;;; | CD PLAYERS | 2 |
  261. ;;;; | 2 WAY RADIOS | 2 |
  262. ;;;; +----------------------+-------+
  263. ;;;;
  264. ;;;; We can use the depth value to indent our category names with the
  265. ;;;; CONCAT and REPEAT string functions:
  266. ;;;;
  267. ;;;; #+BEGIN_SRC sql
  268. ;;;; SELECT CONCAT( REPEAT(' ', COUNT(parent.name) - 1), node.name) AS name
  269. ;;;; FROM nested_category AS node,
  270. ;;;; nested_category AS parent
  271. ;;;; WHERE node.lft BETWEEN parent.lft AND parent.rgt
  272. ;;;; GROUP BY node.name
  273. ;;;; ORDER BY node.lft;
  274. ;;;; #+END_SRC
  275. ;;;;
  276. ;;;; #+BEGIN_SRC lisp
  277. (defun category-full-tree-format (&optional (depths (category-tree-depth)))
  278. "Output a formatted display of the CATEGORY tree.
  279. DEPTHS is the depth tree provided by default by CATEGORY-TREE-DEPTH."
  280. (with-output-to-string (s)
  281. (mapcar (lambda (node)
  282. (format s (format nil "~~~d@a~~a~~%"
  283. (getf node :depth))
  284. "" (getf node :name)))
  285. depths)))
  286. ;;;; #+END_SRC
  287. ;;;;
  288. ;;;; +-----------------------+
  289. ;;;; | name |
  290. ;;;; +-----------------------+
  291. ;;;; | ELECTRONICS |
  292. ;;;; | TELEVISIONS |
  293. ;;;; | TUBE |
  294. ;;;; | LCD |
  295. ;;;; | PLASMA |
  296. ;;;; | PORTABLE ELECTRONICS |
  297. ;;;; | MP3 PLAYERS |
  298. ;;;; | FLASH |
  299. ;;;; | CD PLAYERS |
  300. ;;;; | 2 WAY RADIOS |
  301. ;;;; +-----------------------+
  302. ;;;;
  303. ;;;; Of course, in a client-side application you will be more likely to use
  304. ;;;; the depth value directly to display your hierarchy. Web developers
  305. ;;;; could loop through the tree, adding <li></li> and <ul></ul> tags as
  306. ;;;; the depth number increases and decreases.
  307. ;;;;
  308. ;;;; * Depth of a Sub-Tree
  309. ;;;;
  310. ;;;; When we need depth information for a sub-tree, we cannot limit either
  311. ;;;; the node or parent tables in our self-join because it will corrupt our
  312. ;;;; results. Instead, we add a third self-join, along with a sub-query to
  313. ;;;; determine the depth that will be the new starting point for our
  314. ;;;; sub-tree:
  315. ;;;;
  316. ;;;; #+BEGIN_SRC sql
  317. ;;;; SELECT node.name, (COUNT(parent.name) - (sub_tree.depth + 1)) AS depth
  318. ;;;; FROM nested_category AS node,
  319. ;;;; nested_category AS parent,
  320. ;;;; nested_category AS sub_parent,
  321. ;;;; (
  322. ;;;; SELECT node.name, (COUNT(parent.name) - 1) AS depth
  323. ;;;; FROM nested_category AS node,
  324. ;;;; nested_category AS parent
  325. ;;;; WHERE node.lft BETWEEN parent.lft AND parent.rgt
  326. ;;;; AND node.name = 'PORTABLE ELECTRONICS'
  327. ;;;; GROUP BY node.name
  328. ;;;; ORDER BY node.lft
  329. ;;;; ) AS sub_tree
  330. ;;;; WHERE node.lft BETWEEN parent.lft AND parent.rgt
  331. ;;;; AND node.lft BETWEEN sub_parent.lft AND sub_parent.rgt
  332. ;;;; AND sub_parent.name = sub_tree.name
  333. ;;;; GROUP BY node.name
  334. ;;;; ORDER BY node.lft;
  335. ;;;; #+END_SRC
  336. (defun category-subtree-depth (name)
  337. (retrieve-by-sql
  338. (sxql:select
  339. (:node.name (:as (:- (:count :parent.name) (:+ :sub_tree.depth 1)) :depth))
  340. (sxql:from (:as :category :node)
  341. (:as :category :parent)
  342. (:as :category :sub_parent)
  343. (:as (sxql:select
  344. (:node.name (:as (:- (:count :parent.name) 1) :depth))
  345. (sxql:from (:as :category :node)
  346. (:as :category :parent))
  347. (sxql:where (:and (sxql:make-op :raw "node.left between parent.left and parent.right")
  348. (:= :node.name name)))
  349. (sxql:group-by :node.name)
  350. (sxql:order-by :node.left))
  351. :sub_tree))
  352. (sxql:where (:and (sxql:make-op :raw "node.left between parent.left and parent.right")
  353. (sxql:make-op :raw "node.left between sub_parent.left and sub_parent.right")
  354. (:= :sub_parent.name :sub_tree.name)))
  355. (sxql:group-by :node.name)
  356. (sxql:order-by :node.left))))
  357. ;;;;
  358. ;;;; +----------------------+-------+
  359. ;;;; | name | depth |
  360. ;;;; +----------------------+-------+
  361. ;;;; | PORTABLE ELECTRONICS | 0 |
  362. ;;;; | MP3 PLAYERS | 1 |
  363. ;;;; | FLASH | 2 |
  364. ;;;; | CD PLAYERS | 1 |
  365. ;;;; | 2 WAY RADIOS | 1 |
  366. ;;;; +----------------------+-------+
  367. ;;;;
  368. ;;;; This function can be used with any node name, including the root
  369. ;;;; node. The depth values are always relative to the named node.
  370. ;;;;
  371. ;;;; * Find the Immediate Subordinates of a Node
  372. ;;;;
  373. ;;;; Imagine you are showing a category of electronics products on a
  374. ;;;; retailer web site. When a user clicks on a category, you would want to
  375. ;;;; show the products of that category, as well as list its immediate
  376. ;;;; sub-categories, but not the entire tree of categories beneath it. For
  377. ;;;; this, we need to show the node and its immediate sub-nodes, but no
  378. ;;;; further down the tree. For example, when showing the PORTABLE
  379. ;;;; ELECTRONICS category, we will want to show MP3 PLAYERS, CD PLAYERS,
  380. ;;;; and 2 WAY RADIOS, but not FLASH.
  381. ;;;;
  382. ;;;; This can be easily accomplished by adding a HAVING clause to our previous query:
  383. ;;;;
  384. ;;;; #+BEGIN_SRC sql
  385. ;;;; SELECT node.name, (COUNT(parent.name) - (sub_tree.depth + 1)) AS depth
  386. ;;;; FROM nested_category AS node,
  387. ;;;; nested_category AS parent,
  388. ;;;; nested_category AS sub_parent,
  389. ;;;; (
  390. ;;;; SELECT node.name, (COUNT(parent.name) - 1) AS depth
  391. ;;;; FROM nested_category AS node,
  392. ;;;; nested_category AS parent
  393. ;;;; WHERE node.lft BETWEEN parent.lft AND parent.rgt
  394. ;;;; AND node.name = 'PORTABLE ELECTRONICS'
  395. ;;;; GROUP BY node.name
  396. ;;;; ORDER BY node.lft
  397. ;;;; ) AS sub_tree
  398. ;;;; WHERE node.lft BETWEEN parent.lft AND parent.rgt
  399. ;;;; AND node.lft BETWEEN sub_parent.lft AND sub_parent.rgt
  400. ;;;; AND sub_parent.name = sub_tree.name
  401. ;;;; GROUP BY node.name
  402. ;;;; HAVING depth <= 1
  403. ;;;; ORDER BY node.lft;
  404. ;;;; #+END_SRC
  405. (defun category-subtree-max-depth (name &optional (max-depth 1))
  406. "TODO This doesn't seem to work. It returns FLASH with DEPTH = 2"
  407. (retrieve-by-sql
  408. (sxql:select
  409. (:node.name (:as (:- (:count :parent.name) (:+ :sub_tree.depth 1)) :depth))
  410. (sxql:from (:as :category :node)
  411. (:as :category :parent)
  412. (:as :category :sub_parent)
  413. (:as (sxql:select
  414. (:node.name (:as (:- (:count :parent.name) 1) :depth))
  415. (sxql:from (:as :category :node)
  416. (:as :category :parent))
  417. (sxql:where (:and (sxql:make-op :raw "node.left between parent.left and parent.right")
  418. (:= :node.name name)))
  419. (sxql:group-by :node.name)
  420. (sxql:order-by :node.left))
  421. :sub_tree))
  422. (sxql:where (:and (sxql:make-op :raw "node.left between parent.left and parent.right")
  423. (sxql:make-op :raw "node.left between sub_parent.left and sub_parent.right")
  424. (:= :sub_parent.name :sub_tree.name)))
  425. (sxql:group-by :node.name)
  426. (sxql:having (:<= :depth max-depth))
  427. (sxql:order-by :node.left))))
  428. ;;;;
  429. ;;;; +----------------------+-------+
  430. ;;;; | name | depth |
  431. ;;;; +----------------------+-------+
  432. ;;;; | PORTABLE ELECTRONICS | 0 |
  433. ;;;; | MP3 PLAYERS | 1 |
  434. ;;;; | CD PLAYERS | 1 |
  435. ;;;; | 2 WAY RADIOS | 1 |
  436. ;;;; +----------------------+-------+
  437. ;;;;
  438. ;;;; If you do not wish to show the parent node, change the HAVING depth <= 1 line to HAVING depth = 1.
  439. ;;;;
  440. ;;;; * Aggregate Functions in a Nested Set
  441. ;;;;
  442. ;;;; Let’s add a table of products that we can use to demonstrate aggregate
  443. ;;;; functions with:
  444. ;;;;
  445. ;;;; #+BEGIN_SRC sql
  446. ;;;; CREATE TABLE product
  447. ;;;; (
  448. ;;;; product_id INT AUTO_INCREMENT PRIMARY KEY,
  449. ;;;; name VARCHAR(40),
  450. ;;;; category_id INT NOT NULL
  451. ;;;; );
  452. ;;;;
  453. ;;;; INSERT INTO product(name, category_id)
  454. ;;;; VALUES
  455. ;;;; ('20" TV',3),
  456. ;;;; ('36" TV',3),
  457. ;;;; ('Super-LCD 42"',4),
  458. ;;;; ('Ultra-Plasma 62"',5),
  459. ;;;; ('Value Plasma 38"',5),
  460. ;;;; ('Power-MP3 5gb',7),
  461. ;;;; ('Super-Player 1gb',8),
  462. ;;;; ('Porta CD',9),
  463. ;;;; ('CD To go!',9),
  464. ;;;; ('Family Talk 360',10);
  465. ;;;;
  466. ;;;; SELECT * FROM product;
  467. ;;;; #+END_SRC
  468. ;;;;
  469. ;;;; +------------+-------------------+-------------+
  470. ;;;; | product_id | name | category_id |
  471. ;;;; +------------+-------------------+-------------+
  472. ;;;; | 1 | 20" TV | 3 |
  473. ;;;; | 2 | 36" TV | 3 |
  474. ;;;; | 3 | Super-LCD 42" | 4 |
  475. ;;;; | 4 | Ultra-Plasma 62" | 5 |
  476. ;;;; | 5 | Value Plasma 38" | 5 |
  477. ;;;; | 6 | Power-MP3 128mb | 7 |
  478. ;;;; | 7 | Super-Shuffle 1gb | 8 |
  479. ;;;; | 8 | Porta CD | 9 |
  480. ;;;; | 9 | CD To go! | 9 |
  481. ;;;; | 10 | Family Talk 360 | 10 |
  482. ;;;; +------------+-------------------+-------------+
  483. ;;;;
  484. ;;;; Now let’s produce a query that can retrieve our category tree, along
  485. ;;;; with a product count for each category:
  486. ;;;;
  487. ;;;; #+BEGIN_SRC sql
  488. ;;;; SELECT parent.name, COUNT(product.name)
  489. ;;;; FROM nested_category AS node ,
  490. ;;;; nested_category AS parent,
  491. ;;;; product
  492. ;;;; WHERE node.lft BETWEEN parent.lft AND parent.rgt
  493. ;;;; AND node.category_id = product.category_id
  494. ;;;; GROUP BY parent.name
  495. ;;;; ORDER BY node.lft;
  496. ;;;; #+END_SRC
  497. ;;;;
  498. ;;;; +----------------------+---------------------+
  499. ;;;; | name | COUNT(product.name) |
  500. ;;;; +----------------------+---------------------+
  501. ;;;; | ELECTRONICS | 10 |
  502. ;;;; | TELEVISIONS | 5 |
  503. ;;;; | TUBE | 2 |
  504. ;;;; | LCD | 1 |
  505. ;;;; | PLASMA | 2 |
  506. ;;;; | PORTABLE ELECTRONICS | 5 |
  507. ;;;; | MP3 PLAYERS | 2 |
  508. ;;;; | FLASH | 1 |
  509. ;;;; | CD PLAYERS | 2 |
  510. ;;;; | 2 WAY RADIOS | 1 |
  511. ;;;; +----------------------+---------------------+
  512. ;;;;
  513. ;;;; This is our typical whole tree query with a COUNT and GROUP BY added,
  514. ;;;; along with a reference to the product table and a join between the
  515. ;;;; node and product table in the WHERE clause. As you can see, there is a
  516. ;;;; count for each category and the count of subcategories is reflected in
  517. ;;;; the parent categories.
  518. ;;;;
  519. ;;;; * Adding New Nodes
  520. ;;;;
  521. ;;;; ** category-insert-right-of
  522. ;;;;
  523. ;;;; If we wanted to add a new node between the TELEVISIONS and PORTABLE
  524. ;;;; ELECTRONICS nodes, the new node would have lft and rgt values of 10
  525. ;;;; and 11, and all nodes to its right would have their lft and rgt values
  526. ;;;; increased by two. We would then add the new node with the appropriate
  527. ;;;; lft and rgt values. While this can be done with a stored procedure in
  528. ;;;; MySQL 5, I will assume for the moment that most readers are using 4.1,
  529. ;;;; as it is the latest stable version, and I will isolate my queries with
  530. ;;;; a LOCK TABLES statement instead:
  531. ;;;;
  532. ;;;; #+BEGIN_SRC sql
  533. ;;;; LOCK TABLE nested_category WRITE;
  534. ;;;;
  535. ;;;; SELECT @myRight := rgt FROM nested_category
  536. ;;;; WHERE name = 'TELEVISIONS';
  537. ;;;;
  538. ;;;; UPDATE nested_category SET rgt = rgt + 2 WHERE rgt > @myRight;
  539. ;;;; UPDATE nested_category SET lft = lft + 2 WHERE lft > @myRight;
  540. ;;;;
  541. ;;;; INSERT INTO nested_category(name, lft, rgt) VALUES('GAME CONSOLES', @myRight + 1, @myRight + 2);
  542. ;;;;
  543. ;;;; UNLOCK TABLES;
  544. ;;;; #+END_SRC
  545. ;;;;
  546. ;;;; #+BEGIN_SRC lisp
  547. (defun category-insert-right-of (name &optional left-of)
  548. "Create a new category tree. LEFT-OF is the NAME of the node to the
  549. left of this new node named NAME. If LEFT-OF is NIL, insert
  550. all-the-way at the right."
  551. (with-connection (db)
  552. (let* ((found (ignore-errors
  553. (mito:find-dao 'category :name left-of)))
  554. (my-right (if (and left-of found)
  555. (ignore-errors
  556. (category-right-of found))
  557. (max-dao 'category))))
  558. (with-transaction
  559. (mapcar #'mito:execute-sql
  560. (list
  561. (sxql:update :category
  562. (sxql:set= :right (:+ :right 2))
  563. (sxql:where (:> :right my-right)))
  564. (sxql:update :category
  565. (sxql:set= :left (:+ :left 2))
  566. (sxql:where (:> :left my-right)))))
  567. (mito:create-dao 'category :name name
  568. :left (+ my-right 1)
  569. :right (+ my-right 2))))))
  570. ;;;; #+END_SRC
  571. ;;;;
  572. ;;;; We can then check our nesting with our indented tree query:
  573. ;;;;
  574. ;;;; +-----------------------+
  575. ;;;; | name |
  576. ;;;; +-----------------------+
  577. ;;;; | ELECTRONICS |
  578. ;;;; | TELEVISIONS |
  579. ;;;; | TUBE |
  580. ;;;; | LCD |
  581. ;;;; | PLASMA |
  582. ;;;; | GAME CONSOLES |
  583. ;;;; | PORTABLE ELECTRONICS |
  584. ;;;; | MP3 PLAYERS |
  585. ;;;; | FLASH |
  586. ;;;; | CD PLAYERS |
  587. ;;;; | 2 WAY RADIOS |
  588. ;;;; +-----------------------+
  589. ;;;;
  590. ;;;; ** category-insert-new-child
  591. ;;;;
  592. ;;;; If we instead want to add a node as a child of a node that has no
  593. ;;;; existing children, we need to modify our procedure slightly. Let’s add
  594. ;;;; a new FRS node below the 2 WAY RADIOS node:
  595. ;;;;
  596. ;;;; #+BEGIN_SRC sql
  597. ;;;; LOCK TABLE nested_category WRITE;
  598. ;;;;
  599. ;;;; SELECT @myLeft := lft FROM nested_category
  600. ;;;;
  601. ;;;; WHERE name = '2 WAY RADIOS';
  602. ;;;;
  603. ;;;; UPDATE nested_category SET rgt = rgt + 2 WHERE rgt > @myLeft;
  604. ;;;; UPDATE nested_category SET lft = lft + 2 WHERE lft > @myLeft;
  605. ;;;;
  606. ;;;; INSERT INTO nested_category(name, lft, rgt) VALUES('FRS', @myLeft + 1, @myLeft + 2);
  607. ;;;;
  608. ;;;; UNLOCK TABLES;
  609. ;;;; #+END_SRC
  610. ;;;;
  611. ;;;; #+BEGIN_SRC lisp
  612. (defun category-insert-new-child (name left-of)
  613. "Create a new category tree. LEFT-OF is the NAME of the node to the
  614. left of this new node named NAME."
  615. (with-connection (db)
  616. (let* ((my-left (category-left-of
  617. (mito:find-dao 'category :name left-of))))
  618. (with-transaction
  619. (mapcar #'mito:execute-sql
  620. (list
  621. (sxql:update :category
  622. (sxql:set= :right (:+ :right 2))
  623. (sxql:where (:> :right my-left)))
  624. (sxql:update :category
  625. (sxql:set= :left (:+ :left 2))
  626. (sxql:where (:> :left my-left)))))
  627. (mito:create-dao 'category :name name
  628. :left (+ my-left 1)
  629. :right (+ my-left 2))))))
  630. ;;;; #+END_SRC
  631. ;;;;
  632. ;;;; In this example we expand everything to the right of the left-hand
  633. ;;;; number of our proud new parent node, then place the node to the right
  634. ;;;; of the left-hand value. As you can see, our new node is now properly
  635. ;;;; nested:
  636. ;;;;
  637. ;;;; #+BEGIN_SRC sql
  638. ;;;; SELECT CONCAT( REPEAT( ' ', (COUNT(parent.name) - 1) ), node.name) AS name
  639. ;;;; FROM nested_category AS node,
  640. ;;;; nested_category AS parent
  641. ;;;; WHERE node.lft BETWEEN parent.lft AND parent.rgt
  642. ;;;; GROUP BY node.name
  643. ;;;; ORDER BY node.lft;
  644. ;;;; #+END_SRC
  645. ;;;;
  646. ;;;; +-----------------------+
  647. ;;;; | name |
  648. ;;;; +-----------------------+
  649. ;;;; | ELECTRONICS |
  650. ;;;; | TELEVISIONS |
  651. ;;;; | TUBE |
  652. ;;;; | LCD |
  653. ;;;; | PLASMA |
  654. ;;;; | GAME CONSOLES |
  655. ;;;; | PORTABLE ELECTRONICS |
  656. ;;;; | MP3 PLAYERS |
  657. ;;;; | FLASH |
  658. ;;;; | CD PLAYERS |
  659. ;;;; | 2 WAY RADIOS |
  660. ;;;; | FRS |
  661. ;;;; +-----------------------+
  662. ;;;;
  663. ;;;; * Deleting Nodes
  664. ;;;;
  665. ;;;; ** DONE category-delete-tree
  666. ;;;;
  667. ;;;; The last basic task involved in working with nested sets is the
  668. ;;;; removal of nodes. The course of action you take when deleting a node
  669. ;;;; depends on the node’s position in the hierarchy; deleting leaf nodes
  670. ;;;; is easier than deleting nodes with children because we have to handle
  671. ;;;; the orphaned nodes.
  672. ;;;;
  673. ;;;; When deleting a leaf node, the process if just the opposite of adding
  674. ;;;; a new node, we delete the node and its width from every node to its
  675. ;;;; right:
  676. ;;;;
  677. ;;;; #+BEGIN_SRC sql
  678. ;;;; LOCK TABLE nested_category WRITE;
  679. ;;;;
  680. ;;;; SELECT @myLeft := lft, @myRight := rgt, @myWidth := rgt - lft + 1
  681. ;;;; FROM nested_category
  682. ;;;; WHERE name = 'GAME CONSOLES';
  683. ;;;;
  684. ;;;; DELETE FROM nested_category WHERE lft BETWEEN @myLeft AND @myRight;
  685. ;;;;
  686. ;;;; UPDATE nested_category SET rgt = rgt - @myWidth WHERE rgt > @myRight;
  687. ;;;; UPDATE nested_category SET lft = lft - @myWidth WHERE lft > @myRight;
  688. ;;;;
  689. ;;;; UNLOCK TABLES;
  690. ;;;; #+END_SRC
  691. ;;;;
  692. ;;;; #+BEGIN_SRC lisp
  693. (defun category-delete-tree (name)
  694. (with-connection (db)
  695. (with-transaction
  696. (let ((found (mito:find-dao 'category :name name)))
  697. (if found
  698. (let* ((my-left (category-left-of found))
  699. (my-right (category-right-of found))
  700. (my-width (1+ (- my-right my-left))))
  701. (mapcar #'mito:execute-sql
  702. (list
  703. (sxql:delete-from :category
  704. (sxql:where (sxql:make-op :raw
  705. (format nil "left between ~d and ~d"
  706. my-left my-right))))
  707. (sxql:update :category
  708. (sxql:set= :right (:- :right my-width))
  709. (sxql:where (:> :right my-right)))
  710. (sxql:update :category
  711. (sxql:set= :left (:- :left my-width))
  712. (sxql:where (:> :left my-right)))))))))))
  713. ;;;; #+END_SRC
  714. ;;;;
  715. ;;;; And once again, we execute our indented tree query to confirm that our
  716. ;;;; node has been deleted without corrupting the hierarchy:
  717. ;;;;
  718. ;;;; +-----------------------+
  719. ;;;; | name |
  720. ;;;; +-----------------------+
  721. ;;;; | ELECTRONICS |
  722. ;;;; | TELEVISIONS |
  723. ;;;; | TUBE |
  724. ;;;; | LCD |
  725. ;;;; | PLASMA |
  726. ;;;; | PORTABLE ELECTRONICS |
  727. ;;;; | MP3 PLAYERS |
  728. ;;;; | FLASH |
  729. ;;;; | CD PLAYERS |
  730. ;;;; | 2 WAY RADIOS |
  731. ;;;; | FRS |
  732. ;;;; +-----------------------+
  733. ;;;;
  734. ;;;; This approach works equally well to delete a node and all its children:
  735. ;;;;
  736. ;;;; And once again, we query to see that we have successfully deleted an entire sub-tree:
  737. ;;;;
  738. ;;;; +-----------------------+
  739. ;;;; | name |
  740. ;;;; +-----------------------+
  741. ;;;; | ELECTRONICS |
  742. ;;;; | TELEVISIONS |
  743. ;;;; | TUBE |
  744. ;;;; | LCD |
  745. ;;;; | PLASMA |
  746. ;;;; | PORTABLE ELECTRONICS |
  747. ;;;; | CD PLAYERS |
  748. ;;;; | 2 WAY RADIOS |
  749. ;;;; | FRS |
  750. ;;;; +-----------------------+
  751. ;;;;
  752. ;;;; ** category-delete-and-reparent
  753. ;;;;
  754. ;;;; The other scenario we have to deal with is the deletion of a parent
  755. ;;;; node but not the children. In some cases you may wish to just change
  756. ;;;; the name to a placeholder until a replacement is presented, such as
  757. ;;;; when a supervisor is fired. In other cases, the child nodes should all
  758. ;;;; be moved up to the level of the deleted parent:
  759. ;;;;
  760. ;;;; #+BEGIN_SRC sql
  761. ;;;; LOCK TABLE nested_category WRITE;
  762. ;;;;
  763. ;;;; SELECT @myLeft := lft, @myRight := rgt, @myWidth := rgt - lft + 1
  764. ;;;; FROM nested_category
  765. ;;;; WHERE name = 'PORTABLE ELECTRONICS';
  766. ;;;;
  767. ;;;; DELETE FROM nested_category WHERE lft = @myLeft;
  768. ;;;;
  769. ;;;; UPDATE nested_category SET rgt = rgt - 1, lft = lft - 1 WHERE lft BETWEEN @myLeft AND @myRight;
  770. ;;;; UPDATE nested_category SET rgt = rgt - 2 WHERE rgt > @myRight;
  771. ;;;; UPDATE nested_category SET lft = lft - 2 WHERE lft > @myRight;
  772. ;;;;
  773. ;;;; UNLOCK TABLES;
  774. ;;;; #+END_SRC
  775. ;;;;
  776. ;;;; #+BEGIN_SRC lisp
  777. (defun category-delete-and-reparent (name)
  778. (with-connection (db)
  779. (with-transaction
  780. (let ((found (mito:find-dao 'category :name name)))
  781. (if found
  782. (let* ((my-left (category-left-of found))
  783. (my-right (category-right-of found)))
  784. (mapcar #'mito:execute-sql
  785. (list
  786. (sxql:delete-from :category
  787. (sxql:where (:= :left my-left)))
  788. (sxql:update :category
  789. (sxql:set= :right (:- :right 1)
  790. :left (:- :left 1))
  791. (sxql:where (sxql:make-op
  792. :raw (format nil "left between ~d and ~d"
  793. my-left my-right))))
  794. (sxql:update :category
  795. (sxql:set= :right (:- :right 2))
  796. (sxql:where (:> :right my-right)))
  797. (sxql:update :category
  798. (sxql:set= :left (:- :left 2))
  799. (sxql:where (:> :left my-right)))))))))))
  800. ;;;; #+END_SRC
  801. ;;;;
  802. ;;;; In this case we subtract two from all elements to the right of the
  803. ;;;; node (since without children it would have a width of two), and one
  804. ;;;; from the nodes that are its children (to close the gap created by the
  805. ;;;; loss of the parent’s left value). Once again, we can confirm our
  806. ;;;; elements have been promoted:
  807. ;;;;
  808. ;;;; +---------------+
  809. ;;;; | name |
  810. ;;;; +---------------+
  811. ;;;; | ELECTRONICS |
  812. ;;;; | TELEVISIONS |
  813. ;;;; | TUBE |
  814. ;;;; | LCD |
  815. ;;;; | PLASMA |
  816. ;;;; | CD PLAYERS |
  817. ;;;; | 2 WAY RADIOS |
  818. ;;;; | FRS |
  819. ;;;; +---------------+
  820. ;;;;
  821. ;;;; ** category-delete-and-promote
  822. ;;;;
  823. ;;;; Other scenarios when deleting nodes would include promoting one of the
  824. ;;;; children to the parent position and moving the child nodes under a
  825. ;;;; sibling of the parent node, but for the sake of space these scenarios
  826. ;;;; will not be covered in this article.
  827. ;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;;
  828. ;; TODO SELECT-CATEGORY ?
  829. (defgeneric by-category (class maybe-category-id)
  830. (:method ((class t) (id category))
  831. (select-dao class (sxql:where (:= :category id))))
  832. (:method ((class t) (id integer))
  833. (select-dao class (sxql:where (:= :category-id id))))
  834. (:method ((class t) (id string))
  835. (by-category class (parse-integer id))))