Skip to content

Commit 399d78f

Browse files
committed
COPY/MOVE
1 parent 551bd43 commit 399d78f

File tree

2 files changed

+35
-4
lines changed

2 files changed

+35
-4
lines changed

MP COPY Subtrees.md

Lines changed: 17 additions & 2 deletions
Original file line numberDiff line numberDiff line change
@@ -6,10 +6,15 @@ parent: Materialized Paths
66
permalink: /mat-paths/copy
77
---
88

9-
The current convention for the COPY operation is to copy category subtrees only for each input category, but no category-item assignment. This convention simplifies the script
9+
The current convention for the COPY operation is to copy category subtrees only for each input category, but no category-item assignment. The core transformation step uses an RCTE loop discussed in the [RCTEs for Recursive Modify](../patterns/rcte-modify) section. Because the total number of existing category paths may be substantially higher than the number of affected paths, it is desirable to isolate the subset of affected paths. The *subtrees_old* CTE achieves this goal by matching the category path prefix against the *path_old* variable (*ops*).
10+
11+
Postprocessing involves several filtering steps. *LOOP_COPY* transforms the initial path set and labels new rows. The *subtrees_new_base* CTE filters out original paths and some of the possible duplicates among the newly created paths. The second step (*subtrees_path*) filters out all remaining duplicates. The final filtering stage (*subtrees_new*) removes already existing paths.
12+
13+
The rest of the code creates the remaining paths (the code is similar to the [CREATE Paths](./create) section).
1014

1115
~~~sql
1216
WITH RECURSIVE
17+
------------------------------ PROLOGUE ------------------------------
1318
json_ops(ops) AS (
1419
VALUES
1520
(json(
@@ -39,12 +44,16 @@ WITH RECURSIVE
3944
trim(json_extract(value, '$.path_new'), '/') AS rootpath_new
4045
FROM json_ops AS jo, json_each(jo.ops) AS terms
4146
),
47+
/********************************************************************/
48+
--------------------------- SUBTREES LIST ----------------------------
4249
subtrees_old AS (
4350
SELECT opid, ascii_id, path AS path_old
4451
FROM base_ops, categories
4552
WHERE path_old like rootpath_old || '%'
4653
ORDER BY opid, path_old
4754
),
55+
/********************************************************************/
56+
----------------------------- COPY LOOP ------------------------------
4857
LOOP_COPY AS (
4958
SELECT 0 AS opid, ascii_id, path_old AS path_new
5059
FROM subtrees_old
@@ -59,6 +68,7 @@ WITH RECURSIVE
5968
WHERE ops.opid = BUFFER.opid + 1
6069
AND BUFFER.path_new like rootpath_old || '%'
6170
),
71+
/********************************************************************/
6272
subtrees_new_base AS (
6373
SELECT ascii_id, path_new
6474
FROM LOOP_COPY
@@ -83,6 +93,7 @@ WITH RECURSIVE
8393
subtrees_new.*
8494
FROM subtrees_new
8595
),
96+
------------------------- ASCII ID GENERATOR -------------------------
8697
id_counts(id_counter) AS (SELECT count(*) FROM new_paths),
8798
json_templates AS (SELECT '[' || replace(hex(zeroblob(id_counter*8/2-1)), '0', '0,') || '0,0]' AS json_template FROM id_counts),
8899
char_templates(char_template) AS (VALUES ('-0123456789ABCDEFGHIJKLMNOPQRSTUVWXYZabcdefghijklmnopqrstuvwxyz_')),
@@ -103,7 +114,11 @@ WITH RECURSIVE
103114
(unicode(substr(ascii_id, 8, 1)) << 8*0) AS bin_id
104115
FROM ascii_ids
105116
),
106-
new_nodes AS (SELECT bin_id AS id, name_new AS name, prefix_new AS prefix FROM new_paths, ids USING (counter))
117+
/********************************************************************/
118+
new_nodes AS (
119+
SELECT bin_id AS id, name_new AS name, prefix_new AS prefix
120+
FROM new_paths, ids USING (counter)
121+
)
107122
INSERT INTO categories (id, name, prefix)
108123
SELECT * FROM new_nodes;
109124
~~~

MP MOVE Subtrees.md

Lines changed: 18 additions & 2 deletions
Original file line numberDiff line numberDiff line change
@@ -6,13 +6,20 @@ parent: Materialized Paths
66
permalink: /mat-paths/move
77
---
88

9+
The MOVE script moves/renames specified categories. The script also needs to handle associated items when necessary. For non-existing new paths, the database updates item associations automatically via foreign key cascades. However, when a collision occurs (existing new path), the scripts keeps one copy only (preferably the existing one), deleting the rest, and must update item associations explicitly before deletion. The current script updates the *files_categories* demo table and needs to be adjusted for actual association tables.
10+
11+
The core transformation step uses an RCTE loop discussed in the [RCTEs for Recursive Modify](../patterns/rcte-modify) section. The MOVE operation does not create new paths as opposed to the COPY operation, so the loop code is simplified. Because the total number of existing category paths may be substantially higher than the number of affected paths, it is desirable to isolate the subset of affected paths. The *subtrees_old* CTE achieves this goal by matching the category path prefix against the *path_old* variable (*ops*).
12+
13+
Postprocessing code includes two filters. The *subtrees_path* CTE matches the old and new paths and filters out unchanged categories. The *new_paths* CTE labels category rows for which path already exists in the *categories* table or duplicate *path_new* entries are present in the *subtrees_new_base*. The final set is used to update the *categories* table and associated relationship tables.
14+
915
~~~sql
1016
CREATE TEMP TABLE IF NOT EXISTS move_targets (
1117
ascii_id, path_old, path_new, prefix_new, name_new, target_exists
1218
);
1319
DELETE FROM temp.move_targets;
1420

1521
WITH RECURSIVE
22+
------------------------------ PROLOGUE ------------------------------
1623
json_ops(ops) AS (
1724
VALUES
1825
(json(
@@ -42,12 +49,16 @@ WITH RECURSIVE
4249
trim(json_extract(value, '$.path_new'), '/') AS rootpath_new
4350
FROM json_ops AS jo, json_each(jo.ops) AS terms
4451
),
52+
/********************************************************************/
53+
--------------------------- SUBTREES LIST ----------------------------
4554
subtrees_old AS (
4655
SELECT opid, ascii_id, path AS path_old
4756
FROM base_ops, categories
4857
WHERE path_old like rootpath_old || '%'
4958
ORDER BY opid, path_old
5059
),
60+
/********************************************************************/
61+
----------------------------- MOVE LOOP ------------------------------
5162
LOOP_MOVE AS (
5263
SELECT 0 AS opid, ascii_id, path_old AS path_new
5364
FROM subtrees_old
@@ -59,6 +70,7 @@ WITH RECURSIVE
5970
FROM LOOP_MOVE AS BUFFER, base_ops AS ops
6071
WHERE ops.opid = BUFFER.opid + 1
6172
),
73+
/********************************************************************/
6274
subtrees_new_base AS (
6375
SELECT ascii_id, path_new,
6476
json_extract('["' || replace(trim(path_new, '/'), '/', '", "') || '"]', '$[#-1]') AS name_new
@@ -86,13 +98,17 @@ SELECT * FROM new_paths ORDER BY target_exists, path_old;
8698
PRAGMA defer_foreign_keys = 1;
8799
SAVEPOINT "MOVE_CATS";
88100

101+
-- Collision-free category updates
89102
UPDATE categories SET (name, prefix) = (name_new, prefix_new)
90103
FROM temp.move_targets AS mvt
91-
WHERE mvt.path_old = categories.path AND mvt.target_exists = 0;
104+
WHERE mvt.target_exists = 0
105+
AND mvt.path_old = categories.path;
92106

107+
-- Update association tables
93108
UPDATE files_categories SET cat_id = path_new
94109
FROM temp.move_targets AS mvt
95-
WHERE mvt.path_old = cat_id;
110+
WHERE mvt.target_exists = 1
111+
AND mvt.path_old = cat_id;
96112

97113
DELETE FROM categories
98114
WHERE path IN (

0 commit comments

Comments
 (0)