From: Bborie Park Date: Sun, 15 Dec 2013 19:24:35 +0000 (+0000) Subject: Add ST_CountAgg(). Ticket #2567 X-Git-Tag: 2.2.0rc1~1281 X-Git-Url: https://granicus.if.org/sourcecode?a=commitdiff_plain;h=b51daacc4196768e3afae442d2af78669c18641a;p=postgis Add ST_CountAgg(). Ticket #2567 git-svn-id: http://svn.osgeo.org/postgis/trunk@12161 b70326c6-7e19-0410-871a-916f4a2858ee --- diff --git a/NEWS b/NEWS index 9309047f4..acf5cbf9f 100644 --- a/NEWS +++ b/NEWS @@ -5,10 +5,12 @@ PostGIS 2.2.0 - #2565, ST_SummaryStats(tablename, rastercolumn, ...) uses ST_SummaryStatsAgg() + - #2567, ST_Count(tablename, rastercolumn, ...) uses ST_CountAgg() * Deprecated signatures * - #2565, ST_SummaryStats(tablename, rastercolumn, ...) + - #2567, ST_Count(tablename, rastercolumn, ...) * New Features * @@ -18,6 +20,7 @@ PostGIS 2.2.0 variable GDAL_DATA - #2397, read encoding info automatically in shapefile loader - #2565, ST_SummaryStatsAgg() + - #2567, ST_CountAgg() * Enhancements * diff --git a/doc/reference_raster.xml b/doc/reference_raster.xml index f9bc5f03a..7bbeb9bde 100644 --- a/doc/reference_raster.xml +++ b/doc/reference_raster.xml @@ -6593,6 +6593,7 @@ select st_bandisnodata(rast, 1) from dummy_rast where rid = 1; -- Expected true Raster Band Statistics and Analytics + ST_Count @@ -6634,6 +6635,13 @@ select st_bandisnodata(rast, 1) from dummy_rast where rid = 1; -- Expected true Returns the number of pixels in a given band of a raster or raster coverage. If no band is specified nband defaults to 1. If exclude_nodata_value is set to true, will only count pixels with value not equal to the nodata value of the raster. Set exclude_nodata_value to false to get count all pixels Availability: 2.0.0 + + + + The ST_Count(rastertable, rastercolumn, ...) variants are deprecated as of 2.2.0. Use instead. + + + @@ -6653,7 +6661,104 @@ rid | exclude_nodata | include_nodata See Also - + + , + , + + + + + + + + ST_CountAgg + + Aggregate. Returns the number of pixels in a given band of a set of rasters. If no band is specified defaults to band 1. If exclude_nodata_value is set to true, will only count pixels that are not equal to the NODATA value. + + + + + + + bigint ST_CountAgg + raster rast + integer nband + boolean exclude_nodata_value + double precision sample_percent + + + + bigint ST_CountAgg + raster rast + integer nband + boolean exclude_nodata_value + + + + bigint ST_CountAgg + raster rast + boolean exclude_nodata_value + + + + + + + Description + + Returns the number of pixels in a given band of a set of rasters. If no band is specified nband defaults to 1. + + If exclude_nodata_value is set to true, will only count pixels with value not equal to the NODATA value of the raster. Set exclude_nodata_value to false to get count all pixels + + By default will sample all pixels. To get faster response, set sample_percent to value between zero (0) and one (1) + + Availability: 2.2.0 + + + + Examples + +WITH foo AS ( + SELECT + rast.rast + FROM ( + SELECT ST_SetValue( + ST_SetValue( + ST_SetValue( + ST_AddBand( + ST_MakeEmptyRaster(10, 10, 10, 10, 2, 2, 0, 0,0) + , 1, '64BF', 0, 0 + ) + , 1, 1, 1, -10 + ) + , 1, 5, 4, 0 + ) + , 1, 5, 5, 3.14159 + ) AS rast + ) AS rast + FULL JOIN ( + SELECT generate_series(1, 10) AS id + ) AS id + ON 1 = 1 +) +SELECT + ST_CountAgg(rast, 1, TRUE) +FROM foo; + + st_countagg +------------- + 20 +(1 row) + + + + + See Also + + , + , + + diff --git a/raster/rt_pg/rtpostgis.sql.in b/raster/rt_pg/rtpostgis.sql.in index 16c03fd59..d50ab37e3 100644 --- a/raster/rt_pg/rtpostgis.sql.in +++ b/raster/rt_pg/rtpostgis.sql.in @@ -551,7 +551,7 @@ CREATE OR REPLACE FUNCTION _st_summarystats( stats summarystats; BEGIN EXECUTE 'SELECT (stats).* FROM (SELECT ST_SummaryStatsAgg(' - || $2 || ', ' + || quote_ident($2) || ', ' || $3 || ', ' || $4 || ', ' || $5 || ') AS stats ' @@ -620,10 +620,10 @@ CREATE OR REPLACE FUNCTION st_approxsummarystats( AS $$ SELECT _st_summarystats($1, $2, 1, TRUE, $3) $$ LANGUAGE 'sql' STABLE STRICT; - ----------------------------------------------------------------------- -- ST_Count and ST_ApproxCount ----------------------------------------------------------------------- + CREATE OR REPLACE FUNCTION _st_count(rast raster, nband int DEFAULT 1, exclude_nodata_value boolean DEFAULT TRUE, sample_percent double precision DEFAULT 1) RETURNS bigint AS $$ @@ -670,69 +670,190 @@ CREATE OR REPLACE FUNCTION st_approxcount(rast raster, sample_percent double pre AS $$ SELECT _st_count($1, 1, TRUE, $2) $$ LANGUAGE 'sql' IMMUTABLE STRICT; -CREATE OR REPLACE FUNCTION _st_count(rastertable text, rastercolumn text, nband integer DEFAULT 1, exclude_nodata_value boolean DEFAULT TRUE, sample_percent double precision DEFAULT 1) +----------------------------------------------------------------------- +-- ST_CountAgg +----------------------------------------------------------------------- + +CREATE TYPE agg_count AS ( + count bigint, + nband integer, + exclude_nodata_value boolean, + sample_percent double precision +); + +CREATE OR REPLACE FUNCTION _st_countagg_finalfn(agg agg_count) RETURNS bigint AS $$ - DECLARE - curs refcursor; + BEGIN + IF agg IS NULL THEN + RAISE EXCEPTION 'Cannot count coverage'; + END IF; - ctable text; - ccolumn text; - rast raster; + RETURN agg.count; + END; + $$ LANGUAGE 'plpgsql' IMMUTABLE; - rtn bigint; - tmp bigint; +CREATE OR REPLACE FUNCTION __st_countagg_transfn( + agg agg_count, + rast raster, + nband integer DEFAULT 1, exclude_nodata_value boolean DEFAULT TRUE, + sample_percent double precision DEFAULT 1 +) + RETURNS agg_count + AS $$ + DECLARE + _count bigint; + rtn_agg agg_count; BEGIN - -- nband - IF nband < 1 THEN - RAISE WARNING 'Invalid band index (must use 1-based). Returning NULL'; - RETURN NULL; - END IF; - -- sample percent - IF sample_percent < 0 OR sample_percent > 1 THEN - RAISE WARNING 'Invalid sample percentage (must be between 0 and 1). Returning NULL'; - RETURN NULL; + -- only process parameter args once + IF agg IS NULL THEN + rtn_agg.count := 0; + + IF nband < 1 THEN + RAISE EXCEPTION 'Band index must be greater than zero (1-based)'; + ELSE + rtn_agg.nband := nband; + END IF; + + IF exclude_nodata_value IS FALSE THEN + rtn_agg.exclude_nodata_value := FALSE; + ELSE + rtn_agg.exclude_nodata_value := TRUE; + END IF; + + IF sample_percent < 0. OR sample_percent > 1. THEN + RAISE EXCEPTION 'Sample percent must be between zero and one'; + ELSE + rtn_agg.sample_percent := sample_percent; + END IF; + ELSE + rtn_agg := agg; END IF; - -- exclude_nodata_value IS TRUE - IF exclude_nodata_value IS TRUE THEN - SELECT count INTO rtn FROM _st_summarystats($1, $2, $3, $4, $5); - RETURN rtn; + IF rast IS NOT NULL THEN + IF rtn_agg.exclude_nodata_value IS FALSE THEN + SELECT width * height INTO _count FROM ST_Metadata(rast); + ELSE + SELECT count INTO _count FROM _st_summarystats( + rast, + rtn_agg.nband, rtn_agg.exclude_nodata_value, + rtn_agg.sample_percent + ); + END IF; END IF; - -- clean rastertable and rastercolumn - ctable := quote_ident(rastertable); - ccolumn := quote_ident(rastercolumn); + rtn_agg.count := rtn_agg.count + _count; + RETURN rtn_agg; + END; + $$ LANGUAGE 'plpgsql' IMMUTABLE; - BEGIN - OPEN curs FOR EXECUTE 'SELECT ' - || ccolumn - || ' FROM ' - || ctable - || ' WHERE ' - || ccolumn - || ' IS NOT NULL'; - EXCEPTION - WHEN OTHERS THEN - RAISE WARNING 'Invalid table or column name. Returning NULL'; - RETURN NULL; - END; +CREATE OR REPLACE FUNCTION _st_countagg_transfn( + agg agg_count, + rast raster, + nband integer, exclude_nodata_value boolean, + sample_percent double precision +) + RETURNS agg_count + AS $$ + DECLARE + rtn_agg agg_count; + BEGIN + rtn_agg := __st_countagg_transfn( + agg, + rast, + nband, exclude_nodata_value, + sample_percent + ); + RETURN rtn_agg; + END; + $$ LANGUAGE 'plpgsql' IMMUTABLE; - rtn := 0; - LOOP - FETCH curs INTO rast; - EXIT WHEN NOT FOUND; +CREATE AGGREGATE st_countagg( + raster, + integer, boolean, + double precision +) ( + SFUNC = _st_countagg_transfn, + STYPE = agg_count, + FINALFUNC = _st_countagg_finalfn +); - SELECT (width * height) INTO tmp FROM ST_Metadata(rast); - rtn := rtn + tmp; - END LOOP; +CREATE OR REPLACE FUNCTION _st_countagg_transfn( + agg agg_count, + rast raster, + nband integer, exclude_nodata_value boolean +) + RETURNS agg_count + AS $$ + DECLARE + rtn_agg agg_count; + BEGIN + rtn_agg := __st_countagg_transfn( + agg, + rast, + nband, exclude_nodata_value, + 1 + ); + RETURN rtn_agg; + END; + $$ LANGUAGE 'plpgsql' IMMUTABLE; - CLOSE curs; +CREATE AGGREGATE st_countagg( + raster, + integer, boolean +) ( + SFUNC = _st_countagg_transfn, + STYPE = agg_count, + FINALFUNC = _st_countagg_finalfn +); - RETURN rtn; +CREATE OR REPLACE FUNCTION _st_countagg_transfn( + agg agg_count, + rast raster, + exclude_nodata_value boolean +) + RETURNS agg_count + AS $$ + DECLARE + rtn_agg agg_count; + BEGIN + rtn_agg := __st_countagg_transfn( + agg, + rast, + 1, exclude_nodata_value, + 1 + ); + RETURN rtn_agg; END; - $$ LANGUAGE 'plpgsql' STABLE STRICT; + $$ LANGUAGE 'plpgsql' IMMUTABLE; + +CREATE AGGREGATE st_countagg(raster, boolean) ( + SFUNC = _st_countagg_transfn, + STYPE = agg_count, + FINALFUNC = _st_countagg_finalfn +); + +----------------------------------------------------------------------- +-- ST_Count for table +----------------------------------------------------------------------- + +CREATE OR REPLACE FUNCTION _st_count(rastertable text, rastercolumn text, nband integer DEFAULT 1, exclude_nodata_value boolean DEFAULT TRUE, sample_percent double precision DEFAULT 1) + RETURNS bigint + AS $$ + DECLARE + count bigint; + BEGIN + EXECUTE 'SELECT ST_CountAgg(' + || quote_ident($2) || ', ' + || $3 || ', ' + || $4 || ', ' + || $5 || ') ' + || 'FROM ' || quote_ident($1) + INTO count; + RETURN count; + END; + $$ LANGUAGE 'plpgsql' STABLE STRICT; CREATE OR REPLACE FUNCTION st_count(rastertable text, rastercolumn text, nband int DEFAULT 1, exclude_nodata_value boolean DEFAULT TRUE) RETURNS bigint @@ -767,6 +888,7 @@ CREATE OR REPLACE FUNCTION st_approxcount(rastertable text, rastercolumn text, s ----------------------------------------------------------------------- -- ST_Histogram and ST_ApproxHistogram ----------------------------------------------------------------------- + -- Cannot be strict as "width", "min" and "max" can be NULL CREATE OR REPLACE FUNCTION _st_histogram( rast raster, nband int DEFAULT 1, diff --git a/raster/rt_pg/rtpostgis_drop.sql.in b/raster/rt_pg/rtpostgis_drop.sql.in index 86f711838..5f20ab1ab 100644 --- a/raster/rt_pg/rtpostgis_drop.sql.in +++ b/raster/rt_pg/rtpostgis_drop.sql.in @@ -511,3 +511,8 @@ DROP FUNCTION IF EXISTS _st_slope4ma(float8[], text, text[]); DROP AGGREGATE IF EXISTS ST_SummaryStatsAgg(raster, integer, boolean, double precision); DROP AGGREGATE IF EXISTS ST_SummaryStatsAgg(raster, boolean, double precision); DROP AGGREGATE IF EXISTS ST_SummaryStatsAgg(raster, integer, boolean); + +-- drop aggregates +DROP AGGREGATE IF EXISTS ST_CountAgg(raster, integer, boolean, double precision); +DROP AGGREGATE IF EXISTS ST_CountAgg(raster, integer, boolean); +DROP AGGREGATE IF EXISTS ST_CountAgg(raster, boolean); diff --git a/raster/test/regress/rt_count.sql b/raster/test/regress/rt_count.sql index 39f7bd894..5c0c22be7 100644 --- a/raster/test/regress/rt_count.sql +++ b/raster/test/regress/rt_count.sql @@ -90,4 +90,24 @@ SELECT ST_Count('test', 'rast', 1, FALSE); SELECT ST_Count('test', 'rast', 1); SELECT ST_Count('test', 'rast', FALSE); SELECT ST_Count('test', 'rast'); + +SELECT ST_CountAgg(rast, 1, TRUE, 1) FROM test; +SELECT ST_CountAgg(rast, 1, TRUE, 0) FROM test; +SELECT ST_CountAgg(rast, 1, FALSE, 1) FROM test; +SELECT ST_CountAgg(rast, 1, FALSE, 0) FROM test; +SELECT ST_CountAgg(rast, 1, TRUE) FROM test; +SELECT ST_CountAgg(rast, 1, FALSE) FROM test; +SELECT ST_CountAgg(rast, TRUE) FROM test; +SELECT ST_CountAgg(rast, FALSE) FROM test; + +SAVEPOINT test; +SELECT ST_CountAgg(rast, 2, TRUE) FROM test; +ROLLBACK TO SAVEPOINT test; +RELEASE SAVEPOINT test; + +SAVEPOINT test; +SELECT ST_CountAgg(rast, 1, TRUE, 2) FROM test; +ROLLBACK TO SAVEPOINT test; +RELEASE SAVEPOINT test; + ROLLBACK; diff --git a/raster/test/regress/rt_count_expected b/raster/test/regress/rt_count_expected index 5e8f6c689..11c5664a1 100644 --- a/raster/test/regress/rt_count_expected +++ b/raster/test/regress/rt_count_expected @@ -8,4 +8,29 @@ BEGIN 20 1000 20 +20 +20 +1000 +1000 +20 +1000 +20 +1000 +SAVEPOINT +NOTICE: Invalid band index (must use 1-based). Returning NULL +NOTICE: Invalid band index (must use 1-based). Returning NULL +NOTICE: Invalid band index (must use 1-based). Returning NULL +NOTICE: Invalid band index (must use 1-based). Returning NULL +NOTICE: Invalid band index (must use 1-based). Returning NULL +NOTICE: Invalid band index (must use 1-based). Returning NULL +NOTICE: Invalid band index (must use 1-based). Returning NULL +NOTICE: Invalid band index (must use 1-based). Returning NULL +NOTICE: Invalid band index (must use 1-based). Returning NULL +NOTICE: Invalid band index (must use 1-based). Returning NULL +COMMIT +RELEASE +SAVEPOINT +ERROR: Sample percent must be between zero and one +COMMIT +RELEASE COMMIT