Commit 84b2efab authored by Christine Plumejeaud's avatar Christine Plumejeaud
Browse files

Export of ships and captains descriptions for shiproutes Web application

parent f90c74f1
......@@ -74,7 +74,7 @@ def retrieveDataFromPostgres(query, cast_columns_to_types=None) :
see read_sql_query() doc : https://pandas.pydata.org/pandas-docs/stable/reference/api/pandas.read_sql_query.html
columns can be type-casted using the cast_columns_to_types dictionary argument : { 'column_sql_name' : 'type'}. For 'type', see dtype String Aliases : https://pandas.pydata.org/docs/user_guide/basics.html#basics-dtypes
"""
import pandas.io.sql as psql
#import pandas.io.sql as psql
import pandas as pd
#connection = pg.connect("host='134.158.33.179' port='5433' dbname='portic_v3' user='api_user' password='portic'")
connection = pg.connect("""host='localhost' port='%s' dbname='%s' user='api_user' password='portic'"""% (postgresport, database))
......@@ -1127,6 +1127,60 @@ Examples :
# execute SQL query, and format resulting data :
return retrieveDataAndFormatOutput(query, 'ports', cast_df_columns_to_types)
@app.route('/api/ships/')
def getShipsDescription():
"""
Return the ships that we can follow in travels
Will be extracted from postgres, schema navigoviz, table ship (see navigocorpus/ETL and sql/portic_detailviz.sql),
but with a filter on the lang : only fr or en attributes
- lang : **fr** | en, language for flag(_standardized), homeport, and birthplace (later on)
http://127.0.0.1:80/api/ships/?format=csv&lang=fr
http://127.0.0.1:80/api/ships/?format=json&lang=en
"""
# language given by user (defaults to "fr")
lang = request.args.get("lang") # read requested language
lang=validateLang(lang) # "fr" or "en" valid only (defaults to "fr")
localizedDatabaseFieldNames = f"occurences_homeports_{lang} as occurences_homeports, occurences_flags_{lang} as occurences_flags"
query = f"""select ship_id, occurences_names, {localizedDatabaseFieldNames}, occurences_class, occurences_tonnageclass
from navigoviz.ship"""
## Warning, no comments have been set on ship table
## Si jamais on demande shortenFields= true, ca va planter.
return retrieveDataAndFormatOutput(query, api='ships')
@app.route('/api/captains/')
def getCaptainsDescription():
"""
Return the captains that we can follow in travels
Will be extracted from postgres, schema navigoviz, table captain (see navigocorpus/ETL and sql/portic_detailviz.sql),
but with a filter on the lang : only fr or en attributes
- lang : **fr** | en, language for flag(_standardized), homeport, and birthplace (implemented later on)
Translation of birthplace in standardized en/fr is not done at that moment (15 June 2022) : there is only a birthplace_id to link with port in the ETL...
The attribute citizenship has not its own id filled neither in navigocorpus.
http://127.0.0.1:5004/api/ships/?format=csv&lang=fr
http://127.0.0.1:80/api/ships/?format=json&lang=en
"""
# language given by user (defaults to "fr")
lang = request.args.get("lang") # read requested language
lang=validateLang(lang) # "fr" or "en" valid only (defaults to "fr")
localizedDatabaseFieldNames = f"occurences_birthplaces, occurences_citizenships"
# f"occurences_birthplaces_{lang} as occurences_birthplaces, occurences_citizenships_{lang} as occurences_citizenships"
query = f"""select captain_id, occurences_names, {localizedDatabaseFieldNames}
from navigoviz.captain"""
##Warning, no comments have been set on captain table
## Si jamais on demande shortenFields= true, ca va planter.
return retrieveDataAndFormatOutput(query, api='ships')
@app.route('/api/test/')
def getTest():
"""
......
-----------------------------------------------------------------
-- API pour detailviz
-----------------------------------------------------------------
set search_path = navigoviz, ports, public;
select count(*) from built_travels where source_entry != 'both-to';
-- 63204 segments
select distinct p.captain_id , p.captain_name , p.captain_uncertainity ,
p.birthplace , p.birthplace_uhgs_id , p.birthplace_uncertainity , p.birthplace_uhgs_id_uncertainity ,
p.citizenship , p.citizenship_uncertainity
-- ATTENTION, à ajouter dans travels : captain_citizenship_id
--captain_last_name, captain_age, captain_status,
--captain_citizenship, captain_birthplace, captain_birthplace_id, captain_origin, captain_origin_id
from navigoviz.built_travels p
where source_entry != 'both-to'
order by captain_id
-- 21994
drop table navigoviz.captain;
CREATE TABLE navigoviz.captain (
captain_id text,
occurences_names json,
occurences_birthplaces json,
occurences_citizenships json
);
INSERT INTO navigoviz.captain(captain_id)
SELECT DISTINCT captain_id FROM navigoviz.built_travels where captain_id is not null;
--- 12329
-- where source_entry != 'both-to'
update navigoviz.captain c set occurences_names = k.occurences_name
FROM
(select captain_local_id, array_to_json(array_agg(json_build_object(captain_name ,occurences))) as occurences_name
FROM
(
Select captain_id as captain_local_id, captain_name, count (distinct source_doc_id) as occurences
FROM navigoviz.pointcall p
WHERE p.captain_id in (select distinct captain_id from built_travels)
GROUP BY captain_name, captain_id
ORDER BY captain_id, occurences DESC
) t
WHERE occurences > 0
GROUP BY captain_local_id
) as k
WHERE c.captain_id = k.captain_local_id;
-- 12329
select * from navigoviz.captain where occurences_names is null;
update navigoviz.captain c set occurences_birthplaces = k.occurence_birthplace
FROM
(select captain_local_id, array_to_json(array_agg(json_build_object(birthplace ,occurences))) as occurence_birthplace
FROM
(
Select captain_id as captain_local_id, birthplace, count (distinct source_doc_id) as occurences
FROM navigoviz.pointcall p
WHERE p.captain_id in (select distinct captain_id from built_travels)
GROUP BY birthplace,captain_id
ORDER BY captain_id, occurences DESC
) t
WHERE occurences > 0 and birthplace is not null
GROUP BY captain_local_id
) as k
WHERE c.captain_id = k.captain_local_id;
-- 2331
update navigoviz.captain c set occurences_citizenships = k.occurences_citizenship
FROM
(select captain_local_id, array_to_json(array_agg(json_build_object(citizenship ,occurences))) as occurences_citizenship
FROM
(
Select captain_id as captain_local_id, citizenship, count (distinct source_doc_id) as occurences
FROM navigoviz.pointcall p
WHERE p.captain_id in (select distinct captain_id from built_travels)
GROUP BY citizenship,captain_id
ORDER BY captain_id, occurences DESC
) t
WHERE occurences > 0 and citizenship is not null
GROUP BY captain_local_id
) as k
WHERE c.captain_id = k.captain_local_id;
-- 1084
select * from navigoviz.captain where captain_id in ('00002765', '00002763', '00002472', '00014569', '00011637') ;
-- 00014569 [{"Accamo, Jean Baptiste" : 18},{"Accamo,Jean Baptiste" : 1},{"Accame, Jean Baptiste" : 1},{"Accamé, Jean Baptiste" : 1},{"Accamo, Jean BAptiste" : 1}] [{"Génois" : 18},{"Genois" : 3}]
-- 00002763 [{"Taglierani, Jean Antoine" : 1}] [{"Ragusois" : 1}]
-- 00002472 [{"Perron, Joseph" : 3},{"Person, Joseph" : 2},{"Le Person, Joseph" : 1},{"Porson, Joseph" : 1},{"Le Perron, Joseph" : 1}] [{"Ile aux moines" : 2}]
-- 00011637 [{"Rouilla, François" : 2},{"Rouilla, Fancois" : 1},{"Rolla, François" : 1}] [{"Tossa" : 3},{"Tosse [Tossa]" : 1}] [{"Catalan" : 3},{"Catalogne" : 1}]
-- 00002765 [{"Cazabon, Jean" : 1},{"Casaubon, Jean" : 1}]
select captain_name, * from navigoviz.pointcall where captain_id = '00002472'
order by captain_name
--- Pour les navires
drop table navigoviz.ship;
CREATE TABLE navigoviz.ship(
ship_id text,
occurences_names json,
occurences_homeports_fr json,--use standardized homeports fr et en; should be only ONE ?
occurences_homeports_en json,--use standardized homeports fr et en; should be only ONE ?
occurences_flags_fr json,-- use standardized flag fr et en; should be only ONE ?
occurences_flags_en json,-- use standardized flag fr et en; should be only ONE ?
occurences_class json,
occurences_tonnageclass json
);
INSERT INTO navigoviz.ship(ship_id,occurences_names)
select ship_id, array_to_json(array_agg(json_build_object(ship_name ,occurences))) as occurences_name
FROM
(
Select ship_id, ship_name, count (distinct source_doc_id) as occurences
FROM navigoviz.pointcall p
WHERE p.ship_id in (select distinct ship_id from built_travels)
GROUP BY ship_name,ship_id
ORDER BY ship_id, occurences DESC
) as k
GROUP BY ship_id;
-- 11618
update navigoviz.ship s set occurences_names = k.occurences_name
FROM
(select ship_id, array_to_json(array_agg(json_build_object(ship_name ,occurences))) as occurences_name
from (
Select ship_id, ship_name, count (distinct source_doc_id) as occurences
FROM navigoviz.pointcall p
WHERE p.ship_id in (select distinct ship_id from built_travels)
GROUP BY ship_name,ship_id
ORDER BY ship_id, occurences DESC
) as k
GROUP BY ship_id
) as k
WHERE s.ship_id = k.ship_id;
select * from navigoviz.built_travels where ship_name is null ;
update navigoviz.ship s set occurences_flags_fr = k.flags
FROM
(SELECT t.ship_id, array_to_json(array_agg(json_build_object(t.ship_flag ,t.occurences))) as flags
FROM(
Select ship_id,
ship_flag_standardized_fr as ship_flag, count (distinct source_doc_id) as occurences
FROM navigoviz.pointcall p
WHERE p.ship_id in (select distinct ship_id from built_travels)
GROUP BY ship_id, p.ship_flag_standardized_fr
ORDER BY ship_id, occurences DESC
) t
WHERE occurences > 0 and ship_flag is not null
GROUP BY t.ship_id
) as k
WHERE s.ship_id = k.ship_id;
-- 11104
update navigoviz.ship s set occurences_flags_en = k.flags
FROM
(SELECT t.ship_id, array_to_json(array_agg(json_build_object(t.ship_flag ,t.occurences))) as flags
FROM(
Select ship_id,
ship_flag_standardized_en as ship_flag, count (distinct source_doc_id) as occurences
FROM navigoviz.pointcall p
WHERE p.ship_id in (select distinct ship_id from built_travels)
GROUP BY ship_id, p.ship_flag_standardized_en
ORDER BY ship_id, occurences DESC
) t
WHERE occurences > 0 and ship_flag is not null
GROUP BY t.ship_id
) as k
WHERE s.ship_id = k.ship_id;
-- 11104
-- Requête JSON à faire : existe-t-il des cas où le flag n'est pas consistent pour le même navire ?
-- OUI : 26 cas sur 11104
-- taille du tableau ?
select distinct json_array_length (occurences_flags_fr) from navigoviz.ship
select * from navigoviz.ship where json_array_length (occurences_flags_fr) > 1
select * from navigoviz.ship where json_array_length (occurences_flags_fr) > 1
select (occurences_flags_fr)::json->0->>'f1' from navigoviz.ship where occurences_flags_fr is not null
select (occurences_flags_fr)::json->0->>'f1' from navigoviz.ship where occurences_flags_fr is not null and (occurences_flags_fr)::json->0->>'f1' = ''
update navigoviz.ship s set occurences_homeports_fr = k.homeports
FROM
(SELECT t.ship_id, array_to_json(array_agg(json_build_object(t.ship_homeport ,t.occurences))) as homeports
FROM(
Select ship_id,
homeport_toponyme_fr as ship_homeport, count (distinct source_doc_id) as occurences
FROM navigoviz.pointcall p
WHERE p.ship_id in (select distinct ship_id from built_travels)
GROUP BY ship_id, homeport_toponyme_fr
ORDER BY ship_id, occurences DESC
) t
WHERE occurences > 0 and ship_homeport is not null
GROUP BY t.ship_id
) as k
WHERE s.ship_id = k.ship_id;
--- 7798
update navigoviz.ship s set occurences_homeports_en = k.homeports
FROM
(SELECT t.ship_id, array_to_json(array_agg(json_build_object(t.ship_homeport ,t.occurences))) as homeports
FROM(
Select ship_id,
homeport_toponyme_en as ship_homeport, count (distinct source_doc_id) as occurences
FROM navigoviz.pointcall p
WHERE p.ship_id in (select distinct ship_id from built_travels)
GROUP BY ship_id, homeport_toponyme_en
ORDER BY ship_id, occurences DESC
) t
WHERE occurences > 0 and ship_homeport is not null
GROUP BY t.ship_id
) as k
WHERE s.ship_id = k.ship_id;
--- 7798
-- update navigoviz.ship s set occurences_class = null
update navigoviz.ship s set occurences_class = k.class
FROM
(SELECT t.ship_id, array_to_json(array_agg(json_build_object(t.ship_class ,t.occurences))) as class
FROM(
Select ship_id,
class as ship_class, count (distinct source_doc_id) as occurences
FROM navigoviz.pointcall p
WHERE p.ship_id in (select distinct ship_id from built_travels)
GROUP BY ship_id, class
ORDER BY ship_id, occurences DESC
) t
WHERE occurences > 0 and ship_class is not null
GROUP BY t.ship_id
) as k
WHERE s.ship_id = k.ship_id;
-- 4466
select * from navigoviz.ship s
update navigoviz.ship s set occurences_tonnageclass = k.tonnageclass
FROM
(SELECT t.ship_id, array_to_json(array_agg(json_build_object(t.ship_tonnage ,t.occurences))) as tonnageclass
FROM(
Select ship_id,
tonnage_class as ship_tonnage, count (distinct source_doc_id) as occurences
FROM navigoviz.pointcall p
WHERE p.ship_id in (select distinct ship_id from built_travels)
GROUP BY ship_id, tonnage_class
ORDER BY ship_id, occurences desc
) t
WHERE occurences > 0 and ship_tonnage is not null
GROUP BY t.ship_id
) as k
WHERE s.ship_id = k.ship_id;
-- 9048
select * from navigoviz.ship where json_array_length (occurences_tonnageclass) > 1 --622
select * from navigoviz.ship where json_array_length (occurences_tonnageclass) > 1 --622
select (occurences_tonnageclass)::json->0->>'f1' from navigoviz.ship where occurences_tonnageclass is not null
select travel_id, source_doc_id, outdate_fixed, indate_fixed, departure_uhgs_id, departure_fr, destination_uhgs_id, destination_fr,
ship_id, ship_name, tonnage_class, ship_flag_standardized_fr, homeport_toponyme_fr,
captain_id , captain_name, birthplace, citizenship, travel_rank, nbproduits
from navigoviz.built_travels
where ship_id = '0013102N' and source_entry!='both-to'
order by travel_rank;
-- and captain_id=''
-- Renvoyer les variantes de noms de navires ou de capitaines
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