Commit daff6abf authored by Christine Plumejeaud's avatar Christine Plumejeaud
Browse files

API for vizsources :

when a port is totally missing, or has CR filled only for one source, but has no data input_done (thus no pointcalls), a line will be returned describing its position and nomenclature anyway, but filled with null for missing attributes.
Corresponding SQL documentation si version 3
Changed also wsgi script to match the new structure of porticapi folder.
Tested on prod. OK.
parent 1602d25e
...@@ -777,13 +777,18 @@ def getTupleNomChamp(champ): ...@@ -777,13 +777,18 @@ def getTupleNomChamp(champ):
Internal method Internal method
called by getDictChampsSelect(fields_for_select) : called by getDictChampsSelect(fields_for_select) :
returns a tuple (nom='name of SQL field', champ='code of field in select SQL clause') returns a tuple (nom='name of SQL field', champ='code of field in select SQL clause')
Examples
ST_AsGeoJSON(ST_Transform(geom,4326)) as point RENVOIE (point, ST_AsGeoJSON(ST_Transform(geom,4326)) as point)
toponyme_standard_fr as toponym RENVOIE (toponym, toponyme_standard_fr)
""" """
#print("getTupleNomChamp champ : " + champ)
separateur=" as " separateur=" as "
if separateur in champ : if separateur in champ :
parties_champ=champ.split(separateur) parties_champ=champ.split(separateur)
nom=parties_champ[1].strip() nom=parties_champ[1].strip()
else : else :
nom=champ.strip() nom=champ.strip()
#print("nom : " + nom)
return (nom, champ.strip()) return (nom, champ.strip())
def getDictChampsSelect(fields_for_select): def getDictChampsSelect(fields_for_select):
...@@ -795,6 +800,8 @@ def getDictChampsSelect(fields_for_select): ...@@ -795,6 +800,8 @@ def getDictChampsSelect(fields_for_select):
""" """
list_champs=fields_for_select.split(", ") list_champs=fields_for_select.split(", ")
dict_champs=dict([getTupleNomChamp(champ) for champ in list_champs]) # dictionnaire {"nom du champ": "code du champ"} dict_champs=dict([getTupleNomChamp(champ) for champ in list_champs]) # dictionnaire {"nom du champ": "code du champ"}
# Example : (toponym : toponyme_standard_fr),
# (point : ST_AsGeoJSON(ST_Transform(geom,4326)) as point)
return dict_champs return dict_champs
def handleParams(champs): def handleParams(champs):
...@@ -856,27 +863,32 @@ def keepDfCastsFoundInSelect(dict_cast_colonnes_df, champs_select): ...@@ -856,27 +863,32 @@ def keepDfCastsFoundInSelect(dict_cast_colonnes_df, champs_select):
@app.route('/api/sources/') @app.route('/api/sources/')
def getSources(): def getSources():
""" """
Get statistics about the amount of pointcall data found in sources (couverture des sources de navigo), related to ports of France only. Only observed ("O") pointcalls are taken in account. Get statistics about the amount of pointcall data found in sources (couverture des sources de navigo), related to ports of France only. Only observed ("O") pointcalls are taken into account.
Port data is grouped by : source, port, and year. This means that for a given source (source_suite = G5 | Marseille | ...), the API lists the ports (identified by a : toponym, ogc_fid or uhgs_id), and for each port, there is data for each year (pointcall_year = 1787 | 1789 | ...). So there may be more than one record for each port ! You can filter or sum port data received, by source, and / or by year, to build your own map for instance. Port data is a dataframe grouped by : source, port, and year.
This means that for a given source (source_suite = G5 | Santé Marseille | Registre du petit cabotage (1786-1787) | ...),
the API lists the ports (identified by a : toponym, ogc_fid or uhgs_id), and for each port,
there is data for each year (pointcall_year = 1787 | 1789 | ...) except if port is missing in all sources.
So there may be more than one record for each port ! You can filter or sum port data received, by source, and / or by year, to build your own map for instance.
Fields available : Fields available :
- source_suite : the source (G5 | Marseille | ...) where the data comes from - source_suite : the source (G5 | Santé Marseille | Registre du petit cabotage (1786-1787) | Expéditions "coloniales" Marseille (1789) ) where the data comes from
- pointcall_year : the year ( 1787 | 1789 ) for which data is computed. A data line is returned for each year (if data is available) - pointcall_year : the year ( 1787 | 1789 ) for which data is computed. A data line is returned for each year (if data is available)
Fields counting congés data from sources : Fields counting congés data from sources :
- nb_conges_inputdone : total number of observed ("O") pointcalls (congés) actually recorded in database for this port in this source, outgoing ships, computed for a given year - nb_conges_inputdone : total number of observed ("O") pointcalls (congés) actually recorded in database for this port in this source, outgoing ships, computed for a given year or null if none
- nb_conges_cr : number of congés that are known to exist, according to national records (archives), and that are expected. For a given year - nb_conges_cr : number of congés that are known to exist, according to national records (archives), and that are expected. For a given year or null if none
- nb_conges_sante : number of congés recorded in database, from register of the office of health of Marseille, incoming ships only. For a given year - nb_conges_sante : number of congés recorded in database, from register of the office of health of Marseille, incoming ships only. For a given year or null if none
- nb_petitcabotage : number of congés recorded in database, from register "Petit cabotage" of Marseille (mainly ships coming from Mediterranean areas), incoming ships only. For a given year - nb_petitcabotage : number of congés recorded in database, from register "Petit cabotage" of Marseille (mainly ships coming from Mediterranean areas), incoming ships only. For a given year or null if none
Other computed fields : Other computed fields :
- nb_tonnage_filled : number of pointcalls where tonnage data (volume de marchandise en tonneaux ou quintaux) is given - nb_tonnage_filled : number of pointcalls where tonnage data (volume de marchandise en tonneaux ou quintaux) is given or null if none
- nb_homeport_filled : number of pointcalls where homeport (port d'attache du navire) is known - nb_homeport_filled : number of pointcalls where homeport (port d'attache du navire) is known or null if none
- nb_product_filled : number of pointcalls where commodity_purpose (nature de la marchandise transportée, ou objet du voyage) is given - nb_product_filled : number of pointcalls where commodity_purpose (nature de la marchandise transportée, ou objet du voyage) is given or null if none
- nb_birthplace_filled : number of pointcalls where birthplace (lieu d'origine du capitaine du bateau) is known - nb_birthplace_filled : number of pointcalls where birthplace (lieu d'origine du capitaine du bateau) is known or null if none
- nb_citizenship_filled : number of pointcalls where citizenship (nationalité du capitaine du bateau) is known - nb_citizenship_filled : number of pointcalls where citizenship (nationalité du capitaine du bateau) is known or null if none
- good_sum_tonnage : sum of the tonnage that goes by this port (converted to barrel unit if given in quintals) - nb_flag_filled : number of pointcalls where flag (pavillon du navire, i.e. nationalité/étendard du navire) is known or null if none
- good_sum_tonnage : sum of the tonnage that goes by this port (converted to barrel unit if given in quintals) or null if none
A join is made between pointcall and port data, to get nearly the same information about a port as with the ports api (see /api/fieldnames?api=ports) : A join is made between pointcall and port data, to get nearly the same information about a port as with the ports api (see /api/fieldnames?api=ports) :
- ogc_fid : id - ogc_fid : id
...@@ -884,11 +896,12 @@ A join is made between pointcall and port data, to get nearly the same informati ...@@ -884,11 +896,12 @@ A join is made between pointcall and port data, to get nearly the same informati
- toponym : standardised name of the port, in the 'lang' language - toponym : standardised name of the port, in the 'lang' language
- substate : belonging substate of the port in 1787 / 1789. In the 'lang' language - substate : belonging substate of the port in 1787 / 1789. In the 'lang' language
- status : null | "oblique" | "siège amirauté", type of port - status : null | "oblique" | "siège amirauté", type of port
- has_a_clerk : true if there was a clerk (cases of "oblique" ou "siège amirauté")
- geonameid : nearest geoname identifier for the port - geonameid : nearest geoname identifier for the port
- admiralty : name of the home admiralty (amirauté) for the port, in 1787 - admiralty : name of the home admiralty (amirauté) for the port, in 1787
- province : name of the home province for the port, in 1787 - province : name of the home province for the port, in 1787
- shiparea : name of the maritime area for the port in 2020 - shiparea : name of the maritime area for the port in 2020
- point : coordinates for representation on a map - point : projeted coordinates for representation on a map
Will be extracted from postgres, schema navigoviz, table pointcall (see navigocorpus/ETL), completed with schema ports, table port_points. Will be extracted from postgres, schema navigoviz, table pointcall (see navigocorpus/ETL), completed with schema ports, table port_points.
...@@ -907,7 +920,9 @@ Examples : ...@@ -907,7 +920,9 @@ Examples :
- http://localhost/api/sources/?srid=4326&date=1789 - http://localhost/api/sources/?srid=4326&date=1789
- http://localhost/api/sources/?srid=4326&date=1789&lang=en - http://localhost/api/sources/?srid=4326&date=1789&lang=en
- http://localhost/api/sources/?srid=4326&params=uhgs_id,toponym,pointcall_year,nb_conges_inputdone,nb_conges_cr,point - http://localhost/api/sources/?srid=4326&params=uhgs_id,toponym,pointcall_year,nb_conges_inputdone,nb_conges_cr,point
- http://localhost/api/sources/?srid=4326&params=uhgs_id,toponym,pointcall_year,nb_conges_inputdone,nb_conges_cr,point&order=toponym,pointcall_year,source_suite - http://localhost/api/sources/?srid=4326&params=uhgs_id,toponym,pointcall_year,nb_conges_inputdone,nb_conges_cr,point,source_suite&format=csv
- http://localhost/api/sources/?srid=4326&params=uhgs_id,toponym,pointcall_year,nb_conges_inputdone,nb_conges_cr,point,source_suite&order=toponym,pointcall_year,source_suite&format=csv
- http://localhost/api/sources/?srid=4326&params=uhgs_id,toponym,pointcall_year,nb_conges_inputdone,nb_conges_cr,nb_conges_sante,nb_petitcabotage,source_suite,point&order=toponym,pointcall_year,source_suite&format=csv
""" """
# select the srid given by user for geometry transformation # select the srid given by user for geometry transformation
srid = request.args.get("srid") srid = request.args.get("srid")
...@@ -925,17 +940,32 @@ Examples : ...@@ -925,17 +940,32 @@ Examples :
# liste de tous les champs qui peuvent être renvoyés, formatés pour la clause 'select' : # liste de tous les champs qui peuvent être renvoyés, formatés pour la clause 'select' :
# WARNING : ", " is the separator : each line (except last one) must end with ", " (the space is important). There must be ", " between two field names (not just ",") AND no ", " inside a field ! # WARNING : ", " is the separator : each line (except last one) must end with ", " (the space is important). There must be ", " between two field names (not just ",") AND no ", " inside a field !
fields_for_select=f""" fields_for_select=f"""
ogc_fid, uhgs_id, {localizedDatabaseFieldNames} status, geonameid, amiraute as admiralty, province, shiparea , ST_AsGeoJSON(ST_Transform(geom,{srid})) as point, ogc_fid, uhgs_id, {localizedDatabaseFieldNames} status, has_a_clerk, geonameid, amiraute as admiralty, province, shiparea , ST_AsGeoJSON(ST_Transform(geom,{srid})) as point,
source_suite, pointcall_year, source_suite, pointcall_year,
(case when pointcall_year = '1787' then nb_conges_1787_inputdone else nb_conges_1789_inputdone end) as nb_conges_inputdone, (case when pointcall_year = '1787' then nb_conges_1787_inputdone else nb_conges_1789_inputdone end) as nb_conges_inputdone,
(case when pointcall_year = '1787' then nb_conges_1787_cr else nb_conges_1789_cr end) as nb_conges_cr, (case when pointcall_year = '1787' then nb_conges_1787_cr else nb_conges_1789_cr end) as nb_conges_cr,
(case when pointcall_year = '1787' then nb_sante_1787 else nb_sante_1789 end) as nb_conges_sante, (case when pointcall_year = '1787' then nb_sante_1787 else nb_sante_1789 end) as nb_conges_sante,
(case when pointcall_year = '1787' then nb_petitcabotage_1787 else nb_petitcabotage_1789 end) as nb_petitcabotage, (case when pointcall_year = '1787' then nb_petitcabotage_1787 else nb_petitcabotage_1789 end) as nb_petitcabotage,
nb_tonnage_filled, nb_homeport_filled, nb_product_filled, nb_birthplace_filled, nb_citizenship_filled, good_sum_tonnage nb_tonnage_filled, nb_homeport_filled, nb_product_filled, nb_birthplace_filled, nb_citizenship_filled, nb_flag_filled, good_sum_tonnage
""" """
fields_for_select=handleParams(fields_for_select) # ne garde que les champs demandés dans 'params' fields_for_select=handleParams(fields_for_select) # ne garde que les champs demandés dans 'params'
print(fields_for_select) print(fields_for_select)
union_G5_1787_CRonly=f"""
ogc_fid, uhgs_id, {localizedDatabaseFieldNames} status, has_a_clerk, geonameid, amiraute as admiralty, province, shiparea , ST_AsGeoJSON(ST_Transform(geom,900913)) as point, 'G5' as source_suite, 1787 as pointcall_year, nb_conges_1787_inputdone as nb_conges_inputdone, nb_conges_1787_cr as nb_conges_cr, nb_sante_1787 as nb_conges_sante, nb_petitcabotage_1787 as nb_petitcabotage, null as nb_tonnage_filled, null as nb_homeport_filled, null as nb_product_filled, null as nb_birthplace_filled, null as nb_citizenship_filled, null as nb_flag_filled, null as good_sum_tonnage
"""
union_G5_1787_CRonly=handleParams(union_G5_1787_CRonly) # ne garde que les champs demandés dans 'params'
union_missing = union_G5_1787_CRonly.replace('\'G5\'', 'null' )
union_missing = union_missing.replace(' 1787 ', ' null ' )#L'espace est important ?
#print('########### union_missing ###############'+union_missing)
union_G5_1789_CRonly=f"""
ogc_fid, uhgs_id, {localizedDatabaseFieldNames} status, has_a_clerk, geonameid, amiraute as admiralty, province, shiparea , ST_AsGeoJSON(ST_Transform(geom,900913)) as point, 'G5' as source_suite, 1789 as pointcall_year, nb_conges_1789_inputdone as nb_conges_inputdone, nb_conges_1789_cr as nb_conges_cr, nb_sante_1789 as nb_conges_sante, nb_petitcabotage_1789 as nb_petitcabotage, null as nb_tonnage_filled, null as nb_homeport_filled, null as nb_product_filled, null as nb_birthplace_filled, null as nb_citizenship_filled, null as nb_flag_filled, null as good_sum_tonnage
"""
union_G5_1789_CRonly=handleParams(union_G5_1789_CRonly) # ne garde que les champs demandés dans 'params'
# clause order by (qui peut être vide) : ne retenir que les champs demandés dans le paramètre 'order', qui figurent dans le select # clause order by (qui peut être vide) : ne retenir que les champs demandés dans le paramètre 'order', qui figurent dans le select
clause_order_by=handleOrder(fields_for_select) clause_order_by=handleOrder(fields_for_select)
...@@ -950,22 +980,35 @@ Examples : ...@@ -950,22 +980,35 @@ Examples :
count(commodity_purpose) as nb_product_filled, count(commodity_purpose) as nb_product_filled,
count(birthplace) as nb_birthplace_filled, count(birthplace) as nb_birthplace_filled,
count(citizenship) as nb_citizenship_filled, count(citizenship) as nb_citizenship_filled,
count(flag) as nb_flag_filled,
sum(tonnage_numeric) as good_sum_tonnage sum(tonnage_numeric) as good_sum_tonnage
from ( from (
select pointcall_uhgs_id, source_suite, select pointcall_uhgs_id, source_suite,
(coalesce(extract(year from TO_DATE(substring(pointcall_out_date2 for 4),'YYYY')), extract(year from TO_DATE(substring(pointcall_in_date2 for 4),'YYYY'))))::int4 as pointcall_year, (coalesce(extract(year from TO_DATE(substring(pointcall_out_date2 for 4),'YYYY')), extract(year from TO_DATE(substring(pointcall_in_date2 for 4),'YYYY'))))::int4 as pointcall_year,
nb_conges_1787_inputdone, nb_conges_1787_cr, nb_conges_1789_inputdone, nb_conges_1789_cr, nb_conges_1787_inputdone, nb_conges_1787_cr, nb_conges_1789_inputdone, nb_conges_1789_cr,
tonnage, homeport, commodity_purpose, birthplace, citizenship, tonnage, homeport, commodity_purpose, birthplace, citizenship, flag,
(case when tonnage_unit = 'quintaux' then (tonnage::float)/24 else tonnage::float end) as tonnage_numeric (case when tonnage_unit = 'quintaux' then (tonnage::float)/24 else tonnage::float end) as tonnage_numeric
from navigoviz.pointcall p from navigoviz.pointcall p
{filterDate} and state_1789_fr = 'France' and pointcall_function = 'O' {filterDate} and state_1789_fr = 'France' and pointcall_function = 'O'
) as k ) as k
group by pointcall_uhgs_id , source_suite, pointcall_year group by pointcall_uhgs_id , source_suite, pointcall_year
) as toto ) as toto
where toto.pointcall_uhgs_id = pp.uhgs_id where toto.pointcall_uhgs_id = pp.uhgs_id and pp.state_1789_fr = 'France'
union (
select {union_G5_1787_CRonly} from ports.port_points pp
where state_1789_fr = 'France' and nb_conges_1787_cr is not null and nb_conges_1787_inputdone is null
) union (
select {union_G5_1789_CRonly} from ports.port_points pp
where state_1789_fr = 'France' and nb_conges_1789_cr is not null and nb_conges_1789_inputdone is null
) union (
select {union_missing} from ports.port_points pp
where state_1789_fr = 'France' and nb_conges_1787_cr is null and nb_conges_1787_inputdone is null and nb_conges_1789_cr is null and nb_conges_1789_inputdone is null and geom is not null
)
{clause_order_by} {clause_order_by}
""" """
# print(query) #print(query)
# Pandas casts some integers to float when executing SQL request, so to correct this, we ask to cast some columns : # Pandas casts some integers to float when executing SQL request, so to correct this, we ask to cast some columns :
# ( dtype String Aliases : https://pandas.pydata.org/docs/user_guide/basics.html#basics-dtypes ) # ( dtype String Aliases : https://pandas.pydata.org/docs/user_guide/basics.html#basics-dtypes )
...@@ -974,6 +1017,7 @@ Examples : ...@@ -974,6 +1017,7 @@ Examples :
'nb_conges_cr' : 'Int64', 'nb_conges_cr' : 'Int64',
'nb_conges_sante' : 'Int64', 'nb_conges_sante' : 'Int64',
'nb_petitcabotage' : 'Int64', 'nb_petitcabotage' : 'Int64',
'pointcall_year' : 'Int64',
} }
# keep only fields present in the 'select' clause : # keep only fields present in the 'select' clause :
cast_df_columns_to_types=keepDfCastsFoundInSelect(cast_df_columns_to_types, fields_for_select) cast_df_columns_to_types=keepDfCastsFoundInSelect(cast_df_columns_to_types, fields_for_select)
...@@ -983,6 +1027,26 @@ Examples : ...@@ -983,6 +1027,26 @@ Examples :
@app.route('/api/test/') @app.route('/api/test/')
def getTest(): def getTest():
"""
http://data.portic.fr/api/test/ renvoie {"pandas version":"1.3.4","python version ":"3.7.10"}
You can have a look on messages printed in apache2 logs also : sudo tail -f /var/log/apache2/error.log
On Christine machine (outside of WSGI/apache2) - janvier 2022 : http://localhost/api/test/
{ "pandas version": "1.3.4", "python version": "3.7.6"}
Avec apache2, il faut recompiler WSGI avec la version de python 3.7 et dans cette version de python 3.7 il faut installer les packages requis)
voir : https://github.com/GrahamDumpleton/mod_wsgi/releases
wget https://github.com/GrahamDumpleton/mod_wsgi/archive/4.7.1.tar.gz
tar xvfz 4.7.1
cd mod_wsgi-4.7.1
./configure --with-python=/usr/bin/python3.7
make
sudo make install
Installer les package python pour apache2 dans python3.7
- /usr/bin/python3.7 –version
- sudo –H /usr/bin/python3.7 -m pip install -r path2/porticapi/requirements.txt
"""
print("/api/test/") print("/api/test/")
import pandas as pd2 import pandas as pd2
...@@ -992,7 +1056,7 @@ def getTest(): ...@@ -992,7 +1056,7 @@ def getTest():
current_version = str(sys.version_info[0])+"."+str(sys.version_info[1])+"."+str(sys.version_info[2]) current_version = str(sys.version_info[0])+"."+str(sys.version_info[1])+"."+str(sys.version_info[2])
print("PYTHON version :"+current_version) print("PYTHON version :"+current_version)
return json.loads('{"pandas version" : "'+pd2.__version__+'", "python version (of WSGI !)" : "'+current_version+'"}') return json.loads('{"pandas version" : "'+pd2.__version__+'", "python version " : "'+current_version+'"}')
......
...@@ -3,5 +3,5 @@ ...@@ -3,5 +3,5 @@
import sys import sys
import os, os.path import os, os.path
sys.path.append(os.path.abspath(os.path.join(os.path.dirname(__file__), '.'))) sys.path.append(os.path.abspath(os.path.join(os.path.dirname(__file__), '..')))
from porticapi import app as application from porticapi import app as application
...@@ -215,7 +215,6 @@ order by toponym, pointcall_year, source_suite ...@@ -215,7 +215,6 @@ order by toponym, pointcall_year, source_suite
-- version 2 -- version 2
-- version avec flag et avec source_suite à null si le port n'a pas de données. -- version avec flag et avec source_suite à null si le port n'a pas de données.
-- celle retenue pour l'API le 10 janvier 2022 (implication : si nbxxx = null then nbxxx = 0 chez bernard)
select select
ogc_fid, uhgs_id, toponyme_standard_fr as toponym, substate_1789_fr as substate, status, geonameid, amiraute as admiralty, province, shiparea , ST_AsGeoJSON(ST_Transform(geom,900913)) as point, ogc_fid, uhgs_id, toponyme_standard_fr as toponym, substate_1789_fr as substate, status, geonameid, amiraute as admiralty, province, shiparea , ST_AsGeoJSON(ST_Transform(geom,900913)) as point,
...@@ -297,3 +296,86 @@ where state_1789_fr = 'France' and nb_conges_1789_cr is null and nb_conges_1789_ ...@@ -297,3 +296,86 @@ where state_1789_fr = 'France' and nb_conges_1789_cr is null and nb_conges_1789_
order by toponym, pointcall_year, source_suite order by toponym, pointcall_year, source_suite
-- version 3
-- version avec flag, has_a_clerk et avec source_suite et year à null si le port n'a pas de données.
-- celle retenue pour l'API le 10 janvier 2022 (implication : si nbxxx = null then nbxxx = 0 côté client, dans le code de visualisation vizsources)
select
ogc_fid, uhgs_id, toponyme_standard_fr as toponym, substate_1789_fr as substate, status, has_a_clerk, geonameid, amiraute as admiralty, province, shiparea , ST_AsGeoJSON(ST_Transform(geom,900913)) as point,
source_suite, pointcall_year,
(case when pointcall_year = '1787' then nb_conges_1787_inputdone else nb_conges_1789_inputdone end) as nb_conges_inputdone,
(case when pointcall_year = '1787' then nb_conges_1787_cr else nb_conges_1789_cr end) as nb_conges_cr,
(case when pointcall_year = '1787' then nb_sante_1787 else nb_sante_1789 end) as nb_conges_sante,
(case when pointcall_year = '1787' then nb_petitcabotage_1787 else nb_petitcabotage_1789 end) as nb_petitcabotage,
nb_tonnage_filled, nb_homeport_filled, nb_product_filled, nb_birthplace_filled, nb_citizenship_filled, nb_flag_filled, good_sum_tonnage
from ports.port_points pp, -- left outer join
(
select
pointcall_uhgs_id, source_suite, pointcall_year,
count(tonnage) as nb_tonnage_filled,
count(homeport) as nb_homeport_filled,
count(commodity_purpose) as nb_product_filled,
count(birthplace) as nb_birthplace_filled,
count(citizenship) as nb_citizenship_filled,
count(flag) as nb_flag_filled,
sum(tonnage_numeric) as good_sum_tonnage
from (
select pointcall_uhgs_id, source_suite,
(coalesce(extract(year from TO_DATE(substring(pointcall_out_date2 for 4),'YYYY')), extract(year from TO_DATE(substring(pointcall_in_date2 for 4),'YYYY'))))::int4 as pointcall_year,
nb_conges_1787_inputdone, nb_conges_1787_cr, nb_conges_1789_inputdone, nb_conges_1789_cr,
tonnage, homeport, commodity_purpose, birthplace, citizenship, flag,
(case when tonnage_unit = 'quintaux' then (tonnage::float)/24 else tonnage::float end) as tonnage_numeric
from navigoviz.pointcall p
where state_1789_fr = 'France' and pointcall_function = 'O'
) as k
group by pointcall_uhgs_id, source_suite, pointcall_year
) as toto
where toto.pointcall_uhgs_id = pp.uhgs_id and pp.state_1789_fr = 'France'
union
(select
ogc_fid, uhgs_id, toponyme_standard_fr as toponym, substate_1789_fr as substate, status, has_a_clerk, geonameid, amiraute as admiralty, province, shiparea , ST_AsGeoJSON(ST_Transform(geom,900913)) as point,
'G5' as source_suite, 1787 as pointcall_year,
nb_conges_1787_inputdone as nb_conges_inputdone,
nb_conges_1787_cr as nb_conges_cr,
nb_sante_1787 as nb_conges_sante,
nb_petitcabotage_1787 as nb_petitcabotage,
null as nb_tonnage_filled, null as nb_homeport_filled, null as nb_product_filled, null as nb_birthplace_filled, null as nb_citizenship_filled, null as nb_flag_filled, null as good_sum_tonnage
from ports.port_points pp
where state_1789_fr = 'France' and nb_conges_1787_cr is not null and nb_conges_1787_inputdone is null)
/*union
(select
ogc_fid, uhgs_id, toponyme_standard_fr as toponym, substate_1789_fr as substate, status, has_a_clerk, geonameid, amiraute as admiralty, province, shiparea , ST_AsGeoJSON(ST_Transform(geom,900913)) as point,
null as source_suite, 1787 as pointcall_year,
nb_conges_1787_inputdone as nb_conges_inputdone,
nb_conges_1787_cr as nb_conges_cr,
nb_sante_1787 as nb_conges_sante,
nb_petitcabotage_1787 as nb_petitcabotage,
null as nb_tonnage_filled, null as nb_homeport_filled, null as nb_product_filled, null as nb_birthplace_filled, null as nb_citizenship_filled, null as nb_flag_filled, null as good_sum_tonnage
from ports.port_points pp
where state_1789_fr = 'France' and nb_conges_1787_cr is null and nb_conges_1787_inputdone is null and geom is not null)*/
union
(select
ogc_fid, uhgs_id, toponyme_standard_fr as toponym, substate_1789_fr as substate, status, has_a_clerk, geonameid, amiraute as admiralty, province, shiparea , ST_AsGeoJSON(ST_Transform(geom,900913)) as point,
'G5' as source_suite, 1789 as pointcall_year,
nb_conges_1789_inputdone as nb_conges_inputdone,
nb_conges_1789_cr as nb_conges_cr,
nb_sante_1789 as nb_conges_sante,
nb_petitcabotage_1789 as nb_petitcabotage,
null as nb_tonnage_filled, null as nb_homeport_filled, null as nb_product_filled, null as nb_birthplace_filled, null as nb_citizenship_filled, null as nb_flag_filled, null as good_sum_tonnage
from ports.port_points pp
where state_1789_fr = 'France' and nb_conges_1789_cr is not null and nb_conges_1789_inputdone is null )
union
(select
ogc_fid, uhgs_id, toponyme_standard_fr as toponym, substate_1789_fr as substate, status, has_a_clerk, geonameid, amiraute as admiralty, province, shiparea , ST_AsGeoJSON(ST_Transform(geom,900913)) as point,
null as source_suite, null as pointcall_year,
nb_conges_1789_inputdone as nb_conges_inputdone,
nb_conges_1789_cr as nb_conges_cr,
nb_sante_1789 as nb_conges_sante,
nb_petitcabotage_1789 as nb_petitcabotage,
null as nb_tonnage_filled, null as nb_homeport_filled, null as nb_product_filled, null as nb_birthplace_filled, null as nb_citizenship_filled, null as nb_flag_filled, null as good_sum_tonnage
from ports.port_points pp
where state_1789_fr = 'France'
and nb_conges_1787_cr is null and nb_conges_1787_inputdone is null
and nb_conges_1789_cr is null and nb_conges_1789_inputdone is null
and geom is not null)
order by toponym, pointcall_year, source_suite
Supports Markdown
0% or .
You are about to add 0 people to the discussion. Proceed with caution.
Finish editing this message first!
Please register or to comment