Skip to content

Commit f32c85d

Browse files
bors-voyager[bot]erewokkivikakkcarols10cents
committed
Merge #1122
1122: Proposal: Add `path` column to categories table as `ltree` type to make tree traversing easier r=carols10cents a=erewok ## Description This is a proposal inspired by tickets ([1](#1093), and [2](#721)) with the goal of eventually revealing more information about categories on pages where category information is available. It is also motivated by the current application code surrounding categories, which contains lots of SQL with operations like this: `split_part(c2.slug, '::', 1)`. This PR is intended as a suggestion for what to do with the `categories` table. Following are changes included here: - Adds a `path` column as a Postgresql `ltree` type to the `categories` table in order to more easily query trees of categories and subcategories. This allows navigating trees of arbitrary depth and potentially more ergonomic path-finding queries. - Adds a `parent_categories` method to `Category`, which returns parent categories _in order of traversal_ from root to this node. ## Trade-offs to this Approach ### Pros - Easily handle trees of arbitrary depth, ex: "category::sub-category::sub-catgeory-A::sub-category-A-1". - Makes queries to find a whole tree of nodes simpler (and possibly quicker?). Ex: `select slug, path from categories where path <@ 'root.web_programming';` - Makes finding all root-level nodes simpler (assuming one is cool with the syntax). Ex: `select slug, path from categories where path ~ 'root.*{1}';` - Makes finding the direct path from the root node to a particular node easier (see `parent_categories` method). Ex: `select slug, path from categories where path @> 'root.web_programming.http_client' order by path;` - Invisible to current application code: nothing needs to be updated to handle the `path` column because it happens via database triggers. (This could also be a _con_ depending on one's perspective.) ### Cons - Postgresql only (harder to switch databases in the future) - Makes certain characters in slugs disallowed: `[',",-]`. Path labels must consist of "A-Za-z0-9_" separated by "." We swap `-` for `_` and `::` for `.` in the included Postgresql procedure. - This `path` column is nowhere in application code, so this is all hand-written SQL (but the current solution is doing that as well). - Error messages are opaque if you happen to have a bad character in a slug: ``` cargo_registry=# update categories set slug = 'test-new::bla$bla-::parent::child' where slug = 'test-new::parent::child'; ERROR: syntax error at position 17 CONTEXT: PL/pgSQL function set_category_path_to_slug() line 3 at assignment ``` ## Notes - [x] Needs a test for the `parent_categories` method. Co-authored-by: Erik Aker <[email protected]> Co-authored-by: Ashe Connor <[email protected]> Co-authored-by: Carol (Nichols || Goulding) <[email protected]>
2 parents c2d8371 + 13a1f9c commit f32c85d

File tree

21 files changed

+636
-82
lines changed

21 files changed

+636
-82
lines changed

.gitignore

Lines changed: 3 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -1,5 +1,6 @@
11
/target
22
.cargo
3+
.vscode/
34

45
# compiled output
56
/dist
@@ -21,3 +22,5 @@ yarn-error.log
2122
testem.log
2223
.env
2324
docker-compose.override.yml
25+
*~
26+

Cargo.lock

Lines changed: 22 additions & 0 deletions
Some generated files are not rendered by default. Learn more about customizing how changed files appear on GitHub.

Cargo.toml

Lines changed: 1 addition & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -47,6 +47,7 @@ dotenv = "0.11.0"
4747
toml = "0.4"
4848
diesel = { version = "1.3.0", features = ["postgres", "serde_json", "chrono", "r2d2"] }
4949
diesel_full_text_search = "1.0.0"
50+
diesel_ltree = "0.1.3"
5051
serde_json = "1.0.0"
5152
serde_derive = "1.0.0"
5253
serde = "1.0.0"

app/models/category.js

Lines changed: 1 addition & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -8,6 +8,7 @@ export default DS.Model.extend({
88
crates_cnt: DS.attr('number'),
99

1010
subcategories: DS.attr(),
11+
parent_categories: DS.attr(),
1112

1213
crates: DS.hasMany('crate', { async: true }),
1314
});

app/templates/category/index.hbs

Lines changed: 5 additions & 2 deletions
Original file line numberDiff line numberDiff line change
@@ -1,8 +1,11 @@
11
{{ title category.category ' - Categories' }}
22

33
<div id='crates-heading'>
4-
{{svg-jar "crate"}}
5-
<h1>{{ category.category }}</h1>
4+
{{#link-to "categories" (html-attributes aria-label="Categories")}}{{svg-jar "crate"}}{{/link-to}}
5+
<h1>
6+
{{#each category.parent_categories as |parent|}}{{link-to parent.category "category" parent.slug}}::{{/each}}
7+
{{~ category.category }}
8+
</h1>
69
</div>
710

811
<div>

diesel.toml

Lines changed: 1 addition & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -3,5 +3,5 @@
33
[print_schema]
44
file = "src/schema.rs"
55
with_docs = true
6-
import_types = ["diesel::sql_types::*", "diesel_full_text_search::{TsVector as Tsvector}"]
6+
import_types = ["diesel::sql_types::*", "diesel_full_text_search::{TsVector as Tsvector}", "diesel_ltree::Ltree"]
77
patch_file = "src/schema.patch"
Lines changed: 14 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,14 @@
1+
-- This file should undo anything in `up.sql`
2+
DROP TRIGGER set_category_path_update ON categories;
3+
4+
DROP TRIGGER set_category_path_insert ON categories;
5+
6+
DROP FUNCTION IF EXISTS set_category_path_to_slug();
7+
8+
DROP INDEX path_categories_idx;
9+
DROP INDEX path_gist_categories_idx;
10+
11+
ALTER TABLE categories
12+
DROP COLUMN path;
13+
14+
DROP EXTENSION ltree;
Lines changed: 40 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,40 @@
1+
-- Your SQL goes here
2+
CREATE EXTENSION ltree;
3+
4+
-- Create the new column which will represent our category tree.
5+
-- Fill it with values from `slug` column and then set to non-null
6+
ALTER TABLE categories
7+
ADD COLUMN path ltree;
8+
9+
-- Unfortunately, hyphens (dashes) are not allowed...
10+
UPDATE categories
11+
SET path = text2ltree('root.' || trim(replace(replace(slug, '-', '_'), '::', '.')))
12+
WHERE path is NULL;
13+
14+
ALTER TABLE CATEGORIES
15+
ALTER COLUMN path SET NOT NULL;
16+
17+
-- Create some indices that allow us to use GIST operators: '@>', etc
18+
CREATE INDEX path_gist_categories_idx ON categories USING GIST(path);
19+
CREATE INDEX path_categories_idx ON categories USING btree(path);
20+
21+
-- Create procedure and trigger to auto-update path
22+
CREATE OR REPLACE FUNCTION set_category_path_to_slug()
23+
RETURNS trigger AS
24+
$BODY$
25+
BEGIN
26+
NEW.path = text2ltree('root.' || trim(replace(replace(NEW.slug, '-', '_'), '::', '.')));
27+
RETURN NEW;
28+
END;
29+
$BODY$ LANGUAGE plpgsql;
30+
31+
CREATE TRIGGER set_category_path_insert
32+
BEFORE INSERT
33+
ON categories
34+
FOR EACH ROW
35+
EXECUTE PROCEDURE set_category_path_to_slug();
36+
37+
CREATE TRIGGER set_category_path_update
38+
BEFORE UPDATE OF slug ON categories
39+
FOR EACH ROW
40+
EXECUTE PROCEDURE set_category_path_to_slug();

0 commit comments

Comments
 (0)