-
Notifications
You must be signed in to change notification settings - Fork 606
/
Copy pathboundary.sql
858 lines (790 loc) · 29 KB
/
boundary.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
817
818
819
820
821
822
823
824
825
826
827
828
829
830
831
832
833
834
835
836
837
838
839
840
841
842
843
844
845
846
847
848
849
850
851
852
853
854
855
856
857
858
-- etldoc: osm_border_linestring -> osm_border_linestring_gen_z13
-- etldoc: osm_border_linestring_adm -> osm_border_linestring_gen_z13
-- etldoc: osm_border_disp_linestring -> osm_border_linestring_gen_z13
DROP MATERIALIZED VIEW IF EXISTS osm_border_linestring_gen_z13 CASCADE;
CREATE MATERIALIZED VIEW osm_border_linestring_gen_z13 AS
(
SELECT ST_Simplify(ST_Collect(geometry), ZRes(14)) AS geometry,
MAX(adm0_l) AS adm0_l,
MAX(adm0_r) AS adm0_r,
MIN(admin_level) AS admin_level,
BOOL_OR(disputed) AS disputed,
MAX(name) AS name,
MAX(claimed_by) AS claimed_by,
BOOL_OR(maritime) AS maritime
FROM (
-- All admin 3-10 boundaries
SELECT osm_id,
geometry,
NULL::text AS adm0_l,
NULL::text AS adm0_r,
MIN(admin_level) AS admin_level,
BOOL_OR(disputed)
OR BOOL_OR(dispute)
OR BOOL_OR(border_status = 'disputed')
OR BOOL_OR(disputed_by <> '') AS disputed,
NULLIF(name, '') AS name,
NULLIF(claimed_by, '') AS claimed_by,
BOOL_OR(maritime) AS maritime
FROM osm_border_linestring
WHERE admin_level BETWEEN 3 AND 10
AND type = 1 -- ways only
GROUP BY osm_id, geometry, name, claimed_by
UNION ALL
-- All non-disputed admin 2 boundaries
SELECT osm_id,
geometry,
adm0_l,
adm0_r,
admin_level,
FALSE AS disputed,
NULL::text AS name,
NULL::text AS claimed_by,
maritime
FROM osm_border_linestring_adm
UNION ALL
-- All disputed admin 2 boundaries
SELECT osm_id,
geometry,
NULL::text AS adm0_l,
NULL::text AS adm0_r,
2::int AS admin_level,
TRUE AS disputed,
NULLIF(name, '') AS name,
NULLIF(claimed_by, '') AS claimed_by,
maritime
FROM osm_border_disp_linestring
GROUP BY osm_id, geometry, name, claimed_by, maritime
) AS merged_boundary
GROUP by osm_id
)/* DELAY_MATERIALIZED_VIEW_CREATION */ ;
CREATE INDEX IF NOT EXISTS osm_border_linestring_gen_z13_idx ON osm_border_linestring_gen_z13 USING gist (geometry);
-- etldoc: osm_border_linestring_gen_z13 -> osm_border_linestring_gen_z12
DROP MATERIALIZED VIEW IF EXISTS osm_border_linestring_gen_z12 CASCADE;
CREATE MATERIALIZED VIEW osm_border_linestring_gen_z12 AS
(
SELECT ST_Simplify(geometry, ZRes(13)) AS geometry, adm0_l, adm0_r, admin_level, disputed, name, claimed_by, maritime
FROM osm_border_linestring_gen_z13
WHERE admin_level BETWEEN 2 AND 10
) /* DELAY_MATERIALIZED_VIEW_CREATION */ ;
CREATE INDEX IF NOT EXISTS osm_border_linestring_gen_z12_idx ON osm_border_linestring_gen_z12 USING gist (geometry);
-- etldoc: osm_border_linestring_gen_z12 -> osm_border_linestring_gen_z11
DROP MATERIALIZED VIEW IF EXISTS osm_border_linestring_gen_z11 CASCADE;
CREATE MATERIALIZED VIEW osm_border_linestring_gen_z11 AS
(
SELECT ST_Simplify(geometry, ZRes(12)) AS geometry, adm0_l, adm0_r, admin_level, disputed, name, claimed_by, maritime
FROM osm_border_linestring_gen_z12
WHERE admin_level BETWEEN 2 AND 8
) /* DELAY_MATERIALIZED_VIEW_CREATION */ ;
CREATE INDEX IF NOT EXISTS osm_border_linestring_gen_z11_idx ON osm_border_linestring_gen_z11 USING gist (geometry);
-- etldoc: osm_border_linestring_gen_z11 -> osm_border_linestring_gen_z10
DROP MATERIALIZED VIEW IF EXISTS osm_border_linestring_gen_z10 CASCADE;
CREATE MATERIALIZED VIEW osm_border_linestring_gen_z10 AS
(
SELECT ST_Simplify(geometry, ZRes(11)) AS geometry, adm0_l, adm0_r, admin_level, disputed, name, claimed_by, maritime
FROM osm_border_linestring_gen_z11
WHERE admin_level BETWEEN 2 AND 6
) /* DELAY_MATERIALIZED_VIEW_CREATION */ ;
CREATE INDEX IF NOT EXISTS osm_border_linestring_gen_z10_idx ON osm_border_linestring_gen_z10 USING gist (geometry);
-- etldoc: osm_border_linestring_gen_z10 -> osm_border_linestring_gen_z9
DROP MATERIALIZED VIEW IF EXISTS osm_border_linestring_gen_z9 CASCADE;
CREATE MATERIALIZED VIEW osm_border_linestring_gen_z9 AS
(
SELECT ST_Simplify(geometry, ZRes(10)) AS geometry, adm0_l, adm0_r, admin_level, disputed, name, claimed_by, maritime
FROM osm_border_linestring_gen_z10
-- WHERE admin_level BETWEEN 2 AND 6
) /* DELAY_MATERIALIZED_VIEW_CREATION */ ;
CREATE INDEX IF NOT EXISTS osm_border_linestring_gen_z9_idx ON osm_border_linestring_gen_z9 USING gist (geometry);
-- etldoc: osm_border_linestring_gen_z9 -> osm_border_linestring_gen_z8
DROP MATERIALIZED VIEW IF EXISTS osm_border_linestring_gen_z8 CASCADE;
CREATE MATERIALIZED VIEW osm_border_linestring_gen_z8 AS
(
SELECT ST_Simplify(geometry, ZRes(9)) AS geometry, adm0_l, adm0_r, admin_level, disputed, name, claimed_by, maritime
FROM osm_border_linestring_gen_z9
WHERE admin_level BETWEEN 2 AND 4
) /* DELAY_MATERIALIZED_VIEW_CREATION */ ;
CREATE INDEX IF NOT EXISTS osm_border_linestring_gen_z8_idx ON osm_border_linestring_gen_z8 USING gist (geometry);
-- etldoc: osm_border_linestring_gen_z8 -> osm_border_linestring_gen_z7
DROP MATERIALIZED VIEW IF EXISTS osm_border_linestring_gen_z7 CASCADE;
CREATE MATERIALIZED VIEW osm_border_linestring_gen_z7 AS
(
SELECT ST_Simplify(geometry, ZRes(8)) AS geometry, adm0_l, adm0_r, admin_level, disputed, name, claimed_by, maritime
FROM osm_border_linestring_gen_z8
-- WHERE admin_level BETWEEN 2 AND 4
) /* DELAY_MATERIALIZED_VIEW_CREATION */ ;
CREATE INDEX IF NOT EXISTS osm_border_linestring_gen_z7_idx ON osm_border_linestring_gen_z7 USING gist (geometry);
-- etldoc: osm_border_linestring_gen_z7 -> osm_border_linestring_gen_z6
DROP MATERIALIZED VIEW IF EXISTS osm_border_linestring_gen_z6 CASCADE;
CREATE MATERIALIZED VIEW osm_border_linestring_gen_z6 AS
(
SELECT ST_Simplify(geometry, ZRes(7)) AS geometry, adm0_l, adm0_r, admin_level, disputed, name, claimed_by, maritime
FROM osm_border_linestring_gen_z7
-- WHERE admin_level BETWEEN 2 AND 4
) /* DELAY_MATERIALIZED_VIEW_CREATION */ ;
CREATE INDEX IF NOT EXISTS osm_border_linestring_gen_z6_idx ON osm_border_linestring_gen_z6 USING gist (geometry);
-- etldoc: osm_border_linestring_gen_z6 -> osm_border_linestring_gen_z5
DROP MATERIALIZED VIEW IF EXISTS osm_border_linestring_gen_z5 CASCADE;
CREATE MATERIALIZED VIEW osm_border_linestring_gen_z5 AS
(
SELECT ST_Simplify(geometry, ZRes(6)) AS geometry, adm0_l, adm0_r, admin_level, disputed, name, claimed_by, maritime
FROM osm_border_linestring_gen_z6
-- WHERE admin_level BETWEEN 2 AND 4
) /* DELAY_MATERIALIZED_VIEW_CREATION */ ;
CREATE INDEX IF NOT EXISTS osm_border_linestring_gen_z5_idx ON osm_border_linestring_gen_z5 USING gist (geometry);
-- etldoc: osm_border_linestring_gen_z5 -> osm_border_linestring_gen_z4
DROP MATERIALIZED VIEW IF EXISTS osm_border_linestring_gen_z4 CASCADE;
CREATE MATERIALIZED VIEW osm_border_linestring_gen_z4 AS
(
SELECT ST_Simplify(geometry, ZRes(5)) AS geometry, adm0_l, adm0_r, admin_level, disputed, name, claimed_by, maritime
FROM osm_border_linestring_gen_z5
WHERE admin_level = 2 AND maritime
) /* DELAY_MATERIALIZED_VIEW_CREATION */ ;
CREATE INDEX IF NOT EXISTS osm_border_linestring_gen_z4_idx ON osm_border_linestring_gen_z4 USING gist (geometry);
-- ne_10m_admin_0_boundary_lines_land
-- etldoc: ne_10m_admin_0_boundary_lines_land -> ne_10m_admin_0_boundary_lines_land_gen_z4
DROP MATERIALIZED VIEW IF EXISTS ne_10m_admin_0_boundary_lines_land_gen_z4 CASCADE;
CREATE MATERIALIZED VIEW ne_10m_admin_0_boundary_lines_land_gen_z4 AS
(
SELECT ST_Simplify(geometry, ZRes(6)) as geometry,
2 AS admin_level,
(CASE WHEN featurecla LIKE 'Disputed%' THEN TRUE ELSE FALSE END) AS disputed,
NULL::text AS disputed_name,
NULL::text AS claimed_by,
FALSE AS maritime
FROM ne_10m_admin_0_boundary_lines_land
WHERE featurecla <> 'Lease limit'
) /* DELAY_MATERIALIZED_VIEW_CREATION */ ;
CREATE INDEX IF NOT EXISTS ne_10m_admin_0_boundary_lines_land_gen_z4_idx ON ne_10m_admin_0_boundary_lines_land_gen_z4 USING gist (geometry);
-- etldoc: ne_10m_admin_0_boundary_lines_land -> ne_10m_admin_0_boundary_lines_land_disputed
DROP MATERIALIZED VIEW IF EXISTS ne_10m_admin_0_boundary_lines_land_disputed CASCADE;
CREATE MATERIALIZED VIEW ne_10m_admin_0_boundary_lines_land_disputed AS
(
SELECT geometry,
2 AS admin_level,
(CASE WHEN featurecla LIKE 'Disputed%' THEN TRUE ELSE FALSE END) AS disputed,
NULL::text AS disputed_name,
NULL::text AS claimed_by,
FALSE AS maritime
FROM ne_10m_admin_0_boundary_lines_land
WHERE featurecla LIKE 'Disputed%' AND adm0_left = 'South Sudan' AND adm0_right = 'Kenya'
) /* DELAY_MATERIALIZED_VIEW_CREATION */ ;
CREATE INDEX IF NOT EXISTS ne_10m_admin_0_boundary_lines_land_disputed_idx ON ne_10m_admin_0_boundary_lines_land_disputed USING gist (geometry);
-- ne_10m_admin_1_states_provinces_lines
-- etldoc: ne_10m_admin_1_states_provinces_lines -> ne_10m_admin_1_states_provinces_lines_gen_z4
DROP MATERIALIZED VIEW IF EXISTS ne_10m_admin_1_states_provinces_lines_gen_z4 CASCADE;
CREATE MATERIALIZED VIEW ne_10m_admin_1_states_provinces_lines_gen_z4 AS
(
SELECT ST_Simplify(geometry, ZRes(6)) as geometry,
4 AS admin_level,
FALSE AS disputed,
NULL::text AS disputed_name,
NULL::text AS claimed_by,
FALSE AS maritime,
min_zoom
FROM ne_10m_admin_1_states_provinces_lines
WHERE min_zoom <= 7.7
) /* DELAY_MATERIALIZED_VIEW_CREATION */ ;
CREATE INDEX IF NOT EXISTS ne_10m_admin_1_states_provinces_lines_gen_z4_idx ON ne_10m_admin_1_states_provinces_lines_gen_z4 USING gist (geometry);
-- etldoc: ne_10m_admin_1_states_provinces_lines_gen_z4 -> ne_10m_admin_1_states_provinces_lines_gen_z3
DROP MATERIALIZED VIEW IF EXISTS ne_10m_admin_1_states_provinces_lines_gen_z3 CASCADE;
CREATE MATERIALIZED VIEW ne_10m_admin_1_states_provinces_lines_gen_z3 AS
(
SELECT ST_Simplify(geometry, ZRes(5)) as geometry,
admin_level,
disputed,
disputed_name,
claimed_by,
maritime
FROM ne_10m_admin_1_states_provinces_lines_gen_z4
WHERE min_zoom <= 7
) /* DELAY_MATERIALIZED_VIEW_CREATION */ ;
CREATE INDEX IF NOT EXISTS ne_10m_admin_1_states_provinces_lines_gen_z3_idx ON ne_10m_admin_1_states_provinces_lines_gen_z3 USING gist (geometry);
-- etldoc: ne_10m_admin_1_states_provinces_lines_gen_z3 -> ne_10m_admin_1_states_provinces_lines_gen_z2
DROP MATERIALIZED VIEW IF EXISTS ne_10m_admin_1_states_provinces_lines_gen_z2 CASCADE;
CREATE MATERIALIZED VIEW ne_10m_admin_1_states_provinces_lines_gen_z2 AS
(
SELECT ST_Simplify(geometry, ZRes(4)) as geometry,
admin_level,
disputed,
disputed_name,
claimed_by,
maritime
FROM ne_10m_admin_1_states_provinces_lines_gen_z3
) /* DELAY_MATERIALIZED_VIEW_CREATION */ ;
CREATE INDEX IF NOT EXISTS ne_10m_admin_1_states_provinces_lines_gen_z2_idx ON ne_10m_admin_1_states_provinces_lines_gen_z2 USING gist (geometry);
-- etldoc: ne_10m_admin_1_states_provinces_lines_gen_z2 -> ne_10m_admin_1_states_provinces_lines_gen_z1
DROP MATERIALIZED VIEW IF EXISTS ne_10m_admin_1_states_provinces_lines_gen_z1 CASCADE;
CREATE MATERIALIZED VIEW ne_10m_admin_1_states_provinces_lines_gen_z1 AS
(
SELECT ST_Simplify(geometry, ZRes(3)) as geometry,
admin_level,
disputed,
disputed_name,
claimed_by,
maritime
FROM ne_10m_admin_1_states_provinces_lines_gen_z2
) /* DELAY_MATERIALIZED_VIEW_CREATION */ ;
CREATE INDEX IF NOT EXISTS ne_10m_admin_1_states_provinces_lines_gen_z1_idx ON ne_10m_admin_1_states_provinces_lines_gen_z1 USING gist (geometry);
-- ne_50m_admin_0_boundary_lines_land
-- etldoc: ne_50m_admin_0_boundary_lines_land -> ne_50m_admin_0_boundary_lines_land_gen_z3
DROP MATERIALIZED VIEW IF EXISTS ne_50m_admin_0_boundary_lines_land_gen_z3 CASCADE;
CREATE MATERIALIZED VIEW ne_50m_admin_0_boundary_lines_land_gen_z3 AS
(
SELECT ST_Simplify(geometry, ZRes(5)) as geometry,
2 AS admin_level,
(CASE WHEN featurecla LIKE 'Disputed%' THEN TRUE ELSE FALSE END) AS disputed,
NULL::text AS disputed_name,
NULL::text AS claimed_by,
FALSE AS maritime
FROM ne_50m_admin_0_boundary_lines_land
) /* DELAY_MATERIALIZED_VIEW_CREATION */ ;
CREATE INDEX IF NOT EXISTS ne_50m_admin_0_boundary_lines_land_gen_z3_idx ON ne_50m_admin_0_boundary_lines_land_gen_z3 USING gist (geometry);
-- etldoc: ne_50m_admin_0_boundary_lines_land_gen_z3 -> ne_50m_admin_0_boundary_lines_land_gen_z2
DROP MATERIALIZED VIEW IF EXISTS ne_50m_admin_0_boundary_lines_land_gen_z2 CASCADE;
CREATE MATERIALIZED VIEW ne_50m_admin_0_boundary_lines_land_gen_z2 AS
(
SELECT ST_Simplify(geometry, ZRes(4)) as geometry,
admin_level,
disputed,
disputed_name,
claimed_by,
maritime
FROM ne_50m_admin_0_boundary_lines_land_gen_z3
) /* DELAY_MATERIALIZED_VIEW_CREATION */ ;
CREATE INDEX IF NOT EXISTS ne_50m_admin_0_boundary_lines_land_gen_z2_idx ON ne_50m_admin_0_boundary_lines_land_gen_z2 USING gist (geometry);
-- etldoc: ne_50m_admin_0_boundary_lines_land_gen_z2 -> ne_50m_admin_0_boundary_lines_land_gen_z1
DROP MATERIALIZED VIEW IF EXISTS ne_50m_admin_0_boundary_lines_land_gen_z1 CASCADE;
CREATE MATERIALIZED VIEW ne_50m_admin_0_boundary_lines_land_gen_z1 AS
(
SELECT ST_Simplify(geometry, ZRes(3)) as geometry,
admin_level,
disputed,
disputed_name,
claimed_by,
maritime
FROM ne_50m_admin_0_boundary_lines_land_gen_z2
) /* DELAY_MATERIALIZED_VIEW_CREATION */ ;
CREATE INDEX IF NOT EXISTS ne_50m_admin_0_boundary_lines_land_gen_z1_idx ON ne_50m_admin_0_boundary_lines_land_gen_z1 USING gist (geometry);
-- ne_110m_admin_0_boundary_lines_land
-- etldoc: ne_110m_admin_0_boundary_lines_land -> ne_110m_admin_0_boundary_lines_land_gen_z0
DROP MATERIALIZED VIEW IF EXISTS ne_110m_admin_0_boundary_lines_land_gen_z0 CASCADE;
CREATE MATERIALIZED VIEW ne_110m_admin_0_boundary_lines_land_gen_z0 AS
(
SELECT ST_Simplify(geometry, ZRes(2)) as geometry,
2 AS admin_level,
(CASE WHEN featurecla LIKE 'Disputed%' THEN TRUE ELSE FALSE END) AS disputed,
NULL::text AS disputed_name,
NULL::text AS claimed_by,
FALSE AS maritime
FROM ne_110m_admin_0_boundary_lines_land
) /* DELAY_MATERIALIZED_VIEW_CREATION */ ;
CREATE INDEX IF NOT EXISTS ne_110m_admin_0_boundary_lines_land_gen_z0_idx ON ne_110m_admin_0_boundary_lines_land_gen_z0 USING gist (geometry);
CREATE OR REPLACE FUNCTION edit_name(name varchar) RETURNS text AS
$$
SELECT CASE
WHEN POSITION(' at ' IN name) > 0
THEN replace(SUBSTRING(name, POSITION(' at ' IN name) + 4), ' ', '')
ELSE replace(replace(name, ' ', ''), 'Extentof', '')
END;
$$ LANGUAGE SQL IMMUTABLE
-- STRICT
PARALLEL SAFE
;
-- etldoc: ne_110m_admin_0_boundary_lines_land_gen_z0 -> boundary_z0
CREATE OR REPLACE VIEW boundary_z0 AS
(
SELECT geometry,
admin_level,
NULL::text AS adm0_l,
NULL::text AS adm0_r,
disputed,
disputed_name,
claimed_by,
maritime
FROM ne_110m_admin_0_boundary_lines_land_gen_z0
);
-- etldoc: ne_50m_admin_0_boundary_lines_land_gen_z1 -> boundary_z1
-- etldoc: ne_10m_admin_1_states_provinces_lines_gen_z1 -> boundary_z1
-- etldoc: ne_10m_admin_0_boundary_lines_land_disputed -> boundary_z1
-- etldoc: osm_border_disp_linestring_gen_z1 -> boundary_z1
DROP MATERIALIZED VIEW IF EXISTS boundary_z1 CASCADE;
CREATE MATERIALIZED VIEW boundary_z1 AS
(
SELECT geometry,
admin_level,
NULL::text AS adm0_l,
NULL::text AS adm0_r,
disputed,
disputed_name,
claimed_by,
maritime
FROM ne_50m_admin_0_boundary_lines_land_gen_z1
UNION ALL
SELECT geometry,
admin_level,
NULL::text AS adm0_l,
NULL::text AS adm0_r,
disputed,
disputed_name,
claimed_by,
maritime
FROM ne_10m_admin_1_states_provinces_lines_gen_z1
UNION ALL
SELECT geometry,
admin_level,
NULL::text AS adm0_l,
NULL::text AS adm0_r,
disputed,
disputed_name,
claimed_by,
maritime
FROM ne_10m_admin_0_boundary_lines_land_disputed
);
CREATE INDEX IF NOT EXISTS boundary_z1_idx ON boundary_z1 USING gist (geometry);
-- etldoc: ne_50m_admin_0_boundary_lines_land_gen_z2 -> boundary_z2
-- etldoc: ne_10m_admin_1_states_provinces_lines_gen_z2 -> boundary_z2
-- etldoc: ne_10m_admin_0_boundary_lines_land_disputed -> boundary_z2
-- etldoc: osm_border_disp_linestring_gen_z2 -> boundary_z2
DROP MATERIALIZED VIEW IF EXISTS boundary_z2 CASCADE;
CREATE MATERIALIZED VIEW boundary_z2 AS
(
SELECT geometry,
admin_level,
NULL::text AS adm0_l,
NULL::text AS adm0_r,
disputed,
disputed_name,
claimed_by,
maritime
FROM ne_50m_admin_0_boundary_lines_land_gen_z2
UNION ALL
SELECT geometry,
admin_level,
NULL::text AS adm0_l,
NULL::text AS adm0_r,
disputed,
disputed_name,
claimed_by,
maritime
FROM ne_10m_admin_1_states_provinces_lines_gen_z2
UNION ALL
SELECT geometry,
admin_level,
NULL::text AS adm0_l,
NULL::text AS adm0_r,
disputed,
disputed_name,
claimed_by,
maritime
FROM ne_10m_admin_0_boundary_lines_land_disputed
);
CREATE INDEX IF NOT EXISTS boundary_z2_idx ON boundary_z2 USING gist (geometry);
-- etldoc: ne_50m_admin_0_boundary_lines_land_gen_z3 -> boundary_z3
-- etldoc: ne_10m_admin_1_states_provinces_lines_gen_z3 -> boundary_z3
-- etldoc: ne_10m_admin_0_boundary_lines_land_disputed -> boundary_z3
-- etldoc: osm_border_disp_linestring_gen_z3 -> boundary_z3
DROP MATERIALIZED VIEW IF EXISTS boundary_z3 CASCADE;
CREATE MATERIALIZED VIEW boundary_z3 AS
(
SELECT geometry,
admin_level,
NULL::text AS adm0_l,
NULL::text AS adm0_r,
disputed,
disputed_name,
claimed_by,
maritime
FROM ne_50m_admin_0_boundary_lines_land_gen_z3
UNION ALL
SELECT geometry,
admin_level,
NULL::text AS adm0_l,
NULL::text AS adm0_r,
disputed,
disputed_name,
claimed_by,
maritime
FROM ne_10m_admin_1_states_provinces_lines_gen_z3
UNION ALL
SELECT geometry,
admin_level,
NULL::text AS adm0_l,
NULL::text AS adm0_r,
disputed,
disputed_name,
claimed_by,
maritime
FROM ne_10m_admin_0_boundary_lines_land_disputed
);
CREATE INDEX IF NOT EXISTS boundary_z3_idx ON boundary_z3 USING gist (geometry);
-- etldoc: ne_10m_admin_0_boundary_lines_land_gen_z4 -> boundary_z4
-- etldoc: ne_10m_admin_1_states_provinces_lines_gen_z4 -> boundary_z4
-- etldoc: osm_border_linestring_gen_z4 -> boundary_z4
DROP MATERIALIZED VIEW IF EXISTS boundary_z4 CASCADE;
CREATE MATERIALIZED VIEW boundary_z4 AS
(
SELECT geometry,
admin_level,
NULL::text AS adm0_l,
NULL::text AS adm0_r,
disputed,
disputed_name,
claimed_by,
maritime
FROM ne_10m_admin_0_boundary_lines_land_gen_z4
UNION ALL
SELECT geometry,
admin_level,
NULL::text AS adm0_l,
NULL::text AS adm0_r,
disputed,
disputed_name,
claimed_by,
maritime
FROM ne_10m_admin_1_states_provinces_lines_gen_z4
UNION ALL
SELECT geometry,
admin_level,
adm0_l,
adm0_r,
disputed,
CASE WHEN disputed THEN edit_name(name) END AS disputed_name,
claimed_by,
maritime
FROM osm_border_linestring_gen_z4
);
CREATE INDEX IF NOT EXISTS boundary_z4_idx ON boundary_z4 USING gist (geometry);
-- etldoc: osm_border_linestring_gen_z5 -> boundary_z5
CREATE OR REPLACE VIEW boundary_z5 AS
(
SELECT geometry,
admin_level,
adm0_l,
adm0_r,
disputed,
CASE WHEN disputed THEN edit_name(name) END AS disputed_name,
claimed_by,
maritime
FROM osm_border_linestring_gen_z5
WHERE admin_level <= 4
);
-- etldoc: osm_border_linestring_gen_z6 -> boundary_z6
CREATE OR REPLACE VIEW boundary_z6 AS
(
SELECT geometry,
admin_level,
adm0_l,
adm0_r,
disputed,
CASE WHEN disputed THEN edit_name(name) END AS disputed_name,
claimed_by,
maritime
FROM osm_border_linestring_gen_z6
WHERE admin_level <= 4
);
-- etldoc: osm_border_linestring_gen_z7 -> boundary_z7
CREATE OR REPLACE VIEW boundary_z7 AS
(
SELECT geometry,
admin_level,
adm0_l,
adm0_r,
disputed,
CASE WHEN disputed THEN edit_name(name) END AS disputed_name,
claimed_by,
maritime
FROM osm_border_linestring_gen_z7
WHERE admin_level <= 6
);
-- etldoc: osm_border_linestring_gen_z8 -> boundary_z8
CREATE OR REPLACE VIEW boundary_z8 AS
(
SELECT geometry,
admin_level,
adm0_l,
adm0_r,
disputed,
CASE WHEN disputed THEN edit_name(name) END AS disputed_name,
claimed_by,
maritime
FROM osm_border_linestring_gen_z8
WHERE admin_level <= 6
);
-- etldoc: osm_border_linestring_gen_z9 -> boundary_z9
CREATE OR REPLACE VIEW boundary_z9 AS
(
SELECT geometry,
admin_level,
adm0_l,
adm0_r,
disputed,
CASE WHEN disputed THEN edit_name(name) END AS disputed_name,
claimed_by,
maritime
FROM osm_border_linestring_gen_z9
WHERE admin_level <= 6
);
-- etldoc: osm_border_linestring_gen_z10 -> boundary_z10
CREATE OR REPLACE VIEW boundary_z10 AS
(
SELECT geometry,
admin_level,
adm0_l,
adm0_r,
disputed,
CASE WHEN disputed THEN edit_name(name) END AS disputed_name,
claimed_by,
maritime
FROM osm_border_linestring_gen_z10
WHERE admin_level <= 6
);
-- etldoc: osm_border_linestring_gen_z11 -> boundary_z11
CREATE OR REPLACE VIEW boundary_z11 AS
(
SELECT geometry,
admin_level,
adm0_l,
adm0_r,
disputed,
CASE WHEN disputed THEN edit_name(name) END AS disputed_name,
claimed_by,
maritime
FROM osm_border_linestring_gen_z11
WHERE admin_level <= 8
);
-- etldoc: osm_border_linestring_gen_z12 -> boundary_z12
CREATE OR REPLACE VIEW boundary_z12 AS
(
SELECT geometry,
admin_level,
adm0_l,
adm0_r,
disputed,
CASE WHEN disputed THEN edit_name(name) END AS disputed_name,
claimed_by,
maritime
FROM osm_border_linestring_gen_z12
);
-- etldoc: osm_border_linestring_gen_z13 -> boundary_z13
CREATE OR REPLACE VIEW boundary_z13 AS
(
SELECT geometry,
admin_level,
adm0_l,
adm0_r,
disputed,
CASE WHEN disputed THEN edit_name(name) END AS disputed_name,
claimed_by,
maritime
FROM osm_border_linestring_gen_z13
);
-- etldoc: layer_boundary[shape=record fillcolor=lightpink, style="rounded,filled",
-- etldoc: label="<sql> layer_boundary |<z0> z0 |<z1> z1 |<z2> z2 | <z3> z3 | <z4> z4 | <z5> z5 | <z6> z6 | <z7> z7 | <z8> z8 | <z9> z9 |<z10> z10 |<z11> z11 |<z12> z12|<z13> z13|<z14> z14+"]
CREATE OR REPLACE FUNCTION layer_boundary(bbox geometry, zoom_level int)
RETURNS TABLE
(
geometry geometry,
admin_level int,
adm0_l text,
adm0_r text,
disputed int,
disputed_name text,
claimed_by text,
maritime int,
class text,
name text,
tags hstore
)
AS
$$
SELECT geometry, admin_level, adm0_l, adm0_r, disputed::int, disputed_name, claimed_by, maritime::int, NULL::text, NULL::text, NULL::hstore
FROM (
-- etldoc: boundary_z0 -> layer_boundary:z0
SELECT *
FROM boundary_z0
WHERE geometry && bbox
AND zoom_level = 0
UNION ALL
-- etldoc: boundary_z1 -> layer_boundary:z1
SELECT *
FROM boundary_z1
WHERE geometry && bbox
AND zoom_level = 1
UNION ALL
-- etldoc: boundary_z2 -> layer_boundary:z2
SELECT *
FROM boundary_z2
WHERE geometry && bbox
AND zoom_level = 2
UNION ALL
-- etldoc: boundary_z3 -> layer_boundary:z3
SELECT *
FROM boundary_z3
WHERE geometry && bbox
AND zoom_level = 3
UNION ALL
-- etldoc: boundary_z4 -> layer_boundary:z4
SELECT *
FROM boundary_z4
WHERE geometry && bbox
AND zoom_level = 4
UNION ALL
-- etldoc: boundary_z5 -> layer_boundary:z5
SELECT *
FROM boundary_z5
WHERE geometry && bbox
AND zoom_level = 5
UNION ALL
-- etldoc: boundary_z6 -> layer_boundary:z6
SELECT *
FROM boundary_z6
WHERE geometry && bbox
AND zoom_level = 6
UNION ALL
-- etldoc: boundary_z7 -> layer_boundary:z7
SELECT *
FROM boundary_z7
WHERE geometry && bbox
AND zoom_level = 7
UNION ALL
-- etldoc: boundary_z8 -> layer_boundary:z8
SELECT *
FROM boundary_z8
WHERE geometry && bbox
AND zoom_level = 8
UNION ALL
-- etldoc: boundary_z9 -> layer_boundary:z9
SELECT *
FROM boundary_z9
WHERE geometry && bbox
AND zoom_level = 9
UNION ALL
-- etldoc: boundary_z10 -> layer_boundary:z10
SELECT *
FROM boundary_z10
WHERE geometry && bbox
AND zoom_level = 10
UNION ALL
-- etldoc: boundary_z11 -> layer_boundary:z11
SELECT *
FROM boundary_z11
WHERE geometry && bbox
AND zoom_level = 11
UNION ALL
-- etldoc: boundary_z12 -> layer_boundary:z12
SELECT *
FROM boundary_z12
WHERE geometry && bbox
AND zoom_level = 12
UNION ALL
-- etldoc: boundary_z13 -> layer_boundary:z13
SELECT *
FROM boundary_z13
WHERE geometry && bbox
AND zoom_level >= 13
) AS segment_zoom_levels
UNION ALL
SELECT geometry, NULL::int, NULL::text, NULL::text, NULL::int, NULL::text, NULL::text, NULL::int, class, name, tags
FROM (
-- etldoc: osm_boundary_polygon_gen_z4 -> layer_boundary:z4
SELECT geometry,
boundary AS class,
name,
tags
FROM osm_boundary_polygon_gen_z4
WHERE zoom_level = 4
AND geometry && bbox
UNION ALL
-- etldoc: osm_boundary_polygon_gen_z5 -> layer_boundary:z5
SELECT geometry,
boundary AS class,
name,
tags
FROM osm_boundary_polygon_gen_z5
WHERE zoom_level = 5
AND geometry && bbox
UNION ALL
-- etldoc: osm_boundary_polygon_gen_z6 -> layer_boundary:z6
SELECT geometry,
boundary AS class,
name,
tags
FROM osm_boundary_polygon_gen_z6
WHERE zoom_level = 6
AND geometry && bbox
UNION ALL
-- etldoc: osm_boundary_polygon_gen_z7 -> layer_boundary:z7
SELECT geometry,
boundary AS class,
name,
tags
FROM osm_boundary_polygon_gen_z7
WHERE zoom_level = 7
AND geometry && bbox
UNION ALL
-- etldoc: osm_boundary_polygon_gen_z8 -> layer_boundary:z8
SELECT geometry,
boundary AS class,
name,
tags
FROM osm_boundary_polygon_gen_z8
WHERE zoom_level = 8
AND geometry && bbox
UNION ALL
-- etldoc: osm_boundary_polygon_gen_z9 -> layer_boundary:z9
SELECT geometry,
boundary AS class,
name,
tags
FROM osm_boundary_polygon_gen_z9
WHERE zoom_level = 9
AND geometry && bbox
UNION ALL
-- etldoc: osm_boundary_polygon_gen_z10 -> layer_boundary:z10
SELECT geometry,
boundary AS class,
name,
tags
FROM osm_boundary_polygon_gen_z10
WHERE zoom_level = 10
AND geometry && bbox
UNION ALL
-- etldoc: osm_boundary_polygon_gen_z11 -> layer_boundary:z11
SELECT geometry,
boundary AS class,
name,
tags
FROM osm_boundary_polygon_gen_z11
WHERE zoom_level = 11
AND geometry && bbox
UNION ALL
-- etldoc: osm_boundary_polygon_gen_z12 -> layer_boundary:z12
SELECT geometry,
boundary AS class,
name,
tags
FROM osm_boundary_polygon_gen_z12
WHERE zoom_level = 12
AND geometry && bbox
UNION ALL
-- etldoc: osm_boundary_polygon_gen_z13 -> layer_boundary:z13
SELECT geometry,
boundary AS class,
name,
tags
FROM osm_boundary_polygon_gen_z13
WHERE zoom_level = 13
AND geometry && bbox
UNION ALL
-- etldoc: osm_boundary_polygon -> layer_boundary:z14
SELECT geometry,
boundary AS class,
name,
tags
FROM osm_boundary_polygon
WHERE zoom_level = 14
AND geometry && bbox
) AS area_zoom_levels
$$ LANGUAGE SQL STABLE
-- STRICT
PARALLEL SAFE;