Skip to content

Commit 7de5489

Browse files
committed
Add CoY fields to PLUTO
1 parent 703842b commit 7de5489

File tree

6 files changed

+123
-13
lines changed

6 files changed

+123
-13
lines changed

products/pluto/pluto_build/sql/create.sql

Lines changed: 5 additions & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -101,5 +101,9 @@ CREATE TABLE pluto (
101101
basempdate text,
102102
masdate text,
103103
polidate text,
104-
edesigdate text
104+
edesigdate text,
105+
mnffar text,
106+
affresfar text,
107+
trnstzone text,
108+
miharea text
105109
);

products/pluto/pluto_build/sql/export.sql

Lines changed: 8 additions & 2 deletions
Original file line numberDiff line numberDiff line change
@@ -91,7 +91,11 @@ SELECT
9191
dcpedited::varchar(3),
9292
latitude::numeric(19, 7),
9393
longitude::numeric(19, 7),
94-
notes::varchar(20)
94+
notes::varchar(20),
95+
mnffar::numeric(19, 11),
96+
affresfar::numeric(19, 11),
97+
trnstzone::varchar(1),
98+
miharea::varchar(50)
9599
INTO export_pluto
96100
FROM pluto;
97101

@@ -197,7 +201,9 @@ SELECT
197201
a.dcpedited AS "DCPEdited",
198202
a.latitude AS "Latitude",
199203
a.longitude AS "Longitude",
200-
a.notes AS "Notes"
204+
a.notes AS "Notes",
205+
a.trnstzone AS "TrnstZone",
206+
a.miharea AS "MIHArea"
201207
INTO unmapped
202208
FROM export_pluto AS a
203209
WHERE bbl::bigint IN (

products/pluto/pluto_build/sql/export_mappluto_shp.sql

Lines changed: 4 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -92,6 +92,10 @@ SELECT
9292
a.latitude AS "Latitude",
9393
a.longitude AS "Longitude",
9494
a.notes AS "Notes",
95+
a.mnffar AS "ManuFAR",
96+
a.affresfar AS "AffResFAR",
97+
a.trnstzone AS "TrnstZone",
98+
a.miharea AS "MIHArea",
9599
round(st_length(b.:GEOM)::numeric, 11)::numeric(19, 7) AS "Shape_Leng",
96100
round(st_area(b.:GEOM)::numeric, 11)::numeric(19, 7) AS "Shape_Area",
97101
st_makevalid(b.:GEOM) AS geom

products/pluto/pluto_build/sql/far.sql

Lines changed: 33 additions & 10 deletions
Original file line numberDiff line numberDiff line change
@@ -10,15 +10,19 @@ UPDATE pluto a
1010
SET
1111
residfar = b.residfar,
1212
commfar = b.commfar,
13-
facilfar = b.facilfar
13+
facilfar = b.facilfar,
14+
mnffar = b.mnffar,
15+
affresfar = b.affresfar
1416
FROM dcp_zoning_maxfar AS b
1517
WHERE a.zonedist1 = b.zonedist;
1618
-- zoning district 1 with / first p art
1719
UPDATE pluto a
1820
SET
1921
residfar = (coalesce(a.residfar, b.residfar)),
2022
commfar = (coalesce(a.commfar, b.commfar)),
21-
facilfar = (coalesce(a.facilfar, b.facilfar))
23+
facilfar = (coalesce(a.facilfar, b.facilfar)),
24+
mnffar = (coalesce(a.mnffar, b.mnffar)),
25+
affresfar = (coalesce(a.affresfar, b.affresfar))
2226
FROM dcp_zoning_maxfar AS b
2327
WHERE split_part(a.zonedist1, '/', 1) = b.zonedist;
2428

@@ -27,7 +31,9 @@ UPDATE pluto a
2731
SET
2832
residfar = (coalesce(a.residfar, b.residfar)),
2933
commfar = (coalesce(a.commfar, b.commfar)),
30-
facilfar = (coalesce(a.facilfar, b.facilfar))
34+
facilfar = (coalesce(a.facilfar, b.facilfar)),
35+
mnffar = (coalesce(a.mnffar, b.mnffar)),
36+
affresfar = (coalesce(a.affresfar, b.affresfar))
3137
FROM dcp_zoning_maxfar AS b
3238
WHERE split_part(a.zonedist1, '/', 2) = b.zonedist;
3339

@@ -36,7 +42,9 @@ UPDATE pluto a
3642
SET
3743
residfar = (coalesce(a.residfar, b.residfar)),
3844
commfar = (coalesce(a.commfar, b.commfar)),
39-
facilfar = (coalesce(a.facilfar, b.facilfar))
45+
facilfar = (coalesce(a.facilfar, b.facilfar)),
46+
mnffar = (coalesce(a.mnffar, b.mnffar)),
47+
affresfar = (coalesce(a.affresfar, b.affresfar))
4048
FROM dcp_zoning_maxfar AS b
4149
WHERE a.zonedist2 = b.zonedist;
4250

@@ -45,7 +53,9 @@ UPDATE pluto a
4553
SET
4654
residfar = (coalesce(a.residfar, b.residfar)),
4755
commfar = (coalesce(a.commfar, b.commfar)),
48-
facilfar = (coalesce(a.facilfar, b.facilfar))
56+
facilfar = (coalesce(a.facilfar, b.facilfar)),
57+
mnffar = (coalesce(a.mnffar, b.mnffar)),
58+
affresfar = (coalesce(a.affresfar, b.affresfar))
4959
FROM dcp_zoning_maxfar AS b
5060
WHERE split_part(a.zonedist2, '/', 1) = b.zonedist;
5161

@@ -54,7 +64,9 @@ UPDATE pluto a
5464
SET
5565
residfar = (coalesce(a.residfar, b.residfar)),
5666
commfar = (coalesce(a.commfar, b.commfar)),
57-
facilfar = (coalesce(a.facilfar, b.facilfar))
67+
facilfar = (coalesce(a.facilfar, b.facilfar)),
68+
mnffar = (coalesce(a.mnffar, b.mnffar)),
69+
affresfar = (coalesce(a.affresfar, b.affresfar))
5870
FROM dcp_zoning_maxfar AS b
5971
WHERE split_part(a.zonedist2, '/', 2) = b.zonedist;
6072

@@ -63,7 +75,9 @@ UPDATE pluto a
6375
SET
6476
residfar = (coalesce(a.residfar, b.residfar)),
6577
commfar = (coalesce(a.commfar, b.commfar)),
66-
facilfar = (coalesce(a.facilfar, b.facilfar))
78+
facilfar = (coalesce(a.facilfar, b.facilfar)),
79+
mnffar = (coalesce(a.mnffar, b.mnffar)),
80+
affresfar = (coalesce(a.affresfar, b.affresfar))
6781
FROM dcp_zoning_maxfar AS b
6882
WHERE a.zonedist3 = b.zonedist;
6983

@@ -72,7 +86,9 @@ UPDATE pluto a
7286
SET
7387
residfar = (coalesce(a.residfar, b.residfar)),
7488
commfar = (coalesce(a.commfar, b.commfar)),
75-
facilfar = (coalesce(a.facilfar, b.facilfar))
89+
facilfar = (coalesce(a.facilfar, b.facilfar)),
90+
mnffar = (coalesce(a.mnffar, b.mnffar)),
91+
affresfar = (coalesce(a.affresfar, b.affresfar))
7692
FROM dcp_zoning_maxfar AS b
7793
WHERE split_part(a.zonedist3, '/', 1) = b.zonedist;
7894

@@ -81,7 +97,9 @@ UPDATE pluto a
8197
SET
8298
residfar = (coalesce(a.residfar, b.residfar)),
8399
commfar = (coalesce(a.commfar, b.commfar)),
84-
facilfar = (coalesce(a.facilfar, b.facilfar))
100+
facilfar = (coalesce(a.facilfar, b.facilfar)),
101+
mnffar = (coalesce(a.mnffar, b.mnffar)),
102+
affresfar = (coalesce(a.affresfar, b.affresfar))
85103
FROM dcp_zoning_maxfar AS b
86104
WHERE split_part(a.zonedist3, '/', 2) = b.zonedist;
87105

@@ -92,4 +110,9 @@ SET
92110
= (CASE WHEN a.residfar IS NULL OR a.residfar = '-' THEN 0::double precision ELSE a.residfar::double precision END),
93111
commfar
94112
= (CASE WHEN a.commfar IS NULL OR a.commfar = '-' THEN 0::double precision ELSE a.commfar::double precision END),
95-
facilfar = (CASE WHEN a.facilfar IS NULL OR a.facilfar = '-' THEN 0 ELSE a.facilfar::double precision END);
113+
facilfar
114+
= (CASE WHEN a.facilfar IS NULL OR a.facilfar = '-' THEN 0 ELSE a.facilfar::double precision END),
115+
mnffar
116+
= (case when a.mnffar is null or a.mnffar = '-' then 0 else a.mnffar::double precision end),
117+
affresfar
118+
= (case when a.affresfar is null or a.affresfar = '-' then 0 else a.affresfar::double precision end);
Lines changed: 65 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,65 @@
1+
-- calculate how much (total area and percentage) of each lot is covered by MIH areas
2+
-- assign the MIH project ID to each tax lot based on which MIH area covers the majority of the lot
3+
-- a MIH area is only assigned if more than 10% of the lot is covered by the MIH area
4+
-- OR more than 50% of the MIH area overlaps with the lot
5+
6+
DROP TABLE IF EXISTS mihperorder;
7+
CREATE TABLE mihperorder AS
8+
WITH mihper AS (
9+
SELECT
10+
p.id,
11+
p.bbl,
12+
n.project_id,
13+
ST_AREA(
14+
CASE
15+
WHEN ST_COVEREDBY(p.geom, n.wkb_geometry) THEN p.geom
16+
ELSE ST_MULTI(ST_INTERSECTION(p.geom, n.wkb_geometry))
17+
END
18+
) AS segbblgeom,
19+
ST_AREA(p.geom) AS allbblgeom,
20+
ST_AREA(
21+
CASE
22+
WHEN ST_COVEREDBY(n.wkb_geometry, p.geom) THEN n.wkb_geometry
23+
ELSE ST_MULTI(ST_INTERSECTION(n.wkb_geometry, p.geom))
24+
END
25+
) AS segmihgeom,
26+
ST_AREA(n.wkb_geometry) AS allmihgeom
27+
FROM pluto AS p
28+
INNER JOIN dcp_mih AS n
29+
ON ST_INTERSECTS(p.geom, n.wkb_geometry)
30+
),
31+
32+
grouped AS (
33+
SELECT
34+
id,
35+
bbl,
36+
project_id,
37+
SUM(segbblgeom) AS segbblgeom,
38+
SUM(segmihgeom) AS segmihgeom,
39+
SUM(segbblgeom / allbblgeom) * 100 AS perbblgeom,
40+
MAX(segmihgeom / allmihgeom) * 100 AS maxpermihgeom
41+
FROM mihper
42+
GROUP BY id, bbl, project_id
43+
)
44+
45+
SELECT
46+
id,
47+
bbl,
48+
project_id,
49+
segbblgeom,
50+
perbblgeom,
51+
maxpermihgeom,
52+
ROW_NUMBER() OVER (
53+
PARTITION BY id
54+
ORDER BY segbblgeom DESC, segmihgeom DESC
55+
) AS row_number
56+
FROM grouped
57+
WHERE perbblgeom >= 10 OR maxpermihgeom >= 50;
58+
59+
-- assign the MIH project ID with the highest overlap to each lot
60+
UPDATE pluto a
61+
SET miharea = project_id
62+
FROM mihperorder AS b
63+
WHERE
64+
a.id = b.id
65+
AND row_number = 1;
Lines changed: 8 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,8 @@
1+
-- assign transit zone designation based on spatial intersection
2+
-- with the greater transit zone area
3+
-- output is 'Y' if lot intersects with transit zone, NULL otherwise
4+
5+
UPDATE pluto a
6+
SET trnstzone = 'Y'
7+
FROM dcp_greater_transit_zone AS b
8+
WHERE ST_INTERSECTS(a.geom, b.wkb_geometry);

0 commit comments

Comments
 (0)