diff --git a/moped-database/metadata/tables.yaml b/moped-database/metadata/tables.yaml index dc62ed3719..92f5e640f5 100644 --- a/moped-database/metadata/tables.yaml +++ b/moped-database/metadata/tables.yaml @@ -945,6 +945,51 @@ set: updated_by_user_id: x-hasura-user-db-id comment: "" + event_triggers: + - name: activity_log_feature_school_beacons + definition: + enable_manual: false + insert: + columns: '*' + update: + columns: '*' + retry_conf: + interval_sec: 10 + num_retries: 0 + timeout_sec: 60 + webhook_from_env: HASURA_ENDPOINT + headers: + - name: x-hasura-admin-secret + value_from_env: ACTIVITY_LOG_API_SECRET + request_transform: + body: + action: transform + template: |- + { + "query": "mutation InsertActivity($object: moped_activity_log_insert_input!) { insert_moped_activity_log_one(object: $object) { activity_id } }", + "variables": { + "object": { + "record_id": {{ $body.event.data.new.id }}, + "record_type": {{ $body.table.name }}, + "activity_id": {{ $body.id }}, + "record_data": {"event": {{ $body.event }}}, + "description": [{"newSchema": "true"}], + "operation_type": {{ $body.event.op }}, + "updated_by_user_id": {{ $session_variables?['x-hasura-user-db-id'] ?? 1}} + } + } + } + method: POST + query_params: {} + template_engine: Kriti + version: 2 + cleanup_config: + batch_size: 10000 + clean_invocation_logs: false + clear_older_than: 168 + paused: true + schedule: 0 0 * * * + timeout: 60 - table: name: feature_signals schema: public diff --git a/moped-database/migrations/1726852807615_school_beacon_triggers/down.sql b/moped-database/migrations/1726852807615_school_beacon_triggers/down.sql new file mode 100644 index 0000000000..a485a7c0bc --- /dev/null +++ b/moped-database/migrations/1726852807615_school_beacon_triggers/down.sql @@ -0,0 +1,5 @@ +DROP TRIGGER IF EXISTS update_feature_school_beacons_council_district ON feature_school_beacons; + +DROP TRIGGER IF EXISTS feature_school_beacons_parent_audit_log_trigger ON feature_school_beacons; + +DROP TRIGGER IF EXISTS set_feature_school_beacons_updated_at ON feature_school_beacons; diff --git a/moped-database/migrations/1726852807615_school_beacon_triggers/up.sql b/moped-database/migrations/1726852807615_school_beacon_triggers/up.sql new file mode 100644 index 0000000000..4e8a664d9c --- /dev/null +++ b/moped-database/migrations/1726852807615_school_beacon_triggers/up.sql @@ -0,0 +1,20 @@ +CREATE TRIGGER update_feature_school_beacons_council_district BEFORE INSERT OR UPDATE ON +feature_school_beacons FOR EACH ROW EXECUTE FUNCTION update_council_district(); +COMMENT ON TRIGGER update_feature_school_beacons_council_district ON feature_school_beacons IS +'Trigger to insert record in feature_council_district table connecting feature_id with corresponding council district id'; + + +-- Trigger for feature_school_beacons table +CREATE TRIGGER feature_school_beacons_parent_audit_log_trigger +AFTER INSERT OR UPDATE ON feature_school_beacons +FOR EACH ROW +EXECUTE FUNCTION update_audit_fields_with_dynamic_parent_table_name("moped_proj_components", "project_component_id", "component_id"); +COMMENT ON TRIGGER feature_school_beacons_parent_audit_log_trigger ON feature_school_beacons IS 'Trigger to update parent project and component audit fields'; + + +CREATE TRIGGER set_feature_school_beacons_updated_at +BEFORE INSERT OR UPDATE ON feature_school_beacons +FOR EACH ROW +EXECUTE FUNCTION public.set_updated_at(); + +COMMENT ON TRIGGER set_feature_school_beacons_updated_at ON public.feature_school_beacons IS 'Trigger to set updated_at timestamp for each insert or update on feature_school_beacons'; diff --git a/moped-database/migrations/1727229291111_add_beacons_to_unified_features_view/down.sql b/moped-database/migrations/1727229291111_add_beacons_to_unified_features_view/down.sql new file mode 100644 index 0000000000..54e91b38db --- /dev/null +++ b/moped-database/migrations/1727229291111_add_beacons_to_unified_features_view/down.sql @@ -0,0 +1,127 @@ +DROP view IF EXISTS project_geography; +DROP view IF EXISTS uniform_features; + +CREATE OR REPLACE VIEW uniform_features AS + SELECT feature_signals.id, + feature_signals.component_id, + 'feature_signals'::text AS "table", + json_build_object('signal_id', feature_signals.signal_id, 'knack_id', feature_signals.knack_id, 'location_name', feature_signals.location_name, 'signal_type', feature_signals.signal_type) AS attributes, + feature_signals.geography, + districts.council_districts, + NULL::integer AS length_feet, + feature_signals.created_at, + feature_signals.updated_at, + feature_signals.created_by_user_id, + feature_signals.updated_by_user_id + FROM feature_signals + LEFT JOIN ( SELECT d.feature_id, + array_agg(d.council_district_id) AS council_districts + FROM features_council_districts d + GROUP BY d.feature_id) districts ON districts.feature_id = feature_signals.id + WHERE feature_signals.is_deleted = false +UNION ALL + SELECT feature_street_segments.id, + feature_street_segments.component_id, + 'feature_street_segments'::text AS "table", + json_build_object('ctn_segment_id', feature_street_segments.ctn_segment_id, 'from_address_min', feature_street_segments.from_address_min, 'to_address_max', feature_street_segments.to_address_max, 'full_street_name', feature_street_segments.full_street_name, 'line_type', feature_street_segments.line_type, 'symbol', feature_street_segments.symbol, 'source_layer', feature_street_segments.source_layer) AS attributes, + feature_street_segments.geography, + districts.council_districts, + feature_street_segments.length_feet, + feature_street_segments.created_at, + feature_street_segments.updated_at, + feature_street_segments.created_by_user_id, + feature_street_segments.updated_by_user_id + FROM feature_street_segments + LEFT JOIN ( SELECT d.feature_id, + array_agg(d.council_district_id) AS council_districts + FROM features_council_districts d + GROUP BY d.feature_id) districts ON districts.feature_id = feature_street_segments.id + WHERE feature_street_segments.is_deleted = false +UNION ALL + SELECT feature_intersections.id, + feature_intersections.component_id, + 'feature_intersections'::text AS "table", + json_build_object('intersection_id', feature_intersections.intersection_id, 'source_layer', feature_intersections.source_layer) AS attributes, + feature_intersections.geography, + districts.council_districts, + NULL::integer AS length_feet, + feature_intersections.created_at, + feature_intersections.updated_at, + feature_intersections.created_by_user_id, + feature_intersections.updated_by_user_id + FROM feature_intersections + LEFT JOIN ( SELECT d.feature_id, + array_agg(d.council_district_id) AS council_districts + FROM features_council_districts d + GROUP BY d.feature_id) districts ON districts.feature_id = feature_intersections.id + WHERE feature_intersections.is_deleted = false +UNION ALL + SELECT feature_drawn_points.id, + feature_drawn_points.component_id, + 'feature_drawn_points'::text AS "table", + NULL::json AS attributes, + feature_drawn_points.geography, + districts.council_districts, + NULL::integer AS length_feet, + feature_drawn_points.created_at, + feature_drawn_points.updated_at, + feature_drawn_points.created_by_user_id, + feature_drawn_points.updated_by_user_id + FROM feature_drawn_points + LEFT JOIN ( SELECT d.feature_id, + array_agg(d.council_district_id) AS council_districts + FROM features_council_districts d + GROUP BY d.feature_id) districts ON districts.feature_id = feature_drawn_points.id + WHERE feature_drawn_points.is_deleted = false +UNION ALL + SELECT feature_drawn_lines.id, + feature_drawn_lines.component_id, + 'feature_drawn_lines'::text AS "table", + NULL::json AS attributes, + feature_drawn_lines.geography, + districts.council_districts, + feature_drawn_lines.length_feet, + feature_drawn_lines.created_at, + feature_drawn_lines.updated_at, + feature_drawn_lines.created_by_user_id, + feature_drawn_lines.updated_by_user_id + FROM feature_drawn_lines + LEFT JOIN ( SELECT d.feature_id, + array_agg(d.council_district_id) AS council_districts + FROM features_council_districts d + GROUP BY d.feature_id) districts ON districts.feature_id = feature_drawn_lines.id + WHERE feature_drawn_lines.is_deleted = false; + +COMMENT ON VIEW uniform_features IS 'This view unifies various geographical feature data from multiple tables such as signals, street segments, intersections, drawn points, and lines. It provides a view of these features along with their attributes, geographic details, and council district associations.'; + +CREATE OR REPLACE VIEW project_geography AS ( + SELECT + moped_project.project_id, + uniform_features.id AS feature_id, + moped_components.component_id AS component_archtype_id, + moped_components.line_representation AS line_representation, + moped_proj_components.project_component_id AS component_id, + moped_proj_components.is_deleted, + moped_project.project_name, + feature_layers.internal_table AS "table", + feature_layers.reference_layer_primary_key_column AS original_fk, + moped_components.component_name, + uniform_features.attributes, + uniform_features.geography, + uniform_features.council_districts, + uniform_features.length_feet, + uniform_features.created_at AS feature_created_at, + uniform_features.updated_at AS feature_updated_at, + uniform_features.created_by_user_id AS feature_created_by_user_id, + uniform_features.updated_by_user_id AS feature_updated_by_user_id + FROM + moped_project + INNER JOIN moped_proj_components ON moped_project.project_id = moped_proj_components.project_id + INNER JOIN moped_components ON moped_proj_components.component_id = moped_components.component_id + INNER JOIN feature_layers ON moped_components.feature_layer_id = feature_layers.id + INNER JOIN uniform_features ON moped_proj_components.project_component_id = uniform_features.component_id + WHERE + moped_proj_components.is_deleted IS FALSE +); + +COMMENT ON VIEW public.project_geography IS 'The project_geography view merges project-specific data with the unified geographical features from the uniform_features view. It links projects with their respective geographical components, including type, attributes, and location.'; diff --git a/moped-database/migrations/1727229291111_add_beacons_to_unified_features_view/up.sql b/moped-database/migrations/1727229291111_add_beacons_to_unified_features_view/up.sql new file mode 100644 index 0000000000..267788aa0c --- /dev/null +++ b/moped-database/migrations/1727229291111_add_beacons_to_unified_features_view/up.sql @@ -0,0 +1,170 @@ +DROP VIEW IF EXISTS project_geography; +DROP VIEW IF EXISTS uniform_features; + +CREATE OR REPLACE VIEW uniform_features +AS SELECT + feature_signals.id, + feature_signals.component_id, + 'feature_signals'::text AS "table", + json_build_object('signal_id', feature_signals.signal_id, 'knack_id', feature_signals.knack_id, 'location_name', feature_signals.location_name, 'signal_type', feature_signals.signal_type) AS attributes, + feature_signals.geography, + districts.council_districts, + NULL::integer AS length_feet, + feature_signals.created_at, + feature_signals.updated_at, + feature_signals.created_by_user_id, + feature_signals.updated_by_user_id +FROM feature_signals LEFT JOIN + ( + SELECT + d.feature_id, + array_agg(d.council_district_id) AS council_districts + FROM features_council_districts AS d + GROUP BY d.feature_id + ) AS districts ON feature_signals.id = districts.feature_id +WHERE feature_signals.is_deleted = FALSE +UNION ALL +SELECT + feature_street_segments.id, + feature_street_segments.component_id, + 'feature_street_segments'::text AS "table", + json_build_object('ctn_segment_id', feature_street_segments.ctn_segment_id, 'from_address_min', feature_street_segments.from_address_min, 'to_address_max', feature_street_segments.to_address_max, 'full_street_name', feature_street_segments.full_street_name, 'line_type', feature_street_segments.line_type, 'symbol', feature_street_segments.symbol, 'source_layer', feature_street_segments.source_layer) AS attributes, + feature_street_segments.geography, + districts.council_districts, + feature_street_segments.length_feet, + feature_street_segments.created_at, + feature_street_segments.updated_at, + feature_street_segments.created_by_user_id, + feature_street_segments.updated_by_user_id +FROM feature_street_segments +LEFT JOIN ( + SELECT + d.feature_id, + array_agg(d.council_district_id) AS council_districts + FROM features_council_districts AS d + GROUP BY d.feature_id +) AS districts ON feature_street_segments.id = districts.feature_id +WHERE feature_street_segments.is_deleted = FALSE +UNION ALL +SELECT + feature_intersections.id, + feature_intersections.component_id, + 'feature_intersections'::text AS "table", + json_build_object('intersection_id', feature_intersections.intersection_id, 'source_layer', feature_intersections.source_layer) AS attributes, + feature_intersections.geography, + districts.council_districts, + NULL::integer AS length_feet, + feature_intersections.created_at, + feature_intersections.updated_at, + feature_intersections.created_by_user_id, + feature_intersections.updated_by_user_id +FROM feature_intersections +LEFT JOIN ( + SELECT + d.feature_id, + array_agg(d.council_district_id) AS council_districts + FROM features_council_districts AS d + GROUP BY d.feature_id +) AS districts ON feature_intersections.id = districts.feature_id +WHERE feature_intersections.is_deleted = FALSE +UNION ALL +SELECT + feature_drawn_points.id, + feature_drawn_points.component_id, + 'feature_drawn_points'::text AS "table", + NULL::json AS attributes, + feature_drawn_points.geography, + districts.council_districts, + NULL::integer AS length_feet, + feature_drawn_points.created_at, + feature_drawn_points.updated_at, + feature_drawn_points.created_by_user_id, + feature_drawn_points.updated_by_user_id +FROM feature_drawn_points +LEFT JOIN ( + SELECT + d.feature_id, + array_agg(d.council_district_id) AS council_districts + FROM features_council_districts AS d + GROUP BY d.feature_id +) AS districts ON feature_drawn_points.id = districts.feature_id +WHERE feature_drawn_points.is_deleted = FALSE +UNION ALL +SELECT + feature_drawn_lines.id, + feature_drawn_lines.component_id, + 'feature_drawn_lines'::text AS "table", + NULL::json AS attributes, + feature_drawn_lines.geography, + districts.council_districts, + feature_drawn_lines.length_feet, + feature_drawn_lines.created_at, + feature_drawn_lines.updated_at, + feature_drawn_lines.created_by_user_id, + feature_drawn_lines.updated_by_user_id +FROM feature_drawn_lines +LEFT JOIN ( + SELECT + d.feature_id, + array_agg(d.council_district_id) AS council_districts + FROM features_council_districts AS d + GROUP BY d.feature_id +) AS districts ON feature_drawn_lines.id = districts.feature_id +WHERE feature_drawn_lines.is_deleted = FALSE +UNION ALL +SELECT + feature_school_beacons.id, + feature_school_beacons.component_id, + 'feature_school_beacons'::text AS "table", + json_build_object('school_zone_beacon_id', feature_school_beacons.school_zone_beacon_id, 'knack_id', feature_school_beacons.knack_id, 'location_name', feature_school_beacons.location_name, 'zone_name', feature_school_beacons.zone_name, 'beacon_name', feature_school_beacons.beacon_name) AS attributes, + feature_school_beacons.geography, + districts.council_districts, + NULL::integer AS length_feet, + feature_school_beacons.created_at, + feature_school_beacons.updated_at, + feature_school_beacons.created_by_user_id, + feature_school_beacons.updated_by_user_id +FROM feature_school_beacons LEFT JOIN + ( + SELECT + d.feature_id, + array_agg(d.council_district_id) AS council_districts + FROM features_council_districts AS d + GROUP BY d.feature_id + ) AS districts ON feature_school_beacons.id = districts.feature_id +WHERE feature_school_beacons.is_deleted = FALSE; + +COMMENT ON VIEW uniform_features IS 'This view unifies various geographical feature data from multiple tables such as signals, street segments, intersections, drawn points, and lines. It provides a view of these features along with their attributes, geographic details, and council district associations.'; + +CREATE OR REPLACE VIEW project_geography AS ( + SELECT + moped_project.project_id, + uniform_features.id AS feature_id, + moped_components.component_id AS component_archtype_id, + moped_components.line_representation AS line_representation, + moped_proj_components.project_component_id AS component_id, + moped_proj_components.is_deleted, + moped_project.project_name, + feature_layers.internal_table AS "table", + feature_layers.reference_layer_primary_key_column AS original_fk, + moped_components.component_name, + uniform_features.attributes, + uniform_features.geography, + uniform_features.council_districts, + uniform_features.length_feet, + uniform_features.created_at AS feature_created_at, + uniform_features.updated_at AS feature_updated_at, + uniform_features.created_by_user_id AS feature_created_by_user_id, + uniform_features.updated_by_user_id AS feature_updated_by_user_id + FROM + moped_project + INNER JOIN moped_proj_components ON moped_project.project_id = moped_proj_components.project_id + INNER JOIN moped_components ON moped_proj_components.component_id = moped_components.component_id + INNER JOIN feature_layers ON moped_components.feature_layer_id = feature_layers.id + INNER JOIN uniform_features ON moped_proj_components.project_component_id = uniform_features.component_id + WHERE + moped_proj_components.is_deleted IS FALSE +); + + +COMMENT ON VIEW public.project_geography IS 'The project_geography view merges project-specific data with the unified geographical features from the uniform_features view. It links projects with their respective geographical components, including type, attributes, and location.'; diff --git a/moped-database/migrations/1727279529178_update_component_agol_view_school_beacons/down.sql b/moped-database/migrations/1727279529178_update_component_agol_view_school_beacons/down.sql new file mode 100644 index 0000000000..5d7125a94f --- /dev/null +++ b/moped-database/migrations/1727279529178_update_component_agol_view_school_beacons/down.sql @@ -0,0 +1,245 @@ +DROP VIEW IF EXISTS exploded_component_arcgis_online_view; +DROP VIEW IF EXISTS component_arcgis_online_view; + +-- Update arguments of get_project_development_status() and get_project_development_status_date() to consider component-level phase name simple +CREATE OR REPLACE VIEW component_arcgis_online_view AS WITH work_types AS ( + SELECT + mpcwt.project_component_id, + string_agg(mwt.name, ', '::text) AS work_types + FROM moped_proj_component_work_types AS mpcwt + LEFT JOIN moped_work_types AS mwt ON mpcwt.work_type_id = mwt.id + WHERE mpcwt.is_deleted = false + GROUP BY mpcwt.project_component_id +), + +council_districts AS ( + SELECT + features.component_id AS project_component_id, + string_agg(DISTINCT features_council_districts.council_district_id::text, ', '::text) AS council_districts, + string_agg(DISTINCT lpad(features_council_districts.council_district_id::text, 2, '0'::text), ', '::text) AS council_districts_searchable + FROM features_council_districts + LEFT JOIN features ON features_council_districts.feature_id = features.id + WHERE features.is_deleted = false + GROUP BY features.component_id +), + +comp_geography AS ( + SELECT + feature_union.component_id AS project_component_id, + string_agg(DISTINCT feature_union.id::text, ', '::text) AS feature_ids, + st_asgeojson(st_union(array_agg(feature_union.geography)))::json AS geometry, + st_asgeojson(st_union(array_agg(feature_union.line_geography)))::json AS line_geometry, + string_agg(DISTINCT feature_union.signal_id::text, ', '::text) AS signal_ids, + sum(feature_union.length_feet) AS length_feet_total + FROM ( + SELECT + feature_signals.id, + feature_signals.component_id, + feature_signals.geography::geometry AS geography, + st_exteriorring(st_buffer(feature_signals.geography, 7::double precision)::geometry) AS line_geography, + feature_signals.signal_id, + null::integer AS length_feet + FROM feature_signals + WHERE feature_signals.is_deleted = false + UNION ALL + SELECT + feature_street_segments.id, + feature_street_segments.component_id, + feature_street_segments.geography::geometry AS geography, + feature_street_segments.geography::geometry AS line_geography, + null::integer AS signal_id, + feature_street_segments.length_feet + FROM feature_street_segments + WHERE feature_street_segments.is_deleted = false + UNION ALL + SELECT + feature_intersections.id, + feature_intersections.component_id, + feature_intersections.geography::geometry AS geography, + st_exteriorring(st_buffer(feature_intersections.geography, 7::double precision)::geometry) AS line_geography, + null::integer AS signal_id, + null::integer AS length_feet + FROM feature_intersections + WHERE feature_intersections.is_deleted = false + UNION ALL + SELECT + feature_drawn_points.id, + feature_drawn_points.component_id, + feature_drawn_points.geography::geometry AS geography, + st_exteriorring(st_buffer(feature_drawn_points.geography, 7::double precision)::geometry) AS line_geography, + null::integer AS signal_id, + null::integer AS length_feet + FROM feature_drawn_points + WHERE feature_drawn_points.is_deleted = false + UNION ALL + SELECT + feature_drawn_lines.id, + feature_drawn_lines.component_id, + feature_drawn_lines.geography::geometry AS geography, + feature_drawn_lines.geography::geometry AS line_geography, + null::integer AS signal_id, + feature_drawn_lines.length_feet + FROM feature_drawn_lines + WHERE feature_drawn_lines.is_deleted = false + ) AS feature_union + GROUP BY feature_union.component_id +), + +subcomponents AS ( + SELECT + mpcs.project_component_id, + string_agg(ms.subcomponent_name, ', '::text) AS subcomponents + FROM moped_proj_components_subcomponents AS mpcs + LEFT JOIN moped_subcomponents AS ms ON mpcs.subcomponent_id = ms.subcomponent_id + WHERE mpcs.is_deleted = false + GROUP BY mpcs.project_component_id +), + +component_tags AS ( + SELECT + mpct.project_component_id, + string_agg((mct.type || ' - '::text) || mct.name, ', '::text) AS component_tags + FROM moped_proj_component_tags AS mpct + LEFT JOIN moped_component_tags AS mct ON mpct.component_tag_id = mct.id + WHERE mpct.is_deleted = false + GROUP BY mpct.project_component_id +), + +related_projects AS ( + SELECT + pmp.project_id, + concat_ws(', '::text, pmp.project_id, string_agg(cmp.project_id::text, ', '::text)) AS related_project_ids_with_self, + concat_ws(', '::text, lpad(pmp.project_id::text, 5, '0'::text), string_agg(lpad(cmp.project_id::text, 5, '0'::text), ', '::text)) AS related_project_ids_searchable_with_self + FROM moped_project AS pmp + LEFT JOIN moped_project AS cmp ON pmp.project_id = cmp.parent_project_id + WHERE cmp.is_deleted = false + GROUP BY pmp.project_id +), + +latest_public_meeting_date AS ( + SELECT + mpm.project_id, + coalesce(max(mpm.date_actual), max(mpm.date_estimate)) AS latest + FROM moped_proj_milestones AS mpm + WHERE mpm.milestone_id = 65 AND mpm.is_deleted = false + GROUP BY mpm.project_id +), + +earliest_active_or_construction_phase_date AS ( + SELECT + mpp.project_id, + min(mpp.phase_start) AS earliest + FROM moped_proj_phases AS mpp + LEFT JOIN moped_phases AS mp ON mpp.phase_id = mp.phase_id + WHERE (mp.phase_name_simple = any(ARRAY['Active'::text, 'Construction'::text])) AND mpp.is_deleted = false + GROUP BY mpp.project_id +) + +SELECT + mpc.project_id, + comp_geography.project_component_id, + comp_geography.feature_ids, + mpc.component_id, + comp_geography.geometry, + comp_geography.line_geometry, + comp_geography.signal_ids, + council_districts.council_districts, + council_districts.council_districts_searchable, + NOT coalesce(council_districts.council_districts IS null OR council_districts.council_districts = ''::text, false) AS is_within_city_limits, + comp_geography.length_feet_total, + round(comp_geography.length_feet_total::numeric / 5280::numeric, 2) AS length_miles_total, + mc.component_name, + mc.component_subtype, + mc.component_name_full, + 'placeholder text'::text AS component_categories, + subcomponents.subcomponents AS component_subcomponents, + work_types.work_types AS component_work_types, + component_tags.component_tags, + mpc.description AS component_description, + mpc.interim_project_component_id, + coalesce(mpc.completion_date, plv.substantial_completion_date) AS substantial_completion_date, + plv.substantial_completion_date_estimated, + mpc.srts_id, + mpc.location_description AS component_location_description, + plv.project_name, + plv.project_name_secondary, + plv.project_name_full, + plv.project_description, + plv.ecapris_subproject_id, + plv.project_website, + plv.updated_at AS project_updated_at, + mpc.phase_id AS component_phase_id, + mph.phase_name AS component_phase_name, + mph.phase_name_simple AS component_phase_name_simple, + current_phase.phase_id AS project_phase_id, + current_phase.phase_name AS project_phase_name, + current_phase.phase_name_simple AS project_phase_name_simple, + coalesce(mph.phase_name, current_phase.phase_name) AS current_phase_name, + coalesce(mph.phase_name_simple, current_phase.phase_name_simple) AS current_phase_name_simple, + plv.project_team_members, + plv.project_sponsor, + plv.project_lead, + plv.public_process_status, + plv.interim_project_id, + plv.project_partners, + plv.task_order_names, + plv.funding_source_name, + plv.funding_source_and_program_names AS funding_sources, + plv.type_name, + plv.project_status_update, + plv.project_status_update_date_created, + to_char(plv.construction_start_date AT TIME ZONE 'US/Central', 'YYYY-MM-DD'::text) AS construction_start_date, + plv.project_inspector, + plv.project_designer, + plv.project_tags, + plv.workgroup_contractors, + plv.contract_numbers, + plv.parent_project_id, + plv.parent_project_name, + plv.parent_project_url, + plv.parent_project_name AS parent_project_name_full, + rp.related_project_ids_with_self AS related_project_ids, + rp.related_project_ids_searchable_with_self AS related_project_ids_searchable, + plv.knack_project_id AS knack_data_tracker_project_record_id, + plv.project_url, + (plv.project_url || '?tab=map&project_component_id='::text) || mpc.project_component_id::text AS component_url, + get_project_development_status(lpmd.latest::timestamp with time zone, eaocpd.earliest, coalesce(mpc.completion_date, plv.substantial_completion_date), plv.substantial_completion_date_estimated, coalesce(mph.phase_name_simple, current_phase.phase_name_simple)) AS project_development_status, + project_development_status_date.result AS project_development_status_date, + to_char(project_development_status_date.result, 'YYYY')::integer AS project_development_status_date_calendar_year, -- noqa + to_char(project_development_status_date.result, 'FMMonth YYYY') AS project_development_status_date_calendar_year_month, -- noqa + to_char(project_development_status_date.result, 'YYYY-MM') AS project_development_status_date_calendar_year_month_numeric, -- noqa + extract(QUARTER FROM project_development_status_date.result)::text AS project_development_status_date_calendar_year_quarter, -- noqa + CASE WHEN extract(QUARTER FROM project_development_status_date.result) = 4 THEN (to_char(project_development_status_date.result, 'YYYY')::integer + 1)::text ELSE to_char(project_development_status_date.result, 'YYYY') END AS project_development_status_date_fiscal_year, -- noqa + CASE WHEN extract(QUARTER FROM project_development_status_date.result) = 4 THEN 1 ELSE extract(QUARTER FROM project_development_status_date.result) + 1 END::text AS project_development_status_date_fiscal_year_quarter, -- noqa + plv.added_by AS project_added_by +FROM moped_proj_components AS mpc +LEFT JOIN comp_geography ON mpc.project_component_id = comp_geography.project_component_id +LEFT JOIN council_districts ON mpc.project_component_id = council_districts.project_component_id +LEFT JOIN subcomponents ON mpc.project_component_id = subcomponents.project_component_id +LEFT JOIN work_types ON mpc.project_component_id = work_types.project_component_id +LEFT JOIN component_tags ON mpc.project_component_id = component_tags.project_component_id +LEFT JOIN project_list_view AS plv ON mpc.project_id = plv.project_id +LEFT JOIN current_phase_view AS current_phase ON mpc.project_id = current_phase.project_id +LEFT JOIN moped_phases AS mph ON mpc.phase_id = mph.phase_id +LEFT JOIN moped_components AS mc ON mpc.component_id = mc.component_id +LEFT JOIN related_projects AS rp ON mpc.project_id = rp.project_id +LEFT JOIN latest_public_meeting_date AS lpmd ON mpc.project_id = lpmd.project_id +LEFT JOIN earliest_active_or_construction_phase_date AS eaocpd ON mpc.project_id = eaocpd.project_id +LEFT JOIN LATERAL (SELECT get_project_development_status_date(lpmd.latest::timestamp with time zone, eaocpd.earliest, coalesce(mpc.completion_date, plv.substantial_completion_date), plv.substantial_completion_date_estimated, coalesce(mph.phase_name_simple, current_phase.phase_name_simple)) AT TIME ZONE 'US/Central' AS result) AS project_development_status_date ON true -- noqa +WHERE mpc.is_deleted = false AND plv.is_deleted = false; + +-- create exploded view +CREATE VIEW exploded_component_arcgis_online_view AS +SELECT + component_arcgis_online_view.project_id, + component_arcgis_online_view.project_component_id, + ST_GEOMETRYTYPE(dump.geom) AS geometry_type, + dump.path[1] AS point_index, -- ordinal value of the point in the MultiPoint geometry + component_arcgis_online_view.geometry AS original_geometry, + ST_ASGEOJSON(dump.geom) AS exploded_geometry, -- noqa: RF04 + component_arcgis_online_view.project_updated_at +FROM + component_arcgis_online_view, + LATERAL ST_DUMP(ST_GEOMFROMGEOJSON(component_arcgis_online_view.geometry)) AS dump -- noqa: RF04 +WHERE + ST_GEOMETRYTYPE(ST_GEOMFROMGEOJSON(component_arcgis_online_view.geometry)) = 'ST_MultiPoint'; diff --git a/moped-database/migrations/1727279529178_update_component_agol_view_school_beacons/up.sql b/moped-database/migrations/1727279529178_update_component_agol_view_school_beacons/up.sql new file mode 100644 index 0000000000..a996eff7fe --- /dev/null +++ b/moped-database/migrations/1727279529178_update_component_agol_view_school_beacons/up.sql @@ -0,0 +1,261 @@ +DROP VIEW IF EXISTS exploded_component_arcgis_online_view; +DROP VIEW IF EXISTS component_arcgis_online_view; + +CREATE OR REPLACE VIEW component_arcgis_online_view AS WITH +work_types AS ( + SELECT + mpcwt.project_component_id, + string_agg(mwt.name, ', '::text) AS work_types + FROM moped_proj_component_work_types AS mpcwt + LEFT JOIN moped_work_types AS mwt ON mpcwt.work_type_id = mwt.id + WHERE mpcwt.is_deleted = false + GROUP BY mpcwt.project_component_id +), + +council_districts AS ( + SELECT + features.component_id AS project_component_id, + string_agg(DISTINCT features_council_districts.council_district_id::text, ', '::text) AS council_districts, + string_agg(DISTINCT lpad(features_council_districts.council_district_id::text, 2, '0'::text), ', '::text) AS council_districts_searchable + FROM features_council_districts + LEFT JOIN features ON features_council_districts.feature_id = features.id + WHERE features.is_deleted = false + GROUP BY features.component_id +), + +comp_geography AS ( + SELECT + feature_union.component_id AS project_component_id, + string_agg(DISTINCT feature_union.id::text, ', '::text) AS feature_ids, + st_asgeojson(st_union(array_agg(feature_union.geography)))::json AS geometry, + st_asgeojson(st_union(array_agg(feature_union.line_geography)))::json AS line_geometry, + string_agg(DISTINCT feature_union.signal_id::text, ', '::text) AS signal_ids, + sum(feature_union.length_feet) AS length_feet_total + FROM ( + SELECT + feature_signals.id, + feature_signals.component_id, + feature_signals.geography::geometry AS geography, + st_exteriorring(st_buffer(feature_signals.geography, 7::double precision)::geometry) AS line_geography, + feature_signals.signal_id, + null::integer AS length_feet + FROM feature_signals + WHERE feature_signals.is_deleted = false + UNION ALL + SELECT + feature_street_segments.id, + feature_street_segments.component_id, + feature_street_segments.geography::geometry AS geography, + feature_street_segments.geography::geometry AS line_geography, + null::integer AS signal_id, + feature_street_segments.length_feet + FROM feature_street_segments + WHERE feature_street_segments.is_deleted = false + UNION ALL + SELECT + feature_intersections.id, + feature_intersections.component_id, + feature_intersections.geography::geometry AS geography, + st_exteriorring(st_buffer(feature_intersections.geography, 7::double precision)::geometry) AS line_geography, + null::integer AS signal_id, + null::integer AS length_feet + FROM feature_intersections + WHERE feature_intersections.is_deleted = false + UNION ALL + SELECT + feature_drawn_points.id, + feature_drawn_points.component_id, + feature_drawn_points.geography::geometry AS geography, + st_exteriorring(st_buffer(feature_drawn_points.geography, 7::double precision)::geometry) AS line_geography, + null::integer AS signal_id, + null::integer AS length_feet + FROM feature_drawn_points + WHERE feature_drawn_points.is_deleted = false + UNION ALL + SELECT + feature_drawn_lines.id, + feature_drawn_lines.component_id, + feature_drawn_lines.geography::geometry AS geography, + feature_drawn_lines.geography::geometry AS line_geography, + null::integer AS signal_id, + feature_drawn_lines.length_feet + FROM feature_drawn_lines + WHERE feature_drawn_lines.is_deleted = false + UNION ALL + SELECT + feature_school_beacons.id, + feature_school_beacons.component_id, + feature_school_beacons.geography::geometry AS geography, + st_exteriorring(st_buffer(feature_school_beacons.geography, 7::double precision)::geometry) AS line_geography, + null::integer AS signal_id, + null::integer AS length_feet + FROM feature_school_beacons + WHERE feature_school_beacons.is_deleted = false + ) feature_union + GROUP BY feature_union.component_id +), + +subcomponents AS ( + SELECT + mpcs.project_component_id, + string_agg(ms.subcomponent_name, ', '::text) AS subcomponents + FROM moped_proj_components_subcomponents mpcs + LEFT JOIN moped_subcomponents ms ON mpcs.subcomponent_id = ms.subcomponent_id + WHERE mpcs.is_deleted = false + GROUP BY mpcs.project_component_id +), + +component_tags AS ( + SELECT + mpct.project_component_id, + string_agg((mct.type || ' - '::text) || mct.name, ', '::text) AS component_tags + FROM moped_proj_component_tags mpct + LEFT JOIN moped_component_tags mct ON mpct.component_tag_id = mct.id + WHERE mpct.is_deleted = false + GROUP BY mpct.project_component_id +), + +related_projects AS ( + SELECT + pmp.project_id, + concat_ws(', '::text, pmp.project_id, string_agg(cmp.project_id::text, ', '::text)) AS related_project_ids_with_self, + concat_ws(', '::text, lpad(pmp.project_id::text, 5, '0'::text), string_agg(lpad(cmp.project_id::text, 5, '0'::text), ', '::text)) AS related_project_ids_searchable_with_self + FROM moped_project pmp + LEFT JOIN moped_project cmp ON pmp.project_id = cmp.parent_project_id + WHERE cmp.is_deleted = false + GROUP BY pmp.project_id +), + +latest_public_meeting_date AS ( + SELECT + mpm.project_id, + coalesce(max(mpm.date_actual), max(mpm.date_estimate)) AS latest + FROM moped_proj_milestones mpm + WHERE mpm.milestone_id = 65 AND mpm.is_deleted = false + GROUP BY mpm.project_id +), + +earliest_active_or_construction_phase_date AS ( + SELECT + mpp.project_id, + min(mpp.phase_start) AS earliest + FROM moped_proj_phases mpp + LEFT JOIN moped_phases mp ON mpp.phase_id = mp.phase_id + WHERE (mp.phase_name_simple = any(ARRAY['Active'::text, 'Construction'::text])) AND mpp.is_deleted = false + GROUP BY mpp.project_id +) + +SELECT + mpc.project_id, + comp_geography.project_component_id, + comp_geography.feature_ids, + mpc.component_id, + comp_geography.geometry, + comp_geography.line_geometry, + comp_geography.signal_ids, + council_districts.council_districts, + council_districts.council_districts_searchable, + NOT coalesce(council_districts.council_districts IS null OR council_districts.council_districts = ''::text, false) AS is_within_city_limits, + comp_geography.length_feet_total, + round(comp_geography.length_feet_total::numeric / 5280::numeric, 2) AS length_miles_total, + mc.component_name, + mc.component_subtype, + mc.component_name_full, + 'placeholder text'::text AS component_categories, + subcomponents.subcomponents AS component_subcomponents, + work_types.work_types AS component_work_types, + component_tags.component_tags, + mpc.description AS component_description, + mpc.interim_project_component_id, + coalesce(mpc.completion_date, plv.substantial_completion_date) AS substantial_completion_date, + plv.substantial_completion_date_estimated, + mpc.srts_id, + mpc.location_description AS component_location_description, + plv.project_name, + plv.project_name_secondary, + plv.project_name_full, + plv.project_description, + plv.ecapris_subproject_id, + plv.project_website, + plv.updated_at AS project_updated_at, + mpc.phase_id AS component_phase_id, + mph.phase_name AS component_phase_name, + mph.phase_name_simple AS component_phase_name_simple, + current_phase.phase_id AS project_phase_id, + current_phase.phase_name AS project_phase_name, + current_phase.phase_name_simple AS project_phase_name_simple, + coalesce(mph.phase_name, current_phase.phase_name) AS current_phase_name, + coalesce(mph.phase_name_simple, current_phase.phase_name_simple) AS current_phase_name_simple, + plv.project_team_members, + plv.project_sponsor, + plv.project_lead, + plv.public_process_status, + plv.interim_project_id, + plv.project_partners, + plv.task_order_names, + plv.funding_source_name, + plv.funding_source_and_program_names AS funding_sources, + plv.type_name, + plv.project_status_update, + plv.project_status_update_date_created, + to_char(timezone('US/Central'::text, plv.construction_start_date), 'YYYY-MM-DD'::text) AS construction_start_date, + plv.project_inspector, + plv.project_designer, + plv.project_tags, + plv.workgroup_contractors, + plv.contract_numbers, + plv.parent_project_id, + plv.parent_project_name, + plv.parent_project_url, + plv.parent_project_name AS parent_project_name_full, + rp.related_project_ids_with_self AS related_project_ids, + rp.related_project_ids_searchable_with_self AS related_project_ids_searchable, + plv.knack_project_id AS knack_data_tracker_project_record_id, + plv.project_url, + (plv.project_url || '?tab=map&project_component_id='::text) || mpc.project_component_id::text AS component_url, + get_project_development_status(lpmd.latest::timestamp with time zone, eaocpd.earliest, coalesce(mpc.completion_date, plv.substantial_completion_date), plv.substantial_completion_date_estimated, coalesce(mph.phase_name_simple, current_phase.phase_name_simple)) AS project_development_status, + project_development_status_date.result AS project_development_status_date, + to_char(project_development_status_date.result, 'YYYY'::text)::integer AS project_development_status_date_calendar_year, + to_char(project_development_status_date.result, 'FMMonth YYYY'::text) AS project_development_status_date_calendar_year_month, + to_char(project_development_status_date.result, 'YYYY-MM'::text) AS project_development_status_date_calendar_year_month_numeric, + date_part('quarter'::text, project_development_status_date.result)::text AS project_development_status_date_calendar_year_quarter, + CASE + WHEN date_part('quarter'::text, project_development_status_date.result) = 4::double precision THEN (to_char(project_development_status_date.result, 'YYYY'::text)::integer + 1)::text + ELSE to_char(project_development_status_date.result, 'YYYY'::text) + END AS project_development_status_date_fiscal_year, + CASE + WHEN date_part('quarter'::text, project_development_status_date.result) = 4::double precision THEN 1::double precision + ELSE date_part('quarter'::text, project_development_status_date.result) + 1::double precision + END::text AS project_development_status_date_fiscal_year_quarter, + plv.added_by AS project_added_by +FROM moped_proj_components mpc +LEFT JOIN comp_geography ON mpc.project_component_id = comp_geography.project_component_id +LEFT JOIN council_districts ON mpc.project_component_id = council_districts.project_component_id +LEFT JOIN subcomponents ON mpc.project_component_id = subcomponents.project_component_id +LEFT JOIN work_types ON mpc.project_component_id = work_types.project_component_id +LEFT JOIN component_tags ON mpc.project_component_id = component_tags.project_component_id +LEFT JOIN project_list_view plv ON mpc.project_id = plv.project_id +LEFT JOIN current_phase_view current_phase ON mpc.project_id = current_phase.project_id +LEFT JOIN moped_phases mph ON mpc.phase_id = mph.phase_id +LEFT JOIN moped_components mc ON mpc.component_id = mc.component_id +LEFT JOIN related_projects rp ON mpc.project_id = rp.project_id +LEFT JOIN latest_public_meeting_date lpmd ON mpc.project_id = lpmd.project_id +LEFT JOIN earliest_active_or_construction_phase_date eaocpd ON mpc.project_id = eaocpd.project_id +LEFT JOIN LATERAL (SELECT timezone('US/Central'::text, get_project_development_status_date(lpmd.latest::timestamp with time zone, eaocpd.earliest, coalesce(mpc.completion_date, plv.substantial_completion_date), plv.substantial_completion_date_estimated, coalesce(mph.phase_name_simple, current_phase.phase_name_simple))) AS result) project_development_status_date ON true +WHERE mpc.is_deleted = false AND plv.is_deleted = false; + + +CREATE VIEW exploded_component_arcgis_online_view AS +SELECT + component_arcgis_online_view.project_id, + component_arcgis_online_view.project_component_id, + ST_GEOMETRYTYPE(dump.geom) AS geometry_type, + dump.path[1] AS point_index, -- ordinal value of the point in the MultiPoint geometry + component_arcgis_online_view.geometry AS original_geometry, + ST_ASGEOJSON(dump.geom) AS exploded_geometry, -- noqa: RF04 + component_arcgis_online_view.project_updated_at +FROM + component_arcgis_online_view, + LATERAL ST_DUMP(ST_GEOMFROMGEOJSON(component_arcgis_online_view.geometry)) AS dump -- noqa: RF04 +WHERE + ST_GEOMETRYTYPE(ST_GEOMFROMGEOJSON(component_arcgis_online_view.geometry)) = 'ST_MultiPoint'; diff --git a/moped-database/views/component_arcgis_online_view.sql b/moped-database/views/component_arcgis_online_view.sql index 1b2e793a1f..3eec77c4b8 100644 --- a/moped-database/views/component_arcgis_online_view.sql +++ b/moped-database/views/component_arcgis_online_view.sql @@ -1,4 +1,4 @@ --- Most recent migration: moped-database/migrations/1725556123250_add_component_level_phase_simple/up.sql +-- Most recent migration: moped-database/migrations/1727279529178_update_component_agol_view_school_beacons/up.sql CREATE OR REPLACE VIEW component_arcgis_online_view AS WITH work_types AS ( SELECT @@ -79,6 +79,16 @@ comp_geography AS ( feature_drawn_lines.length_feet FROM feature_drawn_lines WHERE feature_drawn_lines.is_deleted = false + UNION ALL + SELECT + feature_school_beacons.id, + feature_school_beacons.component_id, + feature_school_beacons.geography::geometry AS geography, + st_exteriorring(st_buffer(feature_school_beacons.geography, 7::double precision)::geometry) AS line_geography, + null::integer AS signal_id, + null::integer AS length_feet + FROM feature_school_beacons + WHERE feature_school_beacons.is_deleted = false ) feature_union GROUP BY feature_union.component_id ), diff --git a/moped-database/views/exploded_component_arcgis_online_view.sql b/moped-database/views/exploded_component_arcgis_online_view.sql index cddba03fdb..b221558269 100644 --- a/moped-database/views/exploded_component_arcgis_online_view.sql +++ b/moped-database/views/exploded_component_arcgis_online_view.sql @@ -1,4 +1,4 @@ --- Most recent migration: moped-database/migrations/1725649291445_add_exploded_moped_geometry_view_for_agol/up.sql +-- Most recent migration: moped-database/migrations/1727279529178_update_component_agol_view_school_beacons/up.sql CREATE OR REPLACE VIEW exploded_component_arcgis_online_view AS SELECT component_arcgis_online_view.project_id, diff --git a/moped-database/views/project_geography.sql b/moped-database/views/project_geography.sql index e565a85e49..d7ef2b05cd 100644 --- a/moped-database/views/project_geography.sql +++ b/moped-database/views/project_geography.sql @@ -1,4 +1,4 @@ --- Most recent migration: moped-database/migrations/1717191608944_add_line_rep_to_proj_geo_view/up.sql +-- Most recent migration: moped-database/migrations/1727229291111_add_beacons_to_unified_features_view/up.sql CREATE OR REPLACE VIEW project_geography AS SELECT moped_project.project_id, diff --git a/moped-database/views/uniform_features.sql b/moped-database/views/uniform_features.sql index bb1694a8fd..4fb5193376 100644 --- a/moped-database/views/uniform_features.sql +++ b/moped-database/views/uniform_features.sql @@ -1,4 +1,4 @@ --- Most recent migration: moped-database/migrations/1700515731002_add_audit_fields_to_unified_features_view/up.sql +-- Most recent migration: moped-database/migrations/1727229291111_add_beacons_to_unified_features_view/up.sql CREATE OR REPLACE VIEW uniform_features AS SELECT feature_signals.id, @@ -19,7 +19,7 @@ LEFT JOIN ( array_agg(d.council_district_id) AS council_districts FROM features_council_districts d GROUP BY d.feature_id -) districts ON districts.feature_id = feature_signals.id +) districts ON feature_signals.id = districts.feature_id WHERE feature_signals.is_deleted = FALSE UNION ALL SELECT @@ -41,7 +41,7 @@ LEFT JOIN ( array_agg(d.council_district_id) AS council_districts FROM features_council_districts d GROUP BY d.feature_id -) districts ON districts.feature_id = feature_street_segments.id +) districts ON feature_street_segments.id = districts.feature_id WHERE feature_street_segments.is_deleted = FALSE UNION ALL SELECT @@ -63,7 +63,7 @@ LEFT JOIN ( array_agg(d.council_district_id) AS council_districts FROM features_council_districts d GROUP BY d.feature_id -) districts ON districts.feature_id = feature_intersections.id +) districts ON feature_intersections.id = districts.feature_id WHERE feature_intersections.is_deleted = FALSE UNION ALL SELECT @@ -85,7 +85,7 @@ LEFT JOIN ( array_agg(d.council_district_id) AS council_districts FROM features_council_districts d GROUP BY d.feature_id -) districts ON districts.feature_id = feature_drawn_points.id +) districts ON feature_drawn_points.id = districts.feature_id WHERE feature_drawn_points.is_deleted = FALSE UNION ALL SELECT @@ -107,5 +107,27 @@ LEFT JOIN ( array_agg(d.council_district_id) AS council_districts FROM features_council_districts d GROUP BY d.feature_id -) districts ON districts.feature_id = feature_drawn_lines.id -WHERE feature_drawn_lines.is_deleted = FALSE; +) districts ON feature_drawn_lines.id = districts.feature_id +WHERE feature_drawn_lines.is_deleted = FALSE +UNION ALL +SELECT + feature_school_beacons.id, + feature_school_beacons.component_id, + 'feature_school_beacons'::text AS "table", + json_build_object('school_zone_beacon_id', feature_school_beacons.school_zone_beacon_id, 'knack_id', feature_school_beacons.knack_id, 'location_name', feature_school_beacons.location_name, 'zone_name', feature_school_beacons.zone_name, 'beacon_name', feature_school_beacons.beacon_name) AS attributes, + feature_school_beacons.geography, + districts.council_districts, + NULL::integer AS length_feet, + feature_school_beacons.created_at, + feature_school_beacons.updated_at, + feature_school_beacons.created_by_user_id, + feature_school_beacons.updated_by_user_id +FROM feature_school_beacons +LEFT JOIN ( + SELECT + d.feature_id, + array_agg(d.council_district_id) AS council_districts + FROM features_council_districts d + GROUP BY d.feature_id +) districts ON feature_school_beacons.id = districts.feature_id +WHERE feature_school_beacons.is_deleted = FALSE; diff --git a/moped-editor/src/views/projects/projectView/ProjectComponents/utils/makeComponentData.js b/moped-editor/src/views/projects/projectView/ProjectComponents/utils/makeComponentData.js index 501d93dc7c..2443eaa090 100644 --- a/moped-editor/src/views/projects/projectView/ProjectComponents/utils/makeComponentData.js +++ b/moped-editor/src/views/projects/projectView/ProjectComponents/utils/makeComponentData.js @@ -178,7 +178,7 @@ export const getFeatureChangesFromComponentForm = ( } else if (newSchoolBeaconKnackId) { if ( previousSchoolBeacon && - newSchoolBeaconKnackId !== previousSchoolBeacon.id + newSchoolBeaconKnackId !== previousSchoolBeacon.knack_id ) { // changed which Beacon was chosen schoolBeaconToCreate =