Skip to content

Commit 0e442d8

Browse files
authored
Merge pull request #240 from UW-Macrostrat/schema-updates
Schema updates
2 parents 4bec91e + 9996c0a commit 0e442d8

File tree

8 files changed

+157
-29
lines changed

8 files changed

+157
-29
lines changed
Lines changed: 29 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,29 @@
1+
DO $$
2+
DECLARE
3+
_core_project_id integer;
4+
BEGIN
5+
6+
INSERT INTO macrostrat.projects (id, project, descrip, timescale_id, is_composite, slug)
7+
VALUES
8+
(
9+
14,
10+
'Core columns',
11+
'The "best available" default set of regional columns, composited from other datasets.',
12+
1,
13+
TRUE,
14+
'core'
15+
)
16+
ON CONFLICT (id) DO NOTHING;
17+
18+
SELECT id INTO _core_project_id
19+
FROM macrostrat.projects
20+
WHERE slug = 'core';
21+
22+
INSERT INTO macrostrat.projects_tree (parent_id, child_id)
23+
SELECT _core_project_id, id
24+
FROM macrostrat.projects p
25+
WHERE p.slug IN ('north-america', 'caribbean', 'south-america', 'africa', 'eodp')
26+
ON CONFLICT DO NOTHING;
27+
28+
END;
29+
$$ LANGUAGE plpgsql;

cli/macrostrat/cli/database/migrations/api_v3/__init__.py

Lines changed: 1 addition & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -12,7 +12,7 @@ class BaselineMigration(Migration):
1212
readiness_state = "ga"
1313
# Confirm that the tables created by the API v3 migrations are present
1414
postconditions = [
15-
exists("storage", "object_group", "object"),
15+
exists("storage", "object"),
1616
exists("maps_metadata", "ingest_process", "ingest_process_tag"),
1717
exists("macrostrat_auth", "user", "group"),
1818
]

cli/macrostrat/cli/database/migrations/column_builder/00-view-drops.sql

Lines changed: 4 additions & 3 deletions
Original file line numberDiff line numberDiff line change
@@ -2,7 +2,10 @@
22
Drop all views so they can be recreated.
33
TODO: automate this process.
44
*/
5-
DROP VIEW IF EXISTS macrostrat_api.projects;
5+
DROP VIEW IF EXISTS macrostrat_api.units CASCADE;
6+
DROP VIEW IF EXISTS macrostrat_api.unit_liths CASCADE;
7+
DROP VIEW IF EXISTS macrostrat_api.projects CASCADE;
8+
DROP VIEW IF EXISTS macrostrat_api.autocomplete CASCADE;
69
DROP VIEW IF EXISTS macrostrat_api.cols;
710
DROP VIEW IF EXISTS macrostrat_api.col_groups;
811
DROP VIEW IF EXISTS macrostrat_api.environs;
@@ -11,10 +14,8 @@ DROP VIEW IF EXISTS macrostrat_api.intervals;
1114
DROP VIEW IF EXISTS macrostrat_api.timescales;
1215
DROP VIEW IF EXISTS macrostrat_api.strat_tree;
1316
DROP VIEW IF EXISTS macrostrat_api.refs;
14-
DROP VIEW IF EXISTS macrostrat_api.units;
1517
DROP VIEW IF EXISTS macrostrat_api.col_refs;
1618
DROP VIEW IF EXISTS macrostrat_api.unit_environs;
17-
DROP VIEW IF EXISTS macrostrat_api.unit_liths;
1819
DROP VIEW IF EXISTS macrostrat_api.sections;
1920
DROP VIEW IF EXISTS macrostrat_api.strat_names;
2021
DROP VIEW IF EXISTS macrostrat_api.unit_strat_names;
Lines changed: 50 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,50 @@
1+
from pathlib import Path
2+
3+
from macrostrat.core.migrations import Migration, _not, exists, has_columns
4+
5+
6+
def check_slug_not_nullable(db):
7+
result = db.run_query(
8+
"""
9+
SELECT is_nullable::boolean
10+
FROM information_schema.columns
11+
WHERE table_schema = 'macrostrat'
12+
AND table_name = 'projects'
13+
AND column_name = 'slug';
14+
"""
15+
).one_or_none()
16+
if result is None:
17+
return False
18+
return not result.is_nullable
19+
20+
21+
success = [
22+
has_columns("macrostrat", "projects", "is_composite", "slug"),
23+
exists("macrostrat", "projects_tree"),
24+
# Slug is not nullable
25+
check_slug_not_nullable,
26+
]
27+
28+
here = Path(__file__).parent
29+
30+
31+
class CompositeProjects(Migration):
32+
name = "composite-projects"
33+
subsystem = "columns"
34+
description = "Composite projects support"
35+
preconditions = [_not(a) for a in success]
36+
postconditions = success
37+
fixtures = [
38+
here / "projects-evolution.sql",
39+
]
40+
41+
42+
class CompositeProjectFunctions(Migration):
43+
name = "composite-projects-functions"
44+
subsystem = "columns"
45+
description = "Composite projects functions"
46+
depends_on = ["composite-projects"]
47+
always_apply = True
48+
fixtures = [
49+
here / "project-functions.sql",
50+
]
Lines changed: 23 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,23 @@
1+
/** Recursive function to get all descendant project IDs **/
2+
CREATE OR REPLACE FUNCTION macrostrat.flattened_project_ids(project_ids integer[]) RETURNS integer[] AS $$
3+
DECLARE
4+
result_ids integer[] := ARRAY[]::integer[];
5+
current_ids integer[] := project_ids;
6+
child_ids integer[];
7+
BEGIN
8+
LOOP
9+
EXIT WHEN array_length(current_ids, 1) IS NULL;
10+
result_ids := result_ids || current_ids;
11+
SELECT array_agg(pt.child_id)
12+
INTO child_ids
13+
FROM macrostrat.projects_tree pt
14+
WHERE pt.parent_id = ANY(current_ids);
15+
current_ids := child_ids;
16+
END LOOP;
17+
RETURN ARRAY(SELECT DISTINCT unnest(result_ids));
18+
END;
19+
$$ LANGUAGE plpgsql STABLE;
20+
21+
CREATE OR REPLACE FUNCTION macrostrat.core_project_ids() RETURNS integer[] AS $$
22+
SELECT macrostrat.flattened_project_ids(ARRAY[id]) FROM macrostrat.projects WHERE slug = 'core';
23+
$$ LANGUAGE sql STABLE;
Lines changed: 44 additions & 24 deletions
Original file line numberDiff line numberDiff line change
@@ -1,19 +1,33 @@
1+
ALTER SCHEMA macrostrat OWNER TO macrostrat;
2+
3+
DROP VIEW IF EXISTS macrostrat_api.projects;
4+
DROP VIEW IF EXISTS macrostrat_api.col_group_with_cols;
5+
DROP VIEW IF EXISTS macrostrat_api.autocomplete CASCADE;
6+
7+
-- Alter project name to text
8+
ALTER TABLE macrostrat.projects ALTER COLUMN project TYPE TEXT USING project::TEXT;
9+
10+
-- drop custom type
11+
DROP TYPE IF EXISTS macrostrat.projects_project;
112

2-
ALTER TABLE macrostrat.projects ADD COLUMN IF NOT EXISTS is_composite BOOLEAN DEFAULT FALSE;
313

14+
ALTER TABLE macrostrat.projects ADD COLUMN IF NOT EXISTS is_composite BOOLEAN DEFAULT FALSE;
15+
/** Take the opportunity to add a slug for nicer URLs **/
16+
ALTER TABLE macrostrat.projects ADD COLUMN IF NOT EXISTS slug TEXT UNIQUE;
417

5-
CREATE TABLE IF NOT EXISTS macrostrat.project_composite (
18+
CREATE TABLE IF NOT EXISTS macrostrat.projects_tree (
619
id integer PRIMARY KEY GENERATED ALWAYS AS IDENTITY,
7-
parent_project_id integer REFERENCES macrostrat.projects(id) ON DELETE CASCADE,
8-
child_project_id integer REFERENCES macrostrat.projects(id) ON DELETE CASCADE,
9-
UNIQUE (parent_project_id, child_project_id)
20+
parent_id integer NOT NULL REFERENCES macrostrat.projects(id) ON DELETE CASCADE ON UPDATE CASCADE,
21+
child_id integer NOT NULL REFERENCES macrostrat.projects(id) ON DELETE CASCADE ON UPDATE CASCADE,
22+
UNIQUE (parent_id, child_id)
1023
);
24+
ALTER TABLE macrostrat.projects_tree OWNER TO macrostrat;
1125

1226
-- Ensure that only composite projects can be parent of other projects
1327
CREATE OR REPLACE FUNCTION macrostrat.check_composite_parent()
1428
RETURNS TRIGGER AS $$
1529
BEGIN
16-
IF NOT (SELECT is_composite FROM macrostrat.projects WHERE id = NEW.parent_project_id) THEN
30+
IF NOT (SELECT is_composite FROM macrostrat.projects WHERE id = NEW.parent_id) THEN
1731
RAISE EXCEPTION 'Parent project must be a composite project';
1832
END IF;
1933
RETURN NEW;
@@ -22,7 +36,7 @@ $$ LANGUAGE plpgsql;
2236

2337
-- Create the trigger on the project_composite table
2438
CREATE TRIGGER trg_check_composite_parent
25-
BEFORE INSERT OR UPDATE ON macrostrat.project_composite
39+
BEFORE INSERT OR UPDATE ON macrostrat.projects_tree
2640
FOR EACH ROW EXECUTE FUNCTION macrostrat.check_composite_parent();
2741

2842
/**
@@ -46,28 +60,34 @@ CREATE TRIGGER trg_check_column_project_non_composite
4660
BEFORE INSERT OR UPDATE ON macrostrat.cols
4761
FOR EACH ROW EXECUTE FUNCTION macrostrat.check_column_project_non_composite();
4862

49-
50-
/** Take the opportunity to add a slug for nicer URLs **/
51-
ALTER TABLE macrostrat.projects ADD COLUMN IF NOT EXISTS slug TEXT UNIQUE;
52-
53-
/** Function to generate slugs from project names **/
54-
CREATE OR REPLACE FUNCTION macrostrat.generate_project_slug()
55-
RETURNS VOID AS $$
63+
DROP FUNCTION IF EXISTS macrostrat.generate_project_slug(macrostrat.projects);
64+
CREATE OR REPLACE FUNCTION macrostrat.generate_project_slug(_project macrostrat.projects)
65+
RETURNS TEXT AS $$
5666
DECLARE
57-
proj RECORD;
5867
base_slug TEXT;
5968
unique_slug TEXT;
6069
suffix INT;
6170
BEGIN
62-
FOR proj IN SELECT id, name FROM macrostrat.projects WHERE slug IS NULL LOOP
63-
base_slug := lower(regexp_replace(proj.name, '[^a-zA-Z0-9]+', '-', 'g'));
64-
unique_slug := base_slug;
65-
suffix := 1;
66-
WHILE EXISTS (SELECT 1 FROM macrostrat.projects WHERE slug = unique_slug) LOOP
67-
suffix := suffix + 1;
68-
unique_slug := base_slug || '-' || suffix;
69-
END LOOP;
70-
UPDATE macrostrat.projects SET slug = unique_slug WHERE id = proj.id;
71+
base_slug := lower(regexp_replace(_project.project, '[^a-zA-Z0-9]+', '-', 'g'));
72+
unique_slug := base_slug;
73+
suffix := 1;
74+
WHILE EXISTS (SELECT 1 FROM macrostrat.projects p WHERE p.slug = unique_slug AND p.id != _project.id) LOOP
75+
suffix := suffix + 1;
76+
unique_slug := base_slug || '-' || suffix;
7177
END LOOP;
78+
RETURN unique_slug;
7279
END;
7380
$$ LANGUAGE plpgsql;
81+
82+
/** Generate slugs from existing projects **/
83+
UPDATE macrostrat.projects p
84+
SET slug = macrostrat.generate_project_slug(p)
85+
WHERE slug IS NULL;
86+
87+
-- Set slug column to NOT NULL
88+
ALTER TABLE macrostrat.projects ALTER COLUMN slug SET NOT NULL;
89+
90+
91+
-- Create an index on the slug column for faster lookups
92+
CREATE INDEX IF NOT EXISTS idx_projects_slug ON macrostrat.projects(slug);
93+

cli/macrostrat/cli/database/migrations/file_storage_updates/__init__.py

Lines changed: 1 addition & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -13,7 +13,7 @@ class MapFiles(Migration):
1313
postconditions = [
1414
# storage.object no longer has object_group_id
1515
# intersection table exists in storage schema
16-
exists("storage", "map_files"),
16+
exists("maps_metadata", "map_files"),
1717
# intersection table columns exist
1818
has_columns(
1919
"maps_metadata",

core/macrostrat/core/migrations/__init__.py

Lines changed: 5 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -230,6 +230,9 @@ class Migration:
230230

231231
output_mode: OutputMode = OutputMode.SUMMARY
232232

233+
def __init__(self):
234+
pass
235+
233236
def should_apply(self, database: Database) -> ApplicationStatus:
234237
"""Determine whether this migration can run, or has already run."""
235238
if self.always_apply:
@@ -509,6 +512,8 @@ def _run_migrations(
509512

510513
# Hack to allow migrations to follow output mode
511514
_migration.output_mode = output_mode
515+
516+
print(f"\nApplying migration [bold cyan]{_name}[/]...")
512517
_migration.apply(db)
513518
run_counter += 1
514519
# After running migration, reload the database and confirm that application was sucessful

0 commit comments

Comments
 (0)