-- The city engineer wants to know which building footprints are all inside -- the first polygon of the lots ST_MultiPolygon. -- The building_id column uniquely identifies each row of the -- buildingfootprints table. The lot_id column identifies the building's lot. -- The footprints column stores the buildings' geometries. CREATE TABLE buildingfootprints (building_id integer, lot_id integer, footprint ST_MultiPolygon); CREATE TABLE lots (lot_id integer, lot ST_MultiPolygon); INSERT INTO buildingfootprints VALUES( 506, 1010, ST_MPolyFromText('multipolygon (((7.0 45.0,15.0 45.0,15.0 51.0,18.0 51.0,18.0 54.0,8.0 54.0,8.0 51.0,7.0 51.0,7.0 45.0)))',1000) ); INSERT INTO buildingfootprints VALUES( 543, 2930, ST_MPolyFromText('multipolygon (((26.0 55.0,38.0 55.0,38.0 48.0,34.0 48.0,34.0 50.0,26.0 50.0,26.0 55.0)))',1000) ); INSERT INTO buildingfootprints VALUES( 1208, 203, ST_MPolyFromText('multipolygon (((8.0 39.0,12.0 39.0,12.0 33.0,17.0 33.0,17.0 22.0,8.0 22.0,8.0 39.0)))',1000) ); INSERT INTO buildingfootprints VALUES( 178, 5192, ST_MPolyFromText('multipolygon (((26.0 33.0,38.0 33.0,38.0 24.0,33.0 24.0,33.0 27.0,26.0 27.0,26.0 33.0)))',1000) ); INSERT INTO lots VALUES( 1010, ST_MPolyFromText('multipolygon (((2 57,21.5 57,21.5 38,2 38,2 57)))',1000) ); INSERT INTO lots VALUES( 2930, ST_MPolyFromText('multipolygon (((21.5 57,40 57,40 38,21.5 38,21.5 57)))',1000) ); INSERT INTO lots VALUES( 203, ST_MPolyFromText('multipolygon (((21.5 38,40 38,40 20,21.5 20,21.5 38)))',1000) ); INSERT INTO lots VALUES( 5192, ST_MPolyFromText('multipolygon (((2 20,2 38,21.5 38,21.5 20,2 20)))',1000) ); -- The query lists the buildingfootprints' building_id and lot_id -- for all building footprints that are all within the first lot polygon. -- The ST_GeometryN function returns a first lot polygon element in the -- ST_MultiPolygon. SELECT bf.building_id,bf.lot_id FROM buildingfootprints bf,lots WHERE ST_Within(footprint,ST_GeometryN(lot,1)) AND bf.lot_id = lots.lot_id;