1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 27 28 29 30 31 32 33 34 35 36 37 38 39 40 41 42 43 44 45 46 47 48 49 50 51 52 53 54 55 56 57 58 59 60 61 62 63 64 65 66 67 68 69 70 71 72 73 74 75 76 77 78 79 80 81 82 83 84 85 86 87 88 89 90 91 92 93 94 95 96 97 98 99 100 101 102 103 104 105 106 107 108 109 110 111 112 113 114 115 116 117 118 119 120 121 122 123 124 125 126 127 128 129 130 131 132 133 134 135 136 137 138 139 140 141 142 143 144 145 146 147 148 149 150 151 152 153 154 155 156 157 158 159 160 161 162 163 164 165 166 167 168 169 170 171 172 173 174 175 176 177 178 179 180 181 182 183 184 185 186 187 188 189 190 191 192 193 194 195 196 197 198 199 200 201 202 203 204 205 206 207 208 209 210 211 212 213 214 215 216 217 218 219 220 221 222 223 224 225 226 227 228 229 230 231 232 233 234 235 236 237 238 239 240 241 242 243 244 245 246 247 248 249 250 251 252 253 254 255 256 257 258 259 260 261 262 263 264 265 266 267 268 269 270 271 272 273 274 275 276 277 278 279 280 281 282 283 284 285 286 287 288 289 290 291 292 293 294 295 296 297 298 299 300 301 302 303 304 305 306 307 308 309 310 311 312 313 314 315 316 317 318 319 320 321 322 323 324 325 326 327 328 329 330 331 332 333 334 335 336 337 338 339 340 341 342 343 344 345 346 347 348 349 350 351 352 353 354 355 356 357 358 359 360 361 362 363 364 365 366 367 368 369 370 371 372 373 374 375 376 377 378 379
|
SET client_min_messages TO warning;
/*
1 1 1 1 1 1 1 1 1
1 2 2 2 1 2 2 2 1
1 2 3 2 2 2 3 2 1
1 2 2 2 1 2 2 2 1
1 1 2 1 3 1 2 1 1
1 2 2 2 1 2 2 2 1
1 2 3 2 2 2 3 2 1
1 2 2 2 1 2 2 2 1
1 1 1 1 1 1 1 1 1
*/
DROP TABLE IF EXISTS raster_elevation;
CREATE TABLE raster_elevation (rid integer, rast raster);
DROP TABLE IF EXISTS raster_elevation_out;
CREATE TABLE raster_elevation_out (rid integer, functype text, rast raster);
INSERT INTO raster_elevation
SELECT
0 AS rid,
ST_SetValues(
ST_AddBand(ST_MakeEmptyRaster(9, 9, 0, 0, 1, -1, 0, 0, 0), 1, '32BF', 0, -9999),
1, 1, 1, ARRAY[
[1, 1, 1, 1, 1, 1, 1, 1, 1],
[1, 2, 2, 2, 1, 2, 2, 2, 1],
[1, 2, 3, 2, 2, 2, 3, 2, 1],
[1, 2, 2, 2, 1, 2, 2, 2, 1],
[1, 1, 2, 1, 3, 1, 2, 1, 1],
[1, 2, 2, 2, 1, 2, 2, 2, 1],
[1, 2, 3, 2, 2, 2, 3, 2, 1],
[1, 2, 2, 2, 1, 2, 2, 2, 1],
[1, 1, 1, 1, 1, 1, 1, 1, 1]
]::double precision[]
) AS rast
;
INSERT INTO raster_elevation
SELECT
1 AS rid,
ST_SetValues(
ST_AddBand(ST_MakeEmptyRaster(3, 3, 0, 0, 1, -1, 0, 0, 0), 1, '32BF', 0, -9999),
1, 1, 1, ARRAY[
[1, 1, 1],
[1, 2, 2],
[1, 2, 3]
]::double precision[]
) AS rast
UNION ALL
SELECT
2 AS rid,
ST_SetValues(
ST_AddBand(ST_MakeEmptyRaster(3, 3, 0, -3, 1, -1, 0, 0, 0), 1, '32BF', 0, -9999),
1, 1, 1, ARRAY[
[1, 2, 2],
[1, 1, 2],
[1, 2, 2]
]::double precision[]
) AS rast
UNION ALL
SELECT
3 AS rid,
ST_SetValues(
ST_AddBand(ST_MakeEmptyRaster(3, 3, 0, -6, 1, -1, 0, 0, 0), 1, '32BF', 0, -9999),
1, 1, 1, ARRAY[
[1, 2, 3],
[1, 2, 2],
[1, 1, 1]
]::double precision[]
) AS rast
UNION ALL
SELECT
4 AS rid,
ST_SetValues(
ST_AddBand(ST_MakeEmptyRaster(3, 3, 3, 0, 1, -1, 0, 0, 0), 1, '32BF', 0, -9999),
1, 1, 1, ARRAY[
[1, 1, 1],
[2, 1, 2],
[2, 2, 2]
]::double precision[]
) AS rast
UNION ALL
SELECT
5 AS rid,
ST_SetValues(
ST_AddBand(ST_MakeEmptyRaster(3, 3, 3, -3, 1, -1, 0, 0, 0), 1, '32BF', 0, -9999),
1, 1, 1, ARRAY[
[2, 1, 2],
[1, 3, 1],
[2, 1, 2]
]::double precision[]
) AS rast
UNION ALL
SELECT
6 AS rid,
ST_SetValues(
ST_AddBand(ST_MakeEmptyRaster(3, 3, 3, -6, 1, -1, 0, 0, 0), 1, '32BF', 0, -9999),
1, 1, 1, ARRAY[
[2, 2, 2],
[2, 1, 2],
[1, 1, 1]
]::double precision[]
) AS rast
UNION ALL
SELECT
7 AS rid,
ST_SetValues(
ST_AddBand(ST_MakeEmptyRaster(3, 3, 6, 0, 1, -1, 0, 0, 0), 1, '32BF', 0, -9999),
1, 1, 1, ARRAY[
[1, 1, 1],
[2, 2, 1],
[3, 2, 1]
]::double precision[]
) AS rast
UNION ALL
SELECT
8 AS rid,
ST_SetValues(
ST_AddBand(ST_MakeEmptyRaster(3, 3, 6, -3, 1, -1, 0, 0, 0), 1, '32BF', 0, -9999),
1, 1, 1, ARRAY[
[2, 2, 1],
[2, 1, 1],
[2, 2, 1]
]::double precision[]
) AS rast
UNION ALL
SELECT
9 AS rid,
ST_SetValues(
ST_AddBand(ST_MakeEmptyRaster(3, 3, 6, -6, 1, -1, 0, 0, 0), 1, '32BF', 0, -9999),
1, 1, 1, ARRAY[
[3, 2, 1],
[2, 2, 1],
[1, 1, 1]
]::double precision[]
) AS rast
;
/* ST_Slope */
INSERT INTO raster_elevation_out
SELECT
rid,
'slope',
ST_Slope(rast)
FROM raster_elevation
WHERE rid = 0
UNION ALL
SELECT
rid,
'aspect',
ST_Aspect(rast)
FROM raster_elevation
WHERE rid = 0
UNION ALL
SELECT
rid,
'hillshade',
ST_Hillshade(rast)
FROM raster_elevation
WHERE rid = 0
;
/* with coverage */
DO $$
BEGIN
-- this ONLY works for PostgreSQL version 9.1 or higher
IF array_to_string(regexp_matches(split_part(version(), ' ', 2), E'([0-9]+)\.([0-9]+)'), '')::int > 90 THEN
INSERT INTO raster_elevation_out (
SELECT
t1.rid,
'slope',
ST_Slope(ST_Union(t2.rast), 1, t1.rast) AS rast
FROM raster_elevation t1
CROSS JOIN raster_elevation t2
WHERE t1.rid != 0
AND t2.rid != 0
AND ST_Intersects(t1.rast, t2.rast)
GROUP BY t1.rid, t1.rast
ORDER BY t1.rid
) UNION ALL (
SELECT
t1.rid,
'aspect',
ST_Aspect(ST_Union(t2.rast), 1, t1.rast) AS rast
FROM raster_elevation t1
CROSS JOIN raster_elevation t2
WHERE t1.rid != 0
AND t2.rid != 0
AND ST_Intersects(t1.rast, t2.rast)
GROUP BY t1.rid, t1.rast
ORDER BY t1.rid
) UNION ALL (
SELECT
t1.rid,
'hillshade',
ST_Hillshade(ST_Union(t2.rast), 1, t1.rast) AS rast
FROM raster_elevation t1
CROSS JOIN raster_elevation t2
WHERE t1.rid != 0
AND t2.rid != 0
AND ST_Intersects(t1.rast, t2.rast)
GROUP BY t1.rid, t1.rast
ORDER BY t1.rid
);
ELSE
INSERT INTO raster_elevation_out (
WITH foo AS (
SELECT
t1.rid,
ST_Union(t2.rast) AS rast
FROM raster_elevation t1
JOIN raster_elevation t2
ON ST_Intersects(t1.rast, t2.rast)
AND t1.rid != 0
AND t2.rid != 0
GROUP BY t1.rid
)
SELECT
t1.rid,
'slope',
ST_Slope(t2.rast, 1, t1.rast) AS rast
FROM raster_elevation t1
JOIN foo t2
ON t1.rid = t2.rid
ORDER BY t1.rid
) UNION ALL (
WITH foo AS (
SELECT
t1.rid,
ST_Union(t2.rast) AS rast
FROM raster_elevation t1
JOIN raster_elevation t2
ON ST_Intersects(t1.rast, t2.rast)
AND t1.rid != 0
AND t2.rid != 0
GROUP BY t1.rid
)
SELECT
t1.rid,
'aspect',
ST_Aspect(t2.rast, 1, t1.rast) AS rast
FROM raster_elevation t1
JOIN foo t2
ON t1.rid = t2.rid
ORDER BY t1.rid
) UNION ALL (
WITH foo AS (
SELECT
t1.rid,
ST_Union(t2.rast) AS rast
FROM raster_elevation t1
JOIN raster_elevation t2
ON ST_Intersects(t1.rast, t2.rast)
AND t1.rid != 0
AND t2.rid != 0
GROUP BY t1.rid
)
SELECT
t1.rid,
'hillshade',
ST_Hillshade(t2.rast, 1, t1.rast) AS rast
FROM raster_elevation t1
JOIN foo t2
ON t1.rid = t2.rid
ORDER BY t1.rid
);
END IF;
END $$;
WITH foo AS (
SELECT
rid,
functype,
ST_PixelAsPoints(rast) AS papt
FROM raster_elevation_out
)
SELECT
rid,
functype,
(papt).x,
(papt).y,
round((papt).val::numeric, 6) AS val
FROM foo
ORDER BY 2, 1, 4, 3;
DROP TABLE IF EXISTS raster_elevation_out;
DROP TABLE IF EXISTS raster_elevation;
-- ST_TPI
DROP TABLE IF EXISTS raster_value_arrays;
CREATE TABLE raster_value_arrays (
id integer,
val double precision[][]
);
CREATE OR REPLACE FUNCTION make_value_array(
rows integer DEFAULT 3,
columns integer DEFAULT 3,
start_val double precision DEFAULT 1,
step double precision DEFAULT 1,
skip_expr text DEFAULT NULL
)
RETURNS double precision[][][]
AS $$
DECLARE
x int;
y int;
value double precision;
values double precision[][][];
result boolean;
expr text;
BEGIN
value := start_val;
values := array_fill(NULL::double precision, ARRAY[1, columns, rows]);
FOR y IN 1..columns LOOP
FOR x IN 1..rows LOOP
IF skip_expr IS NULL OR length(skip_expr) < 1 THEN
result := TRUE;
ELSE
expr := replace(skip_expr, '[v]'::text, value::text);
EXECUTE 'SELECT (' || expr || ')::boolean' INTO result;
END IF;
IF result IS TRUE THEN
values[1][y][x] := value;
END IF;
value := value + step;
END LOOP;
END LOOP;
RETURN values;
END;
$$ LANGUAGE 'plpgsql';
INSERT INTO raster_value_arrays VALUES
(1, make_value_array()),
(2, make_value_array(3, 3, 15, -1)),
(3, make_value_array(3, 3, 1, 2)),
(4, make_value_array(3, 3, 1, 1, '0')),
(5, make_value_array(3, 3, 1, 1, '[v] % 2')),
(6, make_value_array(3, 3, 1, 1, '([v] % 2) = 0')),
(7, make_value_array(3, 3, 1, 2.1, '([v] NOT IN (7.3, 9.4, 15.7, 17.8))')),
(8, make_value_array(3, 3, 0, 3.14, '([v] IN (3.14, 12.56, 25.12))')),
(9, make_value_array(3, 3, 1, 1, '[v] > 8')),
(10,make_value_array(3,3,3.14,12)),
(11,make_value_array(3,3,2.11,11));
SELECT
id,
val,
round(_st_tpi4ma(val,NULL,NULL)::numeric, 6) as tpi
FROM raster_value_arrays
ORDER BY id;
SELECT
id,
val,
round(_st_roughness4ma(val,NULL,NULL)::numeric, 6) as roughness
FROM raster_value_arrays
ORDER BY id;
SELECT
id,
val,
round(_st_tri4ma(val,NULL,NULL)::numeric, 6) as tri
FROM raster_value_arrays
ORDER BY id;
DROP TABLE IF EXISTS raster_value_arrays;
DROP FUNCTION IF EXISTS make_value_array(integer,integer,double precision, double precision, text);
|