Skip to content

Instantly share code, notes, and snippets.

@justinlewis
Created January 30, 2013 18:03
Show Gist options
  • Save justinlewis/4675247 to your computer and use it in GitHub Desktop.
Save justinlewis/4675247 to your computer and use it in GitHub Desktop.
Creates polygon boundaries around clusters of polygons. Implemented as a PostGIS function. Inputs include data table, geometry field (built for polygon), unique id, and radius (distance between clustered polygons).
-- Function: public.polygon_clusters(character varying, character varying, character varying, numeric)
-- DROP FUNCTION public.polygon_clusters(character varying, character varying, character varying, numeric);
CREATE OR REPLACE FUNCTION public.polygon_clusters(parcels character varying, geom character varying, gid character varying, radius numeric)
RETURNS SETOF record AS
$BODY$
DECLARE
lid_new integer;
dmn_number integer := 1;
outr record;
innr record;
r record;
BEGIN
DROP TABLE IF EXISTS tmp;
EXECUTE 'CREATE TEMPORARY TABLE tmp AS SELECT '||gid||', '||geom||' FROM '||parcels;
ALTER TABLE tmp ADD COLUMN dmn integer;
ALTER TABLE tmp ADD COLUMN chk boolean DEFAULT FALSE;
EXECUTE 'UPDATE tmp SET dmn = '||dmn_number||', chk = FALSE WHERE '||gid||' = (SELECT MIN('||gid||') FROM tmp)';
LOOP
LOOP
FOR outr IN EXECUTE 'SELECT '||gid||' AS gid, '||geom||' AS geom FROM tmp WHERE dmn = '||dmn_number||' AND NOT chk' LOOP
FOR innr IN EXECUTE 'SELECT '||gid||' AS gid, '||geom||' AS geom FROM tmp WHERE dmn IS NULL' LOOP
-- IF ST_DWithin(ST_Transform(ST_SetSRID(outr.geom, 4326), 3785), ST_Transform(ST_SetSRID(innr.geom, 4326), 3785), radius) THEN
IF ST_DWithin(outr.geom, innr.geom, radius) THEN
EXECUTE 'UPDATE tmp SET dmn = '||dmn_number||', chk = FALSE WHERE '||gid||' = '||innr.gid;
END IF;
END LOOP;
EXECUTE 'UPDATE tmp SET chk = TRUE WHERE '||gid||' = '||outr.gid;
END LOOP;
SELECT INTO r dmn FROM tmp WHERE dmn = dmn_number AND NOT chk LIMIT 1;
EXIT WHEN NOT FOUND;
END LOOP;
SELECT INTO r dmn FROM tmp WHERE dmn IS NULL LIMIT 1;
IF FOUND THEN
dmn_number := dmn_number + 1;
EXECUTE 'UPDATE tmp SET dmn = '||dmn_number||', chk = FALSE WHERE '||gid||' = (SELECT MIN('||gid||') FROM tmp WHERE dmn IS NULL LIMIT 1)';
ELSE
EXIT;
END IF;
END LOOP;
RETURN QUERY EXECUTE 'SELECT ST_ConvexHull(ST_Collect('||geom||')) FROM tmp GROUP by dmn';
RETURN;
END
$BODY$
LANGUAGE plpgsql VOLATILE
COST 100
ROWS 1000;
ALTER FUNCTION public.polygon_clusters(character varying, character varying, character varying, numeric)
OWNER TO model_team;
Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment