Skip to content

Commit

Permalink
Merge pull request #1522 from cityofaustin/mike/19855_entities_update
Browse files Browse the repository at this point in the history
Update Moped entities to reflect reorganization
  • Loading branch information
mddilley authored Jan 16, 2025
2 parents 9f4c267 + 16976c5 commit 7615530
Show file tree
Hide file tree
Showing 9 changed files with 380 additions and 14 deletions.
21 changes: 12 additions & 9 deletions moped-database/metadata/tables.yaml
Original file line number Diff line number Diff line change
Expand Up @@ -1669,37 +1669,40 @@
- role: moped-admin
permission:
columns:
- date_added
- department_id
- entity_id
- organization_id
- workgroup_id
- entity_name
- date_added
- entity_uuid
- is_deleted
- organization_id
- workgroup_id
filter: {}
allow_aggregations: true
- role: moped-editor
permission:
columns:
- date_added
- department_id
- entity_id
- organization_id
- workgroup_id
- entity_name
- date_added
- entity_uuid
- is_deleted
- organization_id
- workgroup_id
filter: {}
allow_aggregations: true
- role: moped-viewer
permission:
columns:
- date_added
- department_id
- entity_id
- organization_id
- workgroup_id
- entity_name
- date_added
- entity_uuid
- is_deleted
- organization_id
- workgroup_id
filter: {}
allow_aggregations: true
- table:
Expand Down
Original file line number Diff line number Diff line change
@@ -0,0 +1,3 @@
-- Updating moped_entity table will be up only. If we need to revert, we will need do it manually or
-- update with a future migration.
SELECT 0;
251 changes: 251 additions & 0 deletions moped-database/migrations/1736442550315_update_entities/up.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,251 @@
-- Make is_deleted non-nullable in moped_workgroup and moped_department
ALTER TABLE moped_workgroup
ALTER COLUMN is_deleted SET NOT NULL;

ALTER TABLE moped_department
ALTER COLUMN is_deleted SET NOT NULL;

-- Add is_deleted to moped_entity
ALTER TABLE moped_entity
ADD COLUMN is_deleted BOOLEAN DEFAULT FALSE NOT NULL;


-- Soft delete the old entities
UPDATE moped_entity
SET is_deleted = TRUE
WHERE entity_name IN ('COA PWD Sidewalks & Special Projects', 'COA PWD Urban Trails', 'COA ATD', 'COA PWD');

-- Insert new COA TPW Sidewalks and Urban Trails entity with appropriate department_id, workgroup_id, and organization_id
WITH
workgroup AS (
SELECT workgroup_id
FROM
moped_workgroup
WHERE
workgroup_name = 'Sidewalks and Urban Trails'
),

organization AS (
SELECT organization_id
FROM
moped_organization
WHERE
organization_name = 'City of Austin'
),

department AS (
SELECT department_id
FROM
moped_department
WHERE
department_name = 'Austin Transportation and Public Works'
)

INSERT INTO
moped_entity (entity_name, department_id, workgroup_id, organization_id)
SELECT
'COA TPW Sidewalks and Urban Trails' AS entity_name,
department.department_id,
workgroup.workgroup_id,
organization.organization_id
FROM
department,
workgroup,
organization;

-- Insert new row for COA TPW with appropriate department_id and organization_id (no associated workgroup)
WITH organization AS (
SELECT organization_id FROM moped_organization WHERE organization_name = 'City of Austin'
),

department AS (
SELECT department_id FROM moped_department WHERE department_name = 'Austin Transportation and Public Works'
)

INSERT INTO moped_entity (entity_name, department_id, workgroup_id, organization_id, is_deleted)
SELECT
'COA TPW' AS entity_name,
department.department_id,
NULL AS workgroup_id,
organization.organization_id,
FALSE AS is_deleted
FROM department, organization;

-- Find any records (except the soft-deleted above) that have either ATD or PWD in them and replace with TPW
UPDATE moped_entity
SET
entity_name = REPLACE(REPLACE(entity_name, 'ATD', 'TPW'), 'PWD', 'TPW')
WHERE
(
entity_name LIKE '%ATD%'
OR entity_name LIKE '%PWD%'
)
AND (entity_name NOT IN ('COA PWD Sidewalks & Special Projects', 'COA PWD Urban Trails', 'COA ATD', 'COA PWD'));

-- UPDATE PROJECT SPONSORS

-- Find and update projects that need sponsor to be updated to COA TPW Sidewalks and Urban Trails
WITH project_sponsor_todos AS (
SELECT entity_id AS ids
FROM
moped_entity
WHERE
entity_name IN (
'COA PWD Sidewalks & Special Projects',
'COA PWD Urban Trails'
)
),

new_entity_row AS (
SELECT entity_id AS id
FROM
moped_entity
WHERE
entity_name = 'COA TPW Sidewalks and Urban Trails'
)

UPDATE
moped_project
SET
project_sponsor = (SELECT id FROM new_entity_row)
WHERE
project_sponsor IN (SELECT ids FROM project_sponsor_todos);

-- Find and update projects that need sponsor to be updated to COA TPW
WITH project_sponsor_todos AS (
SELECT entity_id AS ids
FROM
moped_entity
WHERE
entity_name IN (
'COA ATD',
'COA PWD'
)
),

new_entity_row AS (
SELECT entity_id AS id
FROM
moped_entity
WHERE
entity_name = 'COA TPW'
)

UPDATE
moped_project
SET
project_sponsor = (SELECT id FROM new_entity_row)
WHERE
project_sponsor IN (SELECT ids FROM project_sponsor_todos);

-- UPDATE PROJECT LEADS

-- Find and update projects that need lead to be updated to COA TPW Sidewalks and Urban Trails
WITH project_lead_todos AS (
SELECT entity_id AS ids
FROM
moped_entity
WHERE
entity_name IN (
'COA PWD Sidewalks & Special Projects',
'COA PWD Urban Trails'
)
),

new_entity_row AS (
SELECT entity_id AS id
FROM
moped_entity
WHERE
entity_name = 'COA TPW Sidewalks and Urban Trails'
)

UPDATE
moped_project
SET
project_lead_id = (SELECT id FROM new_entity_row)
WHERE
project_lead_id IN (SELECT ids FROM project_lead_todos);

-- Find and update projects that need lead to be updated to COA TPW
WITH project_lead_todos AS (
SELECT entity_id AS ids
FROM
moped_entity
WHERE
entity_name IN (
'COA ATD',
'COA PWD'
)
),

new_entity_row AS (
SELECT entity_id AS id
FROM
moped_entity
WHERE
entity_name = 'COA TPW'
)

UPDATE
moped_project
SET
project_lead_id = (SELECT id FROM new_entity_row)
WHERE
project_lead_id IN (SELECT ids FROM project_lead_todos);

-- UPDATE PROJECT PARTNERS

-- Find and update projects that need lead to be updated to COA TPW Sidewalks and Urban Trails
WITH project_partner_todos AS (
SELECT entity_id AS ids
FROM
moped_entity
WHERE
entity_name IN (
'COA PWD Sidewalks & Special Projects',
'COA PWD Urban Trails'
)
),

new_entity_row AS (
SELECT entity_id AS id
FROM
moped_entity
WHERE
entity_name = 'COA TPW Sidewalks and Urban Trails'
)

UPDATE
moped_proj_partners
SET
entity_id = (SELECT id FROM new_entity_row)
WHERE
entity_id IN (SELECT ids FROM project_partner_todos);

-- Find and update projects that need lead to be updated to COA TPW
WITH project_partner_todos AS (
SELECT entity_id AS ids
FROM
moped_entity
WHERE
entity_name IN (
'COA ATD',
'COA PWD'
)
),

new_entity_row AS (
SELECT entity_id AS id
FROM
moped_entity
WHERE
entity_name = 'COA TPW'
)

UPDATE
moped_proj_partners
SET
entity_id = (SELECT id FROM new_entity_row)
WHERE
entity_id IN (SELECT ids FROM project_partner_todos);
Original file line number Diff line number Diff line change
@@ -0,0 +1,26 @@
-- This example inserts the same moped_component_work_types work types as the Trail - Shared Use Path (Paved) component
-- into the new Trail - Shared Use Path (Paved Dual Trail) component.
-- This is useful when creating a new component that is similar to an existing component.
-- See https://github.com/cityofaustin/atd-moped/pull/1191
WITH inserts_todo AS (
SELECT
work_type_id,
'Trail' AS component_name,
'Shared Use Path (Paved Dual Trail)' AS component_subtype
FROM
moped_component_work_types AS mcwt
LEFT JOIN moped_work_types AS mwt ON mcwt.work_type_id = mwt.id
LEFT JOIN moped_components AS mc ON mcwt.component_id = mc.component_id
WHERE
mc.component_subtype LIKE 'Shared Use Path (Paved)'
)

INSERT INTO moped_component_work_types (component_id, work_type_id)
SELECT
mc.component_id,
inserts_todo.work_type_id
FROM
inserts_todo
-- gets the component id of the new component we created
LEFT JOIN moped_components AS mc ON inserts_todo.component_name = mc.component_name
AND inserts_todo.component_subtype = mc.component_subtype;
28 changes: 28 additions & 0 deletions moped-database/recipes/update_merged_funding_sources.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,28 @@
-- This example finds existing project funding sources that are associated with the sources that merged
-- and updates them to the new funding source.
-- See https://github.com/cityofaustin/atd-moped/pull/1486
WITH funding_source_todos AS (
SELECT funding_source_id AS ids
FROM
moped_fund_sources
WHERE
funding_source_name IN (
'Austin Transportation',
'Public Works'
)
),

new_funding_source_row AS (
SELECT funding_source_id AS id
FROM
moped_fund_sources
WHERE
funding_source_name = 'Austin Transportation and Public Works'
)

UPDATE
moped_proj_funding
SET
funding_source_id = (SELECT id FROM new_funding_source_row)
WHERE
funding_source_id IN (SELECT ids FROM funding_source_todos);
29 changes: 29 additions & 0 deletions moped-database/recipes/update_merged_workgroups.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,29 @@
-- This example finds all users who were previously in the 'Sidewalks' or 'Urban Trails' workgroups and sets their
-- workgroup to the new, merged workgroup called 'Sidewalks and Urban Trails'.
-- This is useful when merging workgroups and needing to update all users associated with the old workgroups.
-- See https://github.com/cityofaustin/atd-moped/pull/1515
WITH user_todos AS (
SELECT workgroup_id AS ids
FROM
moped_workgroup
WHERE
workgroup_name IN (
'Sidewalks',
'Urban Trails'
)
),

new_workgroup_row AS (
SELECT workgroup_id AS id
FROM
moped_workgroup
WHERE
workgroup_name = 'Sidewalks and Urban Trails'
)

UPDATE
moped_users
SET
workgroup_id = (SELECT id FROM new_workgroup_row)
WHERE
workgroup_id IN (SELECT ids FROM user_todos);
Loading

0 comments on commit 7615530

Please sign in to comment.