-
Notifications
You must be signed in to change notification settings - Fork 11
/
rastscratch.sql
817 lines (746 loc) · 31.9 KB
/
rastscratch.sql
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
380
381
382
383
384
385
386
387
388
389
390
391
392
393
394
395
396
397
398
399
400
401
402
403
404
405
406
407
408
409
410
411
412
413
414
415
416
417
418
419
420
421
422
423
424
425
426
427
428
429
430
431
432
433
434
435
436
437
438
439
440
441
442
443
444
445
446
447
448
449
450
451
452
453
454
455
456
457
458
459
460
461
462
463
464
465
466
467
468
469
470
471
472
473
474
475
476
477
478
479
480
481
482
483
484
485
486
487
488
489
490
491
492
493
494
495
496
497
498
499
500
501
502
503
504
505
506
507
508
509
510
511
512
513
514
515
516
517
518
519
520
521
522
523
524
525
526
527
528
529
530
531
532
533
534
535
536
537
538
539
540
541
542
543
544
545
546
547
548
549
550
551
552
553
554
555
556
557
558
559
560
561
562
563
564
565
566
567
568
569
570
571
572
573
574
575
576
577
578
579
580
581
582
583
584
585
586
587
588
589
590
591
592
593
594
595
596
597
598
599
600
601
602
603
604
605
606
607
608
609
610
611
612
613
614
615
616
617
618
619
620
621
622
623
624
625
626
627
628
629
630
631
632
633
634
635
636
637
638
639
640
641
642
643
644
645
646
647
648
649
650
651
652
653
654
655
656
657
658
659
660
661
662
663
664
665
666
667
668
669
670
671
672
673
674
675
676
677
678
679
680
681
682
683
684
685
686
687
688
689
690
691
692
693
694
695
696
697
698
699
700
701
702
703
704
705
706
707
708
709
710
711
712
713
714
715
716
717
718
719
720
721
722
723
724
725
726
727
728
729
730
731
732
733
734
735
736
737
738
739
740
741
742
743
744
745
746
747
748
749
750
751
752
753
754
755
756
757
758
759
760
761
762
763
764
765
766
767
768
769
770
771
772
773
774
775
776
777
778
779
780
781
782
783
784
785
786
787
788
789
790
791
792
793
794
795
796
797
798
799
800
801
802
803
804
805
806
807
808
809
810
811
812
813
814
815
816
state: obs_624e5d2362e08aaa5463d7671e7748432262719c
counties: obs_1babf5a26a1ecda5fb74963e88408f71d0364b81
blockgroups: obs_c6fb99c47d61289fbb8e561ff7773799d3fcc308
censustracts: obs_fc050f0b8673cfe3c6aa1040f749eb40975691b7 '36047031300'
CREATE TABLE testraster (rastergeom raster);
DELETE FROM testraster;
INSERT INTO testraster
SELECT ST_AsRaster(ST_Transform(the_geom, 3857), 1, 1)
FROM observatory.obs_1babf5a26a1ecda5fb74963e88408f71d0364b81
WHERE geoid = '36047';
select st_tile(rastergeom, 1, 1) from testraster;
select st_pixelaspolygons(rastergeom) from testraster;
-- generate an 80 x 80 map with 2x1 pixels (8bit unsigned)
SELECT st_asraster(the_geom, 80, 80, 1, 1, '8BUI', 511, 0)
FROM observatory.obs_1babf5a26a1ecda5fb74963e88408f71d0364b81 WHERE geoid = '36061';
SELECT st_asraster(the_geom, 80, 80, 1, 1, '8BUI', 511, 0)
FROM observatory.obs_624e5d2362e08aaa5463d7671e7748432262719c WHERE geoid = '36';
--SELECT x, y, val, ST_AsText(geom) FROM (
--SELECT (ST_PixelAsPolygons(rast, 1)).* FROM (
--SELECT st_asraster(the_geom, 80, 80, 1, 1, '8BUI', 511, 0) rast
--FROM observatory.obs_624e5d2362e08aaa5463d7671e7748432262719c WHERE geoid = '36'
--) foo) bar;
--SELECT x, y, COUNT(*) FROM observatory.obs_c6fb99c47d61289fbb8e561ff7773799d3fcc308 bg, (
--SELECT (ST_PixelAsPolygons(rast, 1)).* FROM (
--SELECT st_asraster(st_setsrid(st_extent(the_geom), 4326), 80, 80, 1, 1, '8BUI', 511, 0) rast
--FROM observatory.obs_c6fb99c47d61289fbb8e561ff7773799d3fcc308
--) foo) ny
--WHERE ST_Intersects(ny.geom, bg.the_geom)
--GROUP BY x, y
--;
--CREATE TABLE valuetable AS
--SELECT x, y, COUNT(*) / 1333 cnt FROM observatory.obs_c6fb99c47d61289fbb8e561ff7773799d3fcc308 bg, (
--SELECT (ST_PixelAsPolygons(rast, 1)).* FROM (
--SELECT st_asraster(st_setsrid(st_extent(the_geom), 4326), 80, 80, 1, 1, '8BUI', 511, 0) rast
--FROM observatory.obs_c6fb99c47d61289fbb8e561ff7773799d3fcc308
--) foo) ny
--WHERE ST_Intersects(ny.geom, bg.the_geom)
--GROUP BY x, y
--;
-- intersects: SELECT 13278 Time: 240768.308 ms
-- &&: SELECT 38484 Time: 202327.136 ms
DROP TABLE IF EXISTS valuetable ;
CREATE TABLE valuetable AS
SELECT geom, COUNT(*) / ST_Area(geom) density
FROM observatory.obs_c6fb99c47d61289fbb8e561ff7773799d3fcc308 bg, (
SELECT (ST_PixelAsPolygons(rast, 1)).* FROM (
SELECT st_asraster(st_setsrid(st_extent(the_geom), 4326),
(st_xmax(st_transform(st_setsrid(st_extent(the_geom)::geometry, 4326), 3857))
- st_xmin(st_transform(st_setsrid(st_extent(the_geom)::geometry, 4326), 3857)))::INT
/ (1600 * 1000),
(st_ymax(st_transform(st_setsrid(st_extent(the_geom)::geometry, 4326), 3857))
- st_ymin(st_transform(st_setsrid(st_extent(the_geom)::geometry, 4326), 3857)))::INT
/ (1600 * 1000),
1.0,
1.0, '8BUI', 1, 0) rast
FROM observatory.obs_c6fb99c47d61289fbb8e561ff7773799d3fcc308
) foo) us
WHERE us.geom && bg.the_geom
GROUP BY geom
;
DROP TABLE IF EXISTS testraster ;
CREATE TABLE testraster AS
SELECT st_asraster(st_setsrid(st_extent(the_geom), 4326), 80, 40, array['8BUI', '8BUI', '8BUI'], array[4,5,6], array[0,1,2]) rastergeom
FROM observatory.obs_c6fb99c47d61289fbb8e561ff7773799d3fcc308;
UPDATE testraster
SET rastergeom = ST_SetValues(rastergeom, 1,
(SELECT array_agg(row(geom, cnt)::geomval) from valuetable));
-- example, for ascii rep
WITH emptyraster as (
SELECT ST_AsRaster(
st_setsrid(st_extent(the_geom), 4326),
(st_xmax(st_transform(st_setsrid(st_extent(the_geom)::geometry, 4326), 3857))
- st_xmin(st_transform(st_setsrid(st_extent(the_geom)::geometry, 4326), 3857)))::INT
/ (1600 * 50),
(st_ymax(st_transform(st_setsrid(st_extent(the_geom)::geometry, 4326), 3857))
- st_ymin(st_transform(st_setsrid(st_extent(the_geom)::geometry, 4326), 3857)))::INT
/ (1600 * 50), '8BUI', 0, 0
) geom
FROM observatory.obs_c6fb99c47d61289fbb8e561ff7773799d3fcc308 blockgroups
WHERE ST_Intersects(the_geom, st_makeenvelope(-128.27,22.51,-62.44,52.61, 4326))
),
pixels as (SELECT ARRAY_AGG(val) vals FROM
(SELECT ROW(geom, COUNT(bg) / (ST_Area(geom) * 100))::geomval val
FROM (
SELECT (ST_PixelAsPolygons(rast, 1, True)).* FROM (
SELECT st_asraster(st_setsrid(st_extent(the_geom), 4326),
(st_xmax(st_transform(st_setsrid(st_extent(the_geom)::geometry, 4326), 3857))
- st_xmin(st_transform(st_setsrid(st_extent(the_geom)::geometry, 4326), 3857)))::INT
/ (1600 * 50),
(st_ymax(st_transform(st_setsrid(st_extent(the_geom)::geometry, 4326), 3857))
- st_ymin(st_transform(st_setsrid(st_extent(the_geom)::geometry, 4326), 3857)))::INT
/ (1600 * 50),
1.0,
1.0, '8BUI', 1, 0) rast
FROM observatory.obs_c6fb99c47d61289fbb8e561ff7773799d3fcc308
) foo) us JOIN observatory.obs_c6fb99c47d61289fbb8e561ff7773799d3fcc308 bg
ON us.geom && bg.the_geom
WHERE ST_Intersects(geom, st_makeenvelope(-128.27,22.51,-62.44,52.61, 4326))
GROUP BY geom
) bar)
SELECT ST_SetValues(
(SELECT geom FROM emptyraster), 1, (SELECT vals from pixels)
) geom, 'blockgroup' as name
;
-- money!
DROP TABLE IF EXISTS testraster ;
CREATE TABLE testraster AS
WITH emptyraster as (
SELECT ST_AsRaster(
st_setsrid(st_extent(the_geom), 4326),
(st_xmax(st_transform(st_setsrid(st_extent(the_geom)::geometry, 4326), 3857))
- st_xmin(st_transform(st_setsrid(st_extent(the_geom)::geometry, 4326), 3857)))::INT
/ (1600 * 50), -- 50 mile grid
(st_ymax(st_transform(st_setsrid(st_extent(the_geom)::geometry, 4326), 3857))
- st_ymin(st_transform(st_setsrid(st_extent(the_geom)::geometry, 4326), 3857)))::INT
/ (1600 * 50), '16BUI', 0, 0
) geom
FROM observatory.obs_c6fb99c47d61289fbb8e561ff7773799d3fcc308 blockgroups
),
pixels as (SELECT ARRAY_AGG(val) vals FROM
(SELECT ROW(geom, COUNT(bg) / ST_Area(geom))::geomval val
FROM (
SELECT (ST_PixelAsPolygons(rast, 1, True)).* FROM (
SELECT st_asraster(st_setsrid(st_extent(the_geom), 4326),
(st_xmax(st_transform(st_setsrid(st_extent(the_geom)::geometry, 4326), 3857))
- st_xmin(st_transform(st_setsrid(st_extent(the_geom)::geometry, 4326), 3857)))::INT
/ (1600 * 50),
(st_ymax(st_transform(st_setsrid(st_extent(the_geom)::geometry, 4326), 3857))
- st_ymin(st_transform(st_setsrid(st_extent(the_geom)::geometry, 4326), 3857)))::INT
/ (1600 * 50),
1.0,
1.0, '16BUI', 1, 0) rast
FROM observatory.obs_c6fb99c47d61289fbb8e561ff7773799d3fcc308
) foo) us JOIN observatory.obs_c6fb99c47d61289fbb8e561ff7773799d3fcc308 bg
ON us.geom && bg.the_geom
GROUP BY geom
) bar)
SELECT ST_SetValues(
(SELECT geom FROM emptyraster), 1, (SELECT vals from pixels)
) geom, 'blockgroup' as name
;
-- censustract
INSERT INTO testraster
WITH emptyraster as (
SELECT ST_AsRaster(
st_setsrid(st_extent(the_geom), 4326),
(st_xmax(st_transform(st_setsrid(st_extent(the_geom)::geometry, 4326), 3857))
- st_xmin(st_transform(st_setsrid(st_extent(the_geom)::geometry, 4326), 3857)))::INT
/ (1600 * 50),
(st_ymax(st_transform(st_setsrid(st_extent(the_geom)::geometry, 4326), 3857))
- st_ymin(st_transform(st_setsrid(st_extent(the_geom)::geometry, 4326), 3857)))::INT
/ (1600 * 50), '16BUI', 0, 0
) geom
FROM observatory.obs_fc050f0b8673cfe3c6aa1040f749eb40975691b7
),
pixels as (SELECT ARRAY_AGG(val) vals FROM
(SELECT ROW(geom, COUNT(bg) / ST_Area(geom))::geomval val
FROM (
SELECT (ST_PixelAsPolygons(rast, 1, True)).* FROM (
SELECT st_asraster(st_setsrid(st_extent(the_geom), 4326),
(st_xmax(st_transform(st_setsrid(st_extent(the_geom)::geometry, 4326), 3857))
- st_xmin(st_transform(st_setsrid(st_extent(the_geom)::geometry, 4326), 3857)))::INT
/ (1600 * 50),
(st_ymax(st_transform(st_setsrid(st_extent(the_geom)::geometry, 4326), 3857))
- st_ymin(st_transform(st_setsrid(st_extent(the_geom)::geometry, 4326), 3857)))::INT
/ (1600 * 50),
1.0,
1.0, '16BUI', 1, 0) rast
FROM observatory.obs_fc050f0b8673cfe3c6aa1040f749eb40975691b7
) foo) us JOIN observatory.obs_fc050f0b8673cfe3c6aa1040f749eb40975691b7 bg
ON us.geom && bg.the_geom
GROUP BY geom
) bar)
SELECT ST_SetValues(
(SELECT geom FROM emptyraster), 1, (SELECT vals from pixels)
) geom, 'censustract' as name
;
-- county
INSERT INTO testraster
WITH emptyraster as (
SELECT ST_AsRaster(
st_setsrid(st_extent(the_geom), 4326),
(st_xmax(st_transform(st_setsrid(st_extent(the_geom)::geometry, 4326), 3857))
- st_xmin(st_transform(st_setsrid(st_extent(the_geom)::geometry, 4326), 3857)))::INT
/ (1600 * 50),
(st_ymax(st_transform(st_setsrid(st_extent(the_geom)::geometry, 4326), 3857))
- st_ymin(st_transform(st_setsrid(st_extent(the_geom)::geometry, 4326), 3857)))::INT
/ (1600 * 50), '16BUI', 0, 0
) geom
FROM observatory.obs_1babf5a26a1ecda5fb74963e88408f71d0364b81
),
pixels as (SELECT ARRAY_AGG(val) vals FROM
(SELECT ROW(geom, COUNT(bg) / ST_Area(geom))::geomval val
FROM (
SELECT (ST_PixelAsPolygons(rast, 1, True)).* FROM (
SELECT st_asraster(st_setsrid(st_extent(the_geom), 4326),
(st_xmax(st_transform(st_setsrid(st_extent(the_geom)::geometry, 4326), 3857))
- st_xmin(st_transform(st_setsrid(st_extent(the_geom)::geometry, 4326), 3857)))::INT
/ (1600 * 50),
(st_ymax(st_transform(st_setsrid(st_extent(the_geom)::geometry, 4326), 3857))
- st_ymin(st_transform(st_setsrid(st_extent(the_geom)::geometry, 4326), 3857)))::INT
/ (1600 * 50),
1.0,
1.0, '16BUI', 1, 0) rast
FROM observatory.obs_1babf5a26a1ecda5fb74963e88408f71d0364b81
) foo) us JOIN observatory.obs_1babf5a26a1ecda5fb74963e88408f71d0364b81 bg
ON us.geom && bg.the_geom
GROUP BY geom
) bar)
SELECT ST_SetValues(
(SELECT geom FROM emptyraster), 1, (SELECT vals from pixels)
) geom, 'county' as name
;
-- money2
select name, (st_summarystats(st_clip(geom, 1,
st_makeenvelope(-112.74169921875,30.675715404167743,-79.82666015625,45.874712248904764, 4326)
, True))).* from testraster;
select name, (st_summarystats(st_clip(geom, 1,
st_makeenvelope(-74.32456970214844,40.52945798388008,-73.29597473144531,40.99078306643709, 4326)
, True))).* from testraster;
select name, (st_histogram(st_clip(geom, 1,
--st_makeenvelope(-73.125,14.381476281951624,-56.53564453125,23.362428593408826, 4326) -- out over PR
--st_makeenvelope(-67.467041015625,17.695053652675824,-65.39337158203125,18.823116948090483, 4326) -- PR extent
st_makeenvelope(-66.12327575683594,18.416345745681667,-65.99367141723633,18.486772542588447, 4326) -- San Juan, PR
, True))).* from testraster;
select name, (st_histogram(st_intersection(
-- out over PR
--st_asraster(st_makeenvelope(-73.125,14.381476281951624,-56.53564453125,23.362428593408826, 4326), geom)
-- PR extent
--st_asraster(st_makeenvelope(-67.467041015625,17.695053652675824,-65.39337158203125,18.823116948090483, 4326), geom)
-- San Juan
st_asraster(st_makeenvelope(-66.12327575683594,18.416345745681667,-65.99367141723633,18.486772542588447, 4326), geom)
, geom))).* from testraster;
WITH t2 AS (
SELECT
--st_asraster(st_makeenvelope(-73.125,14.381476281951624,-56.53564453125,23.362428593408826, 4326), geom)
--st_asraster(st_makeenvelope(-67.467041015625,17.695053652675824,-65.39337158203125,18.823116948090483, 4326), geom)
st_asraster(st_makeenvelope(-66.12327575683594,18.416345745681667,-65.99367141723633,18.486772542588447, 4326), geom)
geom
from testraster
)
SELECT
name, st_dumpvalues(ST_MapAlgebra(
t1.geom, 1,
t2.geom, 1,
--'([rast2] + [rast1.val]) / 2'
'(10) / 2'
), 1) AS rast
FROM testraster t1
CROSS JOIN t2;
WITH t2 AS (
SELECT
--st_asraster(st_makeenvelope(-73.125,14.381476281951624,-56.53564453125,23.362428593408826, 4326), geom)
--st_asraster(st_makeenvelope(-67.467041015625,17.695053652675824,-65.39337158203125,18.823116948090483, 4326), geom)
st_asraster(st_makeenvelope(-66.12327575683594,18.416345745681667,-65.99367141723633,18.486772542588447, 4326), geom, '8BUI', 1, 1)
geom
from testraster limit 1
)
SELECT
name, st_dumpvalues(ST_MapAlgebra(
t1.geom,
t2.geom,
--'([rast2] + [rast1.val]) / 2'
'(10) / 2',
'8BUI',
'SECOND',
NULL,
NULL,
NULL
), 1) AS rast
FROM testraster t1
CROSS JOIN t2;
SELECT
--st_asraster(st_makeenvelope(-73.125,14.381476281951624,-56.53564453125,23.362428593408826, 4326), geom)
--st_asraster(st_makeenvelope(-67.467041015625,17.695053652675824,-65.39337158203125,18.823116948090483, 4326), geom)
st_asraster(st_makeenvelope(
-66.12327575683594,18.416345745681667,-65.99367141723633,18.486772542588447, 4326), 10, 10, '8BUI', 1, 1)
geom
from testraster limit 1
;
WITH bbox AS (SELECT st_asraster(st_makeenvelope(
-73.125,14.381476281951624,-56.53564453125,23.362428593408826
-- -67.467041015625,17.695053652675824,-65.39337158203125,18.823116948090483
-- -66.12327575683594,18.416345745681667,-65.99367141723633,18.486772542588447
, 4326), 10, 10, '8BUI', 1, 1))
SELECT
name, (st_histogram(st_intersection(geom, st_resample(geom, (SELECT geom FROM bbox))))).*
from testraster
;
-- state
--
--WITH emptyraster as (
-- SELECT ST_AsRaster(
-- st_setsrid(st_extent(the_geom), 4326),
-- (st_xmax(st_transform(st_setsrid(st_extent(the_geom)::geometry, 4326), 3857))
-- - st_xmin(st_transform(st_setsrid(st_extent(the_geom)::geometry, 4326), 3857)))::INT
-- / (1600 * 50),
-- (st_ymax(st_transform(st_setsrid(st_extent(the_geom)::geometry, 4326), 3857))
-- - st_ymin(st_transform(st_setsrid(st_extent(the_geom)::geometry, 4326), 3857)))::INT
-- / (1600 * 50), '8BUI', 0, 0
-- ) geom
-- FROM observatory.WITH emptyraster as (
--),
-- pixels as (SELECT ARRAY_AGG(val) vals FROM
-- (SELECT ROW(geom, COUNT(bg) / ST_Area(geom))::geomval val
-- FROM (
-- SELECT (ST_PixelAsPolygons(rast, 1, True)).* FROM (
-- SELECT st_asraster(st_setsrid(st_extent(the_geom), 4326),
-- (st_xmax(st_transform(st_setsrid(st_extent(the_geom)::geometry, 4326), 3857))
-- - st_xmin(st_transform(st_setsrid(st_extent(the_geom)::geometry, 4326), 3857)))::INT
-- / (1600 * 50),
-- (st_ymax(st_transform(st_setsrid(st_extent(the_geom)::geometry, 4326), 3857))
-- - st_ymin(st_transform(st_setsrid(st_extent(the_geom)::geometry, 4326), 3857)))::INT
-- / (1600 * 50),
-- 1.0,
-- 1.0, '8BUI', 1, 0) rast
-- FROM observatory.WITH emptyraster as (
-- ) foo) us JOIN observatory.WITH emptyraster as ( bg
-- ON us.geom && bg.the_geom
-- GROUP BY geom
-- ) bar)
--SELECT ST_SetValues(
-- (SELECT geom FROM emptyraster), 1, (SELECT vals from pixels)
--) geom, 'blockgroup' as name
--;
SELECT (st_xmax(st_transform(st_setsrid(st_extent(the_geom)::geometry, 4326), 3857))
- st_xmin(st_transform(st_setsrid(st_extent(the_geom)::geometry, 4326), 3857)))::INT
/ (1600 * 500),
(st_ymax(st_transform(st_setsrid(st_extent(the_geom)::geometry, 4326), 3857))
- st_ymin(st_transform(st_setsrid(st_extent(the_geom)::geometry, 4326), 3857)))::INT
/ (1600 * 500)
FROM observatory.obs_c6fb99c47d61289fbb8e561ff7773799d3fcc308
;
SELECT ST_PixelAsPolygons(rast, 1) FROM (
SELECT st_asraster(st_setsrid(st_extent(the_geom), 4326), 80, 80, 1, 1, '8BUI', 511, 0) rast
FROM observatory.obs_c6fb99c47d61289fbb8e561ff7773799d3fcc308
) ny;
SELECT
st_area(the_geom::geography) a,
st_area((ST_Intersection(rastergeom, the_geom)).geom::geography)
/ st_area(rastergeom::geometry::geography) b,
st_area(rastergeom::geometry::geography) c
FROM testraster, observatory.obs_c6fb99c47d61289fbb8e561ff7773799d3fcc308 bg
WHERE testraster.rastergeom && bg.the_geom
;
DROP FUNCTION SummarizeBoundary(regclass,text,integer,integer,integer,integer);
CREATE OR REPLACE FUNCTION SummarizeBoundary(
tablename regclass, -- relation we're summarizing
colname TEXT DEFAULT 'the_geom', -- name of column with geometry
pixelwidth INTEGER DEFAULT 50000, -- width of each pixel in meters
pixelheight INTEGER DEFAULT 50000, -- height of each pixel in meters
tilewidth INTEGER DEFAULT 50, -- width of each tile in pixels
tileheight INTEGER DEFAULT 50 -- height of each tile in pixels
) RETURNS SETOF Raster AS $$
BEGIN
RETURN QUERY
EXECUTE
format(
$string$
WITH extents AS (
SELECT st_setsrid(st_extent(%2$s)::geometry, 4326) extents4326,
st_transform(st_setsrid(st_extent(%2$s)::geometry, 4326), 3857) extents3857
FROM %1$s
),
emptyraster as (
SELECT ROW_NUMBER() OVER () AS id, rast FROM (
SELECT ST_Tile(ST_AsRaster(extents4326,
(st_xmax(extents3857) - st_xmin(extents3857))::INT / ($1),
(st_ymax(extents3857) - st_ymin(extents3857))::INT / ($2),
ARRAY['32BUI', '32BUI'], ARRAY[1, 1], ARRAY[0, 0]
), ARRAY[1, 2], $3, $4) rast
FROM extents
) foo
),
pixelspertile AS (
SELECT id, ARRAY_AGG(median) medians, ARRAY_AGG(cnt) counts FROM (
SELECT id, ROW(FIRST(geom), percentile_cont(0.5) within group (
order by st_area(st_transform(tiger.%2$s, 3857)) / 1000000))::geomval median,
ROW(FIRST(geom), COUNT(tiger.%2$s))::geomval cnt
FROM
(
SELECT id, (ST_PixelAsPolygons(FIRST(rast), 1, True)).*
FROM emptyraster, %1$s tiger
WHERE emptyraster.rast && tiger.%2$s
GROUP BY id
) foo, %1$s tiger
WHERE foo.geom && tiger.%2$s
GROUP BY id, x, y
) bar
GROUP BY id
)
SELECT ST_SetValues(ST_SetValues(er.rast, 1, medians), 2, counts) tile
FROM emptyraster er, pixelspertile ppt
WHERE er.id = ppt.id;
$string$, tablename, colname)
USING pixelwidth, pixelheight, tilewidth, tileheight;
RETURN;
END
$$ LANGUAGE plpgsql;
DROP TABLE IF EXISTS boundarysummaries;
CREATE TABLE boundarysummaries (
id TEXT,
tablename TEXT,
tile RASTER
);
CREATE INDEX ON boundarysummaries USING GIST (ST_ConvexHull(tile));
--INSERT INTO boundarysummaries
--SELECT 'observatory.obs_fc050f0b8673cfe3c6aa1040f749eb40975691b7', * FROM SummarizeBoundary(
--SELECT SummarizeBoundary(
-- --'observatory.obs_624e5d2362e08aaa5463d7671e7748432262719c', -- state
-- --'observatory.obs_1babf5a26a1ecda5fb74963e88408f71d0364b81', -- county
-- 'observatory.obs_fc050f0b8673cfe3c6aa1040f749eb40975691b7', -- tract
-- --'observatory.obs_c6fb99c47d61289fbb8e561ff7773799d3fcc308', -- bg
-- 'the_geom',
-- 100000, 100000,
-- 50, 50
--);
INSERT INTO boundarysummaries
WITH tables AS (SELECT DISTINCT geom_id id, geom_tablename tablename,
(geom_ct_extra->'stats'->>'avg')::NUMERIC avgsize
FROM observatory.obs_meta
WHERE geom_ct_extra IS NOT NULL)
SELECT id, tablename, SummarizeBoundary(
'observatory.' || tablename, 'the_geom', sqrt(avgsize), sqrt(avgsize), 100, 100) tile
FROM tables;
/** test hi-res **/
-- 1970004249729.01
-- 1873975871265.93
-- 6100147269.60413
--
--
-- create census tracts
DROP TABLE IF EXISTS testtiles;
CREATE TABLE testtiles AS
WITH emptyraster as (
SELECT ROW_NUMBER() OVER () AS id, rast FROM (
SELECT ST_Tile(ST_AsRaster(
st_setsrid(st_extent(the_geom), 4326),
(st_xmax(st_transform(st_setsrid(st_extent(the_geom)::geometry, 4326), 3857))
- st_xmin(st_transform(st_setsrid(st_extent(the_geom)::geometry, 4326), 3857)))::INT
/ (50000),
(st_ymax(st_transform(st_setsrid(st_extent(the_geom)::geometry, 4326), 3857))
- st_ymin(st_transform(st_setsrid(st_extent(the_geom)::geometry, 4326), 3857)))::INT
/ (50000), ARRAY['32BF', '32BF'], ARRAY[1, 1], ARRAY[0, 0]
), ARRAY[1, 2], 50, 50) rast
FROM observatory.obs_fc050f0b8673cfe3c6aa1040f749eb40975691b7 tiger
) foo
),
pixelspertile AS (
SELECT id, ARRAY_AGG(median) medians, ARRAY_AGG(cnt) counts FROM (
SELECT id, ROW(
FIRST(geom),
-- determine median area of tiger geometries
percentile_cont(0.5) within group (
order by st_area(st_transform(tiger.the_geom, 3857)) / 1000000)
)::geomval median,
ROW(FIRST(geom),
-- determine number of geoms, including fractions
SUM(ST_Area(ST_Intersection(tiger.the_geom, foo.geom)) /
ST_Area(tiger.the_geom))
)::geomval cnt
--id, x, y, FIRST(geom) pixelgeom,
--count(tiger.the_geom) numtigergeoms,
--max(st_area(st_transform(tiger.the_geom, 3857)) / 1000000) maxtigergeomarea,
--min(st_area(st_transform(tiger.the_geom, 3857)) / 1000000) mintigergeomarea,
--avg(st_area(st_transform(tiger.the_geom, 3857)) / 1000000) avgtigergeomarea,
--percentile_cont(0.5) within group (
-- order by st_area(st_transform(tiger.the_geom, 3857)) / 1000000) mediantigergeomarea
FROM
(
SELECT id, (ST_PixelAsPolygons(FIRST(rast), 1, True)).*
FROM emptyraster,
observatory.obs_fc050f0b8673cfe3c6aa1040f749eb40975691b7 tiger
WHERE emptyraster.rast && tiger.the_geom
GROUP BY id
) foo,
observatory.obs_fc050f0b8673cfe3c6aa1040f749eb40975691b7 tiger
WHERE foo.geom && tiger.the_geom
GROUP BY id, x, y
) bar
GROUP BY id
)
SELECT 'us.census.tiger.census_tract'::text res, er.id,
ST_SetValues(ST_SetValues(er.rast, 1, medians), 2, counts) geom
FROM emptyraster er, pixelspertile ppt
WHERE er.id = ppt.id
;
DELETE FROM testtiles WHERE res = 'us.census.tiger.county';
INSERT INTO testtiles
WITH emptyraster as (
SELECT ROW_NUMBER() OVER () AS id, rast FROM (
SELECT ST_Tile(ST_AsRaster(
st_setsrid(st_extent(the_geom), 4326),
(st_xmax(st_transform(st_setsrid(st_extent(the_geom)::geometry, 4326), 3857))
- st_xmin(st_transform(st_setsrid(st_extent(the_geom)::geometry, 4326), 3857)))::INT
/ (50000),
(st_ymax(st_transform(st_setsrid(st_extent(the_geom)::geometry, 4326), 3857))
- st_ymin(st_transform(st_setsrid(st_extent(the_geom)::geometry, 4326), 3857)))::INT
/ (50000), ARRAY['32BF', '32BF'], ARRAY[1, 1], ARRAY[0, 0]
), ARRAY[1, 2], 50, 50) rast
FROM observatory.obs_1babf5a26a1ecda5fb74963e88408f71d0364b81 tiger
) foo
),
pixelspertile AS (
SELECT id, ARRAY_AGG(median) medians, ARRAY_AGG(cnt) counts FROM (
SELECT id, ROW(
FIRST(geom),
-- determine median area of tiger geometries
percentile_cont(0.5) within group (
order by st_area(st_transform(tiger.the_geom, 3857)) / 1000000)
)::geomval median,
ROW(FIRST(geom),
-- determine number of geoms, including fractions
SUM(ST_Area(ST_Intersection(tiger.the_geom, foo.geom)) /
ST_Area(tiger.the_geom))
)::geomval cnt
FROM
(
SELECT id, (ST_PixelAsPolygons(FIRST(rast), 1, True)).*
FROM emptyraster,
observatory.obs_1babf5a26a1ecda5fb74963e88408f71d0364b81 tiger
WHERE emptyraster.rast && tiger.the_geom
GROUP BY id
) foo,
observatory.obs_1babf5a26a1ecda5fb74963e88408f71d0364b81 tiger
WHERE foo.geom && tiger.the_geom
GROUP BY id, x, y
) bar
GROUP BY id
)
SELECT 'us.census.tiger.county'::text res, er.id,
ST_SetValues(ST_SetValues(er.rast, 1, medians), 2, counts) geom
FROM emptyraster er, pixelspertile ppt
WHERE er.id = ppt.id
;
DELETE FROM testtiles WHERE res = 'us.census.tiger.block_group';
INSERT INTO testtiles
WITH emptyraster as (
SELECT ROW_NUMBER() OVER () AS id, rast FROM (
SELECT ST_Tile(ST_AsRaster(
st_setsrid(st_extent(the_geom), 4326),
(st_xmax(st_transform(st_setsrid(st_extent(the_geom)::geometry, 4326), 3857))
- st_xmin(st_transform(st_setsrid(st_extent(the_geom)::geometry, 4326), 3857)))::INT
/ (50000),
(st_ymax(st_transform(st_setsrid(st_extent(the_geom)::geometry, 4326), 3857))
- st_ymin(st_transform(st_setsrid(st_extent(the_geom)::geometry, 4326), 3857)))::INT
/ (50000), ARRAY['32BF', '32BF'], ARRAY[1, 1], ARRAY[0, 0]
), ARRAY[1, 2], 50, 50) rast
FROM observatory.obs_c6fb99c47d61289fbb8e561ff7773799d3fcc308 tiger
) foo
),
pixelspertile AS (
SELECT id, ARRAY_AGG(median) medians, ARRAY_AGG(cnt) counts FROM (
SELECT id, ROW(
FIRST(geom),
-- determine median area of tiger geometries
percentile_cont(0.5) within group (
order by st_area(st_transform(tiger.the_geom, 3857)) / 1000000)
)::geomval median,
ROW(FIRST(geom),
-- determine number of geoms, including fractions
SUM(ST_Area(ST_Intersection(tiger.the_geom, foo.geom)) /
ST_Area(tiger.the_geom))
)::geomval cnt
FROM
(
SELECT id, (ST_PixelAsPolygons(FIRST(rast), 1, True)).*
FROM emptyraster,
observatory.obs_c6fb99c47d61289fbb8e561ff7773799d3fcc308 tiger
WHERE emptyraster.rast && tiger.the_geom
GROUP BY id
) foo,
observatory.obs_c6fb99c47d61289fbb8e561ff7773799d3fcc308 tiger
WHERE foo.geom && tiger.the_geom
GROUP BY id, x, y
) bar
GROUP BY id
)
SELECT 'us.census.tiger.block_group'::text res, er.id,
ST_SetValues(ST_SetValues(er.rast, 1, medians), 2, counts) geom
FROM emptyraster er, pixelspertile ppt
WHERE er.id = ppt.id
;
INSERT INTO testtiles
WITH emptyraster as (
SELECT ROW_NUMBER() OVER () AS id, rast FROM (
SELECT ST_Tile(ST_AsRaster(
st_setsrid(st_extent(the_geom), 4326),
(st_xmax(st_transform(st_setsrid(st_extent(the_geom)::geometry, 4326), 3857))
- st_xmin(st_transform(st_setsrid(st_extent(the_geom)::geometry, 4326), 3857)))::INT
/ (50000),
(st_ymax(st_transform(st_setsrid(st_extent(the_geom)::geometry, 4326), 3857))
- st_ymin(st_transform(st_setsrid(st_extent(the_geom)::geometry, 4326), 3857)))::INT
/ (50000), ARRAY['32BF', '32BF'], ARRAY[1, 1], ARRAY[0, 0]
), ARRAY[1, 2], 50, 50) rast
FROM observatory.obs_624e5d2362e08aaa5463d7671e7748432262719c tiger
) foo
),
pixelspertile AS (
SELECT id, ARRAY_AGG(median) medians, ARRAY_AGG(cnt) counts FROM (
SELECT id, ROW(
FIRST(geom),
-- determine median area of tiger geometries
percentile_cont(0.5) within group (
order by st_area(st_transform(tiger.the_geom, 3857)) / 1000000)
)::geomval median,
ROW(FIRST(geom),
-- determine number of geoms, including fractions
SUM(ST_Area(ST_Intersection(tiger.the_geom, foo.geom)) /
ST_Area(tiger.the_geom))
)::geomval cnt
FROM
(
SELECT id, (ST_PixelAsPolygons(FIRST(rast), 1, True)).*
FROM emptyraster,
observatory.obs_624e5d2362e08aaa5463d7671e7748432262719c tiger
WHERE st_intersects(emptyraster.rast, tiger.the_geom)
GROUP BY id
) foo,
observatory.obs_624e5d2362e08aaa5463d7671e7748432262719c tiger
WHERE st_intersects(foo.geom, tiger.the_geom)
GROUP BY id, x, y
) bar
GROUP BY id
)
SELECT 'us.census.tiger.state'::text res, er.id,
ST_SetValues(ST_SetValues(er.rast, 1, medians), 2, counts) geom
FROM emptyraster er, pixelspertile ppt
WHERE er.id = ppt.id
;
--CREATE INDEX ON testtiles USING GIST (ST_ConvexHull(geom));
--CREATE UNIQUE INDEX ON testtiles (id);
with testgeom as (
SELECT UNNEST(ARRAY[
st_makeenvelope(-15.1171875, -56.36525013685607,8.7890625, -44.087585028245165),
st_makeenvelope(-179,-89,179,89, 4326),
st_makeenvelope(-74.124755859375,40.61994644839496,-73.59603881835938,40.81926563675481, 4326),
st_makeenvelope(-74.44267272949219,40.506490449822046,-73.31932067871094,40.9052096972736, 4326),
st_makeenvelope(-75.003662109375,40.306759936589636,-72.7569580078125,41.104190944576466, 4326),
st_makeenvelope(-76.12701416015624,39.9034155951341,-71.63360595703125,41.498292501398545, 4326),
st_makeenvelope(-78.3709716796875,39.091699613104595,-69.3841552734375,42.28137302193453, 4326),
st_makeenvelope(-91.845703125,34.03445260967645,-55.8984375,46.78501604269254, 4326)
])
testgeom
)
select
res,
st_area(st_transform(testgeom, 3857)) / 1000000 area,
-- median geom area of first pixel
st_value(FIRST(geom), 1, st_centroid(testgeom)) median,
-- median count of geoms of first pixel
st_value(FIRST(geom), 2, st_centroid(testgeom)) cnt,
-- mean of the median area for these pixels
(st_summarystatsagg(st_clip(geom, 1, testgeom, True), 1, True, 0.5)).mean meanmedianarea,
-- total number of geoms in this area
(st_summarystatsagg(st_clip(geom, 2, testgeom, True), 1, True, 0.5)).sum numgeoms,
-- estimate of the number of these geoms that would fit in the current arae
(st_area(st_transform(testgeom, 3857)) / 1000000) / (st_summarystatsagg(st_clip(geom, 1, testgeom, True), 1, True, 0.5)).mean estnumgeoms,
-- estimate of the area in this area
(st_area(st_transform(testgeom, 3857)) / 1000000) / (st_summarystatsagg(st_clip(geom, 2, testgeom, True), 1, True, 0.5)).mean estmeanarea
--(st_summarystats(geom, 1, True)).*
--st_value(geom, 1, st_setsrid(st_makepoint(0,0), 4326))
from testtiles, testgeom
where st_intersects(testgeom , geom)
group by res, testgeom
;
with testgeom as (
SELECT UNNEST(ARRAY[
st_makeenvelope(-75.003662109375,40.306759936589636,-72.7569580078125,41.104190944576466, 4326)
])
testgeom
)
select
res,
(st_area(st_transform(testgeom, 3857)) / 1000000) / (st_summarystatsagg(st_clip(geom, 1, testgeom, True), 1, True, 0.5)).mean estnumgeoms
from testtiles, testgeom
where st_intersects(testgeom, geom)
group by res, testgeom
;
--FILTER (WHERE (ST_SummaryStats(tile, 2, True)).sum = 0)
-- with ~270 geoms in the tile table, took around 0.5 s
-- with 581 geoms in the tile table, took around 0.5 s w/o index
-- with 581 geoms in the tile table, took around 0.7 s with index
SELECT * FROM (
with testgeom as (
SELECT UNNEST(ARRAY[
--ST_MakeEnvelope(-179, -89, 179, 89, 4326),
st_makeenvelope(-108.97338867187499,47.381614160856806,-105.128173828125,48.765241568534485, 4326),
ST_MakeEnvelope(-103.7548828125, 25.849336891707605, -99.84374999999999, 28.642389157900553, 4326),
ST_MakeEnvelope(-99.30953979492188, 19.269665296502332, -98.975830078125, 19.618011504700913, 4326),
ST_MakeEnvelope(-124.1015625, 11.523087506868514, -84.0234375, 35.31736632923788, 4326),
ST_MakeEnvelope(-129.0234375, 20.96143961409684, -60.1171875, 51.6180165487737, 4326),
ST_MakeEnvelope(-148.359375, 41.77131167976407, -136.7578125, 50.064191736659104, 4326),
ST_MakeEnvelope(-75.003662109375,40.306759936589636,-72.7569580078125,41.104190944576466, 4326)
,ST_MakeEnvelope(-76.66131019592285,39.265553454936644,-76.54586791992188,39.320620435483946, 4326),
ST_MakeEnvelope(-5.6304931640625, 39.2832938689385, -1.768798828125, 41.43860847395721, 4326),
ST_MakeEnvelope(-9.8876953125, 35.782170703266075, 3.515625, 44.05601169578525, 4326),
ST_MakeEnvelope(-9.07470703125, 40.60144147645398, -8.1134033203125, 41.545589036668105, 4326)
]) AS extent, UNNEST(ARRAY[--'World',
'blank-cbsa', 'DF, MX', 'Rural MX', 'MX', 'US', 'north pacific',
'NYC, US', 'Baltimore, US', 'Madrid, ES', 'ES',
'Porto, PT'
]) AS name
)
select
count(*), name, --table_id,
column_id
--, (ST_SummaryStatsAgg(st_clip(tile, extent, True), 1, False, 1)).count > 0
--, (ST_CountAgg(st_clip(tile, extent, True), 2)
, (ST_CountAgg(st_clip(tile, extent, True), 2, True)::Numeric
/ ST_CountAgg(st_clip(tile, extent, True), 2, False))::Numeric(20, 6) notnullpercent
, COALESCE(
((ST_SummaryStatsAgg(st_clip(tile, extent, True), 2, True, 1)).sum),
ST_Value(FIRST(tile), 2, ST_PointOnSurface(extent))
)::Numeric(20, 2) AS numgeoms
-- , COALESCE(
-- ((ST_SummaryStatsAgg(st_clip(tile, extent, True), 1, True, 1)).mean),
-- ST_Value(FIRST(tile), 1, ST_PointOnSurface(extent))
-- )::Numeric(20, 2) AS meanmediansize
, COALESCE(
((ST_SummaryStatsAgg(st_clip(tile, extent, True), 3, True, 1)).mean),
ST_Value(FIRST(tile), 3, ST_PointOnSurface(extent))
)::Numeric(20, 2) AS percentfill
, COALESCE(
((ST_Area(st_transform(extent, 3857)) / 1000000) /
NullIf((ST_SummaryStatsAgg(st_clip(tile, extent, True), 1, True, 1)).mean, 0)),
((ST_Area(st_transform(extent, 3857)) / 1000000) /
NullIf(ST_Value(FIRST(tile), 1, ST_PointOnSurface(extent)), 0))
)::Numeric(20, 2) AS estnumgeoms
from observatory.obs_column_table_tile, testgeom
where st_intersects(extent, tile)
group by name, column_id, table_id, extent
order by name, column_id, table_id
) foo
WHERE notnullpercent > 0.1
AND percentfill > 0.1
AND numgeoms > 0
AND estnumgeoms > 0
;
DROP FUNCTION GetBestBoundary (geometry);
CREATE OR REPLACE FUNCTION GetBestBoundary (
geom geometry
) RETURNS TEXT AS $$
BEGIN
END
$$ LANGUAGE plpgsql;