Skip to content
Draft
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
34 changes: 34 additions & 0 deletions ingest_templates/dcp_greater_transit_zone.yml
Original file line number Diff line number Diff line change
@@ -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
77 changes: 41 additions & 36 deletions ingest_templates/dcp_mih.yml
Original file line number Diff line number Diff line change
Expand Up @@ -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
2 changes: 2 additions & 0 deletions products/pluto/pluto_build/02_build.sh
Original file line number Diff line number Diff line change
Expand Up @@ -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'
Expand Down
6 changes: 5 additions & 1 deletion products/pluto/pluto_build/sql/create.sql
Original file line number Diff line number Diff line change
Expand Up @@ -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
);
10 changes: 8 additions & 2 deletions products/pluto/pluto_build/sql/export.sql
Original file line number Diff line number Diff line change
Expand Up @@ -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;

Expand Down Expand Up @@ -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 (
Expand Down
4 changes: 4 additions & 0 deletions products/pluto/pluto_build/sql/export_mappluto_shp.sql
Original file line number Diff line number Diff line change
Expand Up @@ -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
Expand Down
70 changes: 52 additions & 18 deletions products/pluto/pluto_build/sql/far.sql
Original file line number Diff line number Diff line change
Expand Up @@ -4,30 +4,47 @@ 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,
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
-- 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)),
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;

-- zoning district 1 with / second part
-- zoning district 1 with / second part (Residential)
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;

Expand All @@ -36,25 +53,31 @@ 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;

-- zoning district 2 with / first part
-- zoning district 2 with / first part
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;

-- zoning district 2 with / second part
-- zoning district 2 with / second part
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;

Expand All @@ -63,25 +86,31 @@ 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;

-- zoning district 3 with / first part
-- zoning district 3 with / first part
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;

-- zoning district 3 with / second part
-- zoning district 3 with / second part
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;

Expand All @@ -92,4 +121,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);
70 changes: 70 additions & 0 deletions products/pluto/pluto_build/sql/miharea.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,70 @@
-- 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;
8 changes: 8 additions & 0 deletions products/pluto/pluto_build/sql/transitzone.sql
Original file line number Diff line number Diff line change
@@ -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);
Loading