Skip to content
Snippets Groups Projects
Commit 4f0c07bc authored by Riccardo Boero's avatar Riccardo Boero :innocent:
Browse files

Full impelementation, 1st version

parent c55c7cfd
No related branches found
No related tags found
No related merge requests found
FROM mariadb:11.1
# copy directories with scripts
COPY inputs/update_sys.sh /root/inputs/update_sys.sh
RUN chmod a+x /root/inputs/update_sys.sh
COPY dump /docker-entrypoint-initdb.d
# update system for security reasons
RUN $HOME/inputs/update_sys.sh
#!/bin/bash
# create database
./inputs/setup_db.sh
# load vector data into DB
./inputs/load_vector_data.sh
# load NUTS objects into DB
./inputs/load_table_data.sh
# dump data and drop database on 'local' instance
./inputs/dump_and_drop.sh
echo "*** Dump database:"
mkdir -p ./dump
mariadb-dump -h "plazablanca.nilu.no" -u "root" -pimpadminPSWD! --databases FACT_ports > ./dump/db_ports.sql
echo "*** Drop database:"
mariadb -h "plazablanca.nilu.no" -u "root" -pimpadminPSWD! < inputs/sql/drop_db.sql
#!/bin/bash
# EU
# tonnage
for y in {1997..2022}
do
mkdir -p ./temp
wget -O ./temp/temp_Q1.tsv -N "https://ec.europa.eu/eurostat/api/dissemination/sdmx/3.0/data/dataflow/ESTAT/mar_go_qm/1.0?&c[tra_cov]=TOTAL&c[direct]=TOTAL&c[time_period]=${y}-Q1&format=tsv"
wget -O ./temp/temp_Q2.tsv -N "https://ec.europa.eu/eurostat/api/dissemination/sdmx/3.0/data/dataflow/ESTAT/mar_go_qm/1.0?&c[tra_cov]=TOTAL&c[direct]=TOTAL&c[time_period]=${y}-Q2&format=tsv"
wget -O ./temp/temp_Q3.tsv -N "https://ec.europa.eu/eurostat/api/dissemination/sdmx/3.0/data/dataflow/ESTAT/mar_go_qm/1.0?&c[tra_cov]=TOTAL&c[direct]=TOTAL&c[time_period]=${y}-Q3&format=tsv"
wget -O ./temp/temp_Q4.tsv -N "https://ec.europa.eu/eurostat/api/dissemination/sdmx/3.0/data/dataflow/ESTAT/mar_go_qm/1.0?&c[tra_cov]=TOTAL&c[direct]=TOTAL&c[time_period]=${y}-Q4&format=tsv"
mariadb -h "plazablanca.nilu.no" -u "root" -pimpadminPSWD! -e " \
CREATE TEMPORARY TABLE FACT_ports.staging_1 (Row varchar(50) NOT NULL, Value INT, Year INT); \
LOAD DATA LOCAL INFILE \"temp/temp_Q1.tsv\" INTO TABLE FACT_ports.staging_1 FIELDS TERMINATED BY '\t' LINES TERMINATED BY '\n' IGNORE 1 LINES (@col1, @col2) SET Row=@col1, Value=@col2, Year=${y}; \
DELETE from FACT_ports.staging_1 where length(row) < 29; \
CREATE TEMPORARY TABLE FACT_ports.staging_2 (Row varchar(50) NOT NULL, Value INT, Year INT); \
LOAD DATA LOCAL INFILE \"temp/temp_Q2.tsv\" INTO TABLE FACT_ports.staging_2 FIELDS TERMINATED BY '\t' LINES TERMINATED BY '\n' IGNORE 1 LINES (@col1, @col2) SET Row=@col1, Value=@col2, Year=${y}; \
DELETE from FACT_ports.staging_2 where length(row) < 29; \
CREATE TEMPORARY TABLE FACT_ports.staging_3 (Row varchar(50) NOT NULL, Value INT, Year INT); \
LOAD DATA LOCAL INFILE \"temp/temp_Q3.tsv\" INTO TABLE FACT_ports.staging_3 FIELDS TERMINATED BY '\t' LINES TERMINATED BY '\n' IGNORE 1 LINES (@col1, @col2) SET Row=@col1, Value=@col2, Year=${y}; \
DELETE from FACT_ports.staging_3 where length(row) < 29; \
CREATE TEMPORARY TABLE FACT_ports.staging_4 (Row varchar(50) NOT NULL, Value INT, Year INT); \
LOAD DATA LOCAL INFILE \"temp/temp_Q4.tsv\" INTO TABLE FACT_ports.staging_4 FIELDS TERMINATED BY '\t' LINES TERMINATED BY '\n' IGNORE 1 LINES (@col1, @col2) SET Row=@col1, Value=@col2, Year=${y}; \
DELETE from FACT_ports.staging_4 where length(row) < 29; \
INSERT INTO FACT_ports.eu_tonnage (PORT_ID, Year, Q1) SELECT SUBSTR(SUBSTRING_INDEX(Row,',',-1),5,5), Year, Value FROM FACT_ports.staging_1 ON DUPLICATE KEY UPDATE Q1 = Value; \
INSERT INTO FACT_ports.eu_tonnage (PORT_ID, Year, Q2) SELECT SUBSTR(SUBSTRING_INDEX(Row,',',-1),5,5), Year, Value FROM FACT_ports.staging_2 ON DUPLICATE KEY UPDATE Q2 = Value; \
INSERT INTO FACT_ports.eu_tonnage (PORT_ID, Year, Q3) SELECT SUBSTR(SUBSTRING_INDEX(Row,',',-1),5,5), Year, Value FROM FACT_ports.staging_3 ON DUPLICATE KEY UPDATE Q3 = Value; \
INSERT INTO FACT_ports.eu_tonnage (PORT_ID, Year, Q4) SELECT SUBSTR(SUBSTRING_INDEX(Row,',',-1),5,5), Year, Value FROM FACT_ports.staging_4 ON DUPLICATE KEY UPDATE Q4 = Value; \
"
rm -r ./temp
done
#!/bin/bash
# Europe
# coordinate reference system: ETRS89 / LAEA
echo "*** Downloading and loading EU grid 1km." # expected number of records in DB:
# 2009
mkdir -p ./temp
wget -N 'https://ec.europa.eu/eurostat/cache/GISCO/geodatafiles/PORT_2009_SH.zip' -P ./temp
unzip -d ./temp/ ./temp/PORT_2009_SH.zip
ogr2ogr -f MySQL MySQL:FACT_ports,host=plazablanca.nilu.no,user=root,password=impadminPSWD! ./temp/PORT_2009_SH/shape/data/PORT_PT_2009.shp -nln eu_ports_2009_geo -update -overwrite -lco engine=Aria
rm -r ./temp
# 2013
mkdir -p ./temp
wget -N 'https://ec.europa.eu/eurostat/cache/GISCO/geodatafiles/PORT_2013_SH.zip' -P ./temp
unzip -d ./temp/ ./temp/PORT_2013_SH.zip
ogr2ogr -f MySQL MySQL:FACT_ports,host=plazablanca.nilu.no,user=root,password=impadminPSWD! ./temp/PORT_2013_SH/Data/PORT_PT_2013.shp -nln eu_ports_2013_geo -update -overwrite -lco engine=Aria
rm -r ./temp
# US
mkdir -p ./temp
wget -N 'https://opendata.arcgis.com/api/v3/datasets/e3b6065cce144be8a13a59e03c4195fe_1/downloads/data?format=shp&spatialRefId=4326&where=1%3D1' -O ./temp/Principal_Ports.zip
unzip -d ./temp/ ./temp/Principal_Ports.zip
ogr2ogr -f MySQL MySQL:FACT_ports,host=plazablanca.nilu.no,user=root,password=impadminPSWD! ./temp/Principal_Ports.shp -nln us_ports_geo -update -overwrite -lco engine=Aria
rm -r ./temp
echo "*** Create database:"
mariadb -h "plazablanca.nilu.no" -u "root" -pimpadminPSWD! < inputs/sql/create_db.sql
echo "*** Create tables:"
mariadb -h "plazablanca.nilu.no" -u "root" -pimpadminPSWD! < inputs/sql/create_tables.sql
CREATE DATABASE IF NOT EXISTS FACT_ports;
CREATE TABLE FACT_ports.eu_tonnage (
PORT_ID varchar(5) NOT NULL,
Year INT NOT NULL,
Q1 INT NULL,
Q2 INT NULL,
Q3 INT NULL,
Q4 INT NULL,
PRIMARY KEY (PORT_ID, Year)
)
ENGINE=Aria
DEFAULT CHARSET=utf8mb4
COLLATE=utf8mb4_general_ci;
DROP DATABASE IF EXISTS FACT_ports;
#!/bin/bash
echo "*** Updating system:"
apt update -y && apt upgrade -y
0% Loading or .
You are about to add 0 people to the discussion. Proceed with caution.
Finish editing this message first!
Please register or to comment