BuildPorts.py 53.4 KB
Newer Older
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
# -*- coding: utf-8 -*-
'''
Created on 06 june 2020
@author: cplumejeaud
ANR PORTIC : used to build tables for ports : port_points

This requires :

1. to have loaded data (geo_general, port_points_old) into ports manually 
CREATE TABLE ports.geo_general (
	pointcall_name text NULL,
	pointcall_uhgs_id text NULL,
	latitude text NULL,
	longitude text NULL,
	shippingarea text NULL
); -- ok

2. You must restore the file portic_v4.ports.GIS-202006061653.sql in flatdata/GIS to get extra information
* GIS data that are required to build portic gazetteer
- code_levels : list of admiralties with their head-quarters (siège amirauté) (by name)
- obliques : liste of oblique harbors
- matching_ports : computed using geonames version : 2019 November (see below in computeMatching )
- etats : comes from listings of Silvia Marzagalli + extra computing using geonames (see below : SQL code to translate in Python in updateStateGeonameid )
- world_borders : shp downloaded http://www.mappinghacks.com/data/ , last update 30 July 2008
All is packaged like postgres 11.6 tables, using postgis extension. 2.5

3. If you have new points and you want to add admiralty, province, belonging_states or shiparea information, you must open the GIS files and QGIS to set them manually
Many of data can be fetched from old versions of port_points
Manual updates of etats table are to be done also for new points
'''

# Comprendre les imports en Python : http://sametmax.com/les-imports-en-python/
# print sys.path
# sys.path.append(path.dirname(path.dirname(path.abspath(__file__))))
## pour avoir le path d'un package
## print (psycopg2.__file__)
## C:\Users\cplume01\AppData\Local\Programs\Python\Python37-32\lib\site-packages\psycopg2\__init__.py

from __future__ import nested_scopes

import logging
import configparser
import xlsxwriter
import os
import psycopg2
#from os import sys, path
import sys, traceback

import json


import random
from xlrd import open_workbook, cellname, XL_CELL_TEXT, XL_CELL_DATE, XL_CELL_BLANK, XL_CELL_EMPTY, XL_CELL_NUMBER, \
    xldate_as_tuple



class BuildPorts(object):

    def __init__(self, config):
        """
        Ouvre les fichiers de log et une connexion à la base de données (en fonction des paramètres de config)
        """
        ## Ouvrir le fichier de log
        logging.basicConfig(filename=config.get('log', 'file'), level=int(config.get('log', 'level')), filemode='w')
        self.logger = logging.getLogger('BuildPorts')
        self.logger.debug('log file for DEBUG')
        self.logger.info('log file for INFO')
        self.logger.warning('log file for WARNINGS')
        self.logger.error('log file for ERROR')

        #self = LoadFilemaker(config)

        ## Open both a ssh connexion for copy/remove, and a tunnel for postgres connexion
        self.postgresconn = self.open_connection(config)


    def close_connection(self):
        '''
        Cleanly close DB connection
        :param postgresconn:
        :return:
        '''
        if self.postgresconn is not None:
            self.postgresconn.close()

    def open_connection(self, config):
        '''
        Open database connection with Postgres
        :param config:
        :return:
        '''
        # Acceder aux parametres de configuration
        host = config.get('base', 'host')
        port = config.get('base', 'port')
        dbname = config.get('base', 'dbname')
        user = config.get('base', 'user')
        password = config.get('base', 'password')
        # schema = config.get('base', 'schema')
        driverPostgres = 'host=' + host + ' port=' + port + ' user=' + user + ' dbname=' + dbname + ' password=' + password
        self.logger.debug(driverPostgres)

        conn = None
        try:
            conn = psycopg2.connect(driverPostgres)
        except Exception as e:
            self.logger.error("I am unable to connect to the database. " + str(e))
        # Test DB
        if conn is not None:
            cur = conn.cursor()
            cur.execute('select count(*) from pg_namespace')
            result = cur.fetchone()
            if result is None:
                print('open_connection Failed to get count / use of database failed')
            else:
                print('open_connection Got database connexion : ' + str(result[0]))
        else:
            print('open_connection Failed to get database connexion')

        return conn

    def setExtensionsFunctions(self, config):
        """
        Installe les extensions nécessaires à l'import et l'utilisation des données de navigocorpus dans portic, 
        crée les 3 schémas navigo, navigocheck et navigoviz
        et crée les 4 fonctions spécifiques à navigo pour importer les données
        Ces fonctions programmées en PLPython 3 permettent de retirer les crochets et parenthèses des données de navigo 
        pour les conserver épurées dans navigocheck, avec également un code associé à la présence de ces signes
        - 0 : pas de signe
        - -1 : parenthèses autour ()
        - -2 : crochets autour []
        - -3 : donnée manquante
        testé le 14 mai 2020

        encore un bug sur la dernière function frequency_topo, qu'il faut installer à la main avec un fichier SQL 
        """
        #Prerequis : en tant que postgres, 
        #CREATE ROLE dba WITH SUPERUSER NOINHERIT;
        #GRANT dba TO navigo;

        self.execute_sql('SET ROLE dba')
        self.execute_sql("create extension if not exists postgis")
        self.execute_sql("create extension if not exists fuzzystrmatch")
        self.execute_sql("create extension if not exists pg_trgm")
        self.execute_sql("create extension if not exists postgis_topology")
        self.execute_sql("create extension if not exists plpython3u")
        self.execute_sql("create extension if not exists dblink")

        self.execute_sql("create schema if not exists ports")


        self.execute_sql("DROP FUNCTION if exists ports.test_double_type(tested_value VARCHAR)") 

        query = """CREATE OR REPLACE FUNCTION ports.test_double_type (tested_value VARCHAR) RETURNS boolean AS 
        $BODY$
            begin
                EXECUTE 'select '||quote_literal(tested_value)||'::float'; 	
                return true;

            exception when others then 
                raise notice '% %', SQLERRM, SQLSTATE;
                return false;
            end;
        $BODY$ LANGUAGE plpgsql VOLATILE;"""
        self.execute_sql(query)

        self.execute_sql("DROP FUNCTION if exists  ports.test_int_type(tested_value VARCHAR)") 

        query = """CREATE OR REPLACE FUNCTION ports.test_int_type (tested_value VARCHAR) RETURNS boolean AS 
        $BODY$
            begin
                EXECUTE 'select '||quote_literal(tested_value)||'::int'; 	
                return true;

            exception when others then 
                raise notice '% %', SQLERRM, SQLSTATE;
                return false;
            end;
        $BODY$ LANGUAGE plpgsql VOLATILE;"""
        self.execute_sql(query)

        self.execute_sql("drop type qual_value cascade")
        query = """CREATE TYPE qual_value AS (
            value   text,
            code  integer
            )"""
        self.execute_sql(query)

        self.execute_sql("DROP FUNCTION if exists ports.rm_parentheses_crochets(tested_value text)") 

        query = """CREATE OR REPLACE FUNCTION ports.rm_parentheses_crochets (tested_value text) RETURNS qual_value AS 
            $$
                global result
                global code
                if tested_value is not None : 
                    result = tested_value.strip()
                    code = 0
                    if (tested_value.strip().find('(') == 0):
                        result = result.replace('(', '').replace(')', '') 
                        code = -1
                    if (tested_value.strip().find('[') == 0) or tested_value.strip().find(']') > 0:
                        result = result.replace('[', '').replace(']', '') 
                        code = -2
                    if (result.strip().find('(') == 0):
                        result = result.replace('(', '').replace(')', '') 
                        if code > -1 : 
                            code = -1
                    if (result.strip().find('[') == 0):
                        result = result.replace('[', '').replace(']', '')
                        code = -2 
                    if(len(result.strip()) == 0):
                        code = -3
                        result = None
                else :
                    result = None
                    code = -3
                return [result, code]
            $$ LANGUAGE plpython3u;"""
        self.execute_sql(query)

        # BUG à cause des ''' :+item.replace('\'', '\'\''')+"'"
        query = """CREATE OR REPLACE FUNCTION ports.frequency_topo(uhgs_id text, toustopo text)
                RETURNS json
                LANGUAGE plpython3u
                AS $function$
                    import json
                    from operator import itemgetter
                    global temp
                    global result
                    global topos
                    global query
                    if toustopo is not None :
                        result = []
                        temp = toustopo.replace('{', '').replace('}', '').strip(' ')
                        temp = temp.replace('"', '').strip(' ')
                        topos = temp.split(',')
                        for item in topos:
                            #plpy.notice(item)
                            
                            query = "select count(*) as freq from ports.geo_general where pointcall_uhgs_id = '"+uhgs_id+"' and (ports.rm_parentheses_crochets(pointcall_name)).value='"+item.replace('\'', '\'\'')+"'"
                            #plpy.notice(query)
                            rv = plpy.execute(query)
                            #plpy.notice(rv[0]["freq"])
                            result.append(dict(topo=item, freq=rv[0]["freq"]))
                        result = sorted(result, key=itemgetter('freq'), reverse=True)

                    else :
                        result = None
                    #plpy.notice (result)
                    return json.dumps(result, ensure_ascii=False)
                $function$
        """
        self.execute_sql(query)

        self.execute_sql("ALTER FUNCTION ports.frequency_topo(text, text) OWNER TO dba")

        self.execute_sql('RESET ROLE')



    def updatePlace(self, config):
        '''
        alter table ports.port_points  add column place_state text;
        alter table ports.port_points  add column place_admiralty text;
        alter table ports.port_points  add column place_province text;

        update port_points pp set place_state = k.appartenances 
        from (
        select uhgs_id, json_build_object('relations', array_agg(arelation)) as appartenances
            from
            (select uhgs_id, etat, json_build_object('relationType', 'gvp:broaderPartitive', 'relationTo', 
            case when geonameid is not null then 'http://www.geonames.org/'||geonameid else 'http://vocab.getty.edu/tgn/'||tgnid end,
            'label', etat, 'when', json_build_object('timespans', array_agg(intervalle))) as arelation
            from (
                select  uhgs_id, etat, geonameid, tgnid, json_build_object('start', json_build_object('in',dfrom), 'end', json_build_object('in',dto)) ::text  as intervalle
                from ports.etats 
                where dfrom is not null and dto is not null
                union 
                (
                select  uhgs_id, etat, geonameid, tgnid, json_build_object('start', json_build_object('in',dfrom), 'end', json_build_object('in','*')) ::text as intervalle
                from ports.etats 
                where dfrom is not null and dto is null
                )
                union 
                (
                select  uhgs_id, etat, geonameid, tgnid, json_build_object('start', json_build_object('in','*'), 'end', json_build_object('in',dto))::text as intervalle
                from ports.etats 
                where dfrom is null and dto is not null 
                )
                union 
                (
                select  uhgs_id, etat, geonameid, tgnid, json_build_object('start', json_build_object('in','*'), 'end', json_build_object('in','*'))::text as intervalle
                from ports.etats 
                where dfrom is null and dto is  null 
                )
            ) as k 
            group by uhgs_id, etat, geonameid, tgnid
            ) as k
            group by uhgs_id
            order by uhgs_id
        ) as k
        where pp.uhgs_id = k.uhgs_id
        -- 641

        select distinct state_labels from port_points where place_state is null
        -- france, iceland, Greece
        /*
        * {France}
        {Iceland}
        {"Hellenic Republic"} 390903
        A0339882	Largentiere	Greece	{Greece}
        A0146289	Islande	Iceland	{Iceland} 2629691
        */

        update port_points pp set place_state = k.appartenances 
        from (
        select uhgs_id, json_build_object('relations', array_agg(arelation)) as appartenances
            from
            (select uhgs_id, etat, json_build_object('relationType', 'gvp:broaderPartitive', 'relationTo', 
            'http://www.geonames.org/'||geonameid ,
            'label', etat, 'when', json_build_object('timespans', array_agg(intervalle))) as arelation
            from (
                
                select  uhgs_id, 'France' as etat, 3017382 as geonameid, json_build_object('start', json_build_object('in','*'), 'end', json_build_object('in','*'))::text as intervalle
                from ports.port_points 
                where place_state is null and country2019_name = 'France'
                
                union 
                (
                select  'A0339882' as uhgs_id, 'Hellenic Republic' as etat, 390903 as geonameid, json_build_object('start', json_build_object('in','*'), 'end', json_build_object('in','*'))::text as intervalle
                )
                union 
                (
                select  'A0146289' as uhgs_id, 'Iceland' as etat, 2629691 as geonameid, json_build_object('start', json_build_object('in','*'), 'end', json_build_object('in','*'))::text as intervalle
                )
            ) as k 
            group by uhgs_id, etat, geonameid
            ) as k
            group by uhgs_id
            order by uhgs_id
        ) as k
        where pp.uhgs_id = k.uhgs_id

        -- 319
    '''


    def buildPortTable(self, config):
        """
        A partir de la table geo_general, 
        cette fonction fabrique une table port qui liste pour chaque pointcall_uhgs_id (identifiant du port)
        - le toponym le plus fréquent
        - les autres toponymes
        - l'appartenance aux nomenclatures (amirautés, provinces, fermes, pays actuels)
        - les coordonnées géographiques 
        de ce port. 
        
        Testée le 03 juin 2020
        """

        self.execute_sql("drop table if exists ports.port_points cascade");

        query = """create table if not exists ports.port_points as (
            select pointcall_uhgs_id as uhgs_id, latitude, longitude, null as amiraute, null as province, 
            array_agg(distinct (ports.rm_parentheses_crochets(pointcall_name)).value) as toustopos, (array_agg(distinct shippingarea))[1] as shiparea
            from ports.geo_general
            group by pointcall_uhgs_id, latitude, longitude
        )"""
        self.execute_sql(query)
        
        # table qui va servir pour cartographier les ports issus de geo_general (extraction limitée à 1787 le G5 et Marseille) ; une ligne par code UHGS_id, la clé primaire, et les informations attenantes avec
        self.execute_sql("comment on table ports.port_points is ' table used for mapping ports extracted from geo_general (only 1787 year, and G5 and Marseille sources) ; one line per UHGS_id code, the primary key, with associated data'")

        #Calcul du toponyme le plus fréquent
        self.execute_sql("alter table ports.port_points add column topofreq json")
        self.execute_sql("alter table ports.port_points add column toponyme text")
        query = """update ports.port_points set topofreq = ports.frequency_topo(uhgs_id, array_to_string(toustopos, ',')) where array_length(toustopos, 1) > 0 and ports.test_double_type(longitude) is true"""
        self.execute_sql(query)
        query = """update ports.port_points set toponyme = (topofreq::json->>0)::json->>'topo'"""
        self.execute_sql(query)

        #Récupérer les amirautés et province et shiparea déjà calcules
        query = """update ports.port_points p set amiraute = pp.amiraute , province = pp.province, shiparea=pp.shiparea 
                    from ports.port_points_old pp where pp.uhgs_id = p.uhgs_id """
        self.execute_sql(query)

        #ajouter un point (geometry)
        self.execute_sql("alter table ports.port_points add column  geom geometry")
        query = """
            update ports.port_points set geom = st_setsrid(st_makepoint(regexp_replace(longitude, ',', '.')::float, regexp_replace(latitude, ',', '.')::float), 4326)
        """
        self.execute_sql(query)
        self.execute_sql("alter table ports.port_points add column  point3857 geometry")
        query = """
            update ports.port_points set point3857 = st_setsrid(st_transform(geom, 3857) , 3857)
        """
        self.execute_sql(query)

        #Appartenance aux pays actuels

        self.execute_sql("alter table ports.world_borders add column mpolygone3857 geometry");
        query = """update ports.world_borders set mpolygone3857 = st_setsrid(st_transform(geom, 3857), 3857) 
        where region in (150, 2, 19, 142, 9, 0) and iso2 <>'AQ' """
        '''
        -- 150 : Europe
        -- 2 : Afrique
        -- 19 : Amériques
        -- 142 : Orient / Asie (de la turquie à l'inde)
        -- 9 : Océanie
        '''
        self.execute_sql(query)

        
        self.execute_sql("alter table ports.port_points add column country2019_name text")
        self.execute_sql("alter table ports.port_points add column country2019_iso2code text")
        self.execute_sql("alter table ports.port_points add column country2019_region text")

        
        query = """ update ports.port_points ports set country2019_name = k.name, country2019_iso2code=k.iso2, country2019_region=k.region
        from (
        select uhgs_id, toponyme, shiparea, iso2, name, region 
        from ports.port_points p , ports.world_borders w
        where st_contains(w.geom, p.geom)
        ) as k
        where ports.uhgs_id = k.uhgs_id """
        self.execute_sql(query)

        self.updateCountry(35000)
        self.updateCountry(50000)
        self.updateCountry(100000)
        self.updateCountry(150000)

        # Cas particulier de Lampeduse qui n'est pas dans le fichier world_borders
        query = """update ports.port_points set  country2019_name='Italy', country2019_iso2code ='IT', country2019_region ='150'
            where uhgs_id='A0249937'"""
        self.execute_sql(query)
        
        query = """select count(*) from ports.port_points where country2019_iso2code is null and point3857 is not null"""
        rows = self.select_sql(query);
        for rowk in rows:
            self.logger.error('Nombre de ports.port_points sans country: '+str(rowk[0]))
            print ('Nombre de ports.port_points sans country: ', str(rowk[0]))
        

        #Appartenance aux états historiques

        # Mise à jour des états avec geoname (TODO)

        # self.updateStateGeonameid(config)

        self.execute_sql("alter table ports.port_points add column state_labels text")
        self.execute_sql("alter table ports.port_points add column state_geonameids text")
        self.execute_sql("alter table ports.port_points add column state_labels_en text")

        """
        * 1. attribuer l'agrégat des etats, geonameids, name_ens à  state_labels, state_geonameids, state_labels_en
        * 2. attribuer  l'état de country2019_name à  state_labels, state_geonameids, state_labels_en si state_labels est vide
        * 3. attribuer la suite de relations d'appartenance et leurs date à  state
        """

        # 1. attribuer l'agrégat des etats, geonameids, name_ens à  state_labels, state_geonameids, state_labels_en
        query = """update ports.port_points p set state_labels=k.state_labels, state_geonameids=k.state_geonameids, state_labels_en=k.state_labels_en
        from (
            select p.uhgs_id, p.toponyme, p.country2019_name, array_agg( e.dfrom ||'-'|| e.dto) as aperiod, array_agg( distinct e.etat) as state_labels, array_agg(distinct e.geonameid) as  state_geonameids, array_agg(distinct e.name_en) as state_labels_en
            from ports.port_points p, ports.etats e
            where p.uhgs_id =e.uhgs_id 
            -- and e.etat = 'Etats pontificaux'
            group by p.uhgs_id, p.toponyme, p.country2019_name
            order by aperiod
        ) as k
        where p.uhgs_id = k.uhgs_id"""
        self.execute_sql(query)

        # 2. attribuer  l'état de country2019_name à  state_labels, state_geonameids, state_labels_en si state_labels est vide
        # Cas majoritaire de la France
        query = """update ports.port_points p set state_labels=k.state_labels, state_geonameids=k.state_geonameids, state_labels_en=k.state_labels_en
        from (
            select p.uhgs_id, p.toponyme, p.country2019_name, array_agg(country2019_name)  as state_labels,  array_agg(3017382) as state_geonameids, array_agg(country2019_name) as state_labels_en
            from ports.port_points p 
            where state_labels is  null and p.country2019_name = 'France'
            group by p.uhgs_id, p.toponyme, p.country2019_name
        ) as k
        where p.uhgs_id = k.uhgs_id"""
        self.execute_sql(query)

        #Iceland
        query = """ update ports.port_points p set state_labels=k.state_labels, state_geonameids=k.state_geonameids, state_labels_en=k.state_labels_en
        from (
            select p.uhgs_id, p.toponyme, p.country2019_name, array_agg(country2019_name)  as state_labels,  array_agg(2629691) as state_geonameids, array_agg(country2019_name) as state_labels_en
            from ports.port_points p 
            where state_labels is  null and p.country2019_name = 'Iceland'
            group by p.uhgs_id, p.toponyme, p.country2019_name
        ) as k
        where p.uhgs_id = k.uhgs_id and k.uhgs_id = 'A0146289'"""
        self.execute_sql(query)

        # Greece
        query = """ update ports.port_points p set state_labels=k.state_labels, state_geonameids=k.state_geonameids, state_labels_en=k.state_labels_en
        from (
            select p.uhgs_id, p.toponyme, p.country2019_name, array_agg('Hellenic Republic'::text)  as state_labels,  array_agg(390903::int) as state_geonameids, array_agg('Hellenic Republic'::text) as state_labels_en
            from ports.port_points p 
            where state_labels is  null and p.country2019_name = 'Greece'
            group by p.uhgs_id, p.toponyme, p.country2019_name
        ) as k
        where p.uhgs_id = k.uhgs_id and k.uhgs_id = 'A0339882' """
        self.execute_sql(query)

        # 3. attribuer la suite de relations d'appartenance et leurs date à  state
        self.execute_sql("alter table ports.port_points add column belonging_states text")

        query = """update ports.port_points pp set belonging_states = '['||k.appartenances ||']'
        from (
            select uhgs_id, STRING_AGG(belonging, ',') as appartenances
            from (
                select  uhgs_id, etat,  case when dfrom is null then 1749 else dfrom end as orderingdate, 
                json_build_object((case when dfrom is null then 1749 else dfrom end)||'-'||(case when dto is null then 1815 else dto end), etat) :: text as belonging
                from ports.etats 
                order by uhgs_id, orderingdate
            ) as k 
            group by uhgs_id
        ) as k
        where pp.uhgs_id = k.uhgs_id"""
        self.execute_sql(query)


        query = """update ports.port_points pp set belonging_states = '['||k.appartenances ||']'
            from (
                select  uhgs_id, json_build_object(1749 ||'-'||1815, 'France')::text as appartenances
                from ports.port_points 
                where belonging_states is null and country2019_name = 'France'
                union
                (select 'A0339882' as uhgs_id, json_build_object(1749 ||'-'||1815, 'Hellenic Republic')::text as appartenances)
                union 
                (select 'A0146289' as uhgs_id, json_build_object(1749 ||'-'||1815, 'Iceland')::text as appartenances)
            ) as k 
        where pp.uhgs_id = k.uhgs_id"""
        self.execute_sql(query)

        # Rajouter un identifiant entier unique pour l'export des features

        self.execute_sql("alter table ports.port_points add column ogc_fid serial")
        self.execute_sql("alter table ports.port_points add primary key (ogc_fid)")

        # Le port est oblique ou non
        self.execute_sql("alter table ports.port_points add column oblique boolean")

        self.execute_sql("CREATE INDEX if not Exists trgm_toponyme_idx ON ports.port_points USING GIST (toponyme gist_trgm_ops)")
        self.execute_sql(" update ports.port_points pp set oblique = true from ports.obliques o where pp.uhgs_id =o.uhgs_id");

        # Le status du port : siège d'amiraute / oblique / null
        self.execute_sql("alter table ports.port_points add column status text default null")
        self.execute_sql("update ports.port_points set status = 'oblique' where oblique is true")

        query = """update ports.port_points n set status = 'siège amirauté' from
        (SELECT o.amiraute, toponyme, pp.ogc_fid, similarity(toponyme, o.amiraute) AS sml
        FROM ports.port_points pp, ports.codes_levels o
        WHERE oblique is true  and o.amiraute % toponyme   
        and similarity(o.amiraute, toponyme) > 0.8
        order by o.amiraute_code 
        ) as q
        where q.ogc_fid = n.ogc_fid"""
        self.execute_sql(query)

        query = """update ports.port_points n set status = 'siège amirauté' where uhgs_id in 
        ('A0152606', 'A0196771', 'A0212320', 'A0135548', 'A0187101', 'A0173748', 'A0189004', 'A0138383', 'A0170986')"""
        self.execute_sql(query)

        self.execute_sql("alter table ports.port_points add column geonameid int default null")
        #Récupérer les geonameid déjà calculés
        query = """update ports.port_points p set geonameid = pp.geonameid  
                    from ports.port_points_old pp where pp.uhgs_id = p.uhgs_id """
        self.execute_sql(query)



    def useGeonames(self, config) : 
        self.execute_sql("drop  view IF EXISTS ports.myremote_geonamesplaces")
        query = """create materialized VIEW ports.myremote_geonamesplaces AS
            SELECT *
            FROM dblink('dbname=geonames user=postgres password=postgres options=-csearch_path=',
                        'select geonameid::int, name, (feature_class||''.''||feature_code) as feature_code, alternatenames, country_code,  latitude::float, longitude::float , point3857
                            from geonames.geonames_nov2019.allcountries a 
                            where feature_class||''.''||feature_code in (select code from geonames.geonames_nov2019.feature_code where keep = ''x'')')
            AS t1(geonameid int, name text, feature_code text, alternatenames text , country_code text, latitude float, longitude float, point3857 geometry)"""
        # --- 34 s, 5 012 322 lignes
        self.execute_sql(query)

        self.execute_sql("grant select on  ports.myremote_geonamesplaces to api_user")


        self.execute_sql("CREATE INDEX trgm_geoname_name_idx ON ports.myremote_geonamesplaces USING GIST (name gist_trgm_ops)");
        #-- 1 min 22s

        self.execute_sql("CREATE INDEX gist_geoname_point_idx ON ports.myremote_geonamesplaces USING GIST (point3857)");
        #-- 55 s


    def computeMatching(self, config) : 
        """
        Compute the geoname id of each geo_general point
        not tested yet
        """
        self.execute_sql("drop table IF EXISTS matching_port")
        query = """ create table if not exists ports.matching_port (
            source1 text,
            source2 text,
            id1 int, 
            id2 int, 
            uhgs_id text,
            topo1 text,
            topo2 text,
            simtext float,
            distgeo float,
            best boolean default false,
            certainity int default 1)"""
        self.execute_sql(query)


        query = """comment on table ports.matching_port is 'table de calcul des meilleurs appariements entre les ports de géogenéral - port_points, geonames, 
        et les ports saisis - saisie_13fev2020'"""
        self.execute_sql(query)

        query = """comment on column ports.matching_port.certainity is 'Certitude levels : 2 is less certain (multiple representation for instance) than 1'"""
        self.execute_sql(query)

        
        # Certitude levels : 2 is less certain (multiple representation for instance) than 1


        # Tous les lieux de geonames à moins de 5 km
        query = """insert into matching_port(source1, id1, uhgs_id, topo1, source2, id2, topo2, distgeo, simtext)
        select 'geo_general' as source1, pp.ogc_fid as id1, pp.uhgs_id, pp.toponyme,  'geonames' as source2, s.geonameid, s.toponyme , st_distance(s.point3857, pp.point3857 ), similarity(s.toponyme, pp.toponyme)
        from 
        (select ogc_fid, uhgs_id, unnest(toustopos) as toponyme, point3857 from ports.port_points where geonameid is null) as pp,
        (select geonameid, name as toponyme, point3857 from myremote_geonamesplaces ) as s
        where st_distance(s.point3857, pp.point3857 ) < 5000 
        """
        self.execute_sql(query)

        # 23023 lignes, 132 min ! 


        # 1) m.simtext = k.max and m.distgeo = k.min
        query = """update matching_port m set best = true 
        from (
            select distinct m.id1, m.id2, m.simtext, m.distgeo
            from matching_port m,
            (select id1, max(simtext), min(distgeo)  from matching_port where simtext > 0 and source1 = 'geo_general' and source2='geonames' group by id1 ) as k 
            where source1 = 'geo_general' and source2='geonames' and m.id1 = k.id1 and m.simtext = k.max and m.distgeo = k.min
        ) as k 
        where m.source1 = 'geo_general' and m.source2='geonames' and m.id1 = k.id1 and m.id2 = k.id2 and m.simtext = k.simtext and m.distgeo = k.distgeo"""
        self.execute_sql(query)

       
        query = """update ports.port_points p set geonameid = id2
        from matching_port where source1 = 'geo_general' and source2='geonames' and id1 = p.ogc_fid and  best is true and geonameid is null"""
        self.execute_sql(query)

        # 2) m.simtext = k.max 
        query = """update matching_port m set best = true 
        from (
            select distinct m.topo1, m.topo2, m.id1, m.id2, m.simtext, m.distgeo, m.best
            from ports.port_points p, matching_port m, 
            (select id1, max(simtext), min(distgeo)  from matching_port where simtext > 0 and source1 = 'geo_general' and source2='geonames' group by id1 ) as k 
            where source1 = 'geo_general' and source2='geonames' and m.id1 = k.id1 and m.simtext = k.max 
            and p.ogc_fid = m.id1 and p.geonameid is null
        )
        as k 
        where m.source1 = 'geo_general' and m.source2='geonames' and m.id1 = k.id1 and m.id2 = k.id2 and m.simtext = k.simtext and m.distgeo = k.distgeo"""	
        self.execute_sql(query)

        query = """update ports.port_points p set geonameid = id2
        from matching_port where source1 = 'geo_general' and source2='geonames' and id1 = p.ogc_fid and  best is true and geonameid is null"""
        self.execute_sql(query)
        # 867

        # 3) m.simtext = 0 and m.distgeo = k.min
        query = """update matching_port m set best = true, certainity = 3
        from (
            select distinct m.topo1, m.topo2, m.id1, m.id2, m.simtext, m.distgeo, m.best
            from ports.port_points p, matching_port m, 
            (select id1, max(simtext), min(distgeo)  from matching_port where  source1 = 'geo_general' and source2='geonames' group by id1 ) as k 
            where source1 = 'geo_general' and source2='geonames' and m.id1 = k.id1 and m.distgeo = k.min
            and p.ogc_fid = m.id1 and p.geonameid is null
        )
        as k 
        where m.source1 = 'geo_general' and m.source2='geonames' and m.id1 = k.id1 and m.id2 = k.id2 and m.simtext = k.simtext and m.distgeo = k.distgeo"""	
        self.execute_sql(query)
        # 71

        query = """update ports.port_points p set geonameid = id2
        from matching_port where source1 = 'geo_general' and source2='geonames' and id1 = p.ogc_fid and  best is true and geonameid is null"""
        self.execute_sql(query)

695
696
697
        self.execute_sql("grant select on ports.matching_port to api_user");


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

    def updateStateGeonameid(self, config) : 
        """
        ports.etats is based on the import of a Excel file (csv) with this structure, filled by Silvia Marzagalli
        | Code du port	| Etat d'appartenance	| Sous-état d'appartenance	| "à partir de Rien si < 1749"	| "jusqu'à Rien si > 1815"| 
        |uhgs_id	|   etat	|   subunit	|   dfrom	|   dto |
        the name of the historical state (etat) is given in French only for the moment. 

        Not finished. SQL need only to be integrated with python
        All required SQL is here, except for the build of the geoname database (all is explained on geoname site)
        A lot of manual operations. This lead to etats table. Work with UTF_8 encoding.

        Warning : Silvia may have provided latin1 encoding of state names, and this lead to non utf-8 caractères in state names. 
        Must be fixed when building the table "etats"

        """
        '''
        create extension dblink;
        alter extension dblink set schema public;


        drop view myremote_geonames
        create or replace VIEW myremote_geonames AS
        SELECT *
            FROM dblink('dbname=geonames user=postgres password=postgres options=-csearch_path=',
                        'select geonameid, name, feature_code, country_code, admin1_code, latitude, longitude from geonames.geonames_nov2019.allcountries a 
                        where feature_class =''A'' and feature_code like ''P%'' or feature_code = ''TERR'' or feature_code like ''Z'' ')
            AS t1(geonameid int, name text, feature_code text, country_code text, admin1_code text, latitude float, longitude float);
        
        select * from myremote_geonames
        -- 466 etats

        alter table ports.etats add column geonameid int;
        alter table ports.etats add column name_en text;
        alter table ports.etats add column admin1_code text;
        alter table ports.etats add column latitude float;
        alter table ports.etats add column longitude float;
        alter table ports.etats add column tgnid int;
        alter table ports.etats add column wikipedia text;
        alter table ports.etats add column admin2_code text;
        alter table ports.etats add column admin3_code text;



        update ports.etats set geonameid = 2635167  where etat = 'Grande-Bretagne';
        update ports.etats set geonameid = 2510769  where etat = 'Espagne';
        update ports.etats set geonameid = 6252001  where etat = 'USA';
        update ports.etats set geonameid = 2750405  where etat = 'Provinces-Unies';
        update ports.etats set geonameid = 2750405  where etat = 'Royaume d''Hollande';
        update ports.etats set geonameid = 798544  where etat = 'Pologne';
        update ports.etats set geonameid = 2215636  where etat = 'Régence de Tripoli';
        update ports.etats set geonameid = 2661886  where etat = 'Suède';
        update ports.etats set geonameid = 2264397  where etat = 'Portugal';
        update ports.etats set geonameid = 1814991  where etat = 'Chine';
        update ports.etats set geonameid = 298795  where etat = 'Empire ottoman';
        update ports.etats set geonameid = 3017382  where etat = 'Empire français';
        update ports.etats set geonameid = 3017382  where etat = 'France';
        update ports.etats set geonameid = 2542007  where etat = 'Empire du Maroc';
        update ports.etats set geonameid = 3175395  where etat = 'Royaume d''Italie';
        update ports.etats set geonameid = 2782113  where etat = 'Autriche';
        update ports.etats set geonameid = 2623032  where etat = 'Danemark';
        update ports.etats set geonameid = 2017370  where etat = 'Russie';
        update ports.etats set geonameid = 2993457  where etat = 'Monaco';
        update ports.etats set geonameid = 2562770  where etat = 'Malte';
        update ports.etats set geonameid = 2993457, tgnid=7005289  where etat = 'Hambourg';
        update ports.etats set geonameid = 2944387  where etat = 'Brême';
        update ports.etats set geonameid = 2872567  where etat = 'Duché de Mecklenbourg';
        update ports.etats set geonameid = 3165361  where etat = 'Toscane';

        update ports.etats set etat = 'Royaume d''Étrurie' where etat= 'Royaume d''Etrurie';
        update ports.etats set geonameid = 3165361, wikipedia='https://fr.wikipedia.org/wiki/%C3%89trurie'  where etat = 'Royaume d''Étrurie';


        update ports.etats set geonameid = 3164600 where etat = 'République de Venise';
        update ports.etats set etat = 'République ligurienne' where etat= 'Republique Ligure';
        update ports.etats set geonameid = 3174725  where etat = 'République ligurienne';

        update ports.etats set geonameid = 3176217, tgnid=7008546  where etat = 'République de Gênes';
        update ports.etats set geonameid = 7577034, tgnid = 7015500, wikipedia='https://fr.wikipedia.org/wiki/R%C3%A9publique_de_Raguse'  where etat = 'République de Raguse';
        update ports.etats set geonameid = 3164670, tgnid=7009981, wikipedia='https://fr.wikipedia.org/wiki/%C3%89tats_pontificaux'  where etat = 'Etats pontificaux';
        update ports.etats set geonameid = 2523228, wikipedia='https://fr.wikipedia.org/wiki/Royaume_de_Sardaigne_(1720-1861)'  where etat = 'Royaume de Piémont-Sardaigne';
        update ports.etats set geonameid = 3174976, wikipedia='https://fr.wikipedia.org/wiki/R%C3%A9publique_romaine_(1849)'  where etat = 'République romaine';
        update ports.etats set geonameid = 3174529, wikipedia='https://fr.wikipedia.org/wiki/R%C3%A9publique_de_Lucques'  where etat = 'République de Lucques';
        update ports.etats set geonameid = 6541646, wikipedia='https://fr.wikipedia.org/wiki/%C3%89trurie'  where etat = 'Principauté de Piombino';
        update ports.etats set geonameid = 3173767, wikipedia='https://fr.wikipedia.org/wiki/Duch%C3%A9_de_Massa_et_Carrare'  where etat = 'Duché de Massa et Carrare';
        update ports.etats set geonameid = 3249071, wikipedia='https://fr.wikipedia.org/wiki/L%C3%BCbeck'  where etat = 'Lubeck';
        update ports.etats set geonameid = 3221095, wikipedia='https://fr.wikipedia.org/wiki/Duch%C3%A9_d%27Oldenbourg'  where etat = 'Duché d''Oldenbourg';
        update ports.etats set geonameid = 6697805, wikipedia='https://fr.wikipedia.org/wiki/R%C3%A9publique_des_Sept-%C3%8Eles' where etat ='Sept Iles';

        update ports.etats set tgnid=7003012, wikipedia='https://fr.wikipedia.org/wiki/Royaume_de_Naples' where etat = 'Royaume de Naples';
        update ports.etats set tgnid = 7016646, wikipedia='https://fr.wikipedia.org/wiki/Duch%C3%A9_de_Courlande'  where etat = 'Duché de Courlande';
        update ports.etats set tgnid = 7016786  where etat = 'Prusse';


        select distinct etat  from etats where geonameid is null

        update etats e set name_en=g.name, admin1_code=g.admin1_code, latitude=g.latitude, longitude=g.longitude 
        from myremote_geonames g
        where g.geonameid = e.geonameid
        '''

    def updateRelationState(self, config) : 
        """
        to run AFTER updateStateGeonameid
        This is required to build a json-ld description of various belongings of the port to historical states : relation_state
        Result is used by the API of the gazetteer to export broader relations to state with dates of belongings to historical states (former administrative division)
        Work with UTF_8 encoding.

        Warning : Silvia may have provided latin1 encoding of state names, and this lead to non utf-8 caractères in state names. 
        Must be fixed when building the table "etats" 
        """
        
        # --- Used to generate linked place model
        query = """ alter table ports.port_points  add column relation_state text"""
        self.execute_sql(query)

        query = """ update ports.port_points set relation_state = null"""
        self.execute_sql(query)
        
        query = """update port_points pp set relation_state = k.appartenances
        from (
        select uhgs_id, json_agg(arelation) as appartenances
            from
            (select uhgs_id, etat, json_build_object('relationType', 'gvp:broaderPartitive', 'relationTo', 
            case when geonameid is not null then 'http://www.geonames.org/'||geonameid else 'http://vocab.getty.edu/tgn/'||tgnid end,
            'label', etat, 'when', json_build_object('timespans', json_agg(intervalle))) as arelation
            from (
                select  uhgs_id, etat, geonameid, tgnid, json_build_object('start', json_build_object('in',dfrom), 'end', json_build_object('in',dto))   as intervalle
                from ports.etats 
                where dfrom is not null and dto is not null
                union all
                (
                select  uhgs_id, etat, geonameid, tgnid, json_build_object('start', json_build_object('in',dfrom), 'end', json_build_object('in','*'))  as intervalle
                from ports.etats 
                where dfrom is not null and dto is null
                )
                union all
                (
                select  uhgs_id, etat, geonameid, tgnid, json_build_object('start', json_build_object('in','*'), 'end', json_build_object('in',dto)) as intervalle
                from ports.etats 
                where dfrom is null and dto is not null 
                )
                union all
                (
                select  uhgs_id, etat, geonameid, tgnid, json_build_object('start', json_build_object('in','*'), 'end', json_build_object('in','*')) as intervalle
                from ports.etats 
                where dfrom is null and dto is  null 
                )
            ) as k 
            group by uhgs_id, etat, geonameid, tgnid
            ) as k
            group by uhgs_id
            order by uhgs_id
        ) as k
        where pp.uhgs_id = k.uhgs_id
        """
        self.execute_sql(query)


        query = """update port_points pp set relation_state = k.appartenances ::text
        from (
        select uhgs_id,  json_agg(arelation) as appartenances
            from
            (select uhgs_id, etat, json_build_object('relationType', 'gvp:broaderPartitive', 'relationTo', 
            'http://www.geonames.org/'||geonameid ,
            'label', etat, 'when', json_build_object('timespans', json_agg (intervalle))) as arelation
            from (
                
                select  uhgs_id, 'France' as etat, 3017382 as geonameid, json_build_object('start', json_build_object('in','*'), 'end', json_build_object('in','*')) as intervalle
                from ports.port_points 
                where relation_state is null and country2019_name = 'France'
                
                union all
                (
                select  'A0339882' as uhgs_id, 'Hellenic Republic' as etat, 390903 as geonameid, json_build_object('start', json_build_object('in','*'), 'end', json_build_object('in','*')) as intervalle
                )
                union all
                (
                select  'A0146289' as uhgs_id, 'Iceland' as etat, 2629691 as geonameid, json_build_object('start', json_build_object('in','*'), 'end', json_build_object('in','*')) as intervalle
                )
            ) as k 
            group by uhgs_id, etat, geonameid
            ) as k
            group by uhgs_id
            order by uhgs_id
        ) as k
        where pp.uhgs_id = k.uhgs_id"""
        self.execute_sql(query)

        self.execute_sql("update port_points set relation_state = substring(relation_state from 2 for length(relation_state)-2)")

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

    def exportJSONfeatures(self, config) : 
        """
        Export port_points en JSON
        Testée ok : 6 juin 2020
        """
        query = """SELECT jsonb_build_object(
                'type',     'FeatureCollection',
                'features', jsonb_agg(feature)
            )
            FROM (
            SELECT jsonb_build_object(
                'type',       'Feature',
                'id',         ogc_fid,
                'geometry',   ST_AsGeoJSON(geom)::jsonb,
                'properties', to_jsonb(row) - 'ogc_fid' 
            ) AS feature
            FROM (
            SELECT ogc_fid, uhgs_id, total, toponyme as  toponym, belonging_states, status, geonameid, amiraute as admiralty, province, shiparea , geom
            FROM ports.port_points p, 
                    (select pointcall_uhgs_id, count( *) as total
                    from navigoviz.pointcall gg group by pointcall_uhgs_id) as k
                    where p.uhgs_id = k.pointcall_uhgs_id
            ) row) features;"""
        rows = self.select_sql(query);

        #json_str = json.dumps(dataframe.to_json(orient='records'))
        #return json.loads(json_str)

        filename = config['ports']['geojson_output']
        print(filename)
        
        output = open(filename, "w")
        for rowk in rows:
            self.logger.info('Export json: \n'+str(rowk[0]))
            output.write( json.dumps(rowk[0]))
        output.close()


    def updateCountry(self, radius) : 
        query = """update ports.port_points ports set country2019_name = k.name, country2019_iso2code=k.iso2, country2019_region=k.region
            from (
            select q.*
            from 	(
                    select uhgs_id, min (d) from
                    (
                    select uhgs_id, toponyme, shiparea, iso2, name, region, st_distance (p.point3857, w.mpolygone3857) as d
                    from ports.port_points p , ports.world_borders w
                    where st_intersects(w.mpolygone3857, st_buffer(p.point3857, %f)) and country2019_iso2code is null
                    order by uhgs_id
                    ) as k group by uhgs_id 
                ) as k,
                (
                select uhgs_id, toponyme, shiparea, iso2, name, region, st_distance (p.point3857, w.mpolygone3857) as d
                from ports.port_points p , ports.world_borders w
                where st_intersects(w.mpolygone3857, st_buffer(p.point3857,  %f)) and country2019_iso2code is null
                order by uhgs_id
                ) as q
            where q.d = k.min and q.uhgs_id = k.uhgs_id
            ) as k
            where  country2019_name is null and ports.uhgs_id = k.uhgs_id """ % (radius,radius)
        self.execute_sql(query)

    def importShapefile(self, config) : 
        """
        import a shp  
        https://pypi.org/project/GDAL/#usage
        """
        import os.path  
        import psycopg2
  
        self.execute_sql("drop table if exists ports.world_borders cascade")

        query = """CREATE TABLE ports.world_borders (
            id serial NOT NULL,
            geom geometry(MULTIPOLYGON, 4326) NULL,
            fips varchar(2) NULL,
            iso2 varchar(2) NULL,
            iso3 varchar(3) NULL,
            un int4 NULL,
            "name" varchar(50) NULL,
            area int4 NULL,
            pop2005 int8 NULL,
            region int4 NULL,
            subregion int4 NULL,
            lon float8 NULL,
            lat float8 NULL,
            mpolygone3857 geometry NULL,
            CONSTRAINT world_borders_pkey PRIMARY KEY (id)
        ); """
        self.execute_sql(query)
        self.execute_sql("CREATE INDEX sidx_world_borders_geom ON ports.world_borders USING gist (geom);");
 
        
        filename = config['ports']['word_borders']
        print(filename)  

        '''
        import osgeo.ogr  

        shapefile = osgeo.ogr.Open(filename)    
        layer = shapefile.GetLayer(0)    
        for i in range(layer.GetFeatureCount()):  
            feature = layer.GetFeature(i)  
            name = feature.GetField("NAME").decode("Latin-1")
            iso2 = feature.GetField("iso2").decode("Latin-1")
            region = feature.GetField("region")   
            wkt = feature.GetGeometryRef().ExportToWkt()  
            self.execute_sql("INSERT INTO ports.world_borders (name,iso2,region,outline) " +"VALUES (%s, %s, %f, ST_GeometryFromText(%s, " +"4326))", 
                (name.encode("utf8"), iso2.encode("utf8"), region, wkt))  
        '''