~ubuntu-geonames-hackers/ubuntu-geonames/trunk

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
#!/bin/bash
# If DB is local pass no arguments else
# ./import-geonames.sh -u user -h host -p port -d dbname
while getopts u:h:p:d: flag; do
    case $flag in
        u) PGUSER=$OPTARG;
           PGUSER_PARAM="--username $OPTARG";;
        h) PGHOST="--host $OPTARG";;
        p) PGPORT="--port $OPTARG";;
        d) PGDBNAME="--dbname $OPTARG";;
    esac
done
PGDBNAME=${PGDBNAME:="geonames"}
PGUSER=${PGUSER:="geouser"}

PSQL_CMD="psql $PGUSER_PARAM $PGPASS $PGHOST $PGPORT $PGDBNAME"
WORKPATH="$(mktemp -d)"

chmod 755 $WORKPATH
cd $WORKPATH
trap "rm -rf $WORKPATH" EXIT HUP INT QUIT TERM
pwd
# allCountries.zip contains allCountries.txt
# alternateNames.zip contains iso-languagecodes.txt alternateNames.txt
ZIPFILES="allCountries.zip alternateNames.zip"
TXTFILES="admin1CodesASCII.txt admin2Codes.txt countryInfo.txt timeZones.txt"
for i in $ZIPFILES $TXTFILES
do
	wget "https://download.geonames.org/export/dump/$i"
done
for i in $ZIPFILES
do
	unzip -o -qq $i
done

# alter files for import
tail -n +2 iso-languagecodes.txt > iso-languagecodes.txt.tmp
grep -v '^#' countryInfo.txt > countryInfo.txt.tmp
tail -n +2 timeZones.txt > timeZones.txt.tmp

LOAD_POSTFIX="_load" 
BACKUP_POSTFIX="_bkup" 
$PSQL_CMD <<EOT
BEGIN;
DROP TABLE IF EXISTS geoname${LOAD_POSTFIX};
CREATE TABLE geoname${LOAD_POSTFIX} (
	geonameid int,
	name varchar(200),
	asciiname varchar(200),
	alternatenames varchar(12000),
	latitude float,
	longitude float,
	fclass char(1),
	fcode varchar(10),
	country varchar(2),
	cc2 varchar(200),
	admin1 varchar(20),
	admin2 varchar(80),
	admin3 varchar(20),
	admin4 varchar(20),
	population bigint,
	elevation int,
	gtopo30 int,
	timezone varchar(40),
	moddate date
);
\copy geoname${LOAD_POSTFIX} (geonameid,name,asciiname,alternatenames,latitude,longitude,fclass,fcode,country,cc2, admin1,admin2,admin3,admin4,population,elevation,gtopo30,timezone,moddate) from $WORKPATH/allCountries.txt null as ''

DROP TABLE IF EXISTS alternatename${LOAD_POSTFIX};
CREATE TABLE alternatename${LOAD_POSTFIX} (
	alternatenameId int,
	geonameid int,
	isoLanguage varchar(7),
	alternateName varchar(400),
	isPreferredName boolean,
	isShortName boolean,
	isColloquial boolean,
	isHistoric boolean
);
\copy alternatename${LOAD_POSTFIX}  (alternatenameid,geonameid,isoLanguage,alternateName,isPreferredName,isShortName,isColloquial,isHistoric) from $WORKPATH/alternateNames.txt null as '';

DROP TABLE IF EXISTS countryinfo${LOAD_POSTFIX};
CREATE TABLE countryinfo${LOAD_POSTFIX} (
	iso_alpha2 char(2),
	iso_alpha3 char(3),
	iso_numeric integer,
	fips_code character varying(3),
	name character varying(200),
	capital character varying(200),
	areainsqkm double precision,
	population bigint,
	continent char(2),
	tld char(3),
	currency char(3),
	currencyName character varying(20),
	Phone char(20),
	postalCodeFormat char(60),
	postalCodeRegex char(200),
	languages character varying(200),
	geonameId int,
	neighbours char(50),
	equivalentFipsCode char(10)
);
\copy countryInfo${LOAD_POSTFIX} (iso_alpha2,iso_alpha3,iso_numeric,fips_code,name,capital,areaInSqKm,population,continent,tld,currency,currencyName,Phone,postalCodeFormat,postalCodeRegex,languages,geonameId,neighbours,equivalentFipsCode) from $WORKPATH/countryInfo.txt.tmp null as ''

DROP TABLE IF EXISTS iso_languagecodes${LOAD_POSTFIX};
CREATE TABLE iso_languagecodes${LOAD_POSTFIX}(
	iso_639_3 CHAR(4),
	iso_639_2 VARCHAR(50),
	iso_639_1 VARCHAR(50),
	language_name VARCHAR(200)
);
\copy iso_languagecodes${LOAD_POSTFIX} (iso_639_3, iso_639_2, iso_639_1, language_name) from $WORKPATH/iso-languagecodes.txt.tmp null as ''

DROP TABLE IF EXISTS admin1codes${LOAD_POSTFIX};
CREATE TABLE admin1codes${LOAD_POSTFIX} (
	code varchar(20),
	name TEXT,
	nameAscii TEXT,
	geonameid int
);
\copy admin1codes${LOAD_POSTFIX} (code,name,nameAscii,geonameid) from $WORKPATH/admin1CodesASCII.txt null as ''

DROP TABLE IF EXISTS admin2codes${LOAD_POSTFIX};
CREATE TABLE admin2codes${LOAD_POSTFIX} (
        code varchar(80),
        name TEXT,
        nameAscii TEXT,
        geonameid int
);
\copy admin2codes${LOAD_POSTFIX} (code,name,nameAscii,geonameid) from $WORKPATH/admin2Codes.txt null as ''

DROP TABLE IF EXISTS timeZones${LOAD_POSTFIX};
CREATE TABLE timeZones${LOAD_POSTFIX} (
	code CHAR(2),
	timeZoneId VARCHAR(200),
	GMT_offset numeric(3,1),
	DST_offset numeric(3,1),
	RAW_offset numeric(3,1)
);
\copy timeZones${LOAD_POSTFIX} (code,timeZoneId,GMT_offset,DST_offset,RAW_offset) from $WORKPATH/timeZones.txt.tmp null as ''

DROP TABLE IF EXISTS continentCodes${LOAD_POSTFIX};
CREATE TABLE continentCodes${LOAD_POSTFIX} (
	code CHAR(2),
	name VARCHAR(20),
	geonameid INT
);
INSERT INTO continentCodes${LOAD_POSTFIX} VALUES ('AF', 'Africa', 6255146);
INSERT INTO continentCodes${LOAD_POSTFIX} VALUES ('AS', 'Asia', 6255147);
INSERT INTO continentCodes${LOAD_POSTFIX} VALUES ('EU', 'Europe', 6255148);
INSERT INTO continentCodes${LOAD_POSTFIX} VALUES ('NA', 'North America', 6255149);
INSERT INTO continentCodes${LOAD_POSTFIX} VALUES ('OC', 'Oceania', 6255150);
INSERT INTO continentCodes${LOAD_POSTFIX} VALUES ('SA', 'South America', 6255151);
INSERT INTO continentCodes${LOAD_POSTFIX} VALUES ('AN', 'Antarctica', 6255152);
CREATE INDEX geoname_id_idx${LOAD_POSTFIX} ON geoname${LOAD_POSTFIX}(geonameid);
CREATE INDEX geoname_admin1codes_code_idx${LOAD_POSTFIX} ON admin1codes${LOAD_POSTFIX}(code);
CREATE INDEX geoname_admin2codes_code_idx${LOAD_POSTFIX} ON admin2codes${LOAD_POSTFIX}(code);
CREATE INDEX geoname_countryinfo_isoalpha2_idx${LOAD_POSTFIX} ON countryinfo${LOAD_POSTFIX}(iso_alpha2);
CREATE INDEX geoname_alternatename_idx${LOAD_POSTFIX} ON alternatename${LOAD_POSTFIX}(alternatenameId);
ANALYZE geoname${LOAD_POSTFIX};
ANALYZE admin1codes${LOAD_POSTFIX};
ANALYZE admin2codes${LOAD_POSTFIX};
ANALYZE countryinfo${LOAD_POSTFIX};
ANALYZE alternatename${LOAD_POSTFIX};
COMMIT;
EOT

# If the live tables exist, back them up and drop the indexes
#TABLES_PRESENT=$(psql $PGUSER_PARAM $PGPASS $PGHOST $PGPORT $PGDBNAME -A -q -t -c "select count(*) from pg_tables where tablename='geoname'")
TABLES_PRESENT=$($PSQL_CMD -A -q -t -c "select count(*) from pg_tables where tablename='geoname'")
if [[ $TABLES_PRESENT == 1 ]]; then
    echo "Backing up current tables"
    $PSQL_CMD <<EOT
BEGIN;
DROP TABLE IF EXISTS geoname${BACKUP_POSTFIX};
DROP TABLE IF EXISTS alternatename${BACKUP_POSTFIX};
DROP TABLE IF EXISTS countryinfo${BACKUP_POSTFIX};
DROP TABLE IF EXISTS iso_languagecodes${BACKUP_POSTFIX};
DROP TABLE IF EXISTS admin1codes${BACKUP_POSTFIX};
DROP TABLE IF EXISTS admin2codes${BACKUP_POSTFIX};                                                                                                                                                                                                  
DROP TABLE IF EXISTS timeZones${BACKUP_POSTFIX};
DROP TABLE IF EXISTS continentCodes${BACKUP_POSTFIX};
DROP INDEX IF EXISTS geoname_id_idx;
DROP INDEX IF EXISTS geoname_admin1codes_code_idx;
DROP INDEX IF EXISTS geoname_admin2codes_code_idx;
DROP INDEX IF EXISTS geoname_countryinfo_isoalpha2_idx;
DROP INDEX IF EXISTS geoname_alternatename_idx;
ALTER TABLE geoname RENAME TO geoname${BACKUP_POSTFIX};
ALTER TABLE alternatename RENAME TO alternatename${BACKUP_POSTFIX};
ALTER TABLE countryinfo RENAME TO countryinfo${BACKUP_POSTFIX};
ALTER TABLE iso_languagecodes RENAME TO iso_languagecodes${BACKUP_POSTFIX};
ALTER TABLE admin1codes RENAME TO admin1codes${BACKUP_POSTFIX};
ALTER TABLE admin2codes RENAME TO admin2codes${BACKUP_POSTFIX};
ALTER TABLE timeZones RENAME TO timeZones${BACKUP_POSTFIX};
ALTER TABLE continentCodes RENAME TO continentCodes${BACKUP_POSTFIX};
COMMIT;
EOT
fi

# Put the load tables live and rebuild the indexes
$PSQL_CMD <<EOT
BEGIN;
ALTER TABLE geoname${LOAD_POSTFIX} RENAME TO geoname;
ALTER TABLE alternatename${LOAD_POSTFIX} RENAME TO alternatename;
ALTER TABLE countryinfo${LOAD_POSTFIX} RENAME TO countryinfo;
ALTER TABLE iso_languagecodes${LOAD_POSTFIX} RENAME TO iso_languagecodes;
ALTER TABLE admin1codes${LOAD_POSTFIX} RENAME TO admin1codes;
ALTER TABLE admin2codes${LOAD_POSTFIX} RENAME TO admin2codes;
ALTER TABLE timeZones${LOAD_POSTFIX} RENAME TO timeZones;
ALTER TABLE continentCodes${LOAD_POSTFIX} RENAME TO continentCodes;
ALTER INDEX geoname_id_idx${LOAD_POSTFIX} RENAME TO geoname_id_idx;
ALTER INDEX geoname_admin1codes_code_idx${LOAD_POSTFIX} RENAME TO geoname_admin1codes_code_idx;
ALTER INDEX geoname_admin2codes_code_idx${LOAD_POSTFIX} RENAME TO geoname_admin2codes_code_idx;
ALTER INDEX geoname_countryinfo_isoalpha2_idx${LOAD_POSTFIX} RENAME TO geoname_countryinfo_isoalpha2_idx;
ALTER INDEX geoname_alternatename_idx${LOAD_POSTFIX} RENAME TO geoname_alternatename_idx;
GRANT ALL PRIVILEGES ON geoname, admin1codes, countryInfo, alternatename TO "$PGUSER";
GRANT SELECT ON geoname, admin1codes, admin2codes, countryInfo, alternatename TO public;
COMMIT;
EOT