Skip to content

Commit 091116b

Browse files
committed
Add DB migration for adding and filling in term_ids, constructor_ids and type_ids
1 parent aaa745c commit 091116b

File tree

1 file changed

+141
-0
lines changed

1 file changed

+141
-0
lines changed
Lines changed: 141 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,141 @@
1+
-- Name lookup tables were created before the new PG schema, so they don't actually link in term ids, type ids, or
2+
-- constructor ids. It'll help us join over things if we use the proper foreign keys here.
3+
4+
-- === First the term name lookup: ===
5+
6+
-- Adds term_id and constructor_id to scoped_term_name_lookup.
7+
-- Each row must have exactly one of term_id or constructor_id set.
8+
-- We add a constraint to enforce it.
9+
BEGIN;
10+
ALTER TABLE scoped_term_name_lookup
11+
ADD COLUMN term_id INTEGER NULL REFERENCES terms(id) ON DELETE CASCADE,
12+
ADD COLUMN constructor_id INTEGER NULL REFERENCES constructors(id) ON DELETE CASCADE;
13+
14+
15+
-- === Now the type name lookup: ===
16+
17+
-- Adds type_id to scoped_type_name_lookup
18+
ALTER TABLE scoped_type_name_lookup
19+
ADD COLUMN type_id INTEGER NULL REFERENCES types(id) ON DELETE CASCADE;
20+
21+
-- Replace the old name lookup builder with one that inserts the new columns.
22+
CREATE OR REPLACE FUNCTION add_name_lookup_definitions_at_namespace(root_namespace_hash_id INTEGER, namespace_path TEXT, reversed_namespace_path TEXT, current_namespace_hash_id INTEGER) RETURNS VOID AS $$
23+
BEGIN
24+
INSERT INTO scoped_term_name_lookup(root_branch_hash_id,
25+
reversed_name,
26+
last_name_segment,
27+
namespace,
28+
referent_builtin,
29+
referent_component_hash_id,
30+
referent_component_index,
31+
referent_constructor_index,
32+
referent_constructor_type,
33+
term_id,
34+
constructor_id
35+
)
36+
SELECT root_namespace_hash_id,
37+
n_term_name_segment.text || '.' || reversed_namespace_path,
38+
n_term_name_segment.text,
39+
namespace_path,
40+
builtin.text,
41+
COALESCE(term.component_hash_id, constructor_type.component_hash_id),
42+
COALESCE(term.component_index, constructor_type.component_index),
43+
constr.constructor_index,
44+
CASE
45+
WHEN constructor_type.kind = 'data' THEN 0
46+
WHEN constructor_type.kind = 'ability' THEN 1
47+
ELSE NULL
48+
END,
49+
n_term.term_id,
50+
n_term.constructor_id
51+
52+
FROM namespace_terms n_term
53+
JOIN text n_term_name_segment ON n_term.name_segment_id = n_term_name_segment.id
54+
LEFT JOIN text builtin ON n_term.builtin_id = builtin.id
55+
LEFT JOIN terms term ON n_term.term_id = term.id
56+
LEFT JOIN constructors constr ON n_term.constructor_id = constr.id
57+
LEFT JOIN types constructor_type ON constr.type_id = constructor_type.id
58+
WHERE n_term.namespace_hash_id = current_namespace_hash_id;
59+
60+
INSERT INTO scoped_type_name_lookup(root_branch_hash_id,
61+
reversed_name,
62+
last_name_segment,
63+
namespace,
64+
reference_builtin,
65+
reference_component_hash_id,
66+
reference_component_index,
67+
type_id
68+
)
69+
SELECT root_namespace_hash_id,
70+
n_typ_name_segment.text || '.' || reversed_namespace_path,
71+
n_typ_name_segment.text,
72+
namespace_path,
73+
builtin.text,
74+
typ.component_hash_id,
75+
typ.component_index,
76+
n_typ.type_id
77+
FROM namespace_types n_typ
78+
JOIN text n_typ_name_segment ON n_typ.name_segment_id = n_typ_name_segment.id
79+
LEFT JOIN text builtin ON n_typ.builtin_id = builtin.id
80+
LEFT JOIN types typ ON n_typ.type_id = typ.id
81+
WHERE n_typ.namespace_hash_id = current_namespace_hash_id;
82+
END;
83+
$$ LANGUAGE plpgsql;
84+
-- Commit table changes quickly so we don't block transactions.
85+
COMMIT;
86+
87+
-- Fill in the new columns with the appropriate values.
88+
BEGIN;
89+
UPDATE scoped_term_name_lookup AS nl
90+
SET term_id = (SELECT t.id FROM terms t
91+
WHERE t.component_hash_id = nl.referent_component_hash_id
92+
AND t.component_index = nl.referent_component_index
93+
),
94+
constructor_id = (SELECT c.id
95+
FROM constructors c
96+
JOIN types typ ON c.type_id = typ.id
97+
WHERE typ.component_hash_id = nl.referent_component_hash_id
98+
AND typ.component_index = nl.referent_component_index
99+
AND c.constructor_index = nl.referent_constructor_index
100+
);
101+
COMMIT;
102+
103+
104+
105+
-- Fill in the new column with the appropriate values.
106+
BEGIN;
107+
UPDATE scoped_type_name_lookup AS nl
108+
SET type_id = (SELECT typ.id FROM types typ
109+
WHERE typ.component_hash_id = nl.reference_component_hash_id
110+
AND typ.component_index = nl.reference_component_index
111+
);
112+
COMMIT;
113+
114+
115+
116+
-- === Now we add constraints and indexes to the new columns: ===
117+
118+
-- Each row must be either a term or constructor, so one of term_id or constructor_id must be set, OR it must be a builtin.
119+
BEGIN;
120+
ALTER TABLE scoped_term_name_lookup
121+
ADD CONSTRAINT term_or_constructor_or_builtin CHECK (
122+
(term_id IS NOT NULL AND constructor_id IS NULL AND referent_builtin IS NULL) OR
123+
(term_id IS NULL AND constructor_id IS NOT NULL AND referent_builtin IS NULL) OR
124+
(term_id IS NULL AND constructor_id IS NULL AND referent_builtin IS NOT NULL)
125+
);
126+
127+
-- We should really have _some_ unique index for this table.
128+
-- Each root should only have a single row for a given name <-> definition pair
129+
CREATE UNIQUE INDEX scoped_term_name_lookup_unique ON scoped_term_name_lookup(root_branch_hash_id, reversed_name, term_id, constructor_id, referent_builtin) NULLS NOT DISTINCT;
130+
131+
-- Each row must have a corresponding type_id set, OR it must be a builtin.
132+
ALTER TABLE scoped_type_name_lookup
133+
ADD CONSTRAINT type_or_builtin CHECK (
134+
(type_id IS NOT NULL AND reference_builtin IS NULL) OR
135+
(type_id IS NULL AND reference_builtin IS NOT NULL)
136+
);
137+
138+
-- We should really have _some_ unique index for this table.
139+
-- Each root should only have a single row for a given name <-> definition pair
140+
CREATE UNIQUE INDEX scoped_type_name_lookup_key ON scoped_type_name_lookup(root_branch_hash_id, reversed_name, type_id, reference_builtin) NULLS NOT DISTINCT;
141+
COMMIT;

0 commit comments

Comments
 (0)