Hi All,
As partial resolution to this, below are a couple of working examples of SQL, thanks to an example from Regina Obe's book.
These work on smaller subsets of the data I've used for testing, though unfortunately in running on the entire datasets, after running for hours, I receive an error: Invalid memory allocation request size 1109458944. Thoughts/suggestions welcome, but otherwise I hope these examples are useful to tothers.
Mike
--SQL CODE
with
cte as (
select bbl,
st_valuecount(
st_clip(st_union(p.rast), geom_2263),1, true, ARRAY[0,1,2,3,4,5,6,7]
) as pv
FROM
base_rasters.landcover6in as p
inner join
results_scratch.polys_test
on st_intersects(p.rast, geom_2263)
group by bbl, geom_2263
)
SELECT bbl,
(pv).value, sum((pv).count)
from cte
group by bbl, (pv).value
ORDER by bbl, (pv).value;
--End SQL
And to get the results with land cover by polygon in a 'wide' format (e.g., amounts of different land cover in columns):
--SQL CODE
with
cte as (
select bbl,geom_2263,
st_valuecount(
st_clip(st_union(p.rast), geom_2263),1, true, ARRAY[0,1,2,3,4,5,6,7]
) as pv
FROM
base_rasters.landcover6in as p
inner join
results_scratch.polys_test
on st_intersects(p.rast, geom_2263)
group by bbl, geom_2263
)
SELECT bbl, geom_2263,
(sum((pv).count) filter (where (pv).value = 0)::numeric/sum((pv).count))::numeric(5,4) as prop_na,
(sum((pv).count) filter (where (pv).value = 1)::numeric/sum((pv).count))::numeric(5,4) as prop_canopy,
(sum((pv).count) filter (where (pv).value = 2)::numeric/sum((pv).count))::numeric(5,4) as prop_grass,
(sum((pv).count) filter (where (pv).value = 3)::numeric/sum((pv).count))::numeric(5,4) as prop_bare,
(sum((pv).count) filter (where (pv).value = 4)::numeric/sum((pv).count))::numeric(5,4) as prop_water,
(sum((pv).count) filter (where (pv).value = 5)::numeric/sum((pv).count))::numeric(5,4) as prop_bldgs,
(sum((pv).count) filter (where (pv).value = 6)::numeric/sum((pv).count))::numeric(5,4) as prop_roads,
(sum((pv).count) filter (where (pv).value = 7)::numeric/sum((pv).count))::numeric(5,4) as prop_paved,
((sum((pv).count) filter (where (pv).value = 0)) * 0.25)::numeric(12,2) as area_na,
((sum((pv).count) filter (where (pv).value = 1)) * 0.25)::numeric(12,2) as area_canopy,
((sum((pv).count) filter (where (pv).value = 2)) * 0.25)::numeric(12,2) as area_grass,
((sum((pv).count) filter (where (pv).value = 3)) * 0.25)::numeric(12,2) as area_bare,
((sum((pv).count) filter (where (pv).value = 4)) * 0.25)::numeric(12,2) as area_water,
((sum((pv).count) filter (where (pv).value = 5)) * 0.25)::numeric(12,2) as area_bldgs,
((sum((pv).count) filter (where (pv).value = 6)) * 0.25)::numeric(12,2) as area_roads,
((sum((pv).count) filter (where (pv).value = 7)) * 0.25)::numeric(12,2) as area_paved
from cte
group by bbl, geom_2263
ORDER by bbl;
--End SQL