From 597deda9942488c0c62e32d0c735f7375df9dca2 Mon Sep 17 00:00:00 2001 From: Alex Richey Date: Mon, 1 Dec 2025 14:14:29 -0500 Subject: [PATCH 1/6] temp hack: set prev pluto --- products/pluto/recipe.yml | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/products/pluto/recipe.yml b/products/pluto/recipe.yml index e760b30600..06fa5450d4 100644 --- a/products/pluto/recipe.yml +++ b/products/pluto/recipe.yml @@ -21,7 +21,7 @@ inputs: - name: dcp_limitedheight - name: dcp_pluto # this env var is set in dcpy/builds/plan.py in a slightly hacky way for now - version_env_var: VERSION_PREV + version: 25v2 import_as: previous_pluto - name: dcp_policeprecincts - name: dcp_school_districts From 571e0051bed659ac5163956e434d236a683a0f70 Mon Sep 17 00:00:00 2001 From: Alex Richey Date: Mon, 1 Dec 2025 15:41:44 -0500 Subject: [PATCH 2/6] add template for greater_transit_zone --- ingest_templates/dcp_greater_transit_zone.yml | 34 +++++++++++++++++++ products/pluto/recipe.yml | 1 + 2 files changed, 35 insertions(+) create mode 100644 ingest_templates/dcp_greater_transit_zone.yml diff --git a/ingest_templates/dcp_greater_transit_zone.yml b/ingest_templates/dcp_greater_transit_zone.yml new file mode 100644 index 0000000000..335550f53d --- /dev/null +++ b/ingest_templates/dcp_greater_transit_zone.yml @@ -0,0 +1,34 @@ +id: dcp_greater_transit_zone +acl: public-read + +attributes: + name: Greater Transit Zone + description: > + The Greater Transit Zone boundaries are used for several zoning rules. + They determine where special rules for Qualifying Residential Sites are + applicable and how non-residential parking is calculated in some zoning + districts. Being located within the Greater Transit Zone may allow for + more or different development opportunities. + url: https://www.nyc.gov/content/planning/pages/resources/datasets/greater-transit-zone + +ingestion: + target_crs: EPSG:4326 + source: + type: file_download + url: https://s-media.nyc.gov/agencies/dcp/assets/files/zip/data-tools/bytes/greater-transit-zone/nyc_greater_transit_zone.zip + file_format: + type: shapefile + unzipped_filename: greater_transit_zone_{{ version }}.shp + crs: EPSG:2263 + processing_steps: + - name: clean_column_names + args: { "lower": True } + - name: rename_columns + args: + map: { "geom": "wkb_geometry" } + +columns: + - id: gtz_qs + data_type: text + - id: wkb_geometry + data_type: geometry diff --git a/products/pluto/recipe.yml b/products/pluto/recipe.yml index 06fa5450d4..508c42a1b0 100644 --- a/products/pluto/recipe.yml +++ b/products/pluto/recipe.yml @@ -19,6 +19,7 @@ inputs: - name: dcp_healthareas - name: dcp_healthcenters - name: dcp_limitedheight + - name: dcp_mih - name: dcp_pluto # this env var is set in dcpy/builds/plan.py in a slightly hacky way for now version: 25v2 From e19ac5bae1e9c2497a928d1b38d50672088f0133 Mon Sep 17 00:00:00 2001 From: Alex Richey Date: Mon, 8 Dec 2025 16:15:41 -0500 Subject: [PATCH 3/6] Add CoY fields to PLUTO --- products/pluto/pluto_build/02_build.sh | 2 + products/pluto/pluto_build/sql/create.sql | 6 +- products/pluto/pluto_build/sql/export.sql | 10 ++- .../pluto_build/sql/export_mappluto_shp.sql | 4 ++ products/pluto/pluto_build/sql/far.sql | 43 +++++++++--- products/pluto/pluto_build/sql/miharea.sql | 68 +++++++++++++++++++ .../pluto/pluto_build/sql/transitzone.sql | 8 +++ products/pluto/recipe.yml | 1 + 8 files changed, 129 insertions(+), 13 deletions(-) create mode 100644 products/pluto/pluto_build/sql/miharea.sql create mode 100644 products/pluto/pluto_build/sql/transitzone.sql diff --git a/products/pluto/pluto_build/02_build.sh b/products/pluto/pluto_build/02_build.sh index 5657da5a6e..a22aaa3dae 100755 --- a/products/pluto/pluto_build/02_build.sh +++ b/products/pluto/pluto_build/02_build.sh @@ -98,6 +98,8 @@ run_sql_file sql/spatialjoins.sql run_sql_file sql/numericfields_geomfields.sql run_sql_file sql/sanitboro.sql run_sql_file sql/latlong.sql +run_sql_file sql/miharea.sql +run_sql_file sql/transitzone.sql run_sql_command "VACUUM ANALYZE pluto;" echo 'Populating PLUTO tags and version fields' diff --git a/products/pluto/pluto_build/sql/create.sql b/products/pluto/pluto_build/sql/create.sql index 055503bbed..f7e985f860 100644 --- a/products/pluto/pluto_build/sql/create.sql +++ b/products/pluto/pluto_build/sql/create.sql @@ -101,5 +101,9 @@ CREATE TABLE pluto ( basempdate text, masdate text, polidate text, - edesigdate text + edesigdate text, + mnffar text, + affresfar text, + trnstzone text, + miharea text ); diff --git a/products/pluto/pluto_build/sql/export.sql b/products/pluto/pluto_build/sql/export.sql index 659b5a688b..8c01c10cd5 100644 --- a/products/pluto/pluto_build/sql/export.sql +++ b/products/pluto/pluto_build/sql/export.sql @@ -91,7 +91,11 @@ SELECT dcpedited::varchar(3), latitude::numeric(19, 7), longitude::numeric(19, 7), - notes::varchar(20) + notes::varchar(20), + mnffar::numeric(19, 11), + affresfar::numeric(19, 11), + trnstzone::varchar(1), + miharea::varchar(50) INTO export_pluto FROM pluto; @@ -197,7 +201,9 @@ SELECT a.dcpedited AS "DCPEdited", a.latitude AS "Latitude", a.longitude AS "Longitude", - a.notes AS "Notes" + a.notes AS "Notes", + a.trnstzone AS "TrnstZone", + a.miharea AS "MIHArea" INTO unmapped FROM export_pluto AS a WHERE bbl::bigint IN ( diff --git a/products/pluto/pluto_build/sql/export_mappluto_shp.sql b/products/pluto/pluto_build/sql/export_mappluto_shp.sql index 2b3a78425e..0e8499a317 100644 --- a/products/pluto/pluto_build/sql/export_mappluto_shp.sql +++ b/products/pluto/pluto_build/sql/export_mappluto_shp.sql @@ -92,6 +92,10 @@ SELECT a.latitude AS "Latitude", a.longitude AS "Longitude", a.notes AS "Notes", + a.mnffar AS "ManuFAR", + a.affresfar AS "AffResFAR", + a.trnstzone AS "TrnstZone", + a.miharea AS "MIHArea", round(st_length(b.:GEOM)::numeric, 11)::numeric(19, 7) AS "Shape_Leng", round(st_area(b.:GEOM)::numeric, 11)::numeric(19, 7) AS "Shape_Area", st_makevalid(b.:GEOM) AS geom diff --git a/products/pluto/pluto_build/sql/far.sql b/products/pluto/pluto_build/sql/far.sql index 5af0d45c49..cecf4f924b 100644 --- a/products/pluto/pluto_build/sql/far.sql +++ b/products/pluto/pluto_build/sql/far.sql @@ -10,7 +10,9 @@ UPDATE pluto a SET residfar = b.residfar, commfar = b.commfar, - facilfar = b.facilfar + facilfar = b.facilfar, + mnffar = b.mnffar, + affresfar = b.affresfar FROM dcp_zoning_maxfar AS b WHERE a.zonedist1 = b.zonedist; -- zoning district 1 with / first p art @@ -18,7 +20,9 @@ UPDATE pluto a SET residfar = (coalesce(a.residfar, b.residfar)), commfar = (coalesce(a.commfar, b.commfar)), - facilfar = (coalesce(a.facilfar, b.facilfar)) + facilfar = (coalesce(a.facilfar, b.facilfar)), + mnffar = (coalesce(a.mnffar, b.mnffar)), + affresfar = (coalesce(a.affresfar, b.affresfar)) FROM dcp_zoning_maxfar AS b WHERE split_part(a.zonedist1, '/', 1) = b.zonedist; @@ -27,7 +31,9 @@ UPDATE pluto a SET residfar = (coalesce(a.residfar, b.residfar)), commfar = (coalesce(a.commfar, b.commfar)), - facilfar = (coalesce(a.facilfar, b.facilfar)) + facilfar = (coalesce(a.facilfar, b.facilfar)), + mnffar = (coalesce(a.mnffar, b.mnffar)), + affresfar = (coalesce(a.affresfar, b.affresfar)) FROM dcp_zoning_maxfar AS b WHERE split_part(a.zonedist1, '/', 2) = b.zonedist; @@ -36,7 +42,9 @@ UPDATE pluto a SET residfar = (coalesce(a.residfar, b.residfar)), commfar = (coalesce(a.commfar, b.commfar)), - facilfar = (coalesce(a.facilfar, b.facilfar)) + facilfar = (coalesce(a.facilfar, b.facilfar)), + mnffar = (coalesce(a.mnffar, b.mnffar)), + affresfar = (coalesce(a.affresfar, b.affresfar)) FROM dcp_zoning_maxfar AS b WHERE a.zonedist2 = b.zonedist; @@ -45,7 +53,9 @@ UPDATE pluto a SET residfar = (coalesce(a.residfar, b.residfar)), commfar = (coalesce(a.commfar, b.commfar)), - facilfar = (coalesce(a.facilfar, b.facilfar)) + facilfar = (coalesce(a.facilfar, b.facilfar)), + mnffar = (coalesce(a.mnffar, b.mnffar)), + affresfar = (coalesce(a.affresfar, b.affresfar)) FROM dcp_zoning_maxfar AS b WHERE split_part(a.zonedist2, '/', 1) = b.zonedist; @@ -54,7 +64,9 @@ UPDATE pluto a SET residfar = (coalesce(a.residfar, b.residfar)), commfar = (coalesce(a.commfar, b.commfar)), - facilfar = (coalesce(a.facilfar, b.facilfar)) + facilfar = (coalesce(a.facilfar, b.facilfar)), + mnffar = (coalesce(a.mnffar, b.mnffar)), + affresfar = (coalesce(a.affresfar, b.affresfar)) FROM dcp_zoning_maxfar AS b WHERE split_part(a.zonedist2, '/', 2) = b.zonedist; @@ -63,7 +75,9 @@ UPDATE pluto a SET residfar = (coalesce(a.residfar, b.residfar)), commfar = (coalesce(a.commfar, b.commfar)), - facilfar = (coalesce(a.facilfar, b.facilfar)) + facilfar = (coalesce(a.facilfar, b.facilfar)), + mnffar = (coalesce(a.mnffar, b.mnffar)), + affresfar = (coalesce(a.affresfar, b.affresfar)) FROM dcp_zoning_maxfar AS b WHERE a.zonedist3 = b.zonedist; @@ -72,7 +86,9 @@ UPDATE pluto a SET residfar = (coalesce(a.residfar, b.residfar)), commfar = (coalesce(a.commfar, b.commfar)), - facilfar = (coalesce(a.facilfar, b.facilfar)) + facilfar = (coalesce(a.facilfar, b.facilfar)), + mnffar = (coalesce(a.mnffar, b.mnffar)), + affresfar = (coalesce(a.affresfar, b.affresfar)) FROM dcp_zoning_maxfar AS b WHERE split_part(a.zonedist3, '/', 1) = b.zonedist; @@ -81,7 +97,9 @@ UPDATE pluto a SET residfar = (coalesce(a.residfar, b.residfar)), commfar = (coalesce(a.commfar, b.commfar)), - facilfar = (coalesce(a.facilfar, b.facilfar)) + facilfar = (coalesce(a.facilfar, b.facilfar)), + mnffar = (coalesce(a.mnffar, b.mnffar)), + affresfar = (coalesce(a.affresfar, b.affresfar)) FROM dcp_zoning_maxfar AS b WHERE split_part(a.zonedist3, '/', 2) = b.zonedist; @@ -92,4 +110,9 @@ SET = (CASE WHEN a.residfar IS NULL OR a.residfar = '-' THEN 0::double precision ELSE a.residfar::double precision END), commfar = (CASE WHEN a.commfar IS NULL OR a.commfar = '-' THEN 0::double precision ELSE a.commfar::double precision END), - facilfar = (CASE WHEN a.facilfar IS NULL OR a.facilfar = '-' THEN 0 ELSE a.facilfar::double precision END); + facilfar + = (CASE WHEN a.facilfar IS NULL OR a.facilfar = '-' THEN 0 ELSE a.facilfar::double precision END), + mnffar + = (CASE WHEN a.mnffar IS NULL OR a.mnffar = '-' THEN 0 ELSE a.mnffar::double precision END), + affresfar + = (CASE WHEN a.affresfar IS NULL OR a.affresfar = '-' THEN 0 ELSE a.affresfar::double precision END); diff --git a/products/pluto/pluto_build/sql/miharea.sql b/products/pluto/pluto_build/sql/miharea.sql new file mode 100644 index 0000000000..50f6fc5205 --- /dev/null +++ b/products/pluto/pluto_build/sql/miharea.sql @@ -0,0 +1,68 @@ +-- calculate how much (total area and percentage) of each lot is covered by MIH areas +-- assign the MIH project ID to each tax lot based on which MIH area covers the +-- majority of the lot +-- a MIH area is only assigned if more than 10% of the lot is covered by the MIH area +-- OR more than 50% of the MIH area overlaps with the lot +DROP TABLE IF EXISTS mihperorder; +CREATE TABLE mihperorder AS +WITH mih_unioned AS ( + SELECT CONCAT(project_name, ' - ', mih_option) as mih_area_key, ST_UNION(wkb_geometry) AS wkb_geometry + FROM dcp_mih + group by CONCAT(project_name, ' - ', mih_option) +), +mihper AS ( + SELECT + p.id, + p.bbl, + mih_area_key, + ST_AREA( + CASE + WHEN ST_COVEREDBY(p.geom, m.wkb_geometry) THEN p.geom + ELSE ST_MULTI(ST_INTERSECTION(p.geom, m.wkb_geometry)) + END + ) AS segbblgeom, + ST_AREA(p.geom) AS allbblgeom, + ST_AREA( + CASE + WHEN ST_COVEREDBY(m.wkb_geometry, p.geom) THEN m.wkb_geometry + ELSE ST_MULTI(ST_INTERSECTION(m.wkb_geometry, p.geom)) + END + ) AS segmihgeom, + ST_AREA(m.wkb_geometry) AS allmihgeom + FROM pluto AS p + INNER JOIN mih_unioned AS m + ON ST_INTERSECTS(p.geom, m.wkb_geometry) +), +grouped AS ( + SELECT + id, + bbl, + mih_area_key, + SUM(segbblgeom) AS segbblgeom, + SUM(segmihgeom) AS segmihgeom, + SUM(segbblgeom / allbblgeom) * 100 AS perbblgeom, + MAX(segmihgeom / allmihgeom) * 100 AS maxpermihgeom + FROM mihper + GROUP BY id, bbl, mih_area_key +) +SELECT + id, + bbl, + mih_area_key, + segbblgeom, + perbblgeom, + maxpermihgeom, + ROW_NUMBER() OVER ( + PARTITION BY id + ORDER BY segbblgeom DESC, segmihgeom DESC + ) AS row_number +FROM grouped +WHERE perbblgeom >= 10 OR maxpermihgeom >= 50; + +-- assign the MIH project ID with the highest overlap to each lot +UPDATE pluto a +SET miharea = mih_area_key +FROM mihperorder AS b +WHERE + a.id = b.id + AND row_number = 1; diff --git a/products/pluto/pluto_build/sql/transitzone.sql b/products/pluto/pluto_build/sql/transitzone.sql new file mode 100644 index 0000000000..906e66a8fa --- /dev/null +++ b/products/pluto/pluto_build/sql/transitzone.sql @@ -0,0 +1,8 @@ +-- assign transit zone designation based on spatial intersection +-- with the greater transit zone area +-- output is 'Y' if lot intersects with transit zone, NULL otherwise + +UPDATE pluto a +SET trnstzone = 'Y' +FROM dcp_greater_transit_zone AS b +WHERE ST_INTERSECTS(a.geom, b.wkb_geometry); diff --git a/products/pluto/recipe.yml b/products/pluto/recipe.yml index 508c42a1b0..8b3cf83609 100644 --- a/products/pluto/recipe.yml +++ b/products/pluto/recipe.yml @@ -16,6 +16,7 @@ inputs: - name: dcp_developments # only used for data tests - name: dcp_edesignation - name: dcp_firecompanies + - name: dcp_greater_transit_zone - name: dcp_healthareas - name: dcp_healthcenters - name: dcp_limitedheight From 4d401334da09e7664ff79a2d85d1c96333089440 Mon Sep 17 00:00:00 2001 From: Alex Richey Date: Thu, 11 Dec 2025 14:03:12 -0500 Subject: [PATCH 4/6] Comment on FAR values --- products/pluto/pluto_build/sql/far.sql | 27 ++++++++++++++++++-------- 1 file changed, 19 insertions(+), 8 deletions(-) diff --git a/products/pluto/pluto_build/sql/far.sql b/products/pluto/pluto_build/sql/far.sql index cecf4f924b..3cad004464 100644 --- a/products/pluto/pluto_build/sql/far.sql +++ b/products/pluto/pluto_build/sql/far.sql @@ -4,8 +4,18 @@ UPDATE pluto SET builtfar = round(bldgarea::numeric / lotarea::numeric, 2) WHERE lotarea != '0' AND lotarea IS NOT NULL; --- using dcp_zoning_maxfar maintained by zoning division --- base on zoning district 1 +-- walks through PLUTO zonedist1, zonedist2, zonedist3 (including split parts like +-- M1-1A/R6B) +-- and sets FAR values using dcp_zoning_maxfar maintained by zoning division +-- +-- Note: the FAR fields in dcp_zoning_maxfar have both nulls and "-". +-- "-" acts to suppress the FAR value for lesser-ranked zoning districts. +-- e.g. R8B has commfar of -. +-- if zonedist1 = R8B/C6-2A, we'd expect a 0 commfar value, as opposed to getting the +-- nonzero commfar value from C6-2A. +-- +-- By contrast R10H has null commfar, +-- so if zonedist1 = R10H/C6-2A, we'd expect to get the commfar value from C6-2A. UPDATE pluto a SET residfar = b.residfar, @@ -15,7 +25,8 @@ SET affresfar = b.affresfar FROM dcp_zoning_maxfar AS b WHERE a.zonedist1 = b.zonedist; --- zoning district 1 with / first p art +-- zoning district 1 with / first part (Manufacturing) +-- These are all in the form of a Manufacturing and Residential zone. e.g. M1-1A/R6B UPDATE pluto a SET residfar = (coalesce(a.residfar, b.residfar)), @@ -26,7 +37,7 @@ SET FROM dcp_zoning_maxfar AS b WHERE split_part(a.zonedist1, '/', 1) = b.zonedist; --- zoning district 1 with / second part +-- zoning district 1 with / second part (Residential) UPDATE pluto a SET residfar = (coalesce(a.residfar, b.residfar)), @@ -48,7 +59,7 @@ SET FROM dcp_zoning_maxfar AS b WHERE a.zonedist2 = b.zonedist; --- zoning district 2 with / first part +-- zoning district 2 with / first part UPDATE pluto a SET residfar = (coalesce(a.residfar, b.residfar)), @@ -59,7 +70,7 @@ SET FROM dcp_zoning_maxfar AS b WHERE split_part(a.zonedist2, '/', 1) = b.zonedist; --- zoning district 2 with / second part +-- zoning district 2 with / second part UPDATE pluto a SET residfar = (coalesce(a.residfar, b.residfar)), @@ -81,7 +92,7 @@ SET FROM dcp_zoning_maxfar AS b WHERE a.zonedist3 = b.zonedist; --- zoning district 3 with / first part +-- zoning district 3 with / first part UPDATE pluto a SET residfar = (coalesce(a.residfar, b.residfar)), @@ -92,7 +103,7 @@ SET FROM dcp_zoning_maxfar AS b WHERE split_part(a.zonedist3, '/', 1) = b.zonedist; --- zoning district 3 with / second part +-- zoning district 3 with / second part UPDATE pluto a SET residfar = (coalesce(a.residfar, b.residfar)), From b9d62713d3b50a67e105cc891d150d895fe514ed Mon Sep 17 00:00:00 2001 From: Alex Richey Date: Thu, 11 Dec 2025 18:01:47 -0500 Subject: [PATCH 5/6] Fix MIH template --- ingest_templates/dcp_mih.yml | 77 +++++++++++++++++++----------------- 1 file changed, 41 insertions(+), 36 deletions(-) diff --git a/ingest_templates/dcp_mih.yml b/ingest_templates/dcp_mih.yml index e5262ceb39..846ef0cde5 100644 --- a/ingest_templates/dcp_mih.yml +++ b/ingest_templates/dcp_mih.yml @@ -12,46 +12,51 @@ attributes: url: https://www1.nyc.gov/site/planning/data-maps/open-data.page#housingdevelopment ingestion: - target_crs: EPSG:4326 source: - type: edm.publishing.gis - name: dcp_inclusionary_housing + type: file_download + url: >- + https://s-media.nyc.gov/agencies/dcp/assets/files/zip/data-tools/bytes/mandatory-inclusionary-housing/nycmih_{{ version }}.zip + target_crs: EPSG:4326 file_format: type: shapefile crs: EPSG:2263 processing_steps: - - name: clean_column_names - args: { "replace": { " ": "_" }, "lower": True } - - name: rename_columns - args: - map: { "geom": "wkb_geometry" } - - name: coerce_column_types - args: - column_types: { "dateadopte": "date" } - - name: multi + - name: clean_column_names + args: { "replace": { " ": "_" }, "lower": True } + - name: rename_columns + args: + map: + { + "geom": "wkb_geometry", + "projectnam": "project_name", + "dateadopte": "date_adopted", + "zr_ulurpno": "zr_ulurp_no", + } columns: -- id: boro - data_type: text -- id: status - data_type: text -- id: projectnam - data_type: text -- id: dateadopte - data_type: date -- id: zr_map - data_type: text -- id: leadaction - data_type: text -- id: cd - data_type: text -- id: shape_star - data_type: decimal -- id: shape_stle - data_type: decimal -- id: shape_leng - data_type: decimal -- id: shape_area - data_type: decimal -- id: wkb_geometry - data_type: geometry + - id: boro + data_type: text + - id: status + data_type: text + - id: project_name + data_type: text + - id: date_adopted + data_type: date + - id: zr_ulurp_no + data_type: text + - id: zr_map + data_type: text + - id: cd + data_type: text + - id: mih_option + data_type: text + - id: project_id + data_type: text + - id: zoning_map + data_type: text + - id: shape_leng + data_type: decimal + - id: shape_area + data_type: decimal + - id: wkb_geometry + data_type: geometry From 0fa57a18ed88719f47dd86707525dbf9782439fe Mon Sep 17 00:00:00 2001 From: Alex Richey Date: Wed, 17 Dec 2025 17:21:02 -0500 Subject: [PATCH 6/6] Fix SQL Formatting --- products/pluto/pluto_build/sql/miharea.sql | 6 ++++-- 1 file changed, 4 insertions(+), 2 deletions(-) diff --git a/products/pluto/pluto_build/sql/miharea.sql b/products/pluto/pluto_build/sql/miharea.sql index 50f6fc5205..9937c0b484 100644 --- a/products/pluto/pluto_build/sql/miharea.sql +++ b/products/pluto/pluto_build/sql/miharea.sql @@ -6,9 +6,11 @@ DROP TABLE IF EXISTS mihperorder; CREATE TABLE mihperorder AS WITH mih_unioned AS ( - SELECT CONCAT(project_name, ' - ', mih_option) as mih_area_key, ST_UNION(wkb_geometry) AS wkb_geometry + SELECT + CONCAT(project_name, ' - ', mih_option) AS mih_area_key, + ST_UNION(wkb_geometry) AS wkb_geometry FROM dcp_mih - group by CONCAT(project_name, ' - ', mih_option) + GROUP BY CONCAT(project_name, ' - ', mih_option) ), mihper AS ( SELECT