-
Notifications
You must be signed in to change notification settings - Fork 3
/
schema.sql
1186 lines (889 loc) · 27 KB
/
schema.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
859
860
861
862
863
864
865
866
867
868
869
870
871
872
873
874
875
876
877
878
879
880
881
882
883
884
885
886
887
888
889
890
891
892
893
894
895
896
897
898
899
900
901
902
903
904
905
906
907
908
909
910
911
912
913
914
915
916
917
918
919
920
921
922
923
924
925
926
927
928
929
930
931
932
933
934
935
936
937
938
939
940
941
942
943
944
945
946
947
948
949
950
951
952
953
954
955
956
957
958
959
960
961
962
963
964
965
966
967
968
969
970
971
972
973
974
975
976
977
978
979
980
981
982
983
984
985
986
987
988
989
990
991
992
993
994
995
996
997
998
999
1000
--
-- PostgreSQL database dump
--
-- Dumped from database version 10.0
-- Dumped by pg_dump version 10.0
SET statement_timeout = 0;
SET lock_timeout = 0;
SET idle_in_transaction_session_timeout = 0;
SET client_encoding = 'UTF8';
SET standard_conforming_strings = on;
SET check_function_bodies = false;
SET client_min_messages = warning;
SET row_security = off;
--
-- Name: plpgsql; Type: EXTENSION; Schema: -; Owner: -
--
CREATE EXTENSION IF NOT EXISTS plpgsql WITH SCHEMA pg_catalog;
--
-- Name: EXTENSION plpgsql; Type: COMMENT; Schema: -; Owner: -
--
COMMENT ON EXTENSION plpgsql IS 'PL/pgSQL procedural language';
--
-- Name: intarray; Type: EXTENSION; Schema: -; Owner: -
--
CREATE EXTENSION IF NOT EXISTS intarray WITH SCHEMA public;
--
-- Name: EXTENSION intarray; Type: COMMENT; Schema: -; Owner: -
--
COMMENT ON EXTENSION intarray IS 'functions, operators, and index support for 1-D arrays of integers';
--
-- Name: postgis; Type: EXTENSION; Schema: -; Owner: -
--
CREATE EXTENSION IF NOT EXISTS postgis WITH SCHEMA public;
--
-- Name: EXTENSION postgis; Type: COMMENT; Schema: -; Owner: -
--
COMMENT ON EXTENSION postgis IS 'PostGIS geometry, geography, and raster spatial types and functions';
SET search_path = public, pg_catalog;
SET default_tablespace = '';
SET default_with_oids = false;
--
-- Name: atlas; Type: TABLE; Schema: public; Owner: -
--
CREATE TABLE atlas (
gid integer NOT NULL,
code text,
geom geometry(MultiPolygon,4326),
city text
);
--
-- Name: census_areas; Type: TABLE; Schema: public; Owner: -
--
CREATE TABLE census_areas (
gid integer NOT NULL,
cod_reg numeric,
cod_istat numeric,
pro_com integer,
sez2011 character varying(13) NOT NULL,
sez numeric,
cod_stagno numeric,
cod_fiume numeric,
cod_lago numeric,
cod_laguna numeric,
cod_val_p numeric,
cod_zona_c numeric,
cod_is_amm numeric,
cod_is_lac numeric,
cod_is_mar numeric,
cod_area_s numeric,
cod_mont_d numeric,
loc2011 numeric,
cod_loc numeric,
tipo_loc numeric,
com_asc numeric,
cod_asc character varying(50),
ace integer,
shape_leng numeric,
shape_area numeric,
geom geometry(MultiPolygon,4326)
);
--
-- Name: cities; Type: TABLE; Schema: public; Owner: -
--
CREATE TABLE cities (
name character varying(150) NOT NULL,
pro_com integer NOT NULL,
boundary_geom geometry(MultiPolygon,4326)
);
--
-- Name: istat_sezioni; Type: MATERIALIZED VIEW; Schema: public; Owner: -
--
CREATE MATERIALIZED VIEW istat_sezioni AS
SELECT st_multi(st_union(c.geom)) AS geom,
c.ace,
c.pro_com
FROM census_areas c
INNER JOIN cities c2 ON c2.pro_com = c.pro_com
GROUP BY c.ace, c.pro_com
WITH NO DATA;
--
-- Name: atlas_sezioni; Type: MATERIALIZED VIEW; Schema: public; Owner: -
--
CREATE MATERIALIZED VIEW atlas_sezioni AS
SELECT atlas.gid,
atlas.code,
atlas.geom,
sezione.ace,
sezione.pro_com
FROM (istat_sezioni sezione
JOIN atlas ON (st_intersects(sezione.geom, atlas.geom)))
WHERE (sezione.pro_com IN ( SELECT cities.pro_com
FROM cities))
WITH NO DATA;
--
-- Name: atlas_area_novac; Type: MATERIALIZED VIEW; Schema: public; Owner: -
--
CREATE MATERIALIZED VIEW atlas_area_novac AS
SELECT COALESCE(sum(st_area((
CASE
WHEN st_coveredby(s.geom, a.geom) THEN s.geom
ELSE st_multi(st_intersection(a.geom, s.geom))
END)::geography)), (0)::double precision) AS area,
s.ace,
s.pro_com
FROM (atlas_sezioni a
JOIN istat_sezioni s ON (((s.ace = a.ace) AND (s.pro_com = a.pro_com))))
WHERE (a.code = ANY (ARRAY['50000'::text, '14100'::text, '40000'::text, '30000'::text, '31000'::text]))
GROUP BY s.ace, s.pro_com
WITH NO DATA;
--
-- Name: atlas_gid_seq; Type: SEQUENCE; Schema: public; Owner: -
--
CREATE SEQUENCE atlas_gid_seq
AS integer
START WITH 1
INCREMENT BY 1
NO MINVALUE
NO MAXVALUE
CACHE 1;
--
-- Name: atlas_gid_seq; Type: SEQUENCE OWNED BY; Schema: public; Owner: -
--
ALTER SEQUENCE atlas_gid_seq OWNED BY atlas.gid;
--
-- Name: atlas_railways; Type: MATERIALIZED VIEW; Schema: public; Owner: -
--
CREATE TABLE railways (
geom geometry(MultiPolygon,4326),
city text
);
CREATE INDEX ON railways USING GIST (geom);
create materialized view atlas_railways as
select geom, pro_com
from (
select a.geom, b.pro_com
from railways a
INNER JOIN cities b ON ST_INTERSECTS(a.geom, b.boundary_geom)
) as foo
where not ST_IsEmpty(geom);
--
-- Name: buildings; Type: TABLE; Schema: public; Owner: -
--
CREATE TABLE buildings (
gid integer NOT NULL,
geom geometry(MultiPolygon,4326),
city text,
osm_id text
);
--
-- Name: buildings_gid_seq; Type: SEQUENCE; Schema: public; Owner: -
--
CREATE SEQUENCE buildings_gid_seq
AS integer
START WITH 1
INCREMENT BY 1
NO MINVALUE
NO MAXVALUE
CACHE 1;
--
-- Name: buildings_gid_seq; Type: SEQUENCE OWNED BY; Schema: public; Owner: -
--
ALTER SEQUENCE buildings_gid_seq OWNED BY buildings.gid;
--
-- Name: buildings_sezioni; Type: MATERIALIZED VIEW; Schema: public; Owner: -
--
CREATE MATERIALIZED VIEW buildings_sezioni AS
SELECT (st_dump(st_multi(st_union(buildings.geom)))).geom AS geom,
sezione.ace,
sezione.pro_com
FROM istat_sezioni sezione,
buildings
WHERE (st_intersects(sezione.geom, buildings.geom) AND (NOT st_touches(sezione.geom, buildings.geom)))
GROUP BY sezione.ace, sezione.pro_com
WITH NO DATA;
--
-- Name: census_areas_gid_seq; Type: SEQUENCE; Schema: public; Owner: -
--
CREATE SEQUENCE census_areas_gid_seq
START WITH 1
INCREMENT BY 1
NO MINVALUE
NO MAXVALUE
CACHE 1;
--
-- Name: census_areas_gid_seq; Type: SEQUENCE OWNED BY; Schema: public; Owner: -
--
ALTER SEQUENCE census_areas_gid_seq OWNED BY census_areas.gid;
--
-- Name: companies; Type: TABLE; Schema: public; Owner: -
--
CREATE TABLE companies (
long double precision,
lat double precision,
dimension text,
geom geometry,
city text
);
CREATE TABLE companies_temp (
long double precision,
lat double precision,
dimension text
);
--
-- Name: foursquare_venues; Type: TABLE; Schema: public; Owner: -
--
CREATE TABLE foursquare_venues (
gridcell integer,
category text,
geom geometry(Point,4326),
name text,
venueid text,
city text
);
CREATE TABLE foursquare_venues_temp (
long double precision,
lat double precision,
category character varying(200),
name character varying(200),
venueid character varying(200)
);
--
-- Name: istat_indicatori; Type: TABLE; Schema: public; Owner: -
--
CREATE TABLE istat_indicatori (
"CODREG" numeric,
"REGIONE" character varying,
"CODPRO" numeric,
"PROVINCIA" character varying,
"CODCOM" numeric,
"COMUNE" character varying,
"PROCOM" numeric,
"SEZ2011" numeric,
"NSEZ" numeric,
"ACE" numeric,
"CODLOC" numeric,
"CODASC" numeric,
"P1" numeric,
"P2" numeric,
"P3" numeric,
"P4" numeric,
"P5" numeric,
"P6" numeric,
"P7" numeric,
"P8" numeric,
"P9" numeric,
"P10" numeric,
"P11" numeric,
"P12" numeric,
"P13" numeric,
"P14" numeric,
"P15" numeric,
"P16" numeric,
"P17" numeric,
"P18" numeric,
"P19" numeric,
"P20" numeric,
"P21" numeric,
"P22" numeric,
"P23" numeric,
"P24" numeric,
"P25" numeric,
"P26" numeric,
"P27" numeric,
"P28" numeric,
"P29" numeric,
"P30" numeric,
"P31" numeric,
"P32" numeric,
"P33" numeric,
"P34" numeric,
"P35" numeric,
"P36" numeric,
"P37" numeric,
"P38" numeric,
"P39" numeric,
"P40" numeric,
"P41" numeric,
"P42" numeric,
"P43" numeric,
"P44" numeric,
"P45" numeric,
"P46" numeric,
"P47" numeric,
"P48" numeric,
"P49" numeric,
"P50" numeric,
"P51" numeric,
"P52" numeric,
"P53" numeric,
"P54" numeric,
"P55" numeric,
"P56" numeric,
"P57" numeric,
"P58" numeric,
"P59" numeric,
"P60" numeric,
"P61" numeric,
"P62" numeric,
"P64" numeric,
"P65" numeric,
"P66" numeric,
"P128" numeric,
"P129" numeric,
"P130" numeric,
"P131" numeric,
"P132" numeric,
"P135" numeric,
"P136" numeric,
"P137" numeric,
"P138" numeric,
"P139" numeric,
"P140" numeric,
"ST1" numeric,
"ST2" numeric,
"ST3" numeric,
"ST4" numeric,
"ST5" numeric,
"ST6" numeric,
"ST7" numeric,
"ST8" numeric,
"ST9" numeric,
"ST10" numeric,
"ST11" numeric,
"ST12" numeric,
"ST13" numeric,
"ST14" numeric,
"ST15" numeric,
"A2" numeric,
"A3" numeric,
"A5" numeric,
"A6" numeric,
"A7" numeric,
"A44" numeric,
"A46" numeric,
"A47" numeric,
"A48" numeric,
"PF1" numeric,
"PF2" numeric,
"PF3" numeric,
"PF4" numeric,
"PF5" numeric,
"PF6" numeric,
"PF7" numeric,
"PF8" numeric,
"PF9" numeric,
"E1" numeric,
"E2" numeric,
"E3" numeric,
"E4" numeric,
"E5" numeric,
"E6" numeric,
"E7" numeric,
"E8" numeric,
"E9" numeric,
"E10" numeric,
"E11" numeric,
"E12" numeric,
"E13" numeric,
"E14" numeric,
"E15" numeric,
"E16" numeric,
"E17" numeric,
"E18" numeric,
"E19" numeric,
"E20" numeric,
"E21" numeric,
"E22" numeric,
"E23" numeric,
"E24" numeric,
"E25" numeric,
"E26" numeric,
"E27" numeric,
"E28" numeric,
"E29" numeric,
"E30" numeric,
"E31" numeric
);
--
-- Name: istat_industria; Type: TABLE; Schema: public; Owner: -
--
CREATE TABLE istat_industria (
"TIPO_SOGGETTO" character varying,
"CODREG" numeric,
"PROCOM" numeric,
"NSEZ" numeric,
"ATECO3" numeric,
"NUM_UNITA" numeric,
"ADDETTI" numeric,
"ALTRI_RETRIB" numeric,
"VOLONTARI" numeric
);
--
-- Name: parks; Type: TABLE; Schema: public; Owner: -
--
CREATE TABLE parks (
osm_id bigint,
geom geometry(MultiPolygon,4326),
city text,
geoarea float
);
--
-- Name: roads; Type: TABLE; Schema: public; Owner: -
--
CREATE TABLE roads (
gid integer NOT NULL,
area character varying(254),
highway character varying(254),
junction character varying(254),
name character varying(254),
city text,
geom geometry(LineString,4326)
);
--
-- Name: roads_roundabout; Type: MATERIALIZED VIEW; Schema: public; Owner: -
--
CREATE MATERIALIZED VIEW roads_roundabout AS
WITH RECURSIVE inter_agg AS (
SELECT r.gid,
(ARRAY[r.gid] || array_agg(r2.gid)) AS arr
FROM (roads r
JOIN roads r2 ON ((r.gid <> r2.gid)))
WHERE (st_intersects(r.geom, r2.geom) AND ((r.junction)::text = 'roundabout'::text) AND ((r2.junction)::text = 'roundabout'::text))
GROUP BY r.gid
), final AS (
SELECT DISTINCT i.gid,
i.arr AS inter,
ARRAY[i.gid] AS ex
FROM inter_agg i
UNION
SELECT f.gid,
uniq(sort((f.inter || i.arr))) AS uniq,
uniq(sort((f.ex || ARRAY[i.gid]))) AS uniq
FROM (final f
JOIN inter_agg i ON (((f.gid < i.gid) AND (f.inter @> ARRAY[i.gid]) AND ((f.ex @> ARRAY[i.gid]) IS FALSE))))
)
SELECT ( SELECT st_union(roads.geom) AS st_union
FROM roads
WHERE (roads.gid = ANY (final.inter))) AS geom,
final.inter
FROM final
WHERE (final.inter = final.ex)
WITH NO DATA;
--
-- Name: roads_2ways; Type: MATERIALIZED VIEW; Schema: public; Owner: -
--
CREATE MATERIALIZED VIEW roads_2ways AS
SELECT foo.p,
foo.road1,
foo.road2
FROM ( SELECT DISTINCT (st_dump(st_setsrid(st_intersection(a.geom, b.geom), 4326))).geom AS p,
a.gid AS road1,
b.gid AS road2
FROM (roads a
JOIN roads b ON ((((a.city)::text = (b.city)::text) AND st_intersects(a.geom, b.geom) AND (a.gid < b.gid) AND ((((a.highway)::text <> (b.highway)::text) AND (a.name IS NULL) AND (b.name IS NULL)) OR ((((a.name)::text <> (b.name)::text) OR (a.name IS NULL) OR (b.name IS NULL)) AND (NOT ((a.name IS NULL) AND (b.name IS NULL))))))))
WHERE ((NOT (a.gid IN ( SELECT unnest(roads_roundabout.inter) AS unnest
FROM roads_roundabout))) AND (NOT (b.gid IN ( SELECT unnest(roads_roundabout.inter) AS unnest
FROM roads_roundabout))))) foo
WHERE ((NOT (EXISTS ( SELECT foo2.inter
FROM roads_roundabout foo2
WHERE st_intersects(foo.p, foo2.geom)
LIMIT 1))) AND (geometrytype(foo.p) = 'POINT'::text))
WITH NO DATA;
--
-- Name: roads_2ways_sezioni; Type: MATERIALIZED VIEW; Schema: public; Owner: -
--
CREATE MATERIALIZED VIEW roads_2ways_sezioni AS
SELECT DISTINCT roads_2ways.p,
roads_2ways.road1,
roads_2ways.road2,
sezione.ace,
sezione.pro_com
FROM (roads_2ways
JOIN istat_sezioni sezione ON (st_within(roads_2ways.p, sezione.geom)))
WITH NO DATA;
--
-- Name: roads_3ways; Type: MATERIALIZED VIEW; Schema: public; Owner: -
--
CREATE MATERIALIZED VIEW roads_3ways AS
SELECT st_setsrid(st_intersection(a.geom, b.p), 4326) AS p,
b.road1,
b.road2,
a.gid AS road3
FROM (roads a
JOIN roads_2ways b ON ((st_intersects(a.geom, b.p) AND (a.gid < b.road2) AND (a.gid < b.road1))))
WHERE (geometrytype(st_intersection(a.geom, b.p)) = 'POINT'::text)
WITH NO DATA;
--
-- Name: roads_4ways; Type: MATERIALIZED VIEW; Schema: public; Owner: -
--
CREATE MATERIALIZED VIEW roads_4ways AS
SELECT DISTINCT st_setsrid(st_intersection(a.geom, b.p), 4326) AS p,
b.road1,
b.road2,
b.road3,
a.gid AS road4
FROM (roads a
JOIN roads_3ways b ON ((st_intersects(a.geom, b.p) AND (a.gid < b.road2) AND (a.gid < b.road1) AND (a.gid < b.road3))))
WHERE (geometrytype(st_intersection(a.geom, b.p)) = 'POINT'::text)
WITH NO DATA;
--
-- Name: roads_4ways_sezioni; Type: MATERIALIZED VIEW; Schema: public; Owner: -
--
CREATE MATERIALIZED VIEW roads_4ways_sezioni AS
SELECT DISTINCT roads_4ways.p,
roads_4ways.road1,
roads_4ways.road2,
roads_4ways.road3,
roads_4ways.road4,
sezione.ace,
sezione.pro_com
FROM (roads_4ways
JOIN istat_sezioni sezione ON (st_within(roads_4ways.p, sezione.geom)))
WITH NO DATA;
--
-- Name: roads_sezioni; Type: MATERIALIZED VIEW; Schema: public; Owner: -
--
CREATE MATERIALIZED VIEW roads_sezioni AS
SELECT roads.gid,
roads.geom,
sezione.ace,
sezione.pro_com,
roads.name
FROM istat_sezioni sezione,
roads
WHERE st_intersects(sezione.geom, roads.geom)
WITH NO DATA;
--
-- Name: roads_union; Type: MATERIALIZED VIEW; Schema: public; Owner: -
--
CREATE MATERIALIZED VIEW roads_union AS
SELECT st_multi(st_union(roads_sezioni.geom)) AS geom,
roads_sezioni.ace,
roads_sezioni.pro_com
FROM roads_sezioni
GROUP BY roads_sezioni.ace, roads_sezioni.pro_com
WITH NO DATA;
--
-- Name: roads_buffered; Type: MATERIALIZED VIEW; Schema: public; Owner: -
--
CREATE MATERIALIZED VIEW roads_buffered AS
SELECT st_buffer(roads_union.geom, (0.00005)::double precision) AS geom,
roads_union.pro_com,
roads_union.ace
FROM roads_union
WITH NO DATA;
--
-- Name: roads_gid_seq; Type: SEQUENCE; Schema: public; Owner: -
--
CREATE SEQUENCE roads_gid_seq
AS integer
START WITH 1
INCREMENT BY 1
NO MINVALUE
NO MAXVALUE
CACHE 1;
--
-- Name: roads_gid_seq; Type: SEQUENCE OWNED BY; Schema: public; Owner: -
--
ALTER SEQUENCE roads_gid_seq OWNED BY roads.gid;
--
-- Name: roads_roundabout_sezioni; Type: MATERIALIZED VIEW; Schema: public; Owner: -
--
CREATE MATERIALIZED VIEW roads_roundabout_sezioni AS
SELECT a.inter,
a.geom,
( SELECT count(b.name) AS count
FROM roads b
WHERE (st_intersects(a.geom, b.geom) AND (NOT (b.gid = ANY (a.inter))))) AS num,
( SELECT count(DISTINCT b.name) AS count
FROM roads b
WHERE (st_intersects(a.geom, b.geom) AND (NOT (b.gid = ANY (a.inter))))) AS numd,
sezione.ace,
sezione.pro_com
FROM (roads_roundabout a
JOIN istat_sezioni sezione ON (st_intersects(a.geom, sezione.geom)))
WITH NO DATA;
--
-- Name: temp_atlas; Type: TABLE; Schema: public; Owner: -
--
CREATE TABLE temp_atlas (
ogc_fid integer NOT NULL,
cities character varying(254),
luz_or_cit character varying(254),
code character varying(7),
item character varying(150),
prod_date character varying(4),
shape_len numeric(32,10),
shape_area numeric(32,10),
wkb_geometry geometry(Geometry,3035)
);
--
-- Name: temp_atlas_ogc_fid_seq; Type: SEQUENCE; Schema: public; Owner: -
--
CREATE SEQUENCE temp_atlas_ogc_fid_seq
AS integer
START WITH 1
INCREMENT BY 1
NO MINVALUE
NO MAXVALUE
CACHE 1;
--
-- Name: temp_atlas_ogc_fid_seq; Type: SEQUENCE OWNED BY; Schema: public; Owner: -
--
ALTER SEQUENCE temp_atlas_ogc_fid_seq OWNED BY temp_atlas.ogc_fid;
--
-- Name: temp_boundaries; Type: TABLE; Schema: public; Owner: -
--
CREATE TABLE temp_boundaries (
"URAU_ID" text,
"URAU_NAME" text,
"CNTR_CODE" text,
"URAU_CATG" text,
"CAPT" text,
"GRCITY_COD" text,
"URBC_POPL" bigint,
"URBC_P_SCR" text,
"URAU_POPL" bigint,
"URAU_P_SRC" text,
"NUTS3_2010" text,
"NUTS3_2006" text,
"FUA_CODE" text,
"PORT" text,
"AREA_SQK" double precision,
"URBC_CODE" text,
geom geometry(MultiPolygon,4326),
cities character varying(254),
luz_or_cit character varying(254),
code character varying(7),
item character varying(150),
prod_date character varying(4),
shape_len numeric(32,10),
shape_area numeric(32,10)
);
--
-- Name: atlas gid; Type: DEFAULT; Schema: public; Owner: -
--
ALTER TABLE ONLY atlas ALTER COLUMN gid SET DEFAULT nextval('atlas_gid_seq'::regclass);
--
-- Name: buildings gid; Type: DEFAULT; Schema: public; Owner: -
--
ALTER TABLE ONLY buildings ALTER COLUMN gid SET DEFAULT nextval('buildings_gid_seq'::regclass);
--
-- Name: census_areas gid; Type: DEFAULT; Schema: public; Owner: -
--
ALTER TABLE ONLY census_areas ALTER COLUMN gid SET DEFAULT nextval('census_areas_gid_seq'::regclass);
--
-- Name: roads gid; Type: DEFAULT; Schema: public; Owner: -
--
ALTER TABLE ONLY roads ALTER COLUMN gid SET DEFAULT nextval('roads_gid_seq'::regclass);
--
-- Name: temp_atlas ogc_fid; Type: DEFAULT; Schema: public; Owner: -
--
ALTER TABLE ONLY temp_atlas ALTER COLUMN ogc_fid SET DEFAULT nextval('temp_atlas_ogc_fid_seq'::regclass);
--
-- Name: census_areas census_areas_pkey; Type: CONSTRAINT; Schema: public; Owner: -
--
ALTER TABLE ONLY census_areas
ADD CONSTRAINT census_areas_pkey PRIMARY KEY (sez2011);
--
-- Name: cities cities_pkey; Type: CONSTRAINT; Schema: public; Owner: -
--
ALTER TABLE ONLY cities
ADD CONSTRAINT cities_pkey PRIMARY KEY (name, pro_com);
ALTER TABLE ONLY cities
ADD CONSTRAINT cities_ukey UNIQUE (pro_com);
ALTER TABLE ONLY cities
ADD CONSTRAINT cities_ukey2 UNIQUE (name);
--
-- Name: temp_atlas temp_atlas_pkey; Type: CONSTRAINT; Schema: public; Owner: -
--
ALTER TABLE ONLY temp_atlas
ADD CONSTRAINT temp_atlas_pkey PRIMARY KEY (ogc_fid);
ALTER TABLE atlas
ADD CONSTRAINT fk_atlas FOREIGN KEY (city) REFERENCES cities (name) ON UPDATE RESTRICT ON DELETE CASCADE;
ALTER TABLE buildings
ADD CONSTRAINT fk_buildings FOREIGN KEY (city) REFERENCES cities (name) ON UPDATE RESTRICT ON DELETE CASCADE;
ALTER TABLE roads
ADD CONSTRAINT fk_roads FOREIGN KEY (city) REFERENCES cities (name) ON UPDATE RESTRICT ON DELETE CASCADE;
ALTER TABLE companies
ADD CONSTRAINT fk_companies FOREIGN KEY (city) REFERENCES cities (name) ON UPDATE RESTRICT ON DELETE CASCADE;
ALTER TABLE foursquare_venues
ADD CONSTRAINT fk_foursquare_venues FOREIGN KEY (city) REFERENCES cities (name) ON UPDATE RESTRICT ON DELETE CASCADE;
ALTER TABLE railways
ADD CONSTRAINT fk_railways FOREIGN KEY (city) REFERENCES cities (name) ON UPDATE RESTRICT ON DELETE CASCADE;
ALTER TABLE parks
ADD CONSTRAINT fk_parks FOREIGN KEY (city) REFERENCES cities (name) ON UPDATE RESTRICT ON DELETE CASCADE;
--
-- Name: atlas_area_novac_ace_pro_com_idx; Type: INDEX; Schema: public; Owner: -
--
CREATE INDEX atlas_area_novac_ace_pro_com_idx ON atlas_area_novac USING btree (ace, pro_com);
--
-- Name: atlas_code_idx; Type: INDEX; Schema: public; Owner: -
--
CREATE INDEX atlas_code_idx ON atlas USING btree (code);
--
-- Name: atlas_geom_idx; Type: INDEX; Schema: public; Owner: -
--
CREATE INDEX atlas_geom_idx ON atlas USING gist (geom);
--
-- Name: atlas_railways_geom_idx; Type: INDEX; Schema: public; Owner: -
--
CREATE INDEX atlas_railways_geom_idx ON atlas_railways USING gist (geom);
--
-- Name: atlas_railways_pro_com_idx; Type: INDEX; Schema: public; Owner: -
--
CREATE INDEX atlas_railways_pro_com_idx ON atlas_railways USING btree (pro_com);
--
-- Name: atlas_sezioni_ace_pro_com_idx; Type: INDEX; Schema: public; Owner: -
--
CREATE INDEX atlas_sezioni_ace_pro_com_idx ON atlas_sezioni USING btree (ace, pro_com);
CREATE INDEX ON atlas_sezioni USING btree (pro_com, ace);
--
-- Name: atlas_sezioni_code_idx; Type: INDEX; Schema: public; Owner: -
--
CREATE INDEX atlas_sezioni_code_idx ON atlas_sezioni USING hash (code);
--
-- Name: atlas_sezioni_geom_idx; Type: INDEX; Schema: public; Owner: -
--
CREATE INDEX atlas_sezioni_geom_idx ON atlas_sezioni USING gist (geom);
--
-- Name: atlas_sezioni_gid_idx; Type: INDEX; Schema: public; Owner: -
--
CREATE INDEX atlas_sezioni_gid_idx ON atlas_sezioni USING btree (gid);
create index on buildings USING gist (geom);
--
-- Name: buildings_sezioni_ace_pro_com_idx; Type: INDEX; Schema: public; Owner: -
--
CREATE INDEX buildings_sezioni_ace_pro_com_idx ON buildings_sezioni USING btree (ace, pro_com);
--
-- Name: buildings_sezioni_geom_idx; Type: INDEX; Schema: public; Owner: -
--
CREATE INDEX buildings_sezioni_geom_idx ON buildings_sezioni USING gist (geom);
--
-- Name: census_areas_geom_idx; Type: INDEX; Schema: public; Owner: -
--
CREATE INDEX census_areas_geom_idx ON census_areas USING gist (geom);
--
-- Name: census_areas_pro_com_idx; Type: INDEX; Schema: public; Owner: -
--
CREATE INDEX census_areas_pro_com_idx ON census_areas USING btree (pro_com);
--
-- Name: census_areas_sez2011_idx; Type: INDEX; Schema: public; Owner: -
--
CREATE INDEX census_areas_sez2011_idx ON census_areas USING btree (sez2011);
--
-- Name: companies_geom_idx; Type: INDEX; Schema: public; Owner: -
--
CREATE INDEX companies_geom_idx ON companies USING gist (geom);
--
-- Name: idx_temp_boundaries_geom; Type: INDEX; Schema: public; Owner: -
--
CREATE INDEX idx_temp_boundaries_geom ON temp_boundaries USING gist (geom);
--
-- Name: istat_indicatori_ACE_idx; Type: INDEX; Schema: public; Owner: -
--
CREATE INDEX "istat_indicatori_ACE_idx" ON istat_indicatori USING btree ("ACE");
--
-- Name: istat_indicatori_PROCOM_idx; Type: INDEX; Schema: public; Owner: -