DIADROMOUS FISH DATABASE : Scripts to create StockDB (import of data from WGNAS, WGEEL and WGBAST) Creation of referentials (dictionaries). This document is still in construction.
Author
Briand Cédric, Oliviero Jules, Helminen Jani
Published
28-10-2025
The main structure of the database has been proposed during the online DIASPARA meeting : database structure. This stucture would allow to store the data necessary to run the international stock models for the different working groups working on diadromous fishes. The structure of the proposed database and the structure of the wgeel database are very similar. This documents creates the diaspara database, first creating referential table for the different types proposed, and then populates the database with the contents of the wgeel and wgnas database. All chunks are run sequentially to run the database, but some are later marked with eval = FALSE to speed up the process of running the quarto document. The diadromous fish database is made of two main structures. The first is called *** Stock Database*** and holds values aggregated at the scale of the assessment unit, or stock unit. This scale has been created using a hierarchical structure of the habitat of the migratory fishes (see habitat report).
1 Hierarchical structure of the database
The database starts with the simplest structure, with a basic table corresponding to all data. Then three tables are created, one per Working group Since SQL server does not handle inheritance, once the table built, some of those will have to be replaced with views or partitioned views.
1.1 Referential tables
Similarly, referential tables are created with a mother table from which specific (or wg specific) tables inherit. All mother tables will be held in a schema called ref. Having working group specific tables make the setting up of consistent foreign key more easy. For instance wgeel references different stages than wgnas. Most of these referential table are common between species and whenever possible they are sourced from ICES vocab.
1.2 Unicity constraints
Another important point to add is unique constraint. As some values would be null, creating unique constraints with indexes would be necessary. These allow to have different levels of constraints for instance the unique constraint would be defined for : (year, age, area, parameter) (year, age, parameter) (year, area, parameter) (year, parameter)
One of the table will have to contain twice the area it will have to be treated separately. (year, area, area, parameter)
1.3 Creating the diaspara database
All along this document, the database will be named diaspara. The database is created with postgres.
Some rules
By default values will be capitalised for the first letter e.g. Public for the code in dataaccess.
Code ELE, ANG, TRS are capitalized, as are the working group names WGEEL, WGNAS, or country codes.
Units are lowercase e.g. g, mm …
All integer used for primary keys are called id all text used for primary keys are called code, the text is always called description.
All tables end with a 3 letter summary which allows to identify the source of one column so the table dataaccess will be called tr_dataaccess_dta. And the column for code will be named
Referential tables or dictionaries are called tr_(sometable), tables build in conjuction from other tables and not in the dictionaries are called t_(sometable).
Foreign key are used instead of check constraints as check constraint might not ensure the integrity of data after their integration (only when new rows are created or modified).
Foreign key are name fk_columnname where the column name is the name in the table
Primary keys are names tablename_pkey (with the constraint possibly referering to more than one column).
Other constraints are check constraints ck_columnname and unique contraints uk_columnname
All tables and column have a definition, we will ask the working groups to check those.
Column and table name are ALWAYS LOWERCASE, the underscore is only used to separate type of table and table shortcode t_table_abc. In column is separates table code abc_def_code (table abc will reference the column def_code in table def).
The database can be created an run in localhost, check the wp3_habitat repository for code to set up access to the database. Two roles are created, diaspara_admin and diaspara_read and users are given specific rights.
DIASPARA technical note
need to edit the pb_hba.conf on the server if not in localhost to allow access to diaspara.
Code to create the diaspara DB
# dbExecute(con_diaspara_admin, "DROP schema if exists ref CASCADE;");# dbExecute(con_diaspara_admin, "CREATE schema ref;")# dbExecute(con_diaspara_admin, "GRANT ALL PRIVILEGES ON SCHEMA ref TO diaspara_admin ;")# dbExecute(con_diaspara_admin, "GRANT ALL PRIVILEGES ON SCHEMA public TO diaspara_read ;")# dbExecute(con_diaspara_admin, paste0("GRANT CONNECT ON DATABASE ",cred$dbnamediaspara," TO diaspara_read;"))# dbExecute(con_diaspara_admin, paste0("ALTER DATABASE ",cred$dbnamediaspara," OWNER TO diaspara_admin;"))# dbExecute(con_diaspara_admin, "DROP schema if exists refeel CASCADE;");# dbExecute(con_diaspara_admin, "CREATE SCHEMA refeel;")# dbExecute(con_diaspara_admin, "ALTER SCHEMA refeel OWNER TO diaspara_admin;")# dbExecute(con_diaspara_admin, "DROP schema if exists refnas CASCADE;");# dbExecute(con_diaspara_admin, "CREATE SCHEMA refnas;")# dbExecute(con_diaspara_admin, "ALTER SCHEMA refnas OWNER TO diaspara_admin;")# dbExecute(con_diaspara_admin, "DROP schema if exists refbast CASCADE;");# dbExecute(con_diaspara_admin, "CREATE SCHEMA refbast;")# dbExecute(con_diaspara_admin, "ALTER SCHEMA refbast OWNER TO diaspara_admin;")# dbExecute(con_diaspara_admin, "DROP schema if exists reftrutta CASCADE;");# dbExecute(con_diaspara_admin, "CREATE SCHEMA reftrutta;")# dbExecute(con_diaspara_admin, "ALTER SCHEMA reftrutta OWNER TO diaspara_admin;")# # # Create foreign data wrapper to wgeel database# # dbExecute(con_diaspara_admin, "CREATE EXTENSION IF NOT EXISTS postgres_fdw;")# # dbExecute(con_diaspara_admin,"# CREATE SERVER wgeel_data_wrapper# FOREIGN DATA WRAPPER postgres_fdw# OPTIONS (host 'localhost', port '5432', dbname 'wgeel');")# dbExecute(con_diaspara_admin,"# CREATE SERVER wgnas_data_wrapper# FOREIGN DATA WRAPPER postgres_fdw# OPTIONS (host 'localhost', port '5432', dbname 'salmoglob');")# dbExecute(con_diaspara_admin,"# CREATE USER MAPPING FOR USER# SERVER wgeel_data_wrapper# OPTIONS (user 'postgres', password 'postgres');")# dbExecute(con_diaspara_admin," # CREATE SCHEMA refwgeel;")# dbExecute(con_diaspara_admin,"IMPORT FOREIGN SCHEMA ref # FROM SERVER wgeel_data_wrapper# INTO refwgeel;")# # dbExecute(con_diaspara_admin, paste0("COMMENT ON DATABASE ",cred$dbnamediaspara," IS 'This database is named Frankenstein :-)'")) # dbExecute(con_diaspara_admin,# "GRANT ALL PRIVILEGES ON SCHEMA refwgeel TO diaspara_admin;")
SQL code to additional data schema
Listing 1: Building additional schema
--| echo: TRUE--| eval: FALSE-- this one is straight into sql ... DROPSCHEMAIFEXISTS dat CASCADE;CREATESCHEMA dat;ALTERSCHEMA dat OWNER TO diaspara_admin;COMMENTONSCHEMA dat IS'SCHEMA common to all migratory fish, filled by inheritance';DROPSCHEMAIFEXISTS dateel CASCADE;CREATESCHEMA dateel;ALTERSCHEMA dateel OWNER TO diaspara_admin;COMMENTONSCHEMA dateel IS'SCHEMA for WGEEL';DROPSCHEMAIFEXISTS dateel CASCADE;CREATESCHEMA dateel;ALTERSCHEMA dateel OWNER TO diaspara_admin;COMMENTONSCHEMA dateel IS'SCHEMA for WGNAS';DROPSCHEMAIFEXISTS datbast CASCADE;CREATESCHEMA datbast;ALTERSCHEMA datbast OWNER TO diaspara_admin;COMMENTONSCHEMA datbast IS'SCHEMA for WGBAST';DROPSCHEMAIFEXISTS dattrutta CASCADE;CREATESCHEMA dattrutta;ALTERSCHEMA dattrutta OWNER TO diaspara_admin;COMMENTONSCHEMA dattrutta IS'SCHEMA for WKTRUTTA';
Now the database has been created with different schema (Figure 1). The main schema for dictionaries is ref, and a schema is created per working group for specific referential tables. The Schema refwgeel is a schema created with a foreign data wrapper to get the data from wgeel, the same schema exists for wgnas. We’ll see later for wgbast and wgtrutta.
Figure 1: Structure of the schema in diaspara. Dashed arrow indicate an import of data from existing
Now the database has been created with different schema (Figure 1). The main schema for dictionaries is ref, and a schema is created per working group for specific referential tables. The Schema refwgeel has been filled in with a foreign data wrapper to get the data from wgeel, the same schema exists for wgnas. We’ll see later for wgbast and wgtrutta. The schema dat is the common schema for all data. For each working group, schema datbast, dateel, datnas are created. The tables are be created in dat and later similar or a bit more complex tables (with some more columns) will be created using the INHERIT FROM syntax, which will allow to have a hierarchical structure in the db, and maintain the structure in a table common to all fishes. Note thatdat should not containt any data, but will hold all the views and inherited tables comming from the different schema.
2 Creating referentials
This script holds all referentials necesary for the metricDB and the stockDB.
2.1 species (tr_species_spe)
The first thing is to create a referential table for species. Anyways, we searched a bit for other species, even if we don’t plan to start storing data on Alosa and Lamprey it’s good to prepare the database. There are no code in ICES vocab for Alosa alosa, Alosa fallax, Petromyzon marinus, Lampetra fluviatilis.
Note Cédric : Thinking later about this, I chose to get rid of ELE and select ANG. This column with species will be everywhere. We want to avoid generations of researchers to avoid what ELE is (apart from elephants). For the others I’ve taken as close as possible to the latin name.
QUESTION ICES: species code
ANG, ALA, ALF, PET, LAM are these internal code OK ? Should we use SpecWoRMS or is Aphia OK ?
ANSWER ICES : Maria
For species, we would recommend that you use AphiaIDs (a copy of which is SpecWoRMs). You can also use the FAO ASFIS list, or both, but we would recommend having the AphiaIDs for sure.
ANSWER WGTRUTTA : Iain
I would suggest the common name for Salmo Trutta should just be trout (as you normally can’t differentiate migratory and resident forms of the juveniles). In our database we also have a field “salmonid” for circumstances where people electrofish very early in the year and it isn’t readily possible to separate trout and salmon fry.
Creating a referential table for species - code and queries to ICES
# No code for Lampetra, Alosa, petromyzonsp <-getCodeList("IC_species")grep("Lampetra", sp$description)
integer(0)
grep("Petromyzon", sp$description)
integer(0)
grep("Alosa", sp$description)
integer(0)
bind_rows( ele <-getCodeDetail("IC_species","ELE")$detail, sal <-getCodeDetail("IC_species","SAL")$detail, trs <-getCodeDetail("IC_species","TRS")$detail) |> knitr::kable(caption ="Codes for migratory species in ICES, no code found for other species (Lamprey, Alosa ...)") |>kable_styling(bootstrap_options =c("striped", "hover", "condensed"))if (file.exists("data/tr_species_spe_temp.Rdata")) {load("data/tr_species_spe_temp.Rdata") } else { species_list <-tibble(spe_code =c("SAL", "ANG", "TRS", "ALA", "ALF", "PET", "LAM"),spe_icspecieskey =c("SAL", "ELE", "TRS", NA,NA,NA,NA),spe_commonname =c("Atlantic salmon", "European eel", "Sea trout", "Twait shad", "Allis shad", "Sea lamprey", "European river lamprey"),spe_scientificname =c("Salmo salar", "Anguilla anguilla", "Salmo trutta", "Alosa alosa", "Alosa fallax", "Petromyzon marinus", "Lampetra fluviatilis") ) tr_species_spe_temp <- species_list |>rowwise() |>mutate(spe_codeaphia =findAphia(spe_scientificname, latin =TRUE) ) |>ungroup()save(tr_species_spe_temp, file ="data/tr_species_spe_temp.Rdata") }knitr::kable(tr_species_spe_temp) |>kable_styling(bootstrap_options =c("striped", "hover", "condensed"))
Table 1: species in ICES
(a) Code found in IC_species
Id
Guid
Key
Description
LongDescription
Modified
77905
fea31ebb-fc69-4562-af1b-3fec866e7e58
ELE
Anguilla anguilla
2019-04-15T12:39:51.97
77934
810c0c92-d333-4b16-ab8c-dfe63a7c1a20
SAL
Salmo salar
2019-04-15T13:19:13.723
77943
b0de7924-ee6c-483e-a2e3-91c80ca033c2
TRS
Salmo trutta
2019-04-15T13:23:25.033
(b) Three letter code for species. Should we use ang instead of ele ?
spe_code
spe_commonname
spe_scientificname
spe_codeaphia
SAL
Atlantic salmon
Salmo salar
127186
ELE
European eel
Anguilla anguilla
126281
TRT
Sea trout
Salmo trutta
127187
ALA
Twait shad
Alosa alosa
126413
ALF
Allis shad
Alosa fallax
126415
SLP
Sea lamprey
Petromyzon marinus
101174
RLP
European river lamprey
Lampetra fluviatilis
101172
SQL code to create table tr_species_spe
--DROP TABLE IF EXISTS ref.tr_species_spe;CREATETABLEref.tr_species_spe ( spe_code CHARACTERVARYING(3) PRIMARYKEY, spe_commonnname TEXT, spe_scientificname TEXT, spe_codeaphia numericNOTNULL, spe_description TEXT);COMMENTONTABLEref.tr_species_spe IS'Table of species code';GRANTALLONTABLEref.tr_species_spe to diaspara_admin;GRANTSELECTONTABLEref.tr_species_spe to diaspara_read;C
dbWriteTable(conn=con_diaspara, name ="tr_species_spe_temp", value = tr_species_spe_temp, overwrite =TRUE)dbExecute(con_diaspara,"INSERT INTO ref.tr_species_spe SELECT * FROM tr_species_spe_temp")#7dbExecute(con_diaspara,"DROP TABLE tr_species_spe_temp")dbExecute(con_diaspara_admin, "COMMENT ON TABLE ref.tr_species_spe IS 'Table of fish species, spe_code SAL, ANG, TRS, ALA, ALF, PET, LAM, with reference to ICES vocabularies.'")
Table 2: Working groups table in the diaspara DB
spe_code
spe_commonnname
spe_scientificname
spe_codeaphia
spe_description
SAL
Atlantic salmon
Salmo salar
127186
NA
ALA
Twait shad
Alosa alosa
126413
NA
ALF
Allis shad
Alosa fallax
126415
NA
SLP
Sea lamprey
Petromyzon marinus
101174
NA
RLP
European river lamprey
Lampetra fluviatilis
101172
NA
ANG
European eel
Anguilla anguilla
126281
NA
TRS
Sea trout
Salmo trutta
127187
NA
TRT
River trout
Salmo trutta
127187
NA
2.2 Working group (tr_icworkinggroup_wkg)
species is not enough. Data will be split by working groups. Several working groups working on the same species. There is a table for working group. Proposed table is Table 3 but need confirmation for WKTRUTTA2.
QUESTION ICES/ WGTRUTTA/ DIASPARA
what is the latest working group for WGTRUTTA, I found a WKTRUTTA2 but that is quite old. Do we want to refer to other groups on diadromous fishes there ? The name of the WGEEL is wrong in the referential, needs to reference GFCM… JOINT EIFAAC/ICES/GFCM WORKING GROUP ON EEL.
Answer ICES
There is a vocab for all groups, it’s expertgroup. WGTRUTTA is not there but we will add it.
SQL code to create table tr_icworkinggroup_wkg
--DROP TABLE IF EXISTS ref.tr_icworkinggroup_wkg CASCADE;CREATETABLEref.tr_icworkinggroup_wkg (wkg_code TEXT PRIMARYKEY,wkg_description TEXT,wkg_icesguid uuid,wkg_stockkeylabel TEXT);COMMENTONTABLEref.tr_icworkinggroup_wkg IS'Table corresponding to the IC_WorkingGroup referential;';COMMENTONCOLUMNref.tr_icworkinggroup_wkg.wkg_code IS'Working group code uppercase, WGEEL, WGNAS, WGBAST, WGTRUTTA';GRANTALLONref.tr_icworkinggroup_wkg TO diaspara_admin;GRANTSELECTONref.tr_icworkinggroup_wkg TO diaspara_read;
Code to create reference table for working groups
# Using the jsonlite to download the guid alsotbl <- jsonlite::fromJSON("https://vocab.ices.dk/services/api/Code/3f6fb38a-a3c5-4f5c-bf31-2045e12536ee")temp_tr_icworkinggroup_wkg <- tbl |>select(key,description,guid) |>rename(wkg_code = key,wkg_description = description,wkg_icesguid = guid)|>filter(wkg_code %in%c("WGEEL", "WGNAS", "WGBAST"))temp_tr_icworkinggroup_wkg <-bind_rows(temp_tr_icworkinggroup_wkg,data.frame(wkg_code="WKTRUTTA"))temp_tr_icworkinggroup_wkg$wkg_stockkeylabel <-c("sal.27.22–31","ele.2737.nea","sal.neac.all",NA)dbWriteTable(con_diaspara_admin, "temp_tr_icworkinggroup_wkg", temp_tr_icworkinggroup_wkg,overwrite =TRUE)dbExecute(con_diaspara_admin, "INSERT INTO ref.tr_icworkinggroup_wkg SELECT wkg_code, wkg_description, wkg_icesguid::uuid, WKG_stockkeylabel FROM temp_tr_icworkinggroup_wkg;") #4dbExecute(con_diaspara_admin, "DROP TABLE temp_tr_icworkinggroup_wkg;")
Table 3: Working groups table in the diaspara DB
wkg_code
wkg_description
wkg_icesguid
WGBAST
Baltic Salmon and Trout Assessment Working Group
2cac261d-c837-459a-961b-e63e36cc19ec
WGEEL
Joint EIFAAC/ICES Working Group on Eels
7c13a79e-7855-4d0b-b567-21300bcaaf9a
WGNAS
Working Group in North Atlantic Salmon
b5fd158e-b153-4e2e-a6da-c4b0536d684e
WKTRUTTA
NA
NA
2.3 Country (tr_country_cou)
Countries are mostly OK in the wgeel database but we need to add american countries. The shapefiles have been downloaded from https://gisco-services.ec.europa.eu/distribution/v2/countries/download/#countries source EuroGeographics and UN-FAO. Countries (Table 4) are ordered from North to South starting from the Baltic and ending in the Mediterranean, with American number being the highest in order.
SQL code to create table tr_country_cou
DROPTABLEIFEXISTSref.tr_country_cou;CREATETABLEref.tr_country_cou ( cou_code charactervarying(2) NOTNULL, cou_country text NOTNULL, cou_order integerNOTNULL, geom public.geometry, cou_iso3code charactervarying(3));COMMENTONTABLEref.tr_country_cou IS'Table of country codes source EuroGeographics and UN-FAO.';ALTERTABLEref.tr_country_cou OWNER TO diaspara_admin;GRANTSELECTONTABLEref.tr_country_cou TO diaspara_read;
Code to create table tr_country_cou from wgeel and NUTS.
dbExecute(con_diaspara_admin,"INSERT INTO ref.tr_country_cou SELECT * FROM refwgeel.tr_country_cou;") #40# Add some constraintsdbExecute(con_diaspara_admin, "ALTER TABLE ref.tr_country_cou ADD CONSTRAINT t_country_cou_pkey PRIMARY KEY (cou_code);")dbExecute(con_diaspara_admin, "ALTER TABLE ref.tr_country_cou ADD CONSTRAINT uk_cou_iso3code UNIQUE (cou_iso3code);")# missing values from America downloaded from https://gisco-services.ec.europa.eu/distribution/v2/nuts/download/ref-nuts-2024-01m.gdb.zip# uploaded to postgres# the tables# ref-countries-2024-01m — CNTR_RG_01M_2024_4326# have been copied to folder area ref-countries was renamed# ALTER TABLE area."ref-countries-2024-01m — CNTR_RG_01M_2024_4326" # RENAME TO "ref-countries-2024-01m-4326";dbExecute(con_diaspara_admin,"INSERT INTO ref.tr_country_cou ( cou_code, cou_country, cou_iso3code, geom, cou_order)SELECT \"CNTR_ID\" AS cou_code, \"NAME_ENGL\" AS cou_country, \"ISO3_CODE\"AS cou_isocode, geom,CASE WHEN \"CNTR_ID\" = 'GL' THEN 47 WHEN \"CNTR_ID\" = 'CA' THEN 48 ELSE 49 END AS cou_orderFROM area.\"ref-countries-2024-01m-4326\"WHERE \"CNTR_ID\" IN ('GL', 'CA', 'US');") #3# Svalbard et Jan Mayen SJM NO Territory dbExecute(con_diaspara_admin,"INSERT INTO ref.tr_country_cou ( cou_code, cou_country, cou_iso3code, geom, cou_order)SELECT \"CNTR_ID\" AS cou_code, \"NAME_ENGL\" AS cou_country, \"ISO3_CODE\"AS cou_isocode, geom,CASE WHEN \"CNTR_ID\" = 'GL' THEN 47 WHEN \"CNTR_ID\" = 'CA' THEN 48 ELSE 49 END AS cou_orderFROM area.\"ref-countries-2024-01m-4326\"WHERE \"CNTR_ID\" IN ('SJ');") #3dbExecute(con_diaspara_admin,"UPDATE ref.tr_country_cou SET geom = nuts.geom FROM area.\"ref-countries-2024-01m-4326\" nuts WHERE nuts.\"CNTR_ID\" = tr_country_cou.cou_code;") # 40
Code
tr_country_cou <-dbGetQuery(con_diaspara, "SELECT cou_code,cou_country,cou_order, cou_iso3code FROM ref.tr_country_cou order by cou_order")knitr::kable(tr_country_cou) |>kable_styling(bootstrap_options =c("striped", "hover", "condensed"))
Table 4: Country table in the diaspara DB
cou_code
cou_country
cou_order
cou_iso3code
IS
Iceland
0
ISL
NO
Norway
1
NOR
SE
Sweden
2
SWE
AX
Åland
3
ALA
FI
Finland
4
FIN
EE
Estonia
5
EST
LV
Latvia
6
LVA
LT
Lithuania
7
LTU
RU
Russia
8
RUS
PL
Poland
9
POL
CZ
Czech republic
10
CZE
DE
Germany
11
DEU
DK
Denmark
12
DNK
NL
Netherlands
13
NLD
BE
Belgium
14
BEL
LU
Luxembourg
15
LUX
IE
Ireland
16
IRL
GB
Great Britain
17
GBR
FR
France
18
FRA
ES
Spain
19
ESP
PT
Portugal
20
PRT
IT
Italy
21
ITA
MT
Malta
22
MLT
SI
Slovenia
23
SVN
HR
Croatia
24
HRV
BA
Bosnia-Herzegovina
25
BIH
ME
Montenegro
26
MNE
AL
Albania
27
ALB
GR
Greece
28
GRC
TR
Turkey
34
TUR
CY
Cyprus
35
CYP
SY
Syria
36
SYR
LB
Lebanon
37
LBN
IL
Israel
38
ISR
EG
Egypt
39
EGY
LY
Libya
40
LBY
TN
Tunisia
41
TUN
DZ
Algeria
42
DZA
MA
Morocco
43
MAR
VA
Vattican
46
VAT
GL
Greenland
47
GRL
CA
Canada
48
CAN
SJ
Svalbard and Jan Mayen
49
SJM
US
United States
49
USA
Code to create map from table in R
if (file.exists("data/country_sf.Rdata")) load("data/country_sf.Rdata") else { country_sf <- sf::st_read(con_diaspara,query ="SELECT cou_code, ST_MakeValid(geom) from ref.tr_country_cou") |> sf::st_transform(4326) save(country_sf, file="data/country_sf.Rdata")}#see here : https://stackoverflow.com/questions/70756215/#plot-geodata-on-the-globe-perspective-in-r# Note there is a problem of geometry for some of the polygons, and this require # ST_Makevalid before intersection# projection string used for the polygons & ocean backgroundcrs_string <-"+proj=ortho +lon_0=-30 +lat_0=30"# background for the globe - center buffered by earth radiusocean <- sf::st_point(x =c(0,0)) |> sf::st_buffer(dist =6371000) |> sf::st_sfc(crs = crs_string)country_sf2 <- country_sf |> sf::st_intersection(ocean |> sf::st_transform(4326)) |># select visible area only sf::st_transform(crs = crs_string) # reproject to ortho# now the action!g <-ggplot(data = country_sf2) +geom_sf(data = ocean, fill ="aliceblue", color =NA) +# background firstgeom_sf(aes(fill = cou_code), lwd = .1) +# now land over the oceansscale_fill_discrete(guide ="none") +theme_void()# this part is used to avoid long computationspng(filename="images/fig-country.png", bg="transparent")print(g)dev.off()
--DROP TABLE IF EXISTS ref.tr_units_uni CASCADE;CREATETABLEref.tr_units_uni ( uni_code varchar(20) NOTNULL, uni_description text NOTNULL, uni_icesvalue charactervarying(4), uni_icesguid uuid, uni_icestablesource text,CONSTRAINT t_units_uni_pkey PRIMARYKEY (uni_code),CONSTRAINT uk_uni_description UNIQUE (uni_description),CONSTRAINT uk_uni_icesguid UNIQUE (uni_icesguid),CONSTRAINT uk_uni_icesvalue UNIQUE (uni_icesvalue));GRANTALLONref.tr_units_uni TO diaspara_admin;GRANTSELECTONref.tr_units_uni TO diaspara_read; -- I don't add definitions this is an ICES vocab
Creating the unit from wgeel and checking ICES code
First we import from wgeel
Then we standarize using ICES codes, it takes a while to scroll through the vocab. Sometimes several vocab are available for the same thing. We used the p06 as the most common source. Hopefully that was the right choices ?
dbExecute(con_diaspara_admin,"INSERT INTO ref.tr_units_uni (uni_code, uni_description)SELECT * FROM refwgeel.tr_units_uni;")#25dbExecute(con_diaspara_admin, "UPDATE ref.tr_units_uni set uni_icesvalue='KGXX' where uni_code = 'kg';") dbExecute(con_diaspara_admin, "UPDATE ref.tr_units_uni set uni_icesvalue='MTON' where uni_code = 't';") dbExecute(con_diaspara_admin, "UPDATE ref.tr_units_uni set uni_icesvalue='UCNT' where uni_code = 'nr';") dbExecute(con_diaspara_admin, "UPDATE ref.tr_units_uni set uni_icesvalue='UGRM' where uni_code = 'g';")dbExecute(con_diaspara_admin, "UPDATE ref.tr_units_uni set uni_icesvalue='UPMS' where uni_code = 'nr/m2';")dbExecute(con_diaspara_admin, "UPDATE ref.tr_units_uni set uni_icesvalue='UPMM' where uni_code = 'nr/m3';")dbExecute(con_diaspara_admin, "UPDATE ref.tr_units_uni set uni_icesvalue='UYRS' where uni_code = 'nr year';")dbExecute(con_diaspara_admin, "UPDATE ref.tr_units_uni set uni_icesvalue='UXMM' where uni_code = 'mm';")dbExecute(con_diaspara_admin, "UPDATE ref.tr_units_uni set uni_icesvalue='NGPG' where uni_code = 'ng/g';")dbExecute(con_diaspara_admin, "UPDATE ref.tr_units_uni set uni_icesvalue='HCTR' where uni_code = 'ha';")dbExecute(con_diaspara_admin, "UPDATE ref.tr_units_uni set uni_icesvalue='UTAA' where uni_code = 'nr day';")dbExecute(con_diaspara_admin, "UPDATE ref.tr_units_uni set uni_icesvalue='NOPH' where uni_code = 'nr/h';")dbExecute(con_diaspara_admin, "UPDATE ref.tr_units_uni set uni_icesvalue='NGPG' where uni_code = 'ng/g';")dbExecute(con_diaspara_admin, "UPDATE ref.tr_units_uni set uni_icesvalue='UPCT' where uni_code = 'percent';")dbExecute(con_diaspara_admin, "UPDATE ref.tr_units_uni set (uni_icesvalue, uni_description)= ('XXXX', 'Not applicable (without unit)') where uni_code = 'wo';") dbExecute(con_diaspara_admin, "INSERT INTO ref.tr_units_uni VALUES ('year-1', 'Per year', 'XXPY');") dbExecute(con_diaspara_admin, "INSERT INTO ref.tr_units_uni VALUES ('s', 'Seconds', 'UTBB');")p06 <- icesVocab::getCodeList('p06')SamplingUnit <- icesVocab::getCodeList('SamplingUnit')MUNIT <- icesVocab::getCodeList('MUNIT')uni <-dbGetQuery(con_diaspara_admin, "SELECT * FROM ref.tr_units_uni;")tempuni <-inner_join(uni, p06, by=join_by(uni_icesvalue==Key))dbWriteTable(con_diaspara_admin, "tempuni", tempuni, overwrite=TRUE)dbExecute(con_diaspara_admin, "UPDATE ref.tr_units_uni set uni_icesguid = \"GUID\"::uuid FROM tempuni where tempuni.uni_icesvalue=tr_units_uni.uni_icesvalue;") #16dbExecute(con_diaspara_admin, "DROP TABLE tempuni;")dbExecute(con_diaspara_admin,"UPDATE ref.tr_units_uni set uni_icestablesource = 'p06' where uni_icesvalue IS NOT NULL ANDuni_icestablesource IS NULL;") # 16query <-sprintf("INSERT INTO ref.tr_units_uni (uni_code,uni_description, uni_icesvalue, uni_icestablesource,uni_icesguid) VALUES ('%s','%s','%s','%s','%s'::uuid);", "gd", "Gear days for fyke/trap nets","gd", "MUNIT","bf0570b7-45f2-41c7-9a46-de912a2b9ad4") dbExecute(con_diaspara_admin, query)dbExecute(con_diaspara_admin, "UPDATE ref.tr_units_uni set uni_icesvalue='idx', uni_icestablesource = 'MUNIT', uni_icesguid ='87a9cf7f-fff4-4712-b693-76eec1403254'::uuid where uni_code = 'index';")# p06[grep('Ton',p06$Description),c("Description","Key")] # p06[grep('Without',tolower(p06$Description)),c("Description","Key")] # p06[grep('nanogram',tolower(p06$Description)),c("Description","Key")]# p06[grep('index',tolower(p06$Description)),c("Description","Key")]# p06[grep('hour',tolower(p06$Description)),c("Description","Key")]# p06[grep('kilogram',tolower(p06$Description)),c("Description","Key")]# p06[grep('nanogram',tolower(p06$Description)),c("Description","Key")]# p06[grep('haul',tolower(p06$Description)),c("Description","Key")]dbExecute(con_diaspara_admin, "COMMENT ON TABLE ref.tr_units_uni IS 'Table of units, values from tables MUNIT and p06 have corresponding ICES code.'")dbExecute(con_diaspara_admin, "COMMENT ON COLUMN ref.tr_units_uni.uni_code IS 'Unit code, lowercase, nr number, otherwise standard units.'")dbExecute(con_diaspara_admin, "COMMENT ON COLUMN ref.tr_units_uni.uni_description IS 'Unit code, lowercase, nr number, otherwise standard units.'")dbExecute(con_diaspara_admin, "COMMENT ON COLUMN ref.tr_units_uni.uni_icesvalue IS 'ICES code standard from the British Oceanographic Data Centre (p06) or MUNIT table.';") dbExecute(con_diaspara_admin, "COMMENT ON COLUMN ref.tr_units_uni.uni_icestablesource IS 'Table source in ICES.';") dbExecute(con_diaspara_admin, "COMMENT ON COLUMN ref.tr_units_uni.uni_icesguid IS 'GUID, type https://vocab.ices.dk/?codetypeguid=<guidcode> to get access to the vocab in ICES.';") dbExecute(con_diaspara_admin, "GRANT ALL ON TABLE ref.tr_units_uni to diaspara_admin;")dbExecute(con_diaspara_admin, "GRANT SELECT ON TABLE ref.tr_units_uni to diaspara_read;")#for WGBAST#query <-sprintf("INSERT INTO ref.tr_units_uni (uni_code,uni_description, uni_icesvalue, uni_icestablesource,uni_icesguid) VALUES ('%s','%s','%s','%s','%s'::uuid);", "nd", "Net-days (fisheries)","nd", "MUNIT","f2783f1c-defa-4551-a9e3-1cfa173a0b9f") dbExecute(con_diaspara_admin, query)
Table 5: tr_units_uni table, check missing values currently not found in ICES Vocab
uni_code
uni_description
uni_icesvalue
uni_icesguid
uni_icestablesource
kg/d
kilogramme per day
NA
NA
NA
kg/boat/d
kilogramme per boat per day
NA
NA
NA
nr haul
number of haul
NA
NA
NA
nr electrofishing
number of electrofishing campain in the year to collect the recruitment index
NA
NA
NA
nr/haul
number per haul
NA
NA
NA
kg/ha
weight in kilogrammes per surface in hectare
NA
NA
NA
nr net.night
number of net and night
NA
NA
NA
nr fyke.day
number of fyke and day
NA
NA
NA
nr site
number of site
NA
NA
NA
nr/net/day
number per net and day
NA
NA
NA
kg
weight in kilogrammes
KGXX
c1361a50-86e2-412f-b41b-5f1a006fccb1
p06
t
weight in tonnes
MTON
4fc26258-9a01-48f9-8b17-3e20f7a38faa
p06
nr
number
UCNT
24eb2d51-8ee3-4e2e-a054-54d18db2d161
p06
g
gram
UGRM
f0f3c481-168b-4426-b63f-92614d325782
p06
nr/m2
number per square meter
UPMS
d482b028-598d-4266-a9df-81f565297734
p06
nr/m3
number per cubic meter
UPMM
a3314231-4d85-47c8-9615-20f7283f0389
p06
nr year
number of years
UYRS
b5da453a-51f3-46bb-bff2-0ae5a7a0db42
p06
mm
milimeter
UXMM
85d197e0-324c-4343-8314-2c934eca5315
p06
ha
Surface
HCTR
4d1a5474-67a8-46fe-98f9-82c405e025de
p06
nr day
number of days
UTAA
5571062f-f40f-49d9-8b13-8cdd8f9ed6d1
p06
nr/h
number per hour
NOPH
f9095fc1-bfee-40df-b289-e2850000dd26
p06
ng/g
nanogram per gram
NGPG
5ffd54a7-bc8d-4d00-9e60-e1554d57bd89
p06
percent
percentage
UPCT
355bd386-001b-40e8-bb7e-8515b7b737f4
p06
wo
Not applicable (without unit)
XXXX
896e5f8e-f467-49b5-97f3-f6df093a5293
p06
year-1
Per year
XXPY
a69c5e6b-789d-411c-86b3-70c3b89e8884
p06
s
Seconds
UTBB
9bc370c3-ff97-4dde-9e5c-3eba6074d224
p06
gd
Gear days for fyke/trap nets
gd
bf0570b7-45f2-41c7-9a46-de912a2b9ad4
MUNIT
index
calculated value following a specified protocol
idx
87a9cf7f-fff4-4712-b693-76eec1403254
MUNIT
nd
Net-days (fisheries)
nd
f2783f1c-defa-4551-a9e3-1cfa173a0b9f
MUNIT
Some of the values are missing from ICES vocab (Table Table 5).
QUESTION ICES: missing values for units, what do we do ?
What do we do with units without correspondance? These come from FAO (if I remember well). Do we try to search for those in the wgeel database, and then remove if not existing or try to change existing values ?
Kg/day there is a kg/hour do we need to change to that type and convert existing series ?
Nr haul There is a definition of haul in the ICES vocab but it seems very related to sampling box, basket. And it’s not the number of haul.
Before working any further I would like your opinion there.
2.5 Parameters
Parameters are a simple way to reduce the complexity of data. It will correspond to all nimble variables, reduced to their lower level (e.g. 3 dimensional arrays with dimensions [area, year, stage] will be translated as many lines with the corresponding values in columns area, year, and stage), and the identifyer of the variable will be used for all the lines necessary to store this dataset. In practise, parameters also correspond to input data, and output data in the model. The parameters will be described by their metadata as illustrated in Figure 3
Figure 3: Mind map of the metadata structure
We can have a look at the metadata in the analysis done on the WGNAS database WGNAS description.
There is a problem in the “order or the dimensions which need to be aligned. For instance a column can hold year, or age. This is not good. The description could be used within a type array. SQL server does not work with array so it’s not a good idea to use those.
Checking stock codes using icesASD and icesSD packages
Table 6: Access to the advice using icesAdvice
# install.packages('icesAdvice', repos = c('https://ices-tools-prod.r-universe.dev', 'https://cloud.r-project.org'))#install.packages("icesSD", repos = c("https://ices-tools-prod.r-universe.dev", "https://cloud.r-project.org"))library('icesAdvice')library('icesSAG')library('icesSD')# this does not give the advice <-getAdviceViewRecord()advice[grepl('ele',advice$stockCode),c('adviceDOI', 'stockCode','assessmentyear')] |> kablesd <-mapply(getSD, year=2020:2024, SIMPLIFY=FALSE)sd <-do.call(rbind,sd)ww <-grepl('ele',sd$StockKeyLabel) |grepl('Salmo',sd$speciesScientificName)sd[ww,] |>kable()
DIASPARA
Not yet completely sure about this …. Environment (sea, transition …), age, life stage and complex are in the metadata. But they are also in the main table. To start with, we remove them to reduce complexity and avoid errors. The complex will be derived from the spatial structure still in construction
DIASPARA
As in the diagram, added a category (data type in figure Figure 3). The idea is to be able to get quickly all parameters related to a type, e.g. catch, mortality, biomass. Please check and also check definitions.
DIASPARA
WGBAST, WGNAS, WGEEL, WGTRUTTA will have to check definitions in tr_destination_dest. Note this is just a column in t_metadata_met not in the main table. Check if it could not simply be removed if the definition of the parameter is clear ?
DROPTABLEIFEXISTSref.tr_objecttype_oty CASCADE;CREATETABLEref.tr_objecttype_oty (oty_code TEXT PRIMARYKEY,oty_description TEXT);INSERTINTOref.tr_objecttype_oty VALUES ('Single_value', 'Single value');INSERTINTOref.tr_objecttype_oty VALUES ('Vector', 'One dimension vector');INSERTINTOref.tr_objecttype_oty VALUES ('Matrix', 'Two dimensions matrix');INSERTINTOref.tr_objecttype_oty VALUES ('Array', 'Three dimensions array');COMMENTONTABLEref.tr_objecttype_oty IS'Table indicating the dimensions of the object stored in the model, single value, vector, matrix, array';COMMENTONCOLUMNref.tr_objecttype_oty.oty_code IS'code of the object type, single_value, vector, ...';COMMENTONCOLUMNref.tr_objecttype_oty.oty_code IS'description of the object type';GRANTALLONref.tr_objecttype_oty TO diaspara_admin;GRANTSELECTONref.tr_objecttype_oty TO diaspara_read;
Table 7: Object type
oty_code
oty_description
Single_value
Single value
Vector
One dimension vector
Matrix
Two dimensions matrix
Array
Three dimensions array
2.7 Type of parm / data (tr_nimble_nim)
In the salmoglob db, this table (Table 8) corresponded to both tables status and nimble which most often contained the same information.
SQL code to create tables
--nimbleDROPTABLEIFEXISTSref.tr_nimble_nim CASCADE;CREATETABLEref.tr_nimble_nim (nim_code TEXT PRIMARYKEY,nim_description TEXT);COMMENTONTABLEref.tr_nimble_nim IS'Indicate the type of data, parameter constant, parameter estimate, output, other ...';-- Note this is a mix of nimble and status, which mean the same....INSERTINTOref.tr_nimble_nim VALUES ('Data', 'Data entry to the model');INSERTINTOref.tr_nimble_nim VALUES ('Parameter constant', 'Parameter input to the model');INSERTINTOref.tr_nimble_nim VALUES ('Parameter estimate', 'Parameter input to the model');INSERTINTOref.tr_nimble_nim VALUES ('Output', 'Output from the model, derived quantity');-- Do we want another type here ?--INSERT INTO ref.tr_nimble_nim VALUES ('observation', 'Observation not used in the model');INSERTINTOref.tr_nimble_nim VALUES ('Other', 'Applies currently to conservation limits');GRANTALLONref.tr_nimble_nim TO diaspara_admin;GRANTSELECTONref.tr_nimble_nim TO diaspara_read;
Table 8: Nimble
nim_code
nim_description
Data
Data entry to the model
Parameter constant
Parameter input to the model
Parameter estimate
Parameter input to the model
Output
Output from the model, derived quantity
Other
Applies currently to conservation limits
2.8 Version (tr_version_ver)
Currently in the salmoglob metadata there is no information about version. The version number is in the table itself. It seems to correspond to different versions of the same parameter. While currently this information is stored in the database and database_archive it seems to that metadata should also contain information about historical variables. For instance we create a new variable, so we know when it was introduced. So in addition with the data in the main table I’m adding a version number to metadata, Some variables might get deprecated over time. The year will be the year when the variable was introduced. All variables in this version of the DB in metadata will start with SAL-2024-1, the tr_version_ver should be able to store a version number but currently I need to understand to what it corresponds.
Note that the version (Table 9) contains both reference to the datacall (when data are loaded) and to the advice. The advice might still be null at the time the values will be entered into the database. The version will be handled in inherited tables for WGNAS, WGEEL and WGBAST. Here I’m currently entering the WGNAS data.
Question to WNGAS
Check that this is correct, original values in the table metadata were “Const_nimble” “Data_nimble” “Output” “other”
Answer WGNAS (Pierre-Yves Hernvann)
The version number are related to variables, each time they are changed a new variable number is created in metadata by the shiny and the date is set, so we can keep track of the variables. There is also an information on who did the change (not accessible to the public). Pierre Yves agrees that saving the database at each working group is probably the best way to re-run the model at that stage.
TODO
The DB will be held in ICES server. Create a procedure to save the database at each working group to be able to run past versions of the model.
SQL code to create tables
-- It seems to me that metadata should contain information about historical -- variables, so I'm moving this from the main table and adding to metadata-- some variables might get deprecated in time. -- Unless they get a new version this might not change-- I have removed reference to stockkey as there are several stock keys-- for the work of WGNASDROPTABLEIFEXISTSref.tr_version_ver CASCADE;CREATETABLEref.tr_version_ver(ver_code TEXT PRIMARYKEY,ver_year INTEGERNOTNULL,ver_spe_code CHARACTERVARYING(3),CONSTRAINT fk_ver_spe_code FOREIGNKEY (ver_spe_code) REFERENCESref.tr_species_spe(spe_code)ONUPDATECASCADEONDELETERESTRICT,ver_wkg_code TEXT NOTNULL,CONSTRAINT fk_ver_wkg_code FOREIGNKEY (ver_wkg_code)REFERENCESref.tr_icworkinggroup_wkg(wkg_code)ONUPDATECASCADEONDELETERESTRICT,--ver_stockkey INTEGER NOT NULL, ver_stockkeylabel TEXT,---ver_stockadvicedoi TEXT NOT NULL,ver_datacalldoi TEXT NULL,ver_version INTEGERNOTNULL,ver_description TEXT);COMMENTONTABLEref.tr_version_verIS'Table of data or variable version, essentially one datacall or advice.';COMMENTONCOLUMNref.tr_version_ver.ver_code IS'Version code, stockkey-year-version.';COMMENTONCOLUMNref.tr_version_ver.ver_year IS'Year of assessement.';COMMENTONCOLUMNref.tr_version_ver.ver_spe_code IS'Species code e.g. ''ANG'' or ''SAL,TRT'' the reference name should be in tr_species_spe, comma separated';COMMENTONCOLUMNref.tr_version_ver.ver_wkg_code IS'Code of the working group, one of WGBAST, WGEEL, WGNAS, WKTRUTTA';--COMMENT ON COLUMN ref.tr_version_ver.ver_stockkey --IS 'Stockkey (integer) from the stock database.';COMMENTONCOLUMNref.tr_version_ver.ver_stockkeylabel IS'Ver_stockkeylabel e.g. ele.2737.nea.';--COMMENT ON COLUMN ref.tr_version_ver.ver_stockadvicedoi --IS 'Advice DOI corresponding to column adviceDOI --when using icesASD::getAdviceViewRecord().';COMMENTONCOLUMNref.tr_version_ver.ver_datacalldoi IS'Data call DOI, find a way to retreive that information and update this comment';COMMENTONCOLUMNref.tr_version_ver.ver_version IS'Version code in original database, eg 2,4 for wgnas, dc_2020 for wgeel.';COMMENTONCOLUMNref.tr_version_ver.ver_description IS'Description of the data call / version.';GRANTALLONref.tr_version_ver TO diaspara_admin;GRANTSELECTONref.tr_version_ver TO diaspara_read;-- we need to allow several species separated by a comma (several species for a working group)-- the ALTERTABLEref.tr_version_ver DROPCONSTRAINT fk_ver_spe_code;ALTERTABLE refnas.tr_version_ver DROPCONSTRAINT fk_ver_spe_code;ALTERTABLE refeel.tr_version_ver DROPCONSTRAINT fk_ver_spe_code;ALTERTABLEref.tr_version_ver ALTERCOLUMN ver_spe_code type TEXT;
Code to insert values into the tr_version_ver table
#sd <-do.call(rbind,mapply(icesSD::getSD, year= 2020:2024, SIMPLIFY=FALSE))#sd[grepl('Working Group on North Atlantic Salmon',sd$ExpertGroupDescription),]tr_version_ver <-data.frame(ver_code =paste0("WGNAS-",2020:2024,"-1"),ver_year =2020:2024,ver_spe_code ="SAL",ver_wkg_code ="WGNAS",ver_datacalldoi=c(NA,NA,NA,NA,"https://doi.org/10.17895/ices.pub.25071005.v3"), ver_stockkeylabel =c("sal.neac.all"), # sugested by Hilaire. # TODO FIND other DOI (mail sent to ICES)ver_version=c(1,1,1,1,1), # TODO WGNAS check that there is just one version per yearver_description=c(NA,NA,NA,NA,NA)) # TODO WGNAS provide model descriptionDBI::dbWriteTable(con_diaspara_admin, "temp_tr_version_ver", tr_version_ver, overwrite =TRUE)dbExecute(con_diaspara_admin, "INSERT INTO refnas.tr_version_ver(ver_code, ver_year, ver_spe_code, ver_stockkeylabel, ver_datacalldoi, ver_version, ver_description, ver_wkg_code) SELECT ver_code, ver_year, ver_spe_code, ver_stockkeylabel, ver_datacalldoi, ver_version::integer, ver_description, ver_wkg_code FROM temp_tr_version_ver;") # 5DBI::dbExecute(con_diaspara_admin, "DROP TABLE temp_tr_version_ver;")
Question to WNGAS / ICES
Check there is just one version per year
Provide descriptions of the version of the model
Questions sent to ICES to provide access to historical DOI
Exchanges currently on this (17/03/2025) with Etienne / Pierre Yves Hernvann
Table 9: Version
ver_code
ver_year
ver_spe_code
ver_stockkeylabel
ver_datacalldoi
ver_version
ver_description
ver_wkg_code
WGNAS-2020-1
2020
SAL
NA
sal.neac.all
1
NA
WGNAS
WGNAS-2021-1
2021
SAL
NA
sal.neac.all
1
NA
WGNAS
WGNAS-2022-1
2022
SAL
NA
sal.neac.all
1
NA
WGNAS
WGNAS-2023-1
2023
SAL
NA
sal.neac.all
1
NA
WGNAS
WGNAS-2024-1
2024
SAL
https://doi.org/10.17895/ices.pub.25071005.v3
sal.neac.all
1
NA
WGNAS
WGEEL-2025-2
2025
ANG
ele
https://doi.org/10.17895/ices.pub.29254589
2
WGEEL Data call 2025: Joint ICES/GFCM/EIFAAC eel data call
WGEEL
WGEEL-2016-1
2016
ANG
ele
1
Joint EIFAAC/GFCM/ICES Eel Data Call 2016
WGEEL
WGEEL-2017-2
2017
ANG
ele
ele
2
Joint ICES, EIFAAC and GFCM Data Call: Data submission for advice for European eel under WGEEL – Part 2: 2018
WGEEL
WGEEL-2017-1
2017
ANG
ele
ele
1
Data provided by wgeel 2016
WGEEL
WGEEL-2018-1
2018
ANG
ele
ele
1
Data provided by wgeel 2017
WGEEL
WGEEL-2019-1
2019
ANG
ele
ele
1
Joint EIFAAC/GFCM/ICES Eel Data Call 2019
WGEEL
WGEEL-2020-1
2020
ANG
ele
ele
1
Joint EIFAAC/GFCM/ICES Eel Data Call 2020
WGEEL
WGEEL-2021-1
2021
ANG
ele
ele
1
Joint EIFAAC/GFCM/ICES Eel Data Call 2021
WGEEL
WGEEL-2022-1
2022
ANG
ele
ele
1
Joint EIFAAC/GFCM/ICES Eel Data Call 2022
WGEEL
WGEEL-2023-1
2023
ANG
ele
ele
1
Joint EIFAAC/GFCM/ICES Eel Data Call 2023
WGEEL
WGEEL-2024-1
2024
ANG
https://doi.org/10.17895/ices.pub.25816738.v2
https://doi.org/10.17895/ices.pub.25816738.v2
1
Joint EIFAAC/GFCM/ICES Eel Data Call 2024
WGEEL
WGEEL-2025-1
2025
ANG
https://doi.org/10.17895/ices.pub.25816738.v2
https://doi.org/10.17895/ices.pub.25816738.v2
1
WKEMP 2025 special request
WGEEL
WGBAST-2024-1
2024
NA
sal.27.22–31
https://doi.org/10.17895/ices.pub.25071005.v3
1
Joint ICES Fisheries Data call for landings, discards, biological and effort data and other supporting information in support of the ICES fisheries advice in 2024.
WGBAST
WGBAST-2025-1
2025
NA
sal.27.22–31
https://doi.org/10.17895/ices.pub.28218932.v2
1
Combined ICES Fisheries Data call for landings, discards, biological and effort data and other supporting information in support of the ICES fisheries advice in 2025.
WGBAST
QUESTION ICES: What is the vocabulary for datacalls
I would like to access to this table : datacall (see link in ICES webpage). Currently we see the current year, this is nice, how do we access to historical data, is there a way to get it using a query ? We’ve found a link for advice or stocks but not data calls.
2.9 Metric (tr_metric_mtr)
SQL code to create tables
-- metric DROPTABLEIFEXISTSref.tr_metric_mtr CASCADE;CREATETABLEref.tr_metric_mtr(mtr_code TEXT PRIMARYKEY,mtr_description TEXT);INSERTINTOref.tr_metric_mtr VALUES('Estimate' , 'Estimate');INSERTINTOref.tr_metric_mtr VALUES('Index', 'Index');INSERTINTOref.tr_metric_mtr VALUES('Bound', 'Either min or max');INSERTINTOref.tr_metric_mtr VALUES('Hyperparameter', 'Hyperparameter (prior)');INSERTINTOref.tr_metric_mtr VALUES('SD', 'Standard deviation');INSERTINTOref.tr_metric_mtr VALUES('CV', 'Coefficient of variation');INSERTINTOref.tr_metric_mtr VALUES('Precision', 'Inverse of variance');INSERTINTOref.tr_metric_mtr VALUES('Mean', 'Mean');INSERTINTOref.tr_metric_mtr VALUES('Min','Minimum');INSERTINTOref.tr_metric_mtr VALUES('Max','Maximum');GRANTALLONref.tr_metric_mtr TO diaspara_admin;GRANTSELECTONref.tr_metric_mtr TO diaspara_read;COMMENTONTABLEref.tr_metric_mtr IS'Table metric describe the type of parm used, Index, Bound ...';
Table 10: Metric, type of parm used in the model
mtr_code
mtr_description
Estimate
Estimate
Index
Index
Bound
Either min or max
Hyperparameter
Hyperparameter (prior)
SD
Standard deviation
CV
Coefficient of variation
Precision
Inverse of variance
Mean
Mean
Min
Minimum
Max
Maximum
NOTE
This list is probably incomplete. But the metric can be NULL in case of a number of fish released, not of the above (Table 10) will apply.
2.10 Category (tr_category_cat)
categories Table 11 were in the salmoglob metadata, we have simplified to reduce the number of categories and be able to get for instance all parameters dealing with catch.
SQL code to create tables
-- tr_category_catDROPTABLEIFEXISTSref.tr_category_cat CASCADE;CREATETABLEref.tr_category_cat (cat_code TEXT PRIMARYKEY,cat_description TEXT);INSERTINTOref.tr_category_cat VALUES('Catch', 'Catch, including recreational and commercial catch.');INSERTINTOref.tr_category_cat VALUES ('Effort', 'Parameter measuring fishing effort.');INSERTINTOref.tr_category_cat VALUES ('Biomass', 'Biomass of fish either in number or weight.');INSERTINTOref.tr_category_cat VALUES ('Mortality', 'Mortality either expressed in year-1 (instantaneous rate) as F in exp(-FY) but can also be harvest rate.');INSERTINTOref.tr_category_cat VALUES ('Release', 'Release or restocking.');INSERTINTOref.tr_category_cat VALUES ('Density', 'Fish density.');INSERTINTOref.tr_category_cat VALUES ('Count', 'Count or abundance or number of fish.');INSERTINTOref.tr_category_cat VALUES ('Conservation limit', 'Limit of conservation in Number or Number of eggs.');INSERTINTOref.tr_category_cat VALUES ('Life trait', 'Life trait parameterized in model, e.g. growth parameter, fecundity rate ...');INSERTINTOref.tr_category_cat VALUES ('Other', 'Other variable/ parameter used in the model other than the previous categories, origin distribution of catches, proportions, parameters setting the beginning and ending dates....');COMMENTONTABLEref.tr_category_cat IS'Broad category of data or parameter, catch, effort, biomass, mortality, count ..., more details in the table ref.tr_parameter_parm e.g. commercial catch,recreational catch are found in the parameter value and definition and unit, this list is intended to be short.';GRANTALLONref.tr_category_cat TO diaspara_admin;GRANTSELECTONref.tr_category_cat TO diaspara_read;
Table 11: category of parameters
cat_code
cat_description
Catch
Catch, including recreational and commercial catch.
Effort
Parameter measuring fishing effort.
Biomass
Biomass of fish either in number or weight.
Mortality
Mortality either expressed in year-1 (instantaneous rate) as F in exp(-FY) but can also be harvest rate.
Release
Release or restocking.
Density
Fish density.
Count
Count or abundance or number of fish.
Conservation limit
Limit of conservation in Number or Number of eggs.
Life trait
Life trait parameterized in model, e.g. growth parameter, fecundity rate ...
Other
Other variable/ parameter used in the model other than the previous categories, origin distribution of catches, proportions, parameters setting the beginning and ending dates...
2.11 Destination (tr_destination_dest)
A bit cumbersome this table, the idea is “what becomes of this fish”. Different types of landings. But it’s just in metatdata and we need need in WGBAST
SQL code to create tables
-- table ref.tr_destination_desDROPTABLEIFEXISTSref.tr_destination_des CASCADE;CREATETABLEref.tr_destination_des (des_code TEXT PRIMARYKEY,des_description TEXT);COMMENTONTABLEref.tr_destination_des IS'Table of fish destination. When dealing with fish, e.g. in landings,what is the future of the fish, e.g. Released (alive), Seal damage, Removed (from the environment)'; INSERTINTOref.tr_destination_des VALUES('Removed', 'Removed from the environment, e.g. caught and kept');INSERTINTOref.tr_destination_des VALUES ('Seal damaged', 'Seal damage');INSERTINTOref.tr_destination_des VALUES ('Discarded', 'Discards');INSERTINTOref.tr_destination_des VALUES ('Released', 'Released alive');INSERTINTOref.tr_destination_des VALUES ('Released ', 'Released alive');GRANTALLONref.tr_destination_des TO diaspara_admin;GRANTSELECTONref.tr_destination_des TO diaspara_read;
Table 12: category of parameters
des_code
des_description
Removed
Removed from the environment, e.g. caught and kept
Seal damaged
Seal damage
Discarded
Discards
Released
Released alive
NOTE DIASPARA
Here Hilaire say that naming the table “outcome” wasn’t ideal so I’ve followed his suggestion
2.12 Area (tr_area_are)
This table will be created further in the habitat repository… But here we are laying out the foundations. Not assessment unit correpsond to ‘Unit’ level in the for the Baltic.
2.12.1 Habitat level (tr_habitatlevel_lev)
SQL code to create tables
--DROP TABLE IF EXISTS ref.tr_habitatlevel_lev CASCADE;CREATETABLEref.tr_habitatlevel_lev( lev_code TEXT PRIMARYKEY, lev_description TEXT );COMMENTONTABLEref.tr_habitatlevel_lev IS'Table of geographic levels stock, complex, country, region, basin, river,the specific order depend according to working groups.';GRANTALLONref.tr_habitatlevel_lev TO diaspara_admin;GRANTSELECTONref.tr_habitatlevel_lev TO diaspara_read;
Code to fill in tr_habitatlevel_lev
dbExecute(con_diaspara_admin,"INSERT INTO ref.tr_habitatlevel_lev VALUES( 'Panpopulation', 'This is the highest geographic level for assessement.' );")dbExecute(con_diaspara_admin,"INSERT INTO ref.tr_habitatlevel_lev VALUES( 'Complex', 'Corresponds to large sublevels at which the Panpopulation is assessed, e.g. NAC NEC for WGNAST, Gulf of Bothnia for WGBAST, Mediterranean for WGEEL.' );")dbExecute(con_diaspara_admin,"INSERT INTO ref.tr_habitatlevel_lev VALUES( 'Stock', 'Correspond to stock units for which advices are provided in ICES, this can be the level of the panpopulation, or another level e.g. .' );")dbExecute(con_diaspara_admin,"INSERT INTO ref.tr_habitatlevel_lev VALUES( 'Country', 'Corresponds to one or more units, but in almost all stocks this level is relevant to split data.' );")dbExecute(con_diaspara_admin,"INSERT INTO ref.tr_habitatlevel_lev VALUES( 'EMU', 'Administrative unit for eel, the hierarchical next level is country.' );")# note this can be unit or Asssessment unit it can have two meanings ...dbExecute(con_diaspara_admin,"INSERT INTO ref.tr_habitatlevel_lev VALUES( 'Assessment_unit', 'Corresponds to an assessment unit in the Baltic sea, and area for WGNAS, and EMU for WGEEL.' );")dbExecute(con_diaspara_admin,"INSERT INTO ref.tr_habitatlevel_lev VALUES( 'Regional', 'Corresponds to subunits of stock assessment units or basins grouping several river. Although it is not used yet for some models, regional genetic difference or difference in stock dynamic support collecting a regional level.' );")dbExecute(con_diaspara_admin,"INSERT INTO ref.tr_habitatlevel_lev VALUES( 'River', 'One river is a unit corresponding practically almost always to a watershed.' );")dbExecute(con_diaspara_admin,"INSERT INTO ref.tr_habitatlevel_lev VALUES( 'River_section', 'Section of river, only a part of a basin, for instance to separate between wild and mixed river category in the Baltic.' );")dbExecute(con_diaspara_admin,"INSERT INTO ref.tr_habitatlevel_lev VALUES( 'Major', 'Major fishing areas from ICES.' );")dbExecute(con_diaspara_admin,"INSERT INTO ref.tr_habitatlevel_lev VALUES( 'Subarea', 'Subarea from ICES, FAO and NAFO' );")dbExecute(con_diaspara_admin,"INSERT INTO ref.tr_habitatlevel_lev VALUES( 'Division', 'Division from ICES, GFCM and NAFO' );")dbExecute(con_diaspara_admin,"INSERT INTO ref.tr_habitatlevel_lev VALUES( 'Subdivision', 'Subdivision level from ICES, GFCM and NAFO' );")dbExecute(con_diaspara_admin,"INSERT INTO ref.tr_habitatlevel_lev VALUES( 'Lagoons', 'Shallow body of water seperated from a larger body of water by a narrow landform' );")dbExecute(con_diaspara_admin,"INSERT INTO ref.tr_habitatlevel_lev VALUES( 'Subdivision_grouping', 'Groups of subdivision from ICES used in the Baltic' );")dbExecute(con_diaspara_admin,"UPDATE ref.tr_habitatlevel_lev SET lev_description='Corresponds to an assessment unit in the Baltic sea, and area for WGNAS, and EMU for WGEEL.' WHERE lev_code='Assessment_unit'"); # remove spaces ...
Table 13: Geographical level tr_habitatlevel_lev
lev_code
lev_description
Stock
This is the highest geographic level for assessement, stock level.
Complex
Corresponds to large sublevels at which the stock is assessed, e.g. NAC NEC for WGNAST, Gulf of Bothnia for WGBAST, Mediterranean for WGEEL.
Country
Corresponds to one or more units, but in almost all stocks this level is relevant to split data.
Assessment_unit
Corresponds to an assessment unit in the Baltic sea, and area for WGNAS, and EMU for WGEEL.
Regional
Corresponds to subunits of stock assessment units or basins grouping several river. Although it is not used yet for some models, regional genetic difference or difference in stock dynamic support collecting a regional leve
River
One river is a unit corresponding practically almost always to a watershed.
Major
Major fishing areas from ICES.
Subarea
Subarea from ICES, FAO and NAFO
Division
Division from ICES, GFCM and NAFO
Subdivision
Subdivision level from ICES, GFCM and NAFO
Fisheries
Specific fisheries area used by some working groups (WGNAS), e.g. FAR fishery, GLD fishery, LB fishery, LB/SPM/swNF fishery, neNF fishery
EMU
Administrative unit for eel, the hierarchical next level is country.
River_section
Section of river, only a part of a basin, for instance to separate between wild and mixed river category in the Baltic.
Subdivision_grouping
Groups of subdivision from ICES used in the Baltic
2.12.2 Area (tr_area_are)
SQL code to create tables
--DROP TABLE IF EXISTS ref.tr_area_are CASCADE;CREATETABLEref.tr_area_are ( are_id INTEGERPRIMARYKEY, are_are_id INTEGER, are_code TEXT, are_lev_code TEXT, are_wkg_code TEXT, are_ismarine BOOLEAN, are_name TEXT, geom_polygon geometry(MULTIPOLYGON, 4326), geom_line geometry(MULTILINESTRING, 4326),CONSTRAINT fk_are_are_id FOREIGNKEY (are_are_id) REFERENCESref.tr_area_are (are_id) ONDELETECASCADEONUPDATECASCADE,CONSTRAINT uk_are_code UNIQUE (are_code),CONSTRAINT fk_area_lev_code FOREIGNKEY (are_lev_code) REFERENCESref.tr_habitatlevel_lev(lev_code) ONUPDATECASCADEONDELETECASCADE,CONSTRAINT fk_area_wkg_code FOREIGNKEY (are_wkg_code) REFERENCESref.tr_icworkinggroup_wkg(wkg_code) ONUPDATECASCADEONDELETECASCADE);GRANTALLONref.tr_area_are TO diaspara_admin;GRANTSELECTONref.tr_area_are TO diaspara_read;COMMENTONTABLEref.tr_area_are IS'Table corresponding to different geographic levels, from stock to river section.');-- we need to rename the column (fix 16/10/2025)ALTERTABLE"ref".tr_area_are RENAMECOLUMN are_rivername TO are_name;
Note from Hilaire
The working groups might change over time, referencing a working group there is probably not the best. Cédric : Added stockkeylabel, this table is necessary to aggregate data (species is not enough).
Table 14: Geographic areas
are_id
are_are_id
are_code
are_lev_code
are_wkg_code
are_ismarine
306
17
2120027350
River
WGBAST
FALSE
3099
174
20127557
River_section
WGBAST
FALSE
3086
174
20127414
River_section
WGBAST
FALSE
3088
174
20127330
River_section
WGBAST
FALSE
15
3
3 Bothnian Sea
Assessment_unit
WGBAST
FALSE
17
3
5 Eastern Main Basin
Assessment_unit
WGBAST
FALSE
18
3
6 Gulf of Finland
Assessment_unit
WGBAST
FALSE
13
3
1 Northeastern Bothnian Bay
Assessment_unit
WGBAST
FALSE
14
3
2 Western Bothnian Bay
Assessment_unit
WGBAST
FALSE
16
3
4 Western Main Basin
Assessment_unit
WGBAST
FALSE
Figure 4: The nested structure layed out in table tr_area_area, dotted box indicate that the level is optional. This table will be created specifically for each group.
2.13 Data access (tr_dataaccess_dta)
Type of data Public, or Restricted
SQL code to create tables
--DROP TABLE IF EXISTS ref.tr_dataaccess_dta CASCADE;CREATETABLEref.tr_dataaccess_dta( dta_code TEXT PRIMARYKEY, dta_description TEXT );GRANTALLONref.tr_dataaccess_dta TO diaspara_admin;GRANTSELECTONref.tr_dataaccess_dta TO diaspara_read;COMMENTONTABLEref.tr_dataaccess_dta IS'Table with two values, Public or Restricted access.';
Code to create dataaccess tr_dataaccess_dta
tr_dataaccess_dta <-dbGetQuery(con_diaspara_admin, "SELECT * FROM refwgeel.tr_dataaccess_dta")dbExecute(con_diaspara_admin,"INSERT INTO ref.tr_dataaccess_dta SELECT * FROM refwgeel.tr_dataaccess_dta ;")#2
2.14 Missing data (tr_missvalueqal_mis)
SQL code to create tables
--DROP TABLE IF EXISTS ref.tr_missvalueqal_mis CASCADE;CREATETABLEref.tr_missvalueqal_mis( mis_code TEXT PRIMARYKEY, mis_description TEXT NOTNULL, mis_definition TEXT);GRANTALLONref.tr_missvalueqal_mis TO diaspara_admin;GRANTSELECTONref.tr_missvalueqal_mis TO diaspara_read;COMMENTONTABLEref.tr_missvalueqal_mis IS'Table showing the qualification when value is missing, NC, NP, NR.';
This comes from wgeel.
Code to create tr_missvalueqal_mis
dbExecute(con_diaspara_admin,"INSERT INTO ref.tr_missvalueqal_mis SELECT'NR','Not reported', 'Data or activity exist but numbers are not reported to authorities (for example for commercial confidentiality reasons).';")dbExecute(con_diaspara_admin,"INSERT INTO ref.tr_missvalueqal_mis SELECT'NC', 'Not collected', 'Activity / habitat exists but data are not collected by authorities (for example where a fishery exists but the catch data are not collected at the relevant level or at all).';")dbExecute(con_diaspara_admin,"INSERT INTO ref.tr_missvalueqal_mis SELECT'NP', 'Not pertinent','Where the question asked does not apply to the individual case (for example where catch data are absent as there is no fishery or where a habitat type does not exist in a stock unit).';")
Table 15: Code for missing values
mis_code
mis_description
mis_definition
NR
Not reported
Data or activity exist but numbers are not reported to authorities (for example for commercial confidentiality reasons).
NC
Not collected
Activity / habitat exists but data are not collected by authorities (for example where a fishery exists but the catch data are not collected at the relevant level or at all).
NP
Not pertinent
Where the question asked does not apply to the individual case (for example where catch data are absent as there is no fishery or where a habitat type does not exist in a stock unit).
2.15 Life stages (tr_lifestage_lfs)
Life stages cannot easily be shared among all species, they are species specific, probably similar between Sea trout and Salmon, but there is a large gap between a leptocephalus and a parr.
Creating a life stage referential is a challenging issue that will require inputs from the working groups for validation.
2.15.1 Considerations about the database structure
For life stage, unlike in other referentials, using working group specific life stage would lead to confusion. WGBAST and WGNAS would share the same stages for salmon. So unlike in many other table, the referentials will not use inheritance (see paragraph Section 1 for more details on inheritance). This means that we will create a table grouping all life stages and then we will only select the relevant ones at working group levels. For instance currently WGEEL does not use the Egg or Parr stages. It will be listed in the ref.tr_lifestage_lfs table but not in the refeel.tr_lifestage_lfs table. So the working group referentials, refnas, refbast, refeel … will have tr_lifestage_lfs tables with a foreign key to ref.tr_lifestage_lfs, and a subset of values used by the working group.
2.15.2 The lifestages in working group databases
The creation of life stage is discussed in the issue 16 in git github link to issue
Currently the stage is used by WGEEL and not by WGNAS or WGBAST landings data. For WGBAST it is used to describe the numbers release from hatchery at various stages. Spatial information, and information about the age are used to split the dataset, not the stage. We have two solutions : 1 / ignore the stage for WGBAST and WGNAS and only have the stage as a new column in the wgeel database when the inherited table is created. 2/ Add it everywhere and populate the column using the metadata (which should not be too hard) but with no practical use in the table since the information is not used currently. Our preference would go for the second because having a single data structure should make the common shiny development more easy, what do you think ?
Answer from Etienne (WGNAS)
Yes, we could probably live with an additional maturity column, I don’t think their is any big issues with this.
2.15.3 Use of lifestages to include other information
The different steps in the models are identified using spatio temporal units and stages (e.g; post smolt and location at sea) ICES (2024a), a location and stage to descibe the different steps in the return migration (for instance returning adult in seawater, in freshwater…). Some of the elements added in the stage column are not stage per-se, but elements used to describe the spatio-temporal elements within the life-cycle, for instance the use PFA (pre-fishery-abundance) which correspond to the number at sea of different stages before fishery. Note that this parameter is no longer used, that is, it’s in the metadata but the variable in metadata are no longer in the database (this stands for logN4, N4, logit_theta4, tau_theta4, theta4). To deal with these spatio temporal elements that are not stage, we will simplify the stages table, remove elements which are not stages, and still refer to spatio temporal parameters from their definition. Here we are focusing on the stock DB which will group information, but the individual metric database might require more details that the simple adult stage. For this reason, we will add the maturity scale from ICES in the DB.
2.15.4 Adding a bit more complexity with the eel
In some cases mixture of stages are used. Many fyke net fisheries for eel will not distinguish between yellow and silver eel stage and WGEEL uses the YS stage. Some historical trap series did not distinguish between small yellow eels and glass eel, or the glass eel ascending are in a late stage. In that case the GYstage is used to count the recruits.
QUESTION TO WGEEL
The new database will have to include a source WILD/HATCHERY/AQUACULTURE shouldn’t we use that opportunity to get rid of OG (ongrown) and QG (quarantine glass eel) which are cumbersome when we try to make simple graphs ?
2.15.5 Code to create the stage table
The code for creating tr_lifestage_lfs is shown below, it also includes the import of the WGEEL stage table.
SQL code to create table tr_lifestage_lfs
-- Table for lifestage-- there is one table for all working groups -- so this table is not inherited (otherwise two wkg could create referential for the same species)DROPTABLEIFEXISTSref.tr_lifestage_lfs CASCADE;CREATETABLEref.tr_lifestage_lfs ( lfs_id SERIAL PRIMARYKEY, lfs_code TEXT NOTNULLUNIQUE, lfs_name TEXT NOTNULL, lfs_spe_code charactervarying(3) NOTNULL, lfs_description TEXT, lfs_icesvalue charactervarying(4), lfs_icesguid uuid, lfs_icestablesource text,CONSTRAINT fk_lfs_spe_code FOREIGNKEY (lfs_spe_code)REFERENCESref.tr_species_spe(spe_code) ONDELETECASCADEONUPDATECASCADE,CONSTRAINT uk_lfs UNIQUE (lfs_code, lfs_spe_code));COMMENTONTABLEref.tr_lifestage_lfs IS'Table of lifestages';COMMENTONCOLUMNref.tr_lifestage_lfs.lfs_id IS'Integer, primary key of the table';COMMENTONCOLUMNref.tr_lifestage_lfs.lfs_code IS'The code of lifestage';COMMENTONCOLUMNref.tr_lifestage_lfs.lfs_name IS'The english name of lifestage';COMMENTONCOLUMNref.tr_lifestage_lfs.lfs_spe_code IS'The code of the species referenced fromtr_species_spe : one of SAL, ELE, TRT, ALA, ALF, SLP, RLP ';COMMENTONCOLUMNref.tr_lifestage_lfs.lfs_description IS'Definition of the lifestage';COMMENTONCOLUMNref.tr_lifestage_lfs.lfs_icesvalue IS'Code for the lifestage in the ICES database';COMMENTONCOLUMNref.tr_lifestage_lfs.lfs_icesguid IS'GUID in the ICES database';COMMENTONCOLUMNref.tr_lifestage_lfs.lfs_icestablesource IS'Source table in ICES vocab';GRANTALLONref.tr_lifestage_lfs TO diaspara_admin;GRANTSELECTONref.tr_lifestage_lfs TO diaspara_read;
2.15.6 Existing stages in ICES dictionaries
Code
types <- icesVocab::getCodeTypeList()types[grep('stage', tolower(types$Description)),]|>kable()TS_MATURITY <- icesVocab::getCodeList('TS_MATURITY')TS_DevStage <- icesVocab::getCodeList('TS_DevStage')# Devstage is 1 to 15 => no useDevScale <- icesVocab::getCodeList('DevScale')# At the present the codetypes target Eggs and Larvae surveys# This is a description of scales types using different publications => not for use()kable(TS_MATURITY, caption ="TS_MATURITY") |>kable_styling(bootstrap_options =c("striped", "hover", "condensed")) kable(TS_DevStage, caption ="Devstage scale, this seems to be about shrimp (berried seems to an egg which looks at you with eyes in shrimps....)") |>kable_styling(bootstrap_options =c("striped", "hover", "condensed"))
Table 16: ICES vocabularies for life stages
(a) Possible match for stage in ICES vocab.
Id
Guid
Key
Description
LongDescription
Modified
44
52
76fab5ff-5f3e-4488-8167-17d360f47c35
STAGE
Developmental Stage of Specimens
2024-10-22T01:08:23.66
264
1397
dcc61865-822a-47a4-a740-a85a5702d0c5
TS_DevStage
Development stage or maturity
2025-06-06T11:13:36.59
375
1514
eac72d6a-219e-42a7-99b3-f50ac258b607
DevScale
Scale applied for reporting developmental stages
At present, the codetype targets the Eggs and Larvae surveys
2023-09-21T16:00:39.353
376
1515
d943050b-a4e3-4508-b0ca-10b298f308f5
DevStage
Developmental stage codes
2023-09-21T08:38:24.54
490
1692
2e045807-14b1-48b0-bb2e-43967cec51e7
POFStaging
Stages of POF (description to be updated)
2023-09-21T08:39:32.57
512
1715
8b86cce6-b742-4865-986c-13932874d9df
LifeStage
Life stage based on plumage (birds)
2023-09-21T15:58:11.863
530
1733
14cbcbfe-f084-40a8-80e3-052e69b06334
DigestionStage
Digestion stage of stomach content.
Visual-based assessment of digestion stage, in relation to diet studies.
2023-09-21T08:27:35.05
(b) TS_MATURITY table
Id
Guid
Key
Description
LongDescription
Modified
Deprecated
CodeTypeID
CodeTypeGUID
51694
7c946d9d-fe30-48fa-a19d-54e72a4160da
-9
Missing Value
2025-04-08T13:01:38.383
FALSE
128
e5bd5e0b-36a0-401f-acc9-b3c03b18b9aa
34401
0da7235e-9a5f-471f-8685-cdcceb3259c0
1
Juvenile/Immature (4-stage scale)
2024-04-04T22:58:21.42
FALSE
128
e5bd5e0b-36a0-401f-acc9-b3c03b18b9aa
34402
781f7cd8-2e68-4590-9124-f9d936e31f52
2
Maturing (4-stage scale)
2024-04-04T22:58:26.547
FALSE
128
e5bd5e0b-36a0-401f-acc9-b3c03b18b9aa
34403
ebb2258d-81fd-47d0-8383-7bfe88af82cd
3
Spawning (4-stage scale)
2024-04-04T22:58:31.627
FALSE
128
e5bd5e0b-36a0-401f-acc9-b3c03b18b9aa
34404
5e364aed-fe87-494e-81ff-195c6363f191
4
Spent (4-stage scale)
2024-04-04T22:58:34.387
FALSE
128
e5bd5e0b-36a0-401f-acc9-b3c03b18b9aa
34405
02c6638c-9a7d-49d1-b06f-942ee5d95a39
5
Resting/Skip of spawning (4-stage scale, additional option)
2024-04-04T22:58:37.077
FALSE
128
e5bd5e0b-36a0-401f-acc9-b3c03b18b9aa
136076
37d204b2-f8a6-48cd-a244-728ab4010111
51
Immature (5 stage scale)
2024-04-04T22:58:39.777
FALSE
128
e5bd5e0b-36a0-401f-acc9-b3c03b18b9aa
136077
46d154b0-61f7-414a-b1d1-4275839afdfe
52
Developing/Resting (5-stage scale)
2024-04-04T22:58:42.423
FALSE
128
e5bd5e0b-36a0-401f-acc9-b3c03b18b9aa
136078
54992917-0bbd-4dd6-8044-32bb70754279
53
Pre-spawning ((5-stage scale)
2024-04-04T22:58:47.773
FALSE
128
e5bd5e0b-36a0-401f-acc9-b3c03b18b9aa
136079
4146842c-eb45-49cd-8674-8d69ee6b81c1
54
Spawning (5-stage scale)
2024-04-04T22:58:53.03
FALSE
128
e5bd5e0b-36a0-401f-acc9-b3c03b18b9aa
136080
52a5be9c-c656-496f-adba-b6af23ba88a3
55
Post-spawning (5-stage scale)
2024-04-04T22:58:55.76
FALSE
128
e5bd5e0b-36a0-401f-acc9-b3c03b18b9aa
131371
17e59dde-46b3-4764-80f1-01e1134c8ba0
6
Abnormal (4-stage scale, additional option)
2024-04-04T22:58:58.51
FALSE
128
e5bd5e0b-36a0-401f-acc9-b3c03b18b9aa
132160
9dab155a-95e6-4dcc-adaf-c8b67febbb60
61
Juvenile/Immature (6-stage scale)
2025-04-08T13:01:39.907
FALSE
128
e5bd5e0b-36a0-401f-acc9-b3c03b18b9aa
132161
32e854ae-0e44-4523-855d-92b8bccdabbe
62
Maturing (6-stage scale)
2025-04-08T13:01:42.227
FALSE
128
e5bd5e0b-36a0-401f-acc9-b3c03b18b9aa
132162
85c79865-4505-4b6e-96bb-37e5a18b9c95
63
Spawning (6-stage scale)
2025-04-08T13:01:44.447
FALSE
128
e5bd5e0b-36a0-401f-acc9-b3c03b18b9aa
132163
2637e1c0-8dba-4da8-beba-7c865acfd7b4
64
Spent (6-stage scale)
2025-04-08T13:01:46.053
FALSE
128
e5bd5e0b-36a0-401f-acc9-b3c03b18b9aa
132164
f682c57c-f70e-4c1b-859c-ab77f865c3f6
65
Resting/Skip of spawning (6-stage scale)
2025-04-08T13:01:49.053
FALSE
128
e5bd5e0b-36a0-401f-acc9-b3c03b18b9aa
132165
8165075c-ae3b-49e4-b8ed-0dad8f215e78
66
Abnormal (6-stage scale)
2025-04-08T13:01:50.45
FALSE
128
e5bd5e0b-36a0-401f-acc9-b3c03b18b9aa
201769
a25f81c6-91af-47fe-b2a1-6f76a8643ac3
A
Immature
2025-04-08T13:01:53.457
FALSE
128
e5bd5e0b-36a0-401f-acc9-b3c03b18b9aa
201770
62b08142-2f9d-4b8c-b53f-d9bce26b1c35
B
Developing
2025-04-08T13:01:54.993
FALSE
128
e5bd5e0b-36a0-401f-acc9-b3c03b18b9aa
201771
4b4643bd-0255-42bc-a473-0b936492ae9f
Ba
Developing, but functionally immature (first-time developer)
2025-04-08T13:01:56.613
FALSE
128
e5bd5e0b-36a0-401f-acc9-b3c03b18b9aa
201772
5fb2d514-c4f0-4911-8eb4-f4e9c692041d
Bb
Developing and functionally mature
2025-04-08T13:01:58.657
FALSE
128
e5bd5e0b-36a0-401f-acc9-b3c03b18b9aa
136063
1ad95503-f3e6-46a6-997f-eefcba1c9bd7
Be
Berried (crustaceans)
2024-04-04T22:59:28.847
FALSE
128
e5bd5e0b-36a0-401f-acc9-b3c03b18b9aa
201773
c5e12291-673e-4ad2-b7b8-6f2adf52ec21
C
Spawning
2025-04-08T13:02:00.207
FALSE
128
e5bd5e0b-36a0-401f-acc9-b3c03b18b9aa
201774
a9bc29b4-4ee3-4b1b-bf31-76d58170d75e
Ca
Actively spawning
2025-04-08T13:02:02.04
FALSE
128
e5bd5e0b-36a0-401f-acc9-b3c03b18b9aa
201775
8d8784d6-9795-43c0-927b-f404a18f3491
Cb
Spawning capable
2025-04-08T13:02:03.677
FALSE
128
e5bd5e0b-36a0-401f-acc9-b3c03b18b9aa
201776
5af75fd2-06df-4d60-a843-2a3977cd6e5c
D
Regressing / Regenerating
2025-04-08T13:02:05.27
FALSE
128
e5bd5e0b-36a0-401f-acc9-b3c03b18b9aa
201777
c11149a2-e084-4af0-b737-4d41d59d3943
Da
Regressing
2025-04-08T13:02:06.787
FALSE
128
e5bd5e0b-36a0-401f-acc9-b3c03b18b9aa
201778
ecb4cdea-3ac1-42cd-a279-c9b20e360999
Db
Regenerating
2025-04-08T13:02:07.98
FALSE
128
e5bd5e0b-36a0-401f-acc9-b3c03b18b9aa
201779
a1cf8684-f842-4f2f-9912-aefefea6d9d3
E
Omitted spawning
2025-04-08T13:02:10.303
FALSE
128
e5bd5e0b-36a0-401f-acc9-b3c03b18b9aa
136064
1dce569f-2d2d-43a9-8041-d90950ade023
Eg
Elasmobranch egg
2024-04-04T22:59:50.567
FALSE
128
e5bd5e0b-36a0-401f-acc9-b3c03b18b9aa
201780
1736cf72-fbca-4389-868d-e996159664e3
F
Abnormal
2025-04-08T13:02:11.58
FALSE
128
e5bd5e0b-36a0-401f-acc9-b3c03b18b9aa
53838
429ad685-ee68-4781-84eb-90f0cd8f0634
I
Immature / National BITS scale step
2024-04-04T23:00:01.06
FALSE
128
e5bd5e0b-36a0-401f-acc9-b3c03b18b9aa
136357
ad5c19e1-3c59-4bd6-b001-f1cfbcab0b6d
II
National BITS scale step
2020-06-03T11:07:14.56
FALSE
128
e5bd5e0b-36a0-401f-acc9-b3c03b18b9aa
136358
595124ad-a831-4ce0-ba88-26fb4183022c
III
National BITS scale step
2020-06-03T11:07:23.86
FALSE
128
e5bd5e0b-36a0-401f-acc9-b3c03b18b9aa
136359
52e89979-b100-4cee-93c9-206d132a4c2a
IV
National BITS scale step
2024-04-04T23:00:16.427
FALSE
128
e5bd5e0b-36a0-401f-acc9-b3c03b18b9aa
136364
60f82148-71f3-4f0f-98c1-a6cd59918f25
IX
National BITS scale step
2024-04-04T23:00:19.22
FALSE
128
e5bd5e0b-36a0-401f-acc9-b3c03b18b9aa
53839
9ddbe93e-b920-46fc-8f0d-b1bc94cacace
M
Mature
2024-04-04T23:00:21.923
FALSE
128
e5bd5e0b-36a0-401f-acc9-b3c03b18b9aa
198590
4b9a6671-aae4-4731-8a20-6bfa6764cc9c
R1_1
Immature
2024-04-04T23:00:24.69
FALSE
128
e5bd5e0b-36a0-401f-acc9-b3c03b18b9aa
198587
542d1576-cb99-42b4-a046-c5af124c7812
R1_2
Maturing
2024-04-04T23:00:27.453
FALSE
128
e5bd5e0b-36a0-401f-acc9-b3c03b18b9aa
198588
e5dba8d3-daf0-49b7-9a5e-0deaeae94591
R1_3
Spawning
2024-04-04T23:00:30.157
FALSE
128
e5bd5e0b-36a0-401f-acc9-b3c03b18b9aa
198589
35caf0f4-b23e-4114-b004-53ceed7dc5ae
R1_4
Spent
2024-04-04T23:00:32.8
FALSE
128
e5bd5e0b-36a0-401f-acc9-b3c03b18b9aa
198591
cc410273-2714-4253-bfa6-fadd39e83099
R2_2
Immature
2024-04-04T23:00:35.503
FALSE
128
e5bd5e0b-36a0-401f-acc9-b3c03b18b9aa
198592
24e63a36-bbcc-422e-9b42-1938d816574c
R2_4
Maturing
2024-04-04T23:00:38.19
FALSE
128
e5bd5e0b-36a0-401f-acc9-b3c03b18b9aa
198593
6024da49-355d-41e0-9c35-91c92133adef
R2_6
Spawning
2024-04-04T23:00:40.893
FALSE
128
e5bd5e0b-36a0-401f-acc9-b3c03b18b9aa
198594
8f5b8ad1-f335-487a-bb17-58936b4bae8b
R2_8
Spent/Recovering
2024-04-04T23:00:43.587
FALSE
128
e5bd5e0b-36a0-401f-acc9-b3c03b18b9aa
155316
193d1307-7594-4e61-bddb-5ed722448fc1
RF1
Immature redfish
2024-04-04T23:00:46.243
FALSE
128
e5bd5e0b-36a0-401f-acc9-b3c03b18b9aa
155317
2bd20b2d-41f7-4ce4-944c-c124c2ee25bc
RF2
Maturing_mature redfish
2024-04-04T23:00:51.45
FALSE
128
e5bd5e0b-36a0-401f-acc9-b3c03b18b9aa
155318
34288e8c-0586-48e9-bce9-2ea62580d278
RF3
Mature_fertilized redfish
2024-04-04T23:00:56.56
FALSE
128
e5bd5e0b-36a0-401f-acc9-b3c03b18b9aa
155319
8891c3b8-f440-4eca-8cb9-32c3f544cb82
RF4
Parturition redfish
2024-04-04T23:01:01.607
FALSE
128
e5bd5e0b-36a0-401f-acc9-b3c03b18b9aa
155320
94165bd1-2c96-485e-92f7-f8fdbec294d0
RF5
Postspawning redfish
2024-04-04T23:01:06.903
FALSE
128
e5bd5e0b-36a0-401f-acc9-b3c03b18b9aa
155321
b725388b-288c-4895-819e-029e9625d0a4
RF6
Recovery redfish
2024-04-04T23:01:12.193
FALSE
128
e5bd5e0b-36a0-401f-acc9-b3c03b18b9aa
136081
add7abf9-c812-4073-afd5-6168efc473da
S1
Immature (6-stage scale)
2024-04-04T23:01:17.303
FALSE
128
e5bd5e0b-36a0-401f-acc9-b3c03b18b9aa
136082
d94cc258-cf59-41df-8e12-e917b8c8753d
S2
Maturing (6-stage scale)
2024-04-04T23:01:22.41
FALSE
128
e5bd5e0b-36a0-401f-acc9-b3c03b18b9aa
136083
ab5a79b8-c948-41d0-ba0e-2d048c9c2d65
S3
Pre-spawning (6-stage scale)
2024-04-04T23:01:27.557
FALSE
128
e5bd5e0b-36a0-401f-acc9-b3c03b18b9aa
136084
185d00c7-b55b-4b6f-ad48-bc02494e7c3e
S4
Spawning (6-stage scale)
2024-04-04T23:01:32.66
FALSE
128
e5bd5e0b-36a0-401f-acc9-b3c03b18b9aa
136085
d7b6f253-9fa6-41bb-96ff-4e4ee3440858
S5
Post-partial spawning (6-stage scale)
2024-04-04T23:01:37.893
FALSE
128
e5bd5e0b-36a0-401f-acc9-b3c03b18b9aa
136086
2fad9d30-d07a-4ffb-b665-1bd687131d5b
S6
Spent/Recovery (6-stage scale)
2024-04-04T23:01:43.333
FALSE
128
e5bd5e0b-36a0-401f-acc9-b3c03b18b9aa
136360
7d6b8aeb-1019-410c-9377-e03dd45bb06c
V
National BITS scale step
2020-06-03T11:07:55.243
FALSE
128
e5bd5e0b-36a0-401f-acc9-b3c03b18b9aa
136361
61f27c0b-f86f-4d44-b1fc-e695a071ff76
VI
National BITS scale step
2024-04-04T23:01:53.77
FALSE
128
e5bd5e0b-36a0-401f-acc9-b3c03b18b9aa
136362
94bbebde-ffe9-41e9-b0d8-d712018b81e6
VII
National BITS scale step
2024-04-04T23:01:56.567
FALSE
128
e5bd5e0b-36a0-401f-acc9-b3c03b18b9aa
136363
304ebd7a-7749-4b94-b155-301e786d8f6a
VIII
National BITS scale step
2024-04-04T23:01:59.207
FALSE
128
e5bd5e0b-36a0-401f-acc9-b3c03b18b9aa
136365
39a755c5-f830-49f0-8ca1-d1ea31989843
X
National BITS scale step
2024-04-04T23:02:02.05
FALSE
128
e5bd5e0b-36a0-401f-acc9-b3c03b18b9aa
(c) DevScale table
Id
Guid
Key
Description
LongDescription
Modified
Deprecated
CodeTypeID
CodeTypeGUID
148232
16f8c30a-b724-4636-bd78-0a9a1776039e
-9
No information
2024-04-04T22:56:03.417
FALSE
1397
dcc61865-822a-47a4-a740-a85a5702d0c5
141111
c1566f6d-c099-44c3-bd39-222fe4c033de
B
Berried
2024-04-04T22:56:06.12
FALSE
1397
dcc61865-822a-47a4-a740-a85a5702d0c5
141112
0424ae90-03aa-4e73-8cda-e8745d0b8158
E
Egg
2024-04-04T22:56:08.823
FALSE
1397
dcc61865-822a-47a4-a740-a85a5702d0c5
256259
3ea553fe-66cf-47ff-b4ff-eb83d1c28643
J
Juvenile
2025-06-06T11:13:34.427
FALSE
1397
dcc61865-822a-47a4-a740-a85a5702d0c5
QUESTION TO ICES
Does it make sense to use a code outside from its scope (I seems to me that yes). If so can we use the TS_DevStage and add values in it and propose definitions ?
Code to import stages from WGBAST and WGNAS databases.
# below the definition of Smolt, post-smolt and Adult provided by Etienne.lfs <-tribble(~lfs_code, ~lfs_name, ~lfs_spe_code, ~lfs_description, ~lfs_icesvalue, ~lfs_icesguid, ~lfs_icestablesource,"E", "Egg", "SAL" , "In fish, the term egg usually refers to female haploid gametes.", "E", "0424ae90-03aa-4e73-8cda-e8745d0b8158", "TS_DevStage","EE", "Eyed egg", "SAL" , "Eyed eggs are fertilized eggs that have developed to the stage where the eyes of the fish can easily be seen with naked eyes through the translucent egg shell. They might be used for stocking purpose.", NA, NA , NA,"ALV", "Alevin with the yolk sac", "SAL" , "Larval salmon that have hatched but have not yet completely absorbed their yolk sacs and usually have not yet emerged from the gravel. http://purl.dataone.org/odo/SALMON_00000403", NA, NA , NA,"FR", "Fry", "SAL" , "A young salmonid at the post-larval stage who has resorbed the yolk sac but remains buried in the gravel. The stage starts at the end of dependence on the yolk sac as the primary source of nutrition to dispersal from the redd.", NA, NA , NA,"P", "Parr", "SAL", "A young salmonid with parr-marks before migration to the sea and after dispersal from the redd. http://purl.dataone.org/odo/SALMON_00000649",NA, NA, NA,"SM", "Smolt", "SAL", "A young salmonid which has undergone the transformation to adapt to salt water, has developed silvery coloring on its sides, obscuring the parr marks, and is about to migrate or has just migrated into the sea.",NA, NA, NA,"PS", "Post Smolt", "SAL", "A salmonid at sea, after its migration to the sea as smolt. For salmon it usually refer to fishes during their between the smolt migration in spring and the first winter at sea.",NA, NA, NA,"A", "Adult", "SAL", " Salmonids that have fully developed morphological and meristic characters and that have attained sexual maturity. For salmon this might refer to fishes during their migration back to coastal waters for the reproduction, or to spawning adults in freshwater. More details can be given on the sexual maturity of the fish using the maturity scale.", NA, NA, NA,"AL", "All stages", "SAL", "All life stages are concerned.", NA, NA, NA,"_", "No life stage", "SAL", "Reserved when the life stage makes no sense for the variable stored in the database, e.g. a parameter setting the number of years in the model", NA, NA, NA)dbWriteTable(con_diaspara_admin, "temp_lfs", lfs, overwrite =TRUE)dbExecute(con_diaspara_admin, "DELETE FROM ref.tr_lifestage_lfs;")#24dbExecute(con_diaspara_admin, "INSERT INTO ref.tr_lifestage_lfs ( lfs_code, lfs_name, lfs_spe_code, lfs_description, lfs_icesvalue, lfs_icesguid, lfs_icestablesource) SELECT lfs_code, lfs_name, lfs_spe_code, lfs_description, lfs_icesvalue, lfs_icesguid::uuid, lfs_icestablesource FROM temp_lfs;")dbExecute(con_diaspara_admin, "DROP TABLE temp_lfs")
2.15.8 Import lifestages for eel
Code to import stages from WGEEL databases.
dbExecute(con_diaspara_admin,"DELETE FROM ref.tr_lifestage_lfs WHERE lfs_spe_code ='ANG';")dbExecute(con_diaspara_admin, "INSERT INTO ref.tr_lifestage_lfs (lfs_code,lfs_name,lfs_description, lfs_spe_code)SELECT lfs_code,initcap(lfs_name),lfs_definition, 'ANG' FROM refwgeel.tr_lifestage_lfs ;") # 8
2.15.9 Import lifestages for trutta
Code to import stages from WGEEL databases.
dbExecute(con_diaspara_admin, "INSERT INTO ref.tr_lifestage_lfs (lfs_code, lfs_name, lfs_spe_code, lfs_description, lfs_icesvalue, lfs_icesguid, lfs_icestablesource) SELECT lfs_code, lfs_name, 'TRSS' AS lfs_spe_code, lfs_description, lfs_icesvalue, lfs_icesguid::uuid, lfs_icestablesource FROM ref.tr_lifestage_lfs WHERE lfs_spe_code = 'SAL';")
WGTRUTTA Comment (Iain Malcolm)
In terms of stage, we would need alevin, fry (YoY, 0+), parr (>0+). In the Marine Directorate database lifestage is called “field recorded lifestage” to separate from lifestage derived from ageing by scale reading. > DIASPARA : OK this seems to fit to our current vocabulary. For scale reading we have prepared a different field > in the individual metric database. It will not be used in the stock database.
In fish, the term egg usually refers to female haploid gametes.
E
0424ae90-03aa-4e73-8cda-e8745d0b8158
TS_DevStage
51
EE
Eyed egg
SAL
Eyed eggs are fertilized eggs that have developed to the stage where the eyes of the fish can easily be seen with naked eyes through the translucent egg shell. They might be used for stocking purpose.
NA
NA
NA
52
ALV
Alevin with the yolk sac
SAL
Larval salmon that have hatched but have not yet completely absorbed their yolk sacs and usually have not yet emerged from the gravel. http://purl.dataone.org/odo/SALMON_00000403
NA
NA
NA
53
FR
Fry
SAL
A young salmonid at the post-larval stage who has resorbed the yolk sac but remains buried in the gravel. The stage starts at the end of dependence on the yolk sac as the primary source of nutrition to dispersal from the redd.
NA
NA
NA
54
P
Parr
SAL
A young salmonid with parr-marks before migration to the sea and after dispersal from the redd. http://purl.dataone.org/odo/SALMON_00000649
|NA
|NA
|NA
55
SM
Smolt
SAL
A young salmonid which has undergone the transformation to adapt to salt water, has developed silvery coloring on its sides, obscuring the parr marks, and is about to migrate or has just migrated into the sea.
NA
NA
NA
56
PS
Post Smolt
SAL
A salmonid at sea, after its migration to the sea as smolt. For salmon it usually refer to fishes during their between the smolt migration in spring and the first winter at sea.
NA
NA
NA
57
A
Adult
SAL
Salmonids that have fully developed morphological and meristic characters and that have attained sexual maturity. For salmon this might refer to fishes during their migration back to coastal waters for the reproduction, or to spawning adults in freshwater. More details can be given on the sexual maturity of the fish using the maturity scale.
NA
NA
NA
58
AL
All stages
SAL
All life stages are concerned.
NA
NA
NA
59
_
No life stage
SAL
Reserved when the life stage makes no sense for the variable stored in the database, e.g. a parameter setting the number of years in the model
NA
NA
NA
60
G
Glass Eel
ANG
Young, unpigmented eel, recruiting from the sea into continental waters. WGEEL consider the glass eel term to include all recruits of the 0+ cohort age. In some cases, however, also includes the early pigmented stages.
NA
NA
NA
61
S
Silver Eel
ANG
Migratory phase following the yellow eel phase. Eel in this phase are characterized by darkened back, silvery belly with a clearly contrasting black lateral line, enlarged eyes. Silver eel undertake downstream migration towards the sea, and subsequently westwards. This phase mainly occurs in the second half of calendar years, although some are observed throughout winter and following spring.
NA
NA
NA
62
GY
Glass Eel + Yellow Eel
ANG
A mixture of glass and yellow eel, some traps have historical set of data where glass eel and yellow eel were not separated, they were dominated by glass eel
|NA
|NA
|NA
63
OG
Ongrown Eel
ANG
Eel that have been held in water tanks for some days or months between first capture and then release to a new water basin, and they have been fed and grown during that time.
NA
NA
NA
64
QG
Quarantined Eel
ANG
Ongrown eel (see definition above) that have been held in isolation between capture and restocking.
NA
NA
NA
65
AL
All Stages
ANG
All stages combined
NA
NA
NA
66
YS
Yellow Eel+ Silver Eel
ANG
Yellow and Silver eel defined below
NA
NA
NA
67
Y
Yellow Eel
ANG
Life-stage resident in continental waters. Often defined as a sedentary phase, but migration within and between rivers, and to and from coastal waters occurs and therefore includes young pigmented eels (‘elvers’ and bootlace). Sometimes is also called Brown eel.
|NA
|NA
|NA
68
E
Egg
TRS
In fish, the term egg usually refers to female haploid gametes.
E
0424ae90-03aa-4e73-8cda-e8745d0b8158
TS_DevStage
69
EE
Eyed egg
TRS
Eyed eggs are fertilized eggs that have developed to the stage where the eyes of the fish can easily be seen with naked eyes through the translucent egg shell. They might be used for stocking purpose.
NA
NA
NA
70
ALV
Alevin with the yolk sac
TRS
Larval salmon that have hatched but have not yet completely absorbed their yolk sacs and usually have not yet emerged from the gravel. http://purl.dataone.org/odo/SALMON_00000403
NA
NA
NA
71
FR
Fry
TRS
A young salmonid at the post-larval stage who has resorbed the yolk sac but remains buried in the gravel. The stage starts at the end of dependence on the yolk sac as the primary source of nutrition to dispersal from the redd.
NA
NA
NA
72
P
Parr
TRS
A young salmonid with parr-marks before migration to the sea and after dispersal from the redd. http://purl.dataone.org/odo/SALMON_00000649
|NA
|NA
|NA
73
SM
Smolt
TRS
A young salmonid which has undergone the transformation to adapt to salt water, has developed silvery coloring on its sides, obscuring the parr marks, and is about to migrate or has just migrated into the sea.
NA
NA
NA
74
PS
Post Smolt
TRS
A salmonid at sea, after its migration to the sea as smolt. For salmon it usually refer to fishes during their between the smolt migration in spring and the first winter at sea.
NA
NA
NA
75
A
Adult
TRS
Salmonids that have fully developed morphological and meristic characters and that have attained sexual maturity. For salmon this might refer to fishes during their migration back to coastal waters for the reproduction, or to spawning adults in freshwater. More details can be given on the sexual maturity of the fish using the maturity scale.
NA
NA
NA
76
AL
All stages
TRS
All life stages are concerned.
NA
NA
NA
77
_
No life stage
TRS
Reserved when the life stage makes no sense for the variable stored in the database, e.g. a parameter setting the number of years in the model
NA
NA
NA
2.16 Maturity (ts_maturity_mat)
Working on stages, and looking at the ICES vocab, we have decided to include information on maturity.
SQL code to create table tr_maturity_mat
-- maturity table codeDROPTABLEIFEXISTSref.tr_maturity_mat CASCADE;CREATETABLEref.tr_maturity_mat ( mat_id SERIAL PRIMARYKEY, mat_code TEXT NOTNULLCONSTRAINT uk_mat_code UNIQUE, mat_description TEXT, mat_icesvalue charactervarying(4), mat_icesguid uuid, mat_icestablesource text);COMMENTONTABLEref.tr_maturity_mat IS'Table of maturity corresponding to the 6 stage scale of the ICES vocabulary';COMMENTONCOLUMNref.tr_maturity_mat.mat_id IS'Integer, primary key of the table';COMMENTONCOLUMNref.tr_maturity_mat.mat_code IS'The code of maturity stage';COMMENTONCOLUMNref.tr_maturity_mat.mat_description IS'Definition of the maturity stage';COMMENTONCOLUMNref.tr_maturity_mat.mat_icesvalue IS'Code (Key) of the maturity in ICES db';COMMENTONCOLUMNref.tr_maturity_mat.mat_icesguid IS'UUID (guid) of ICES, you can access by pasting ';COMMENTONCOLUMNref.tr_maturity_mat.mat_icestablesource IS'Source table in ICES';GRANTALLONref.tr_maturity_mat TO diaspara_admin;GRANTSELECTONref.tr_maturity_mat TO diaspara_read;
The information about the stage mixes information on stage and maturity. The use of SMSF vocabulary stage is made mandatory for all countries since 2020 and WGBIOP (ICES 2024b) has revised the referential and emphasized the need of its use for a consistent stock assessment.
In the report the stages are defined as following in Maturitstage.
State
Stage
Possible sub-stages
SI. Sexually immature
A. Immature
SM. Sexually mature
B. Developing
Ba. Developing but functionally immature (first-time developer)
The substage Ba identifies a sexually mature but functionally immature (virgin developing for the first time) fish which is not going to contribute to the current upcoming spawning season. Either it is uncertain if the fish will make it for the upcoming spawning season as it is a long time to the current upcoming spawning season (i.e. if maturity is assessed 8 months prior to the spawning season it is unsure if the first time developer will be ready to spawn in 8 months time), or the time between assessing the maturity stage and the current upcoming spawning season is too short to fully develop the oocytes (i.e. if it takes 6 months to fully develop oocytes from previtellogenic to eggs and a Ba fish is found 3 months prior to the current upcoming spawning season, it will not have enough time to develop the oocytes).
the substage Bb identifies a developing and functionally mature (first or repeat spawner!!) fish which, in most of the cases is going to contribute to the current spawning season. This stage has visible oocytes and grainy appearance of the gonads on the macroscopic scale, and vitellogenic oocytes on the histological key.
Following this report and the comments made by ICES data center the following codes are proposed (Table Table 17).
Developing, but functionally immature (first-time developer)
Ba
4b4643bd-0255-42bc-a473-0b936492ae9f
TS_MATURITY
4
Bb
Developing and functionally mature
Bb
5fb2d514-c4f0-4911-8eb4-f4e9c692041d
TS_MATURITY
5
C
Spawning
C
c5e12291-673e-4ad2-b7b8-6f2adf52ec21
TS_MATURITY
6
Ca
Actively spawning
Ca
a9bc29b4-4ee3-4b1b-bf31-76d58170d75e
TS_MATURITY
7
Cb
Spawning capable
Cb
8d8784d6-9795-43c0-927b-f404a18f3491
TS_MATURITY
8
D
Regressing / Regenerating
D
5af75fd2-06df-4d60-a843-2a3977cd6e5c
TS_MATURITY
9
Da
Regressing
Da
c11149a2-e084-4af0-b737-4d41d59d3943
TS_MATURITY
10
Db
Regenerating
Db
ecb4cdea-3ac1-42cd-a279-c9b20e360999
TS_MATURITY
11
E
Omitted spawning
E
a1cf8684-f842-4f2f-9912-aefefea6d9d3
TS_MATURITY
12
F
Abnormal
F
1736cf72-fbca-4389-868d-e996159664e3
TS_MATURITY
2.17 Habitat type (tr_habitattype_hty)
This table (Table Table 18) is used in RDBES, and those stages are consistent with WGBAST and WGEEL. I remember when creating this for WGEEL, we tried to follow the ICES vocab at the time, so it’s mostly similar except that C (coastal) in WGEEL is C (WFD Coastal water) in WLTYP but is also reported as MC (Marine Coastal) in the RDBES and freshwater is F instead of FW. WGBAST separates Marine Open O (instead of MO), Marine coastal C (instead of MC) and rivers R (instead of FW). In the report it is said that S sea is used when it is not possible to distinguish between coastal and marine open, but the code is not in the database (If I’m not wrong see WGBAST database description - catch habitat). Other elements in this vocab will not be used (e.g. TT, Beach … ). Currently the RDBES uses the following codes from FW Fresh water, MC Marine water (coast), MO Marine water (open sea), MC Marine water (coast) and NA Not applicable.
QUESTION TO ICES (Maria, Joana, Henrik)
Why has the code MC been chosen instead of C for RDBES ? What is the rationale for not using the WFD ? Is it for non European countries Eel mostly follows the WFD (in EU countries) as the units should be based on river basins. What should we use there ? Our choice there would be to use MC, MO, T and FW and so add T to the list of vocabularies used by RDBES, would you agree ?
Code
WLTYP <- icesVocab::getCodeList('WLTYP')# At the present the codetypes target Eggs and Larvae surveys# This is a description of scales types using different publications => not for use()kable(WLTYP, caption ="WLTYP") |>kable_styling(bootstrap_options =c("striped", "hover", "condensed"))
Table 18: ICES vocabularies for habiat type (table WLTYP)
WLTYP
Id
Guid
Key
Description
LongDescription
Modified
Deprecated
CodeTypeID
CodeTypeGUID
156363
9388a49e-4a5f-46b3-9b7b-8dcfb03e7b6f
BP
Beach - peri-urban
2021-12-10T10:21:48.54
FALSE
212
70e73f70-643d-497b-8d91-a1560d1c4518
156362
a6e1119b-3bcc-4b0a-8053-f8f7a86f0053
BR
Beach - rural
2019-01-17T21:40:37.613
FALSE
212
70e73f70-643d-497b-8d91-a1560d1c4518
156361
53708e1d-d3c6-47a7-a0ee-1c70e6fa7f9b
BU
Beach - urban
2024-08-26T12:34:32.887
FALSE
212
70e73f70-643d-497b-8d91-a1560d1c4518
53327
86d9897d-6adc-430e-a689-f321b75cadcc
C
WFD Coastal water
2025-07-07T18:16:00.73
FALSE
212
70e73f70-643d-497b-8d91-a1560d1c4518
53329
0a28de1c-018a-4841-b3a3-a68e01c81cd5
CE
Coastal water (Estuary)
2025-07-07T06:20:30.267
FALSE
212
70e73f70-643d-497b-8d91-a1560d1c4518
54066
85a228c9-9033-4f97-accf-4968db78a90a
CF
Coastal water (Fjord)
2025-07-07T18:15:42.03
FALSE
212
70e73f70-643d-497b-8d91-a1560d1c4518
53330
e57989c4-a3f9-4560-9460-60dce3a26185
CR
Coastal water (River)
2024-05-31T09:33:48.397
FALSE
212
70e73f70-643d-497b-8d91-a1560d1c4518
252557
eb979616-8b95-4c1b-92e8-b5f8d8bf1b96
FW
Fresh water
2022-08-19T13:09:47.52
FALSE
212
70e73f70-643d-497b-8d91-a1560d1c4518
53334
c557dc19-27b9-46b6-a164-d7d8d4f55738
L
Land station
2024-11-07T21:41:20.483
FALSE
212
70e73f70-643d-497b-8d91-a1560d1c4518
134991
5b3da387-3b2b-47c4-9967-c3161f533207
LK
Lake
2022-11-01T13:01:25.573
FALSE
212
70e73f70-643d-497b-8d91-a1560d1c4518
252556
b51355b0-b905-4b4e-ab12-98d9b47d7752
MC
Marine water (coast)
2025-07-07T06:25:44.82
FALSE
212
70e73f70-643d-497b-8d91-a1560d1c4518
53333
a75522ef-5e4a-4e2d-8550-38091cb6c994
MO
Marine water (open sea)
2025-07-07T18:20:33.66
FALSE
212
70e73f70-643d-497b-8d91-a1560d1c4518
252558
913ae617-a160-4687-a62c-8923c6762c4f
NA
Not applicable
2022-08-19T13:09:47.543
FALSE
212
70e73f70-643d-497b-8d91-a1560d1c4518
53331
1c792737-6f55-422a-b709-88af2d78c4ea
T
WFD Transitional water - implies reduced salinity
2023-11-29T11:52:37.713
FALSE
212
70e73f70-643d-497b-8d91-a1560d1c4518
53332
4f85f72f-c2f0-41c7-b966-c80c897b80d7
TT
Transitional water (Tidal) - significant tide and reduced salinity
2025-07-07T18:20:02.697
FALSE
212
70e73f70-643d-497b-8d91-a1560d1c4518
2.17.1 Code to create the habitat type table.
The code for creating tr_habitat_type is shown below.
SQL code to create table tr_habitat_type
-- Table for habitattype-- there is one table for all working groups -- This mostly only imports some of the codes from the WLTYP vocabDROPTABLEIFEXISTSref.tr_habitattype_hty CASCADE;CREATETABLEref.tr_habitattype_hty ( hty_id SERIAL PRIMARYKEY, hty_code TEXT NOTNULLUNIQUE, hty_description TEXT, hty_icesvalue charactervarying(4), hty_icesguid uuid, hty_icestablesource text);COMMENTONTABLEref.tr_habitattype_hty IS'Table of habitat types, takes from the WLTYP vocab';COMMENTONCOLUMNref.tr_habitattype_hty.hty_id IS'Integer, primary key of the table';COMMENTONCOLUMNref.tr_habitattype_hty.hty_code IS'The code of the habitat';COMMENTONCOLUMNref.tr_habitattype_hty.hty_description IS'Definition of the lifestage';COMMENTONCOLUMNref.tr_habitattype_hty.hty_icesvalue IS'Code for the lifestage in the ICES database';COMMENTONCOLUMNref.tr_habitattype_hty.hty_icesguid IS'GUID in the ICES database';COMMENTONCOLUMNref.tr_habitattype_hty.hty_icestablesource IS'Source table in ICES vocab';GRANTALLONref.tr_habitattype_hty TO diaspara_admin;GRANTSELECTONref.tr_habitattype_hty TO diaspara_read;
This code is used by wgeel. Currently the WGNAS uses an archive table, WGEEL uses historical data with a different quality ID. Both have chosen never to remove any data, I don’t think that these procedures, handled by shiny app, are compatible with ICES procedures.
QUESTION TO ICES
WGNAS uses an archive table for historical data. WGEEL uses a code to “deprecate” old values.
In practise for WGNAS it means that each time a new row replaces an old one, the data is saved in an archive table, with the same structure as the main data table, but with the name of the people who have handled the change and the date. The version is replaced with a new number in the databasetable.
For WGEEL, all the row are kept in the same table. Historical value get a code like 18, …, 25 which identifies the year that the line was removed. All data submitted to the database are kept, so if during a datacall, a new value is submitted that is a duplicate from an old one, then the user in the shiny has to edit an excel table saying which value he wants to keep. If for instance he wants to keep the old value, then the new row will go into the database with a qal_id 25 if the change is made in 2025. The table Table 20 is used.
How do you work in ICES to keep historical data ?
Table 20
Table tr_quality_qal used by the wgeel
qal_id
qal_level
qal_text
1
good quality
the data passed the quality checks of the wgeel
2
modified
The wgeel has modified that data
4
warnings
The data is used by the wgeel, but there are warnings on its quality (see comments)
0
missing
missing data
3
bad quality
The data has been judged of too poor quality to be used by the wgeel, it is not used
18
discarded_wgeel_2018
This data has either been removed from the database in favour of new data, or corresponds to new data not kept in the database during datacall 2018
19
discarded_wgeel_2019
This data has either been removed from the database in favour of new data, or corresponds to new data not kept in the database during datacall 2019
20
discarded_wgeel_2020
This data has either been removed from the database in favour of new data, or corresponds to new data not kept in the database during datacall 2020
21
discarded_wgeel_2021
This data has either been removed from the database in favour of new data, or corresponds to new data not kept in the database during datacall 2021
-21
discarded 2021 biom mort
This data has either been removed from the database in favour of new data, this has been done systematically in 2021 for biomass and mortality types
22
discarded_wgeel_2022
This data has either been removed from the database in favour of new data, or corresponds to new data not kept in the database during datacall 2022
23
discarded_wgeel 2023
This data has either been removed from the database in favour of new data, or corresponds to new data not kept in the database during datacall 2023
24
discarded_wgeel 2024
This data has either been removed from the database in favour of new data, or corresponds to new data not kept in the database during datacall 2024
2.18.1 Code to create the table
The code for creating tr_quality_qal is shown below.
SQL code to create table tr_quality_qal
-- Table for qualityDROPTABLEIFEXISTSref.tr_quality_qal CASCADE;CREATETABLEref.tr_quality_qal ( qal_code int4 NOTNULL, qal_description text NULL, qal_definition text NULL, qal_kept bool NULL,CONSTRAINT tr_quality_qal_pkey PRIMARYKEY (qal_code));COMMENTONTABLEref.tr_quality_qal IS'Table of quality rating, 1 = good quality, 2 = modified 4 = warnings, 0 = missing, 18 , 19 ... deprecated data in 2018, 2019 ...';COMMENTONCOLUMNref.tr_quality_qal.qal_code IS'Data quality code';COMMENTONCOLUMNref.tr_quality_qal.qal_description IS'Data quality description';COMMENTONCOLUMNref.tr_quality_qal.qal_definition IS'Definition of the quality code';COMMENTONCOLUMNref.tr_quality_qal.qal_kept IS'Are the data with this score kept for analysis';GRANTALLONref.tr_quality_qal TO diaspara_admin;GRANTSELECTONref.tr_quality_qal TO diaspara_read;
2.18.2 Import the quality code
The codes are imported in Table Table 21 using the following code :
Code to import quality from WGEEL.
dbExecute(con_diaspara_admin,"DELETE FROM ref.tr_quality_qal;")dbExecute(con_diaspara_admin, "INSERT INTO ref.tr_quality_qal (qal_code, qal_description, qal_definition, qal_kept)SELECT qal_id, qal_level, qal_text, qal_kept FROM refwgeel.tr_quality_qal ;")# 13# changing one definition linked to wgeeldbExecute(con_diaspara_admin, "UPDATE ref.tr_quality_qal set qal_definition = 'the data passed the quality checks and is considered as good quality' WHERE qal_code = 1")# This one only causes problems.... Remove.dbExecute(con_diaspara_admin, "DELETE FROM ref.tr_quality_qal WHERE qal_code = 0")
The data is used by the wgeel, but there are warnings on its quality (see comments)
TRUE
3
bad quality
The data has been judged of too poor quality to be used by the wgeel, it is not used
FALSE
18
discarded_wgeel_2018
This data has either been removed from the database in favour of new data, or corresponds to new data not kept in the database during datacall 2018
FALSE
19
discarded_wgeel_2019
This data has either been removed from the database in favour of new data, or corresponds to new data not kept in the database during datacall 2019
FALSE
20
discarded_wgeel_2020
This data has either been removed from the database in favour of new data, or corresponds to new data not kept in the database during datacall 2020
FALSE
21
discarded_wgeel_2021
This data has either been removed from the database in favour of new data, or corresponds to new data not kept in the database during datacall 2021
FALSE
-21
discarded 2021 biom mort
This data has either been removed from the database in favour of new data, this has been done systematically in 2021 for biomass and mortality types
FALSE
22
discarded_wgeel_2022
This data has either been removed from the database in favour of new data, or corresponds to new data not kept in the database during datacall 2022
FALSE
23
discarded_wgeel 2023
This data has either been removed from the database in favour of new data, or corresponds to new data not kept in the database during datacall 2023
FALSE
24
discarded_wgeel 2024
This data has either been removed from the database in favour of new data, or corresponds to new data not kept in the database during datacall 2024
FALSE
1
good quality
the data passed the quality checks and is considered as good quality
TRUE
2.19 Age (tr_age_age)
The code for creating tr_age_age (Table Table 22) is shown below.
SQL code to create table tr_age_age
-- Table for age-- there is one table for all working groups -- so this table is not inherited (otherwise two wkg could create referential for the same species)DROPTABLEIFEXISTSref.tr_age_age;CREATETABLEref.tr_age_age (age_value INTEGER,age_envir TEXT NOTNULL,CONSTRAINT ck_age_envir CHECK (age_envir='Seawater'OR age_envir='Freshwater'),age_code varchar(3) PRIMARYKEY,age_description TEXT,age_definition TEXT,age_icesvalue charactervarying(4), age_icesguid uuid,age_icestablesource text);ALTERTABLEref.tr_age_age OWNER TO diaspara_admin;GRANTSELECTONref.tr_age_age TO diaspara_read;INSERTINTOref.tr_age_age VALUES (1, 'Freshwater', '0FW', '0 year in freshwater','Age of juvenile fish in their first year in Freshwater');INSERTINTOref.tr_age_age VALUES (1, 'Freshwater', '1FW', '1 year in freshwater',NULL);INSERTINTOref.tr_age_age VALUES (2, 'Freshwater', '2FW', '2 years in freshwater',NULL);INSERTINTOref.tr_age_age VALUES (3, 'Freshwater', '3FW', '3 years in freshwater',NULL);INSERTINTOref.tr_age_age VALUES (4, 'Freshwater', '4FW', '4 years in freshwater',NULL);INSERTINTOref.tr_age_age VALUES (5, 'Freshwater', '5FW', '5 years in freshwater',NULL);INSERTINTOref.tr_age_age VALUES (6, 'Freshwater', '6FW', '6 years in freshwater',NULL);INSERTINTOref.tr_age_age VALUES (1, 'Seawater', '1SW', '1 year in seawater',NULL);INSERTINTOref.tr_age_age VALUES (2, 'Seawater', '2SW', '2 years in seawater',NULL);INSERTINTOref.tr_age_age VALUES (NULL, 'Seawater', 'MSW', 'Two years or more in seawater',NULL);COMMENTONTABLEref.tr_age_age IS'Table of ages for salmonids';COMMENTONCOLUMNref.tr_age_age.age_value IS'Integer, value of the age as integer';COMMENTONCOLUMNref.tr_age_age.age_envir IS'Freshwater or Seawater';COMMENTONCOLUMNref.tr_age_age.age_code IS'1FW to 6FW and 1SW to 2SW';COMMENTONCOLUMNref.tr_age_age.age_description IS'Description of the age';COMMENTONCOLUMNref.tr_age_age.age_definition IS'Definition of the age';COMMENTONCOLUMNref.tr_age_age.age_icesvalue IS'Code for the age in the ICES database';COMMENTONCOLUMNref.tr_age_age.age_icesguid IS'GUID in the ICES database';COMMENTONCOLUMNref.tr_age_age.age_icestablesource IS'Source table in ICES vocab';
Age of juvenile fish in their first year in Freshwater
NA
NA
NA
1
Freshwater
1FW
1 year in freshwater
NA
NA
NA
NA
2
Freshwater
2FW
2 years in freshwater
NA
NA
NA
NA
3
Freshwater
3FW
3 years in freshwater
NA
NA
NA
NA
4
Freshwater
4FW
4 years in freshwater
NA
NA
NA
NA
5
Freshwater
5FW
5 years in freshwater
NA
NA
NA
NA
6
Freshwater
6FW
6 years in freshwater
NA
NA
NA
NA
1
Seawater
1SW
1 year in seawater
NA
NA
NA
NA
2
Seawater
2SW
2 years in seawater
NA
NA
NA
NA
NA
Seawater
MSW
Two years or more in seawater
NA
NA
NA
NA
ANSWER WGTRUTTA : Iain
Are the ages obtained from scale reading? In our Marine Directorate database we are careful to separate scale read ages from “guessed age” derived from sizes or field derived - observed (e.g. fry = 0+). If these are not clearly recorded in different areas of the database, is there somewhere to store information on the protocols? In MD database we store information on projects / campaigns (describe why and how data collected) and also protocols applied at SiteVisit level. The general definition looks OK. Although, when you store adults, how do you record more complex patterns e.g. 3SW with a spawning mark after year 2? In MD database all this is recorded on the “Scale Record” that links to individual fish. > DIASPARA
2.20 Sex (tr_sex_sex)
There is a referential about sex in ICES (thanks Maria and Joana for pointing that out…) see Table Table 23.
Immature - attempt made but sex could not be destinguished
2023-02-08T11:30:06.127
FALSE
45
4efe3145-65ee-46c7-bca1-3ce9f10101de
26733
9d81d4b2-dfc7-4fb0-86ee-b66e13a2125c
M
Male
2023-02-08T11:30:06.173
FALSE
45
4efe3145-65ee-46c7-bca1-3ce9f10101de
234003
484e5245-7f83-4d0d-957c-43f17c17f0af
T
Transitional
2023-02-08T11:30:06.433
FALSE
45
4efe3145-65ee-46c7-bca1-3ce9f10101de
130028
ea6f732e-cef7-4f5a-abbc-71baa2f4dcfe
U
Undetermined - no attempt made
2024-10-24T01:10:19.893
FALSE
45
4efe3145-65ee-46c7-bca1-3ce9f10101de
26734
4056362e-05ec-4f0f-8e24-d99e30821fe0
X
Mixed
2023-02-08T11:30:06.25
FALSE
45
4efe3145-65ee-46c7-bca1-3ce9f10101de
SQL code to create table tr_sex_sex
DROPTABLEIFEXISTSref.tr_sex_sex CASCADE;CREATETABLEref.tr_sex_sex ( sex_id SERIAL PRIMARYKEY, sex_code TEXT NOTNULLCONSTRAINT uk_sex_code UNIQUE, sex_description TEXT, sex_icesvalue charactervarying(4), sex_icesguid uuid, sex_icestablesource text);COMMENTONTABLEref.tr_sex_sex IS'Table of possible sex values corresponding to the 7 scale of the ICES vocabulary';COMMENTONCOLUMNref.tr_sex_sex.sex_id IS'Integer, primary key of the table';COMMENTONCOLUMNref.tr_sex_sex.sex_code IS'The code of sex';COMMENTONCOLUMNref.tr_sex_sex.sex_description IS'Definition of the sex nature';COMMENTONCOLUMNref.tr_sex_sex.sex_icesvalue IS'Code (Key) of the sex in ICES db';COMMENTONCOLUMNref.tr_sex_sex.sex_icesguid IS'UUID (guid) of ICES, you can access by pasting ';GRANTALLONref.tr_sex_sex TO diaspara_admin;GRANTSELECTONref.tr_sex_sex TO diaspara_read;
Immature - attempt made but sex could not be destinguished
I
48dabe79-03f3-4fc2-ab66-cb1cc52cc735
SEXCO
4
M
Male
M
9d81d4b2-dfc7-4fb0-86ee-b66e13a2125c
SEXCO
5
T
Transitional
T
484e5245-7f83-4d0d-957c-43f17c17f0af
SEXCO
6
U
Undetermined - no attempt made
U
ea6f732e-cef7-4f5a-abbc-71baa2f4dcfe
SEXCO
7
X
Mixed
X
4056362e-05ec-4f0f-8e24-d99e30821fe0
SEXCO
2.21 Gear (ref.tr_gear_gea)
The gears dictionnary is set by FAO and used in EU link. There is a gear dictionary in ICES but it’s used to describe the type of engine on experimental trawling surveys. There might be a need to include more passive engine like trap and fishways.
SQL code to create table tr_gear_gea
DROPTABLEIFEXISTSref.tr_gear_gea;CREATETABLEref.tr_gear_gea ( gea_id serial4 NOTNULL, gea_code text NOTNULL, gea_description text NULL, gea_icesvalue varchar(4) NULL, gea_icesguid uuid NULL, gea_icestablesource text NULL,CONSTRAINT tr_gear_gea_pkey PRIMARYKEY (gea_id),CONSTRAINT uk_gea_code UNIQUE (gea_code));COMMENTONTABLEref.tr_gear_gea IS'Table of fishing gears coming from FAO https://openknowledge.fao.org/server/api/core/bitstreams/830259c5-cbba-49f8-ae0d-819cd54356d3/content';COMMENTONCOLUMNref.tr_gear_gea.gea_id IS'Id of the gear internal serial';COMMENTONCOLUMNref.tr_gear_gea.gea_issscfg_code IS'Isssfg code of the gear';COMMENTONCOLUMNref.tr_gear_gea.gea_description IS'English name of the gear';COMMENTONCOLUMNref.tr_maturity_mat.mat_icesvalue IS'Code (Key) of the maturity in ICES db';COMMENTONCOLUMNref.tr_maturity_mat.mat_icesguid IS'UUID (guid) of ICES, you can access by pasting ';GRANTALLONref.tr_gear_gea TO diaspara_admin;GRANTSELECTONref.tr_gear_gea TO diaspara_read;-- manual code to merge tr_gear_with ICES DBUPDATEref.tr_gear_geaSET gea_icestablesource='GearType',gea_icesvalue='PS'WHERE gea_id=1;UPDATEref.tr_gear_geaSET gea_icestablesource='GearType',gea_icesvalue='SB'WHERE gea_id=4;UPDATEref.tr_gear_geaSET gea_icestablesource='GearType',gea_icesvalue='SBV'WHERE gea_id=5;UPDATEref.tr_gear_geaSET gea_icestablesource='GearType',gea_icesvalue='TBB'WHERE gea_id=7;UPDATEref.tr_gear_geaSET gea_icestablesource='GearType',gea_icesvalue='LLS'WHERE gea_id=45;UPDATEref.tr_gear_geaSET gea_icestablesource='GearType',gea_icesvalue='LLD'WHERE gea_id=46;UPDATEref.tr_gear_geaSET gea_icestablesource='GearType',gea_icesvalue='LTL'WHERE gea_id=49;UPDATEref.tr_gear_geaSET gea_icestablesource='GearType',gea_icesvalue='LX'WHERE gea_id=50;UPDATEref.tr_gear_geaSET gea_icestablesource='GearType',gea_icesvalue='MIS'WHERE gea_id=59;UPDATE"ref".tr_gear_geaSET gea_icestablesource='GearType',gea_icesvalue='HMD'WHERE gea_id=20;UPDATE"ref".tr_gear_geaSET gea_icestablesource='GearType',gea_icesvalue='LA'WHERE gea_id=27;UPDATE"ref".tr_gear_geaSET gea_icestablesource='GearType',gea_icesvalue='GND'WHERE gea_id=30;UPDATE"ref".tr_gear_geaSET gea_icestablesource='GearType',gea_icesvalue='GNC'WHERE gea_id=31;UPDATE"ref".tr_gear_geaSET gea_icestablesource='GearType',gea_icesvalue=''WHERE gea_id=32;UPDATE"ref".tr_gear_geaSET gea_icestablesource='GearType',gea_icesvalue='GRT'WHERE gea_id=33;UPDATE"ref".tr_gear_geaSET gea_icestablesource='GearType',gea_icesvalue='GTN'WHERE gea_id=34;UPDATE"ref".tr_gear_geaSET gea_icestablesource='GearType',gea_icesvalue='FPO'WHERE gea_id=37;UPDATE"ref".tr_gear_geaSET gea_icestablesource='GearType',gea_icesvalue='FYK'WHERE gea_id=38;UPDATE"ref".tr_gear_geaSET gea_icestablesource='GearType',gea_icesvalue='LHP'WHERE gea_id=43;UPDATE"ref".tr_gear_geaSET gea_icestablesource='GearType'WHERE gea_id=1;UPDATE"ref".tr_gear_geaSET gea_icestablesource='GearType'WHERE gea_id=4;UPDATE"ref".tr_gear_geaSET gea_icestablesource='GearType'WHERE gea_id=5;UPDATE"ref".tr_gear_geaSET gea_icestablesource='GearType'WHERE gea_id=7;UPDATE"ref".tr_gear_geaSET gea_icestablesource='GearType'WHERE gea_id=45;UPDATE"ref".tr_gear_geaSET gea_icestablesource='GearType'WHERE gea_id=46;UPDATE"ref".tr_gear_geaSET gea_icestablesource='GearType'WHERE gea_id=49;UPDATE"ref".tr_gear_geaSET gea_icestablesource='GearType'WHERE gea_id=50;UPDATE"ref".tr_gear_geaSET gea_icestablesource='GearType'WHERE gea_id=59; --28UPDATE"ref".tr_gear_geaSET gea_icestablesource='GearType'WHERE gea_id=7;UPDATE"ref".tr_gear_geaSET gea_icestablesource='GearType',gea_icesvalue='OTB'WHERE gea_id=8;UPDATE"ref".tr_gear_geaSET gea_icestablesource='GearType',gea_icesvalue='OTT'WHERE gea_id=10;UPDATE"ref".tr_gear_geaSET gea_icestablesource='GearType',gea_icesvalue='PTB'WHERE gea_id=11;UPDATE"ref".tr_gear_geaSET gea_icestablesource='GearType',gea_icesvalue='OTM'WHERE gea_id=13;ALTERTABLE tr_gear_gea SET gea_code
Hand Implements (Wrenching gear, Clamps, Tongs, Rakes, Spears)
NA
NA
NA
53
10.3
Pumps
NA
NA
NA
54
10.4
Electric fishing
NA
NA
NA
55
10.5
Pushnets
NA
NA
NA
56
10.6
Scoopnets
NA
NA
NA
57
10.7
Drive-in nets
NA
NA
NA
58
10.8
Diving
NA
NA
NA
20
04.3
Mechanized dredges
HMD
NA
GearType
27
06.2
Cover pots/Lantern nets
LA
NA
GearType
30
07.2
Drift gillnets
GND
NA
GearType
31
07.3
Encircling gillnets
GNC
NA
GearType
32
07.4
Fixed gillnets (on stakes)
NA
GearType
33
07.5
Trammel nets
GRT
NA
GearType
34
07.6
Combined gillnets-trammel nets
GTN
NA
GearType
37
08.2
Pots
FPO
NA
GearType
38
08.3
Fyke nets
FYK
NA
GearType
43
09.1
Handlines and hand-operated pole-and-lines
LHP
NA
GearType
1
01.1
Purse seines
PS
NA
GearType
4
02.1
Beach seines
SB
NA
GearType
5
02.2
Boat seines
SBV
NA
GearType
45
09.31
Set longlines
LLS
NA
GearType
46
09.32
Drifting longlines
LLD
NA
GearType
49
09.5
Trolling lines
LTL
NA
GearType
50
09.9
Hooks and lines (nei)
LX
NA
GearType
59
10.9
Gear nei
MIS
NA
GearType
7
03.11
Beam trawls
TBB
NA
GearType
8
03.12
Single boat bottom otter trawls
OTB
NA
GearType
10
03.14
Multiple bottom otter trawls
OTT
NA
GearType
11
03.15
Bottom pair trawls
PTB
NA
GearType
13
03.21
Single boat midwater otter trawls
OTM
NA
GearType
60
99.9
Gear not known
NA
NA
Other dictionaries in ICES
The geartype which corresponds to metier 4 is sourced by the DCF and maintained by the JRC (contact can be provided by ICES). The Sampler type SMTYP provides a dictionary of the scientific gear used in monitoring, this one can be updated
Other source of definition (if needed)
Method used to monitor eel in the mediterranean are referenced in detail in this report.
2.22 ICES areas
We have create entries in the table `tr_fishingarea_fia for FAO major fishing area (27, 21, 37, 34, 31).
source : ICES statistical areas https://gis.ices.dk/shapefiles/ICES_areas.zip https://gis.ices.dk/geonetwork/srv/eng/catalog.search#/metadata/c784a0a3-752f-4b50-b02f-f225f6c815eb
The rest of the word was somewhere on my computer. Cannot trace the source, it’s exaclty the same for NAFO but changed in the med and ICES. For some reasons was not complete in table from wgeel so have to download it again to postgres.
Values for geom have been updated from ICES areas, the new boundaries are different, however, there are more than the previous ones. The values for Areas and Subareas have not been updated but these are for wide maps so we’ll leave it as it is.
Code to create reference fishing area maps
dbExecute(con_diaspara_admin, "DROP TABLE IF EXISTS ref.tr_fishingarea_fia CASCADE;")dbExecute(con_diaspara_admin," CREATE TABLE ref.tr_fishingarea_fia ( fia_level TEXT, fia_code TEXT, fia_status numeric, fia_ocean TEXT, fia_subocean TEXT, fia_area TEXT, fia_subarea TEXT, fia_division TEXT, fia_subdivision TEXT, fia_unit TEXT, fia_name TEXT NULL, geom geometry(MultiPolygon,4326), CONSTRAINT tr_fishingarea_fia_pkey PRIMARY KEY (fia_code), CONSTRAINT uk_fia_subdivision UNIQUE (fia_unit) ) ;")# start with initial FAO dataset#area_all <- dbGetQuery(con_diaspara_admin, "SELECT * FROM area.\"FAO_AREAS\"# WHERE f_area IN ('21','27','31','34','37') ;")# In this table all geom are mixed from unit to division.# It only make sense to extract for a unique f_level# TODO add species, wkdbExecute(con_diaspara_admin, "INSERT INTO ref.tr_fishingarea_fiaSELECT initcap(f_level) AS fia_level, f_code AS fia_code, f_status AS fia_status, ocean AS fia_ocean, subocean AS fia_subocean, f_area AS fia_area, f_subarea AS fia_subarea, f_division AS fia_division, f_subdivis AS fia_subdivision, f_subunit AS fia_unit, NULL as fia_name, geom FROM area.\"FAO_AREAS\" WHERE f_area IN ('21','27','31','34','37') ") # 187# Replace values icesdbExecute(con_diaspara_admin, "UPDATE ref.tr_fishingarea_fia set geom = st_transform(are.geom, 4326) FROM area.\"ICES_Areas_20160601_cut_dense_3857\" are WHERE area_full = fia_code;") # 66# Replace values NAFO (nothing to do ...)# Replace values GFCMdbExecute(con_diaspara_admin, "INSERT INTO ref.tr_fishingarea_fiaSELECT 'Subdivision' AS fia_level, f_gsa AS fia_code,1 AS fia_status,'Atlantic' AS fia_ocean, 3 AS fia_subocean, f_area, f_subarea, f_division, f_gsa AS fia_subdivision,NULL AS fia_unit,smu_name AS fia_name,geomFROM area.\"GSAs_simplified_division\";") # 32dbExecute(con_diaspara_admin, "GRANT ALL ON ref.tr_fishingarea_fia TO diaspara_admin;")dbExecute(con_diaspara_admin, "GRANT SELECT ON ref.tr_fishingarea_fia TO diaspara_read;")dbExecute(con_diaspara_admin, "COMMENT ON TABLE ref.tr_fishingarea_fia IS 'Table of fishing areas, attention, different levels of geometrydetails are present in the table, area, subarea, division, subdivision, unit,most query will use WHERE fia_level = ''Subdivision''';")
Coderedce to create a map of fishing areas at Major level
library(rnaturalearth)world <-ne_countries(scale ="small", returnclass ="sf")if (file.exists("data/fishingareas_major.Rdata")) load("data/fishingareas_major.Rdata") else { fishing_areas_major <- sf::st_read(con_diaspara,query ="SELECT fia_code, ST_MakeValid(geom) from ref.tr_fishingarea_fia WHERE fia_level = 'Major'") |> sf::st_transform(4326) save(fishing_areas_major, file="data/fishing_areas_major.Rdata") }load("data/country_sf.Rdata")crs_string <-"+proj=ortho +lon_0=-30 +lat_0=30"ocean <- sf::st_point(x =c(0,0)) |> sf::st_buffer(dist =6371000) |> sf::st_sfc(crs = crs_string)area_sf2 <- fishing_areas_major |> sf::st_intersection(ocean |> sf::st_transform(4326)) |> sf::st_transform(crs = crs_string) country_sf2 <- country_sf |> sf::st_intersection(ocean |> sf::st_transform(4326)) |> sf::st_transform(crs = crs_string) g <-ggplot() +geom_sf(data = ocean, fill ="deepskyblue4", color =NA) +geom_sf(data = area_sf2, aes(fill = fia_code), color="white", lwd = .1) +geom_sf(data = world, fill="black", color="grey20") +geom_sf(data= country_sf2 , fill="grey10",color="grey30") +theme_void()#scale_fill_discrete(guide = "none") +# this part is used to avoid long computationspng(filename="images/fig-fishingareas_major.png",width=600, height=600, res=300, bg="transparent")print(g)dev.off()
Figure 5: Map of ICES fishing areas at Major level, source NAFO, FAO, ICES, GFCM.
Code to create a map of fishing areas at Subarea level
if (file.exists("data/fishingareas_subarea.Rdata")) load("data/fishingareas_subarea.Rdata") else { fishing_areas_subarea <- sf::st_read(con_diaspara,query ="SELECT fia_code, ST_MakeValid(geom) from ref.tr_fishingarea_fia WHERE fia_level = 'Subarea'") |> sf::st_transform(4326) save(fishing_areas_subarea, file="data/fishing_areas_subarea.Rdata")}crs_string <-"+proj=ortho +lon_0=-30 +lat_0=30"area_sf2 <- fishing_areas_subarea |> sf::st_intersection(ocean |> sf::st_transform(4326)) |> sf::st_transform(crs = crs_string) # reproject to orthog <-ggplot() +geom_sf(data = ocean, fill ="deepskyblue4", color =NA) +geom_sf(data = area_sf2, aes(fill = fia_code), color="white", lwd = .1) +geom_sf(data = world, fill="black", color="grey20") +geom_sf(data= country_sf2 , fill="grey10",color="grey30") +scale_fill_discrete(guide ="none") +theme_void()# this part is used to avoid long computationspng(filename="images/fig-fishingareas_subarea.png", bg="transparent")print(g)dev.off()
Figure 6: Map of ICES fishing areas at Subarea level, source NAFO, FAO, ICES, GFCM.
Code to create a map of fishing areas at Division level
Figure 8: Map of ICES fishing areas at subdivision level, source NAFO, FAO, ICES, GFCM.
2.23 Time period (ref.tr_timeperiod_tip) WGBAST
WGBAST reports data per month, quarter, or half year. There is a vocabulary for quarters, couldn’t find a vocab for half of year.
SQL code to create table tr_timeperiod_tip
-- maturity table codeDROPTABLEIFEXISTSref.tr_timeperiod_tip CASCADE;CREATETABLEref.tr_timeperiod_tip ( tip_id SERIAL PRIMARYKEY, tip_code TEXT NOTNULLCONSTRAINT uk_tip_code UNIQUE, tip_description TEXT, tip_icesvalue TEXT, tip_icesguid uuid, tip_icestablesource text);COMMENTONTABLEref.tr_timeperiod_tip IS'Table of time periods';COMMENTONCOLUMNref.tr_timeperiod_tip.tip_id IS'Integer, primary key of the table';COMMENTONCOLUMNref.tr_timeperiod_tip.tip_code IS'The code of time period';COMMENTONCOLUMNref.tr_timeperiod_tip.tip_description IS'Definition of the time period';COMMENTONCOLUMNref.tr_timeperiod_tip.tip_icesvalue IS'Code (Key) of the time period in ICES db';COMMENTONCOLUMNref.tr_timeperiod_tip.tip_icesguid IS'UUID (guid) of ICES, you can access by pasting ';COMMENTONCOLUMNref.tr_timeperiod_tip.tip_icestablesource IS'Source table in ICES';GRANTALLONref.tr_timeperiod_tip TO diaspara_admin;GRANTSELECTONref.tr_timeperiod_tip TO diaspara_read;
Code to import timeperiod codes
tp <- icesVocab::getCodeList('IC_SeasonType')#I don't want this I want a codetip <-data.frame(tip_id=1:4, tip_code =c(tp$Key, "Half of Year"), tip_description =c("Monthly data, from 1 to 12", "Quarterly data from 1 to 4", "Year value of timeperiod should be NULL and year column filled", "Half of year, either from 1 to 6 (included)=1, or from month 7 to 12 (included)=2"), tip_icesvalue =c(tp$Key,NA),tip_icesguid =c(tp$Guid,NA),tip_icestablesource =c(rep("IC_SeasonType", 3), NA))|>select(tip_id, tip_code, tip_description, tip_icesvalue, tip_icesguid, tip_icestablesource)tip$tip_icesguid <-as.character(tip$tip_icesguid)DBI::dbWriteTable(con_diaspara_admin, "temp_tipr", tip, overwrite =TRUE)DBI::dbExecute(con_diaspara_admin, "DELETE FROM ref.tr_timeperiod_tip")DBI::dbExecute(con_diaspara_admin, "INSERT INTO ref.tr_timeperiod_tip(tip_id, tip_code, tip_description, tip_icesvalue, tip_icesguid, tip_icestablesource)SELECT tip_id, tip_code, tip_description, tip_icesvalue, tip_icesguid::uuid, tip_icestablesourceFROM temp_tipr")# 4DBI::dbExecute(con_diaspara_admin, "DROP table temp_tipr")
Year value of timeperiod should be NULL and year column filled
Year
379109cd-e525-43a8-b3d8-061f1b27d5ae
IC_SeasonType
4
Half of Year
Half of year, either from 1 to 6 (included)=1, or from month 7 to 12 (included)=2
NA
NA
NA
2.24 Data source (ref.tr_datasource_dts) WGBAST
The source of fishery data is included in WGBAST see : WBAST description. THe vocab described her is deprecated and superseeded by datasource.
During exchange with Data Centre (Thanks Maria for hinting at this change), the current way of handling estimated data, is to separate the source of data and the type of estimation. This is how it works currently in RDBES. So a catch can coming from logbook, it is estimated, and when estimated a method must be provided if estimated (estimation method.)
SQL code to create table tr_datasource_dts
-- Table for qualityDROPTABLEIFEXISTSref.tr_datasource_dts CASCADE;CREATETABLEref.tr_datasource_dts ( dts_id int4 PRIMARYKEY, dts_code TEXT NOTNULLCONSTRAINT uk_dts_code UNIQUE, dts_description text NULL, dts_icesvalue TEXT, dts_icesguid uuid, dts_icestablesource text);COMMENTONTABLEref.tr_datasource_dts IS'Table of data source values, e.g. logbooks, Expert value ...';COMMENTONCOLUMNref.tr_datasource_dts.dts_code IS'Data srouce code';COMMENTONCOLUMNref.tr_datasource_dts.dts_description IS'Data source description';COMMENTONCOLUMNref.tr_datasource_dts.dts_icesvalue IS'Code (Key) of the time period in ICES db';COMMENTONCOLUMNref.tr_datasource_dts.dts_icesguid IS'UUID (guid) of ICES, you can access by pasting ';COMMENTONCOLUMNref.tr_datasource_dts.dts_icestablesource IS'Source table in ICES';GRANTALLONref.tr_datasource_dts TO diaspara_admin;GRANTSELECTONref.tr_datasource_dts TO diaspara_read;
Table 27: Table of source of data used by WGBAST, some of the values might fit in there but some will need a work by national expert (EST estimated has no correspondance) though it might be extrapolated by some of the comments. The smolt estimation methods are those reported in the young fish table.
dts_id
dts_code
dts_description
dts_icesvalue
dts_icesguid
dts_icestablesource
1
CombOD
Combination of official data sources (logbooks, sales notes, other forms)
CombOD
0cad919b-6b32-4f61-b46c-15c844ab709c
DataSource
2
Crew
Vessel Crew. Data obtained directly from the crew of the vessel (not via any official data sources).
Crew
55aa9706-acef-48a9-8957-6acee01b414d
DataSource
3
Exprt
Expert knowledge. Data is estimated using expert knowledge about the activity. This could include knowledge about previous or similar activities
Exprt
f27ddbe0-c129-4710-b810-7a6347f218af
DataSource
4
HarbLoc
Harbor location (Landing port harbor used as basis to estimate fishing geographical location)
HarbLoc
3b31e2fc-764b-4dd5-9004-d6207e5bcc0c
DataSource
5
Logb
Logbook data
Logb
fc35fdd4-c1d8-42df-b5f0-69a712acbe8b
DataSource
6
NotApplicable
Not applicable
NotApplicable
39a9619d-b6be-4987-9535-d20b187c8f9f
DataSource
7
Observer
Observer. Data obtained directly by an observer.
Observer
d6a7b983-1b65-4d1b-b737-bd01a1a79ebd
DataSource
8
OthDF
Other declarative forms (i.e. landing declarations and national declarative forms)
OthDF
d92692a7-f647-47cb-8e01-2df27c9a0403
DataSource
9
PosDat
Positional data (other than VMS)
PosDat
10c38e41-cd59-4b19-a474-26a1f16e3b97
DataSource
10
SalN
Sales notes
SalN
f9ccdb0b-16c5-4ebf-a825-a430bc68327a
DataSource
11
SampDC
Commercial sampling data (sampling methodologies specific to each country). This refers to sampling in commercial vessels, not only for commercial species.
SampDC
4c4de39b-b70a-4a24-9f36-b721f160d503
DataSource
12
SampDS
Survey sampling data (sampling methodologies specific to each country)
SampDS
3abbc039-9e7c-4d06-a0fb-0e0ced358a64
DataSource
13
Unknown
Not known
Unknown
88500a0d-2248-4356-ac91-4caa7fa8394e
DataSource
14
VMS
VMS data
VMS
07fd7b3e-cba2-4de0-a517-125a2c6fc220
DataSource
15
Smolt
Smolt count
NA
NA
NA
16
Parr
Parr densities (electrofishing)
NA
NA
NA
17
Spawner
Spawner count
NA
NA
NA
18
Stocking
Stocking data
NA
NA
NA
2.25 Data basis ref.tr_databasis_dtb (WGBAST)
SQL code to create table tr_databasis_dtb
-- Table of estimation methods when databasis is EstimatedDROPTABLEIFEXISTSref.tr_databasis_dtb CASCADE;CREATETABLEref.tr_databasis_dtb ( dtb_id int4 PRIMARYKEY, dtb_code TEXT NOTNULLCONSTRAINT uk_dtb_code UNIQUE, dtb_description text NULL, dtb_icesvalue TEXT, dtb_icesguid uuid, dtb_icestablesource text);COMMENTONTABLEref.tr_databasis_dtb IS'Table of data basis';COMMENTONCOLUMNref.tr_databasis_dtb.dtb_code IS'Data basis code';COMMENTONCOLUMNref.tr_databasis_dtb.dtb_description IS'Data basis description';COMMENTONCOLUMNref.tr_databasis_dtb.dtb_icesvalue IS'Code (Key) of the Data basis in ICES';COMMENTONCOLUMNref.tr_databasis_dtb.dtb_icesguid IS'UUID (guid) of ICES ';COMMENTONCOLUMNref.tr_databasis_dtb.dtb_icestablesource IS'Source table in ICES';GRANTALLONref.tr_databasis_dtb TO diaspara_admin;GRANTSELECTONref.tr_databasis_dtb TO diaspara_read;
2.26 Data estimation method ref.tr_estimationmethod_esm
This table will be inherited, we are proposing working group specific estimation methods. Typically estimation methods of WGBAST. These will only be used if sto_dtb_code = ‘Estimated’
Complete count of smolts.
Sampling of smolts and estimate of total smolt run size.
Estimate of smolt run from parr production by relation developed in the same river.
Estimate of smolt run from parr production by relation developed in another river.
Inference of smolt production from data derived from similar rivers in the region.
Count of spawners.
Estimate inferred from stocking of reared fish in the river.
Salmon catch, exploitation and survival estimate.
SQL code to create table ref.tr_estimationmethod_esm
-- Table of estimation methods when databasis is EstimatedDROPTABLEIFEXISTSref.tr_estimationmethod_esm CASCADE;CREATETABLEref.tr_estimationmethod_esm ( esm_id int4 PRIMARYKEY, esm_code TEXT NOTNULLCONSTRAINT uk_esm_code UNIQUE, esm_description text NULL, esm_wkg_code TEXT NOTNULL,CONSTRAINT fk_esm_wkg_code FOREIGNKEY (esm_wkg_code)REFERENCESref.tr_icworkinggroup_wkg(wkg_code)ONUPDATECASCADEONDELETERESTRICT, esm_icesvalue TEXT, esm_icesguid uuid, esm_icestablesource text);COMMENTONTABLEref.tr_estimationmethod_esm IS'Table of table estimation method, provided when databasis (dtb_code) correspond to Estimated';COMMENTONCOLUMNref.tr_estimationmethod_esm.esm_code IS'Estimation method code';COMMENTONCOLUMNref.tr_estimationmethod_esm.esm_description IS'Estimation method description';COMMENTONCOLUMNref.tr_estimationmethod_esm.esm_icesvalue IS'Code (Key) of the Estimation method in ICES';COMMENTONCOLUMNref.tr_estimationmethod_esm.esm_icesguid IS'UUID (guid) of ICES ';COMMENTONCOLUMNref.tr_estimationmethod_esm.esm_icestablesource IS'Source table in ICES';COMMENTONCOLUMNref.tr_estimationmethod_esm.esm_wkg_code IS'Code of the working group, one of WGBAST, WGEEL, WGNAS, WKTRUTTA';GRANTALLONref.tr_estimationmethod_esm TO diaspara_admin;GRANTSELECTONref.tr_estimationmethod_esm TO diaspara_read;
Note
The estimationmethod are set in each working group table, they are inherited. see refbast.tr_estimationmethod_esm
3 Metadata
3.1 Metadata (dat.t_metadata_met)
The code for creating metadata is listed below
SQL code to create table dat.t_metadata_met
DROPTABLEIFEXISTS dat.t_metadata_met CASCADE;CREATETABLE dat.t_metadata_met ( met_var TEXT NOTNULL, met_spe_code charactervarying(3) NOTNULL, met_wkg_code TEXT NOTNULL, met_ver_code TEXT NULL, met_oty_code TEXT NOTNULL, met_nim_code TEXT NOTNULL, met_dim integerARRAY, met_dimname TEXT ARRAY, met_modelstage TEXT NULL, met_type TEXT NULL, met_location TEXT NULL, met_fishery TEXT NULL, met_mtr_code TEXT NULL, met_des_code TEXT NULL, met_uni_code TEXT NULL, met_cat_code TEXT NULL, met_definition TEXT NULL, met_deprecated BOOLEANDEFAULTFALSE,CONSTRAINT t_metadata_met_pkey PRIMARYKEY(met_var, met_spe_code),CONSTRAINT fk_met_spe_code FOREIGNKEY (met_spe_code)REFERENCESref.tr_species_spe(spe_code) ONDELETECASCADEONUPDATECASCADE,CONSTRAINT fk_met_wkg_code FOREIGNKEY (met_wkg_code)REFERENCESref.tr_icworkinggroup_wkg(wkg_code) ONDELETECASCADEONUPDATECASCADE,CONSTRAINT fk_met_ver_code FOREIGNKEY (met_ver_code)REFERENCESref.tr_version_ver(ver_code) ONDELETECASCADEONUPDATECASCADE,CONSTRAINT fk_met_oty_code FOREIGNKEY (met_oty_code) REFERENCESref.tr_objecttype_oty (oty_code) ONDELETECASCADEONUPDATECASCADE,CONSTRAINT fk_met_nim_code FOREIGNKEY (met_nim_code) REFERENCESref.tr_nimble_nim (nim_code) ONDELETECASCADEONUPDATECASCADE, CONSTRAINT fk_met_mtr_code FOREIGNKEY (met_mtr_code)REFERENCESref.tr_metric_mtr(mtr_code)ONDELETECASCADEONUPDATECASCADE,CONSTRAINT fk_met_uni_code FOREIGNKEY (met_uni_code)REFERENCESref.tr_units_uni(uni_code)ONDELETECASCADEONUPDATECASCADE,CONSTRAINT fk_met_cat_code FOREIGNKEY (met_cat_code)REFERENCESref.tr_category_cat(cat_code)ONDELETECASCADEONUPDATECASCADE,CONSTRAINT fk_met_des_code FOREIGNKEY (met_des_code)REFERENCESref.tr_destination_des(des_code)ONDELETECASCADEONUPDATECASCADE);COMMENTONTABLE dat.t_metadata_met IS'Table (metadata) of each variable (parameter) in the database.';COMMENTONCOLUMN dat.t_metadata_met.met_var IS'Variable code, primary key on both met_spe_code and met_var.';COMMENTONCOLUMN dat.t_metadata_met.met_spe_code IS'Species, ANG, SAL, TRT ... primary key on both met_spe_code and met_var.';COMMENTONCOLUMN dat.t_metadata_met.met_ver_code IS'Code on the version of the model, see table tr_version_ver.';COMMENTONCOLUMN dat.t_metadata_met.met_oty_code IS'Object type, single_value, vector, matrix see table tr_objecttype_oty.';COMMENTONCOLUMN dat.t_metadata_met.met_nim_code IS'Nimble type, one of data, constant, output, other.';COMMENTONCOLUMN dat.t_metadata_met.met_dim IS'Dimension of the Nimble variable, use {10, 100, 100} to insert the description of an array(10,100,100).';COMMENTONCOLUMN dat.t_metadata_met.met_dimname IS'Dimension of the variable in Nimble, use {''year'', ''stage'', ''area''}.';COMMENTONCOLUMN dat.t_metadata_met.met_modelstage IS'Currently one of fit, other, First year.';COMMENTONCOLUMN dat.t_metadata_met.met_type IS'Type of data in the variable, homewatercatches, InitialISation first year,abundance ....';COMMENTONCOLUMN dat.t_metadata_met.met_location IS'Describe process at sea, e.g. Btw. FAR - GLD fisheries, or Aft. Gld fISheries.';COMMENTONCOLUMN dat.t_metadata_met.met_fishery IS'Description of the fishery.';COMMENTONCOLUMN dat.t_metadata_met.met_des_code IS'Outcome of the fish, e.g. Released (alive), Seal damage,Removed (from the environment), references table tr_destination_des.';COMMENTONCOLUMN dat.t_metadata_met.met_uni_code IS'Unit, references table tr_unit_uni.';COMMENTONCOLUMN dat.t_metadata_met.met_cat_code IS'Broad category of data or parameter, catch, effort, biomass, mortality, count ...references table tr_category_cat.';COMMENTONCOLUMN dat.t_metadata_met.met_mtr_code IS'Code of the metric, references tr_metric_mtr, Estimate, Bound, SD, CV ....';COMMENTONCOLUMN dat.t_metadata_met.met_definition IS'Definition of the metric.';COMMENTONCOLUMN dat.t_metadata_met.met_deprecatedIS'Is the variable still used ?';GRANTALLON dat.t_metadata_met TO diaspara_admin;GRANTSELECTON dat.t_metadata_met TO diaspara_read;/*SELECT * FROM refsalmoglob."database" JOINdatnas.t_metadata_met AS tmm ON tmm.met_var = var_modWHERE "year" IS NULL*/
Table 28: metadata
4 WGNAS
The WGNAS database is created in schemas refnas and datna (see Section 1)
4.1 Create referential for WGNAS
Creating the referential for WGNAS
DROPTABLEIFEXISTS refnas.tr_version_ver CASCADE;CREATETABLE refnas.tr_version_ver() inherits (ref.tr_version_ver);ALTERTABLE refnas.tr_version_ver ADDCONSTRAINT ver_code_pkey PRIMARYKEY (ver_code);ALTERTABLE refnas.tr_version_ver ADDCONSTRAINT fk_ver_spe_code FOREIGNKEY (ver_spe_code) REFERENCESref.tr_species_spe(spe_code)ONUPDATECASCADEONDELETECASCADE;COMMENTONTABLE refnas.tr_version_verIS'Table of data or variable version, essentially one datacall or advice, inherits ref.tr_version_ver';COMMENTONCOLUMN refnas.tr_version_ver.ver_code IS'Version code, stockkey-year-version.';COMMENTONCOLUMN refnas.tr_version_ver.ver_year IS'Year of assessement.';COMMENTONCOLUMN refnas.tr_version_ver.ver_spe_code IS'Species code e.g. 'SAL' references tr_species_spe.';COMMENTONCOLUMN refnas.tr_version_ver.ver_stockkeylabel IS'Ver_stockkeylabel e.g. ele.2737.nea.';COMMENTONCOLUMN refnas.tr_version_ver.ver_datacalldoi IS'Data call DOI, find a way to retrieve that information and update this comment';COMMENTONCOLUMN refnas.tr_version_ver.ver_version IS'Version code in original database, eg 2,4 for wgnas, dc_2020 for wgeel.';COMMENTONCOLUMN refnas.tr_version_ver.ver_description IS'Description of the data call / version.';GRANTALLON refnas.tr_version_ver TO diaspara_admin;GRANTSELECTON refnas.tr_version_ver TO diaspara_read;
4.2 Import the metadata table
Creating the referential for WGNAS
DROPTABLEIFEXISTS datnas.t_metadata_met;CREATETABLE datnas.t_metadata_met(met_oldversion numeric)INHERITS (ref.t_metadata_met);-- ADDING CONSTRAINTSALTERTABLE datnas.t_metadata_met ADDCONSTRAINT t_metadata_met_pkey PRIMARYKEY(met_var, met_spe_code);ALTERTABLE datnas.t_metadata_met ADDCONSTRAINT fk_met_spe_code FOREIGNKEY (met_spe_code)REFERENCESref.tr_species_spe(spe_code) ONDELETECASCADEONUPDATECASCADE;ALTERTABLE datnas.t_metadata_met ADDCONSTRAINT ck_met_spe_code CHECK (met_spe_code='SAL'); ALTERTABLE datnas.t_metadata_met ADDCONSTRAINT fk_met_wkg_code FOREIGNKEY (met_wkg_code)REFERENCESref.tr_icworkinggroup_wkg(wkg_code) ONDELETECASCADEONUPDATECASCADE;ALTERTABLE datnas.t_metadata_met ADDCONSTRAINT ck_met_wkg_code CHECK (met_wkg_code='WGNAS');ALTERTABLE datnas.t_metadata_met ADDCONSTRAINT fk_met_ver_code FOREIGNKEY (met_ver_code)REFERENCES refnas.tr_version_ver(ver_code) ONDELETECASCADEONUPDATECASCADE;ALTERTABLE datnas.t_metadata_met ADDCONSTRAINT fk_met_oty_code FOREIGNKEY (met_oty_code) REFERENCESref.tr_objecttype_oty (oty_code) ONDELETECASCADEONUPDATECASCADE;ALTERTABLE datnas.t_metadata_met ADDCONSTRAINT fk_met_nim_code FOREIGNKEY (met_nim_code) REFERENCESref.tr_nimble_nim (nim_code) ONDELETECASCADEONUPDATECASCADE;ALTERTABLE datnas.t_metadata_met ADDCONSTRAINT fk_met_mtr_code FOREIGNKEY (met_mtr_code)REFERENCESref.tr_metric_mtr(mtr_code)ONDELETECASCADEONUPDATECASCADE;ALTERTABLE datnas.t_metadata_met ADDCONSTRAINT fk_met_uni_code FOREIGNKEY (met_uni_code)REFERENCESref.tr_units_uni(uni_code)ONDELETECASCADEONUPDATECASCADE;ALTERTABLE datnas.t_metadata_met ADDCONSTRAINT fk_met_cat_code FOREIGNKEY (met_cat_code)REFERENCESref.tr_category_cat(cat_code)ONDELETECASCADEONUPDATECASCADE;ALTERTABLE datnas.t_metadata_met ADDCONSTRAINT fk_met_des_code FOREIGNKEY (met_des_code)REFERENCESref.tr_destination_des(des_code)ONDELETECASCADEONUPDATECASCADE;-- COMMENTS FOR WGNASCOMMENTONTABLE datnas.t_metadata_met IS'Table (metadata) of each variable (parameter) in the wgnas database.';COMMENTONCOLUMN refnas.t_metadata_met.met_var IS'Variable code, primary key on both met_spe_code and met_var.';COMMENTONCOLUMN refnas.t_metadata_met.met_spe_code IS'Species, SAL primary key on both met_spe_code and met_var.';COMMENTONCOLUMN refnas.t_metadata_met.met_ver_code IS'Code on the version of the model, see table tr_version_ver.';COMMENTONCOLUMN refnas.t_metadata_met.met_oty_code IS'Object type, single_value, vector, matrix see table tr_objecttype_oty.';COMMENTONCOLUMN refnas.t_metadata_met.met_nim_code IS'Nimble type, one of data, constant, output, other.';COMMENTONCOLUMN refnas.t_metadata_met.met_dim IS'Dimension of the Nimble variable, use {10, 100, 100} to insert the description of an array(10,100,100).';COMMENTONCOLUMN refnas.t_metadata_met.met_dimname IS'Dimension of the variable in Nimble, use {''year'', ''stage'', ''area''}.';COMMENTONCOLUMN refnas.t_metadata_met.met_modelstage IS'Currently one of fit, other, First year.';COMMENTONCOLUMN refnas.t_metadata_met.met_type IS'Type of data in the variable, homewatercatches, InitialISation first year,abundance ....';COMMENTONCOLUMN refnas.t_metadata_met.met_location IS'Describe process at sea, e.g. Btw. FAR - GLD fisheries, or Aft. Gld fISheries.';COMMENTONCOLUMN refnas.t_metadata_met.met_fishery IS'Description of the fishery.';COMMENTONCOLUMN refnas.t_metadata_met.met_des_code IS'Destination of the fish, e.g. Released (alive), Seal damage,Removed (from the environment), references table tr_destination_des., this is currently only used by WGBAST,so can be kept NULL';COMMENTONCOLUMN refnas.t_metadata_met.met_uni_code IS'Unit, refnaserences table tr_unit_uni.';COMMENTONCOLUMN refnas.t_metadata_met.met_cat_code IS'Broad category of data or parameter, catch, effort, biomass, mortality, count ...refnaserences table tr_category_cat.';COMMENTONCOLUMN refnas.t_metadata_met.met_mtr_code IS'Code of the metric, refnaserences tr_metric_mtr, Estimate, Bound, SD, CV ....';COMMENTONCOLUMN refnas.t_metadata_met.met_definition IS'Definition of the metric.';COMMENTONCOLUMN refnas.t_metadata_met.met_deprecatedIS'Is the variable still used ?';ALTERTABLE datnas.t_metadata_met OWNER TO diaspara_admin;GRANTSELECTON datnas.t_metadata_met TO diaspara_read;
After integration, the table of metadata from WGNAS is not changed much, apart from adapting to the new referentials. The table is show in Table Table 29.
Standard-deviation of observed catches (log scale) of NAC 1 SW by early Newfoundland fishery
NA
NA
log_C5_NAC_2_lbnf_lab_sd
SAL
WGNAS
WGNAS-2024-1
Vector
Parameter constant
{47,0,0}
{'Year',NULL,NULL}
Fit
Sea catches
Bef. Gld fisheries
LB fishery
SD
NA
NA
Catch
Standard-deviation of observed catches (log scale) of NAC Labrador-origin 1 SW by late Newfoundland, Labrador and Saint Pierre et Miquelon fisheries
NA
NA
log_C5_NAC_2_lbnf_oth_sd
SAL
WGNAS
WGNAS-2024-1
Vector
Parameter constant
{47,0,0}
{'Year',NULL,NULL}
Fit
Sea catches
Bef. Gld fisheries
LB/SPM/swNF fishery
SD
NA
NA
Catch
Standard-deviation of observed catches (log scale) of NAC Labrador-excluded 1 SW by late Newfoundland, Labrador and Saint Pierre et Miquelon fisheries
NA
NA
log_C5_NEC_1_far_sd
SAL
WGNAS
WGNAS-2024-1
Vector
Parameter constant
{47,0,0}
{'Year',NULL,NULL}
Fit
Sea catches
Bef. Gld fisheries
FAR fishery
SD
NA
NA
Catch
Standard-deviation of observed total catches (log scale) of 1SW adults from the NEC complex in Faroe islands
NA
NA
log_C8_2_gld_tot_sd
SAL
WGNAS
WGNAS-2024-1
Vector
Parameter constant
{47,0,0}
{'Year',NULL,NULL}
Fit
Sea catches
Gld fisheries
GLD fishery
SD
NA
NA
Catch
Standard-deviation of observed total catches (log scale) of 2SW adults (mixed complexes) in Greenland
NA
NA
log_C8_NAC_1_lbnf_sd
SAL
WGNAS
WGNAS-2024-1
Vector
Parameter constant
{47,0,0}
{'Year',NULL,NULL}
Fit
Sea catches
Bef. Gld fisheries
neNF fishery
SD
NA
NA
Catch
Standard-deviation of observed catches (log scale) of NAC 1 SW by Labrador/Newfoundland fishery
NA
NA
log_C8_NAC_3_lbnf_sd
SAL
WGNAS
WGNAS-2024-1
Vector
Parameter constant
{47,0,0}
{'Year',NULL,NULL}
Fit
Sea catches
Aft. Gld fisheries
neNF fishery
SD
NA
NA
Catch
Standard-deviation of observed catches (log scale) of NAC 2 SW by early Newfoundland fishery
NA
NA
log_C8_NAC_4_lbnf_lab_sd
SAL
WGNAS
WGNAS-2024-1
Vector
Parameter constant
{47,0,0}
{'Year',NULL,NULL}
Fit
Sea catches
Aft. Gld fisheries
LB fishery
SD
NA
NA
Catch
Standard-deviation of observed catches (log scale) of NAC Labrador-origin 2 SW by late Newfoundland, Labrador and Saint Pierre et Miquelon fisheries
NA
NA
log_C8_NAC_4_lbnf_oth_sd
SAL
WGNAS
WGNAS-2024-1
Vector
Parameter constant
{52,0,0}
{'Year',NULL,NULL}
Fit
Sea catches
Aft. Gld fisheries
LB/SPM/swNF fishery
SD
NA
NA
Catch
Standard-deviation of observed catches (log scale) of NAC Labrador-excluded 2 SW by late Newfoundland, Labrador and Saint Pierre et Miquelon fisheries
NA
NA
log_C8_NEC_1_far_sd
SAL
WGNAS
WGNAS-2024-1
Vector
Parameter constant
{50,0,0}
{'Year',NULL,NULL}
Fit
Sea catches
Bef. Gld fisheries
FAR fishery
SD
NA
NA
Catch
Standard-deviation of observed total catches (log scale) of 2SW individuals from the NEC complex before maturation in Faroe islands
NA
NA
4.3 Import the database table from the salmoglob (WGNAS) database
For data we first need to create the table.
The code for creating t_stock_sto is listed below, this table is created for all working groups, it should not have any lines, only get those from inheritance from schema datnas, datang, datbast…
SQL code to create tables
-- before working there should have been these constraints in the salmoglob DBALTERTABLE"database"ADDCONSTRAINT c_uk_area_varmod_year_location_age UNIQUE (area, var_mod, "year", "location", age);ALTERTABLE"database_archive"ADDCONSTRAINT c_uk_archive_version_area_varmod_year_location_age UNIQUE ("version", area, var_mod, "year", "location", age);-- For the archive db, the constraint is not working meaning that we have duplicated valuesSELECTDISTINCT met_nim_code FROM datnas.t_metadata_metJOIN refsalmoglob."database"ON var_mod = met_varWHERE met_cat_code ='Other'SELECT*FROM datnas.t_metadata_met WHERE met_var LIKE'%mu%'SELECTDISTINCT met_modelstage FROM datnas.t_metadata_met-- This will create the main table to hold the stock data-- I'm currenlty putting foreign key to ref but this is just for show because this table-- will only contain inherited valeusDROPTABLEIFEXISTS dat.t_stock_sto CASCADE;CREATETABLE dat.t_stock_sto ( sto_id SERIAL NOTNULL, sto_met_var TEXT NOTNULL, sto_year INT4 NULL, sto_spe_code VARCHAR(3) NOTNULL,CONSTRAINT fk_sto_met_var_met_spe_codeFOREIGNKEY (sto_met_var, sto_spe_code) REFERENCES dat.t_metadata_met(met_var,met_spe_code) ONUPDATECASCADEONDELETERESTRICT, sto_value NUMERICNULL, sto_are_code TEXT NOTNULL,CONSTRAINT fk_sto_are_code FOREIGNKEY (sto_are_code)REFERENCES"ref".tr_area_are (are_code) ONUPDATECASCADEONDELETERESTRICT,-- NOTE : here I'm referencing the code because it's more easy to grasp than a number, but the id is the primary key.-- should work stil but requires a unique constraint on code (which we have set). sto_cou_code VARCHAR(2) NULL,CONSTRAINT fk_sto_cou_code FOREIGNKEY (sto_cou_code)REFERENCES"ref".tr_country_cou (cou_code)ONUPDATECASCADEONDELETERESTRICT, sto_lfs_code TEXT NOTNULL,CONSTRAINT fk_sto_lfs_code_sto_spe_code FOREIGNKEY (sto_lfs_code, sto_spe_code)REFERENCES"ref".tr_lifestage_lfs (lfs_code, lfs_spe_code) ONUPDATECASCADEONDELETERESTRICT, sto_hty_code VARCHAR(2) NULL, CONSTRAINT fk_hty_code FOREIGNKEY (sto_hty_code)REFERENCES"ref".tr_habitattype_hty(hty_code) ONUPDATECASCADEONDELETERESTRICT,--sto_fia_code TEXT NULL,--CONSTRAINT fk_sto_fia_code FOREIGN KEY(sto_fia_code)-- REFERENCES "ref".tr_fishingarea_fia(fia_code)-- ON UPDATE CASCADE ON DELETE RESTRICT, sto_qal_code INT4 NOTNULL,CONSTRAINT fk_sto_qal_code FOREIGNKEY (sto_qal_code)REFERENCES"ref".tr_quality_qal(qal_code)ONUPDATECASCADEONDELETERESTRICT, sto_qal_comment TEXT NULL, sto_comment TEXT NULL, sto_datelastupdate dateNULL, sto_mis_code VARCHAR(2) NULL,CONSTRAINT fk_sto_mis_code FOREIGNKEY (sto_mis_code)REFERENCES"ref".tr_missvalueqal_mis (mis_code)ONUPDATECASCADEONDELETERESTRICT, sto_dta_code TEXT DEFAULT'Public'NULL,CONSTRAINT fk_dta_code FOREIGNKEY (sto_dta_code)REFERENCES"ref".tr_dataaccess_dta(dta_code) ONUPDATECASCADEONDELETERESTRICT, sto_wkg_code TEXT NOTNULL, CONSTRAINT fk_sto_wkg_code FOREIGNKEY (sto_wkg_code)REFERENCES"ref".tr_icworkinggroup_wkg(wkg_code)ONUPDATECASCADEONDELETERESTRICT, CONSTRAINT uk_sto_id_sto_wkg_code UNIQUE (sto_id, sto_wkg_code),CONSTRAINT ck_notnull_value_and_mis_code CHECK ((((sto_mis_code ISNULL) AND (sto_value ISNOTNULL)) OR ((sto_mis_code ISNOTNULL) AND (sto_value ISNULL)))), sto_ver_code TEXT ,CONSTRAINT fk_sto_ver_code FOREIGNKEY (sto_ver_code)REFERENCESref.tr_version_ver (ver_code)ONUPDATECASCADEONDELETERESTRICT-- We removed qual_id = 0-- CONSTRAINT ck_qal_id_and_missvalue CHECK (((eel_missvaluequal IS NULL) OR (eel_qal_id <> 0))),-- TODO CHECK LATER HOW TO DEAL WITH DEPRECATED-- CONSTRAINT ck_removed_typid CHECK (((COALESCE(eel_qal_id, 1) > 5) OR (eel_typ_id <> ALL (ARRAY[12, 7, 5])))),);COMMENTONTABLE dat.t_stock_sto IS'Table including the stock data from the different schema, dateel, datnas.... This table should be empty, it''s getting its content by inheritance from other tables in other schema, will probably be created by a view in SQL server';COMMENTONCOLUMN dat.t_stock_sto.sto_id IS'Integer serial identifying. Only unique in this tablewhen looking at the pair, sto_id, sto_wkg_code';COMMENTONCOLUMN dat.t_stock_sto.sto_met_var IS'Name of the variable in the database, this was previously namedvar_mod in the salmoglob database and eel_typ_id in the wgeel database, there is a unicity constraint basedon the pair of column sto_spe_code, sto_met_code';-- note if we end up with a single table, then the constraint will have to be set-- on sto_wkg_code, sto_spe_code and sto_met_code.COMMENTONCOLUMN dat.t_stock_sto.sto_year IS'Year';COMMENTONCOLUMN dat.t_stock_sto.sto_value IS'Value if null then provide a value in sto_mis_code to explain why not provided';COMMENTONCOLUMN dat.t_stock_sto.sto_are_code IS'Code of the area, areas are geographical sector most often corresponding to stock units, see tr_area_are.';COMMENTONCOLUMN dat.t_stock_sto.sto_cou_code IS'Code of the country see tr_country_cou, not null';COMMENTONCOLUMN dat.t_stock_sto.sto_lfs_code IS'Code of the lifestage see tr_lifestage_lfs, Not null, the constraint is set on both lfs_code, and lfs_spe_code (as two species can have the same lifestage code.';COMMENTONCOLUMN dat.t_stock_sto.sto_hty_code IS'Code of the habitat type, one of MO (marine open), MC (Marine coastal), T (Transitional water), FW (Freshwater), null accepted';-- COMMENT ON COLUMN dat.t_stock_sto.sto_fia_code IS 'For marine area, code of the ICES area (table tr_fishingarea_fia), Null accepted';COMMENTONCOLUMN dat.t_stock_sto.sto_qal_code IS'Code of data quality (1 good quality, 2 modified by working group, 3 bad quality (not used), 4 dubious, 18, 19 ... historical data not used. Not null, Foreign key set to tr_quality_qal';COMMENTONCOLUMN dat.t_stock_sto.sto_qal_comment IS'Comment for the quality, for instance explaining why a data is qualified as good or dubious.';COMMENTONCOLUMN dat.t_stock_sto.sto_comment IS'Comment on the value';COMMENTONCOLUMN dat.t_stock_sto.sto_datelastupdate IS'Last update of the data';COMMENTONCOLUMN dat.t_stock_sto.sto_mis_code IS'When no value are given in sto_value, justify why with, NC (not collected), NP (Not pertinent), NR (Not reported),references table tr_missvalueqal_mis, should be null if value is provided (can''t have both).';COMMENTONCOLUMN dat.t_stock_sto.sto_dta_code IS'Access to data, default is ''Public''';COMMENTONCOLUMN dat.t_stock_sto.sto_wkg_code IS'Code of the working group, one ofWGBAST, WGEEL, WGNAS, WKTRUTTA';COMMENTONCOLUMN dat.t_stock_sto.sto_spe_code IS'Code of the species';COMMENTONCOLUMN dat.t_stock_sto.sto_ver_code IS'Code of the version';ALTERTABLE dat.t_stock_sto OWNER TO diaspara_admin;GRANTSELECTON dat.t_stock_sto TO diaspara_read;-- trigger on dateDROPFUNCTION dat.update_sto_datelastupdate;CREATEORREPLACEFUNCTION dat.update_sto_datelastupdate() RETURNS trigger LANGUAGE plpgsqlAS $function$BEGINNEW.sto_datelastupdate = now()::date;RETURNNEW; END;$function$;ALTERFUNCTION dat.update_sto_datelastupdate() OWNER TO diaspara_admin;CREATETRIGGER update_sto_datelastupdate BEFOREINSERTORUPDATEON dat.t_stock_sto FOREACHROWEXECUTEFUNCTION dat.update_sto_datelastupdate();/* * * TODO CHECK THOSE TRIGGERS FOR WGEEL *//*CREATE TRIGGER trg_check_no_ices_area AFTERINSERT ORUPDATE ON datawg.t_eelstock_eel FOR EACH ROW EXECUTE FUNCTION datawg.check_no_ices_area();CREATE TRIGGER trg_check_the_stage AFTERINSERT ORUPDATE ON datawg.t_eelstock_eel FOR EACH ROW EXECUTE FUNCTION datawg.check_the_stage();CREATE TRIGGER trg_check_emu_whole_aquaculture AFTERINSERT ORUPDATE ON datawg.t_eelstock_eel FOR EACH ROW EXECUTE FUNCTION datawg.checkemu_whole_country(); *//* * Added afterwards for eel *//*ALTER TABLE dat.t_stock_sto ADD COLUMN sto_ver_code TEXT ;ALTER TABLE dat.t_stock_sto ADD CONSTRAINT fk_sto_ver_code FOREIGN KEY (sto_ver_code) REFERENCES ref.tr_version_ver (ver_code) ON UPDATE CASCADE ON DELETE RESTRICT;ALTER TABLE dat.t_stock_sto DROP COLUMN sto_fia_code CASCADE;*/
The same table t_stock_sto is created in datnas. It is inherited, so this means that all the column are coming from dat.t_stock_sto but we have to recreate all the constraints, as constraints are never inherited. Two additional check constraint are created, the value for species will always be SAL and the value for wkg (expert group) will always be WGNAS.
SQL code to create tables
-- CREATE A TABLE INHERITED FROM dat.t_stock_sto.-- Table dat.stock_sto only gets data by inheritance.-- Here we have to build the constraints again.DROPTABLEIFEXISTS datnas.t_stock_sto;CREATETABLE datnas.t_stock_sto ( sto_add_code TEXT NULL,CONSTRAINT fk_sto_add_code FOREIGNKEY (sto_add_code) REFERENCES refnas.tg_additional_add (add_code), CONSTRAINT fk_sto_met_var_met_spe_codeFOREIGNKEY (sto_met_var, sto_spe_code) REFERENCES datnas.t_metadata_met(met_var,met_spe_code) ONUPDATECASCADEONDELETERESTRICT,CONSTRAINT fk_sto_are_code FOREIGNKEY (sto_are_code)REFERENCES refnas.tr_area_are (are_code) ONUPDATECASCADEONDELETERESTRICT,CONSTRAINT fk_sto_cou_code FOREIGNKEY (sto_cou_code)REFERENCESref.tr_country_cou (cou_code)ONUPDATECASCADEONDELETERESTRICT,CONSTRAINT fk_sto_lfs_code_sto_spe_code FOREIGNKEY (sto_lfs_code, sto_spe_code)REFERENCESref.tr_lifestage_lfs (lfs_code, lfs_spe_code) ONUPDATECASCADEONDELETERESTRICT,CONSTRAINT fk_hty_code FOREIGNKEY (sto_hty_code)REFERENCESref.tr_habitattype_hty(hty_code) ONUPDATECASCADEONDELETERESTRICT,-- CONSTRAINT fk_sto_fia_code FOREIGN KEY(sto_fia_code)-- REFERENCES ref.tr_fishingarea_fia(fia_code)-- ON UPDATE CASCADE ON DELETE RESTRICT, CONSTRAINT fk_sto_qal_code FOREIGNKEY (sto_qal_code)REFERENCESref.tr_quality_qal(qal_code)ONUPDATECASCADEONDELETERESTRICT,CONSTRAINT fk_sto_mis_code FOREIGNKEY (sto_mis_code)REFERENCESref.tr_missvalueqal_mis (mis_code)ONUPDATECASCADEONDELETERESTRICT,CONSTRAINT fk_dta_code FOREIGNKEY (sto_dta_code)REFERENCESref.tr_dataaccess_dta(dta_code) ONUPDATECASCADEONDELETERESTRICT, CONSTRAINT fk_sto_wkg_code FOREIGNKEY (sto_wkg_code)REFERENCESref.tr_icworkinggroup_wkg(wkg_code)ONUPDATECASCADEONDELETERESTRICT, CONSTRAINT c_uk_sto_id_sto_wkg_code UNIQUE (sto_id, sto_wkg_code),CONSTRAINT ck_notnull_value_and_mis_code CHECK ((((sto_mis_code ISNULL) AND (sto_value ISNOTNULL)) OR ((sto_mis_code ISNOTNULL) AND (sto_value ISNULL)))))inherits (dat.t_stock_sto) ;-- This table will always be for SALMON and WGNASALTERTABLE datnas.t_stock_sto ALTERCOLUMN sto_spe_code SETDEFAULT'SAL';ALTERTABLE datnas.t_stock_sto ADDCONSTRAINT ck_spe_code CHECK (sto_spe_code='SAL');ALTERTABLE datnas.t_stock_sto ALTERCOLUMN sto_wkg_code SETDEFAULT'WGNAS';ALTERTABLE datnas.t_stock_sto ADDCONSTRAINT ck_wkg_code CHECK (sto_wkg_code='WGNAS');ALTERTABLE datnas.t_stock_sto OWNER TO diaspara_admin;GRANTALLONTABLE datnas.t_stock_sto TO diaspara_read;COMMENTONTABLE datnas.t_stock_sto IS'Table including the stock data in schema datnas.... This table feeds the dat.t_stock_sto table by inheritance. It correspondsto the database table in the original WGNAS database.';COMMENTONCOLUMN datnas.t_stock_sto.sto_id IS'Integer serial identifying. Only unique in this tablewhen looking at the pair, sto_id, sto_wkg_code';COMMENTONCOLUMN datnas.t_stock_sto.sto_met_var IS'Name of the variable in the database, this was previously namedvar_mod in the salmoglob database and eel_typ_id in the wgeel database, there is a unicity constraint basedon the pair of column sto_spe_code, sto_met_var';-- note if we end up with a single table, then the constraint will have to be set-- on sto_wkg_code, sto_spe_code and sto_met_code.COMMENTONCOLUMN datnas.t_stock_sto.sto_year IS'Year';COMMENTONCOLUMN datnas.t_stock_sto.sto_value IS'Value if null then provide a value in sto_mis_code to explain why not provided';COMMENTONCOLUMN datnas.t_stock_sto.sto_are_code IS'Code of the area, areas are geographical sector most often corresponding to stock units, see tr_area_are.';COMMENTONCOLUMN datnas.t_stock_sto.sto_cou_code IS'Code of the country see tr_country_cou, not null';COMMENTONCOLUMN datnas.t_stock_sto.sto_lfs_code IS'Code of the lifestage see tr_lifestage_lfs, Not null, the constraint is set on both lfs_code, and lfs_spe_code (as two species can have the same lifestage code.';COMMENTONCOLUMN datnas.t_stock_sto.sto_hty_code IS'Code of the habitat type, one of MO (marine open), MC (Marine coastal), T (Transitional water), FW (Freshwater), null accepted';--COMMENT ON COLUMN datnas.t_stock_sto.sto_fia_code IS 'For marine area, code of the ICES area (table tr_fishingarea_fia), Null accepted';COMMENTONCOLUMN datnas.t_stock_sto.sto_qal_code IS'Code of data quality (1 good quality, 2 modified by working group, 3 bad quality (not used), 4 dubious, 18, 19 ... historical data not used. Not null, Foreign key set to tr_quality_qal';COMMENTONCOLUMN datnas.t_stock_sto.sto_qal_comment IS'Comment for the quality, for instance explaining why a data is qualified as good or dubious.';COMMENTONCOLUMN datnas.t_stock_sto.sto_comment IS'Comment on the value';COMMENTONCOLUMN datnas.t_stock_sto.sto_datelastupdate IS'Last update of the data';COMMENTONCOLUMN datnas.t_stock_sto.sto_mis_code IS'When no value are given in sto_value, justify why with, NC (not collected), NP (Not pertinent), NR (Not reported),references table tr_missvalueqal_mis, should be null if value is provided (can''t have both).';COMMENTONCOLUMN datnas.t_stock_sto.sto_dta_code IS'Access to data, default is ''Public''';COMMENTONCOLUMN datnas.t_stock_sto.sto_wkg_code IS'Code of the working group, one ofWGBAST, WGEEL, WGNAS, WKTRUTTA';COMMENTONCOLUMN datnas.t_stock_sto.sto_add_code IS'Additional code in the extra dimension of the table, corresponds to area or age,collated in table tg_additional_add';-- trigger on dateDROPFUNCTIONIFEXISTS datnas.update_sto_datelastupdate;CREATEORREPLACEFUNCTION datnas.update_sto_datelastupdate() RETURNS trigger LANGUAGE plpgsqlAS $function$BEGINNEW.sto_datelastupdate = now()::date;RETURNNEW; END;$function$;ALTERFUNCTION datnas.update_sto_datelastupdate() OWNER TO diaspara_admin;CREATETRIGGER update_sto_datelastupdate BEFOREINSERTORUPDATEON datnas.t_stock_sto FOREACHROWEXECUTEFUNCTION datnas.update_sto_datelastupdate();-- fix after change in wgeel/*SELECT * FROM refnas.tr_version_verUPDATE datnas.t_stock_sto SET sto_ver_code = 'WGNAS-2024-1'; -- 45076*/
While creating the table, we stumbled on some issues (which we have put on the github site for details):
Some of the variables in salmoglob have no year dimension, this leads to dropping the non null constraint on year. We need to check for possible impact in the eel db see issue #14 : NULL values allowed for year
4.4 Table of grouping for area and age : datnas.tg_additional_add
Before doing the import of t_stock_sto are a couple of issues to be fixed.
The year column does not always contain year. In fact the database that we have created is not suited to store transfer matrix where the dimensions have area x area. We only have one area column.
Only the variables eggs, p_smolt, p_smolt_pr and prop_female need an age.
SQL code to create tables
DROPTABLEIFEXISTS refnas.tg_additional_add;CREATETABLE refnas.tg_additional_add ASSELECT are_code AS add_code, 'Area'AS add_type FROM refnas.tr_area_areUNIONSELECT age_code AS add_code, 'Age'AS add_type FROM"ref".tr_age_age; --80ALTERTABLE refnas.tg_additional_add ADDCONSTRAINTuk_add_code UNIQUE (add_code);ALTERTABLE refnas.tg_additional_add OWNER TO diaspara_admin;GRANTALLONTABLE refnas.tg_additional_add TO diaspara_read;COMMENTONTABLE refnas.tg_additional_add IS'Table including the stock data in schema datnas.... This table feeds the dat.t_stock_sto table by inheritance. It correspondsto the database table in the original WGNAS database.';COMMENTONCOLUMN refnas.tg_additional_add.add_code IS'Code coming from are_code intable refnas.tr_area_are or age_code in table ref.tr_age_age';COMMENTONCOLUMN refnas.tg_additional_add.add_type IS'One of Area or Age';
Table 30: Content of the refnas additional table
add_code
add_type
RU_KB
Area
Atlantic
Area
GF
Area
Denmark
Area
coun_Labrador
Area
RU_RP
Area
2FW
Age
coun_France
Area
coun_Finland
Area
NEAC
Area
NO_SW
Area
Finland
Area
NEAC inland
Area
MSW
Age
coun_Scotland
Area
NI_FO
Area
LB fishery
Area
coun_Gulf
Area
6FW
Age
Iceland
Area
NF
Area
coun_US
Area
Netherlands
Area
IC_SW
Area
NI_FB
Area
coun_Iceland_NE
Area
NEC
Area
coun_Iceland_SW
Area
Svalbard and Jan Mayen
Area
Great Britain
Area
coun_Russia
Area
QC
Area
3FW
Age
NO_NO
Area
IR
Area
1FW
Age
5FW
Age
coun_Ireland
Area
2SW
Age
Germany
Area
Russia
Area
Sweden
Area
RU_AK
Area
neNF fishery
Area
FR
Area
FAR fishery
Area
coun_Scotia Fundy
Area
FI
Area
4FW
Age
GLD fishery
Area
SC_EA
Area
coun_England_Wales
Area
Portugal
Area
NO_MI
Area
coun_Sweden
Area
Ireland
Area
coun_Norway
Area
Luxembourg
Area
LB
Area
NAC
Area
Belgium
Area
coun_Newfoundland
Area
LB/SPM/swNF fishery
Area
SC_WE
Area
coun_Northern_Ireland
Area
coun_Quebec
Area
France
Area
NEAC marine
Area
1SW
Age
SW
Area
0FW
Age
EW
Area
US
Area
Spain
Area
NO_SE
Area
Czech republic
Area
RU_KW
Area
SF
Area
Norway
Area
IC_NE
Area
4.5 Import the t_stock_sto
Code to import salmoglob main db into the new database.
dbExecute(con_diaspara,"ALTER SEQUENCE dat.t_stock_sto_sto_id_seq RESTART WITH 1;")dbExecute(con_diaspara_admin,"DELETE FROM datnas.t_stock_sto;")dbExecute(con_diaspara_admin,"INSERT INTO datnas.t_stock_sto(sto_id, sto_met_var, sto_year, sto_spe_code, sto_value, sto_are_code, sto_cou_code, sto_lfs_code, sto_hty_code, sto_qal_code, sto_qal_comment, sto_comment, sto_datelastupdate, sto_mis_code, sto_dta_code, sto_wkg_code,sto_add_code)SELECT nextval('dat.t_stock_sto_sto_id_seq'::regclass) AS sto_id, d.var_mod AS sto_met_var, d.year AS sto_year, 'SAL' AS sto_spe_code, d.value AS sto_value, d.area AS sto_are_code, NULL AS sto_cou_code -- OK can be NULL, CASE WHEN m.life_stage = 'Eggs' THEN 'E' WHEN m.life_stage = 'Adult' THEN 'A' WHEN m.life_stage = 'Multiple' THEN 'AL' WHEN m.life_stage = 'Adults' THEN 'A' WHEN m.life_stage = 'Smolts' THEN 'SM' WHEN m.life_stage = 'Non mature' THEN 'PS' -- IS THAT RIGHT ? WHEN m.life_stage = 'PFA' THEN 'PS' -- No VALUES WHEN m.life_stage = 'Spawners' THEN 'A' -- No values WHEN m.life_stage = '_' THEN '_' ELSE 'TROUBLE' END AS sto_lfs_code , NULL AS sto_hty_code, 1 AS sto_qal_code -- see later TO INSERT deprecated values, NULL AS sto_qal_comment , NULL AS sto_comment, date(d.date_time) AS sto_datelastupdate, NULL AS sto_mis_code, 'Public' AS sto_dta_code, 'WGNAS' AS sto_wkg_code, CASE WHEN d.var_mod IN ('eggs','p_smolt', 'p_smolt_pr', 'prop_female') THEN d.age WHEN d.var_mod IN ('omega') THEN d.LOCATION END AS sto_add_codeFROM refsalmoglob.database d JOINrefsalmoglob.metadata m ON m.var_mod = d.var_mod; ")# 45076
DROPTABLEIFEXISTS dateel.t_metadata_met;CREATETABLE dateel.t_metadata_met(CONSTRAINT t_metadata_met_pkey PRIMARYKEY(met_var, met_wkg_code),CONSTRAINT fk_met_spe_code FOREIGNKEY (met_spe_code)REFERENCESref.tr_species_spe(spe_code) ONUPDATECASCADEONDELETERESTRICT,CONSTRAINT ck_met_spe_code CHECK (met_spe_code='ANG'),CONSTRAINT fk_met_wkg_code FOREIGNKEY (met_wkg_code)REFERENCESref.tr_icworkinggroup_wkg(wkg_code) ONUPDATECASCADEONDELETERESTRICT,CONSTRAINT ck_met_wkg_code CHECK (met_wkg_code='WGEEL'),CONSTRAINT fk_met_ver_code FOREIGNKEY (met_ver_code)REFERENCES refeel.tr_version_ver(ver_code) ONUPDATECASCADEONDELETERESTRICT,CONSTRAINT fk_met_oty_code FOREIGNKEY (met_oty_code) REFERENCESref.tr_objecttype_oty (oty_code) ONUPDATECASCADEONDELETERESTRICT,CONSTRAINT fk_met_nim_code FOREIGNKEY (met_nim_code) REFERENCESref.tr_nimble_nim (nim_code) ONUPDATECASCADEONDELETERESTRICT, CONSTRAINT fk_met_mtr_code FOREIGNKEY (met_mtr_code)REFERENCESref.tr_metric_mtr(mtr_code)ONUPDATECASCADEONDELETERESTRICT,CONSTRAINT fk_met_uni_code FOREIGNKEY (met_uni_code)REFERENCESref.tr_units_uni(uni_code)ONUPDATECASCADEONDELETERESTRICT,CONSTRAINT fk_met_cat_code FOREIGNKEY (met_cat_code)REFERENCESref.tr_category_cat(cat_code)ONUPDATECASCADEONDELETERESTRICT,CONSTRAINT fk_met_des_code FOREIGNKEY (met_des_code)REFERENCESref.tr_destination_des(des_code)ONUPDATECASCADEONDELETERESTRICT)INHERITS (dat.t_metadata_met);-- COMMENTS FOR WGEELCOMMENTONTABLE dateel.t_metadata_met IS'Table (metadata) of each variable (parameter) in the wgeel database.';COMMENTONCOLUMN dateel.t_metadata_met.met_var IS'Variable code, primary key on both met_spe_code and met_var.';COMMENTONCOLUMN dateel.t_metadata_met.met_spe_code IS'Species, ANG primary key on both met_spe_code and met_var.';COMMENTONCOLUMN dateel.t_metadata_met.met_ver_code IS'Code on the version of the model, see table refeel.tr_version_ver.';COMMENTONCOLUMN dateel.t_metadata_met.met_oty_code IS'Object type, single_value, vector, matrix see table tr_objecttype_oty.';COMMENTONCOLUMN dateel.t_metadata_met.met_nim_code IS'Nimble type, one of data, constant, output, other.';COMMENTONCOLUMN dateel.t_metadata_met.met_dim IS'Dimension of the Nimble variable, use {10, 100, 100} to insert the description of an array(10,100,100).';COMMENTONCOLUMN dateel.t_metadata_met.met_dimname IS'Dimension of the variable in Nimble, use {''year'', ''stage'', ''area''}.';COMMENTONCOLUMN dateel.t_metadata_met.met_modelstage IS'Currently one of fit, other, First year.';COMMENTONCOLUMN dateel.t_metadata_met.met_type IS'Type of data in the variable, homewatercatches, InitialISation first year,abundance ....';COMMENTONCOLUMN dateel.t_metadata_met.met_location IS'Describe process with geographical information';COMMENTONCOLUMN dateel.t_metadata_met.met_fishery IS'Description of the fishery.';COMMENTONCOLUMN dateel.t_metadata_met.met_des_code IS'Destination of the fish, e.g. Released (alive), Seal damage,Removed (from the environment), references table tr_destination_des., this is currently only used by WGBAST,so can be kept NULL';COMMENTONCOLUMN dateel.t_metadata_met.met_uni_code IS'Unit, dateelerences table tr_unit_uni.';COMMENTONCOLUMN dateel.t_metadata_met.met_cat_code IS'Broad category of data or parameter, catch, effort, biomass, mortality, count ...dateelerences table tr_category_cat.';COMMENTONCOLUMN dateel.t_metadata_met.met_mtr_code IS'Code of the metric, dateelerences tr_metric_mtr, Estimate, Bound, SD, CV ....';COMMENTONCOLUMN dateel.t_metadata_met.met_definition IS'Definition of the metric.';COMMENTONCOLUMN dateel.t_metadata_met.met_deprecatedIS'Is the variable still used ?';ALTERTABLE dateel.t_metadata_met OWNER TO diaspara_admin;GRANTSELECTON dateel.t_metadata_met TO diaspara_read;
Note :
We currently consider that SumH, and Biom are “Output”, the result of model.
type is not a referential, but used for legacy in WGNAS see type table so I’m leaving it empty currently
Code to import to metadata for eel work in progress …
# t_metadata_meteelstock <-dbGetQuery(con_diaspara_admin, "SELECT * FROM datwgeel.t_eelstock_eel WHERE eel_qal_id in (0,1,2,3,4) ")nrow(eelstock) # 73730unique(eelstock$eel_typ_id)# 6 4 8 9 11 17 18 15 14 13 16 19 10 32 33 34# View(eelstock[eelstock$eel_typ_id ==32,])res <-dbGetQuery(con_diaspara, "SELECT * FROM dateel.t_metadata_met;")clipr::write_clip(colnames(res))typ <-dbGetQuery(con_diaspara_admin,"SELECT * FROM refwgeel.tr_typeseries_typ")# below I'm removing from typ as these values are not actually in the databasetyp <- typ[!typ$typ_id %in%c(1,2,3),] # remove seriestyp <- typ[!typ$typ_id %in%c(16),] # potential_availabe_habitat_production_hatyp <- typ[!typ$typ_id %in%c(5, 7),] # com_catch and rec_catchtyp <- typ[!typ$typ_id %in%c(26:31),] # silver eel equivalents (deprecated)# unique(metadata$metric)# dbGetQuery(con_diaspara, "SELECT * FROM ref.tr_metric_mtr")View(typ)t_metadata_met <-data.frame(met_var = typ$typ_name,met_spe_code ="ANG",met_wkg_code ="WGEEL",met_ver_code ="WGEEL-2025-1", met_oty_code ="Single_value", # https://diaspara.bordeaux-aquitaine.inrae.fr/deliverables/wp3/p7/midb.html#object-type-tr_objectype_otymet_nim_code =case_when( typ$typ_id %in%c(4:12,32,33) ~"Data",.default ="Output"), # https://diaspara.bordeaux-aquitaine.inrae.fr/deliverables/wp3/p7/midb.html#type-of-parm-data-tr_nimble_nimmet_dim =paste0("{", 1, ",",0, ",",0, "}" ),met_dimname =paste0("{'year',NULL,NULL}" ),met_modelstage =NA,met_type = typ$typ_id, # not a referential, used for legacy in WGNAS, and I'm using the old code in wgeel# see https://diaspara.bordeaux-aquitaine.inrae.fr/deliverables/wp3/p4/wgnas_salmoglob_description.html#tbl-globaldata2-4met_location =NA, # something line bef. Fisheries Aft fisheries.... not a referentialmet_fishery =NA, # not a referentialmet_mtr_code =NA, # reference to tr_metrictype (bound, mean, SD, can be left empty)met_des_code =NA,met_uni_code =NA, # (TODO)met_cat_code =case_when(typ$typ_name =="com_landings_kg"~"Catch",typ$typ_name =="rec_landings_kg"~"Catch",typ$typ_name =="other_landings_kg"~"Catch",typ$typ_name =="other_landings_n"~"Catch",typ$typ_name =="gee_n"~"Count",typ$typ_name =="q_aqua_kg"~"Other" ,typ$typ_name =="q_aqua_n"~"Other" ,typ$typ_name =="q_release_kg"~"Release",typ$typ_name =="q_release_n"~"Release",typ$typ_name =="b0_kg"~"Biomass",typ$typ_name =="bbest_kg"~"Biomass",typ$typ_name =="b_current_without_stocking_kg"~"Biomass",typ$typ_name =="bcurrent_kg"~"Biomass",typ$typ_name =="suma"~"Mortality",typ$typ_name =="sumf"~"Mortality",typ$typ_name =="sumh"~"Mortality",typ$typ_name =="sumf_com"~"Mortality",typ$typ_name =="sumf_rec"~"Mortality",typ$typ_name =="sumh_hydro"~"Mortality",typ$typ_name =="sumh_habitat"~"Mortality",typ$typ_name =="sumh_other"~"Mortality",typ$typ_name =="sumh_release"~"Mortality",.default =NA ),met_definition = typ$typ_description,met_deprecated =NA# not integrating any of the deprecated data)res <-dbWriteTable(con_diaspara_admin, "t_metadata_met_wgeel_temp", t_metadata_met, overwrite =TRUE)dbExecute(con_diaspara_admin, "INSERT INTO dateel.t_metadata_met SELECT met_var, met_spe_code, met_wkg_code, met_ver_code, met_oty_code, met_nim_code, met_dim::INTEGER[], met_dimname::TEXT[], met_modelstage, met_type, met_location, met_fishery, met_mtr_code, met_des_code, met_uni_code, met_cat_code, met_definition, met_deprecatedFROM t_metadata_met_wgeel_temp") # 22dbExecute(con_diaspara_admin, "DROP TABLE t_metadata_met_wgeel_temp CASCADE;")
TODO DIASPARA
We still need to add units to the metadata table
5.3 dateel.t_stock_sto
SQL code to create table dateel.t_stock_sto
-- CREATE A TABLE INHERITED FROM dat.t_stock_sto.-- Table dat.stock_sto only gets data by inheritance.-- Here we have to build the constraints again.DROPTABLEIFEXISTS dateel.t_stock_sto;CREATETABLE dateel.t_stock_sto (CONSTRAINT fk_sto_met_var_met_spe_codeFOREIGNKEY (sto_met_var, sto_spe_code) REFERENCES dateel.t_metadata_met(met_var,met_spe_code) ONUPDATECASCADEONDELETERESTRICT,CONSTRAINT fk_sto_are_code FOREIGNKEY (sto_are_code)REFERENCES refeel.tr_area_are (are_code) ONUPDATECASCADEONDELETERESTRICT,CONSTRAINT fk_sto_cou_code FOREIGNKEY (sto_cou_code)REFERENCESref.tr_country_cou (cou_code)ONUPDATECASCADEONDELETERESTRICT,CONSTRAINT fk_sto_lfs_code_sto_spe_code FOREIGNKEY (sto_lfs_code, sto_spe_code)REFERENCESref.tr_lifestage_lfs (lfs_code, lfs_spe_code) ONUPDATECASCADEONDELETERESTRICT,CONSTRAINT fk_hty_code FOREIGNKEY (sto_hty_code)REFERENCESref.tr_habitattype_hty(hty_code) ONUPDATECASCADEONDELETERESTRICT,--CONSTRAINT fk_sto_fia_code FOREIGN KEY(sto_fia_code)-- REFERENCES ref.tr_fishingarea_fia(fia_code)-- ON UPDATE CASCADE ON DELETE RESTRICT, CONSTRAINT fk_sto_qal_code FOREIGNKEY (sto_qal_code)REFERENCESref.tr_quality_qal(qal_code)ONUPDATECASCADEONDELETERESTRICT,CONSTRAINT fk_sto_mis_code FOREIGNKEY (sto_mis_code)REFERENCESref.tr_missvalueqal_mis (mis_code)ONUPDATECASCADEONDELETERESTRICT,CONSTRAINT fk_dta_code FOREIGNKEY (sto_dta_code)REFERENCESref.tr_dataaccess_dta(dta_code) ONUPDATECASCADEONDELETERESTRICT, CONSTRAINT fk_sto_wkg_code FOREIGNKEY (sto_wkg_code)REFERENCESref.tr_icworkinggroup_wkg(wkg_code)ONUPDATECASCADEONDELETERESTRICT, CONSTRAINT c_uk_sto_id_sto_wkg_code UNIQUE (sto_id, sto_wkg_code),CONSTRAINT ck_notnull_value_and_mis_code CHECK ((((sto_mis_code ISNULL) AND (sto_value ISNOTNULL)) OR ((sto_mis_code ISNOTNULL) AND (sto_value ISNULL)))))inherits (dat.t_stock_sto) ;-- This table will always be for EEL (ang) and WGEELALTERTABLE dateel.t_stock_sto ALTERCOLUMN sto_spe_code SETDEFAULT'ANG';ALTERTABLE dateel.t_stock_sto ADDCONSTRAINT ck_spe_code CHECK (sto_spe_code='ANG');ALTERTABLE dateel.t_stock_sto ALTERCOLUMN sto_wkg_code SETDEFAULT'WGEEL';ALTERTABLE dateel.t_stock_sto ADDCONSTRAINT ck_wkg_code CHECK (sto_wkg_code='WGEEL');ALTERTABLE dateel.t_stock_sto OWNER TO diaspara_admin;GRANTALLONTABLE dateel.t_stock_sto TO diaspara_read;COMMENTONTABLE dateel.t_stock_sto IS'Table including the stock data in schema dateel.... This table feeds the dat.t_stock_sto table by inheritance. It correspondsto the t_eelstock_eel table in the original WGEEL database.';COMMENTONCOLUMN dateel.t_stock_sto.sto_id IS'Integer serial identifying. Only unique in this tablewhen looking at the pair, sto_id, sto_wkg_code';COMMENTONCOLUMN dateel.t_stock_sto.sto_met_var IS'Name of the variable in the database, this was previously namedeel_typ_name in the eel database, there is a unicity constraint basedon the pair of column sto_spe_code, sto_met_var';-- note if we end up with a single table, then the constraint will have to be set-- on sto_wkg_code, sto_spe_code and sto_met_code.COMMENTONCOLUMN dateel.t_stock_sto.sto_year IS'Year';COMMENTONCOLUMN dateel.t_stock_sto.sto_value IS'Value if null then provide a value in sto_mis_code to explain why not provided';COMMENTONCOLUMN dateel.t_stock_sto.sto_are_code IS'Code of the area, areas are geographical sector most often corresponding to stock units, see tr_area_are.';COMMENTONCOLUMN dateel.t_stock_sto.sto_cou_code IS'Code of the country see tr_country_cou, not null';COMMENTONCOLUMN dateel.t_stock_sto.sto_lfs_code IS'Code of the lifestage see tr_lifestage_lfs, Not null, the constraint is set on both lfs_code, and lfs_spe_code (as two species can have the same lifestage code.';COMMENTONCOLUMN dateel.t_stock_sto.sto_hty_code IS'Code of the habitat type, one of MO (marine open), MC (Marine coastal), T (Transitional water), FW (Freshwater), null accepted';COMMENTONCOLUMN dateel.t_stock_sto.sto_fia_code IS'For marine area, code of the ICES area (table tr_fishingarea_fia), Null accepted';COMMENTONCOLUMN dateel.t_stock_sto.sto_qal_code IS'Code of data quality (1 good quality, 2 modified by working group, 3 bad quality (not used), 4 dubious, 18, 19 ... historical data not used. Not null, Foreign key set to tr_quality_qal';COMMENTONCOLUMN dateel.t_stock_sto.sto_qal_comment IS'Comment for the quality, for instance explaining why a data is qualified as good or dubious.';COMMENTONCOLUMN dateel.t_stock_sto.sto_comment IS'Comment on the value';COMMENTONCOLUMN dateel.t_stock_sto.sto_datelastupdate IS'Last update of the data';COMMENTONCOLUMN dateel.t_stock_sto.sto_mis_code IS'When no value are given in sto_value, justify why with, NC (not collected), NP (Not pertinent), NR (Not reported),references table tr_missvalueqal_mis, should be null if value is provided (can''t have both).';COMMENTONCOLUMN dateel.t_stock_sto.sto_dta_code IS'Access to data, default is ''Public''';COMMENTONCOLUMN dateel.t_stock_sto.sto_wkg_code IS'Code of the working group, one ofWGBAST, WGEEL, WGNAS, WKTRUTTA';COMMENTONCOLUMN dateel.t_stock_sto.sto_ver_code IS'Version code, references refeel. tr_version_ver, code like WGEEL-2025-1';-- trigger on dateDROPFUNCTIONIFEXISTS dateel.update_sto_datelastupdate CASCADE;CREATEORREPLACEFUNCTION dateel.update_sto_datelastupdate() RETURNS trigger LANGUAGE plpgsqlAS $function$BEGINNEW.sto_datelastupdate = now()::date;RETURNNEW; END;$function$;ALTERFUNCTION dateel.update_sto_datelastupdate() OWNER TO diaspara_admin;CREATETRIGGER update_sto_datelastupdate BEFOREINSERTORUPDATEON dateel.t_stock_sto FOREACHROWEXECUTEFUNCTION dateel.update_sto_datelastupdate();
SQL code to insert values in table dateel.t_stock_sto
DELETEFROM dateel.t_stock_sto;INSERTINTO dateel.t_stock_sto(sto_id, sto_met_var, sto_year, sto_spe_code, sto_value, sto_are_code, sto_cou_code, sto_lfs_code, sto_hty_code, sto_qal_code, sto_qal_comment, sto_comment, sto_datelastupdate, sto_mis_code, sto_dta_code, sto_wkg_code, sto_ver_code)SELECTeel_id AS sto_id, m.met_var AS sto_met_var, e.eel_year AS sto_year, 'ANG'AS sto_spe_code, e.eel_value AS sto_value, CASEWHEN e.eel_emu_nameshort ilike '%total'THEN eel_cou_codeWHEN e.eel_emu_nameshort ISNULLTHEN eel_cou_code ELSE e.eel_emu_nameshort ENDAS sto_are_code, e.eel_cou_code AS sto_cou_code , e.eel_lfs_code AS sto_lfs_code, CASEWHEN e.eel_hty_code ='AL'THENNULLWHEN e.eel_hty_code ='F'THEN'FW'WHEN e.eel_hty_code ='MO'THEN'MO'WHEN e.eel_hty_code ='C'THEN'MC'WHEN e.eel_hty_code ='T'THEN'T'WHEN e.eel_hty_code ISNULLTHENNULLELSE'TROUBLE'ENDAS sto_hty_code--, NULL AS sto_fia_code -- fishing area, e.eel_qal_id AS sto_qal_code -- see later TO INSERT deprecated values, e.eel_qal_comment AS sto_qal_comment , e.eel_comment AS sto_comment, e.eel_datelastupdate AS sto_datelastupdate, e.eel_missvaluequal AS sto_mis_code, 'Public'AS sto_dta_code, 'WGEEL'AS sto_wkg_code, CASEWHEN e.eel_datasource ='wgeel_2016'THEN'WGEEL-2016-1'WHEN e.eel_datasource ='dc_2017'THEN'WGEEL-2017-1'WHEN e.eel_datasource ='weel_2017'THEN'WGEEL-2017-2'WHEN e.eel_datasource ='dc_2018'THEN'WGEEL-2018-1'WHEN e.eel_datasource ='dc_2019'THEN'WGEEL-2019-1'WHEN e.eel_datasource ='dc_2020'THEN'WGEEL-2020-1'WHEN e.eel_datasource ='dc_2021'THEN'WGEEL-2021-1'WHEN e.eel_datasource ='dc_2022'THEN'WGEEL-2022-1'WHEN e.eel_datasource ='dc_2023'THEN'WGEEL-2023-1'WHEN e.eel_datasource ='dc_2024'THEN'WGEEL-2024-1'WHEN e.eel_datasource ='wkemp_2025'THEN'WGEEL-2025-1'ELSE'TROUBLE AND THIS SHOULD FAIL'ENDAS sto_ver_codeFROM datwgeel.t_eelstock_eel e JOIN dateel.t_metadata_met m ON m.met_type::int= e.eel_typ_idWHERE eel_qal_id IN (0,1,2,3,4)AND eel_hty_code NOTIN ('T','M','C') AND eel_missvaluequal !='ND'AND eel_typ_id !=16-- habitat surface ; -- 28247/*SELECT distinct eel_datasource FROM datwgeel.t_eelstock_eel as t SELECT distinct eel_hty_code FROM datwgeel.t_eelstock_eel SELECT * FROM datwgeel.t_eelstock_eel WHERE eel_missvaluequal = 'ND'AND eel_qal_id IN (0,1,2,3,4); --123 lines not kept*/-- OK I can remove for all TINSERTINTO dateel.t_stock_sto(sto_id, sto_met_var, sto_year, sto_spe_code, sto_value, sto_are_code, sto_cou_code, sto_lfs_code, sto_hty_code, sto_qal_code, sto_qal_comment, sto_comment, sto_datelastupdate, sto_mis_code, sto_dta_code, sto_wkg_code, sto_ver_code)SELECTeel_id AS sto_id, m.met_var AS sto_met_var, e.eel_year AS sto_year, 'ANG'AS sto_spe_code, e.eel_value AS sto_value, CASEWHEN e.eel_emu_nameshort ilike '%total'THEN eel_cou_codeWHEN e.eel_emu_nameshort ISNULLTHEN eel_cou_code ELSE e.eel_emu_nameshort ENDAS sto_are_code, e.eel_cou_code AS sto_cou_code , e.eel_lfs_code AS sto_lfs_code, CASEWHEN e.eel_hty_code ='AL'THENNULLWHEN e.eel_hty_code ='F'THEN'FW'WHEN e.eel_hty_code ='MO'THEN'MO'WHEN e.eel_hty_code ='C'THEN'MC'WHEN e.eel_hty_code ='T'THEN'T'WHEN e.eel_hty_code ISNULLTHENNULLELSE'TROUBLE'ENDAS sto_hty_code--, NULL AS sto_fia_code -- fishing area, e.eel_qal_id AS sto_qal_code -- see later TO INSERT deprecated values, e.eel_qal_comment AS sto_qal_comment , e.eel_comment AS sto_comment, e.eel_datelastupdate AS sto_datelastupdate, e.eel_missvaluequal AS sto_mis_code, 'Public'AS sto_dta_code, 'WGEEL'AS sto_wkg_code, CASEWHEN e.eel_datasource ='wgeel_2016'THEN'WGEEL-2016-1'WHEN e.eel_datasource ='dc_2017'THEN'WGEEL-2017-1'WHEN e.eel_datasource ='weel_2017'THEN'WGEEL-2017-2'WHEN e.eel_datasource ='dc_2018'THEN'WGEEL-2018-1'WHEN e.eel_datasource ='dc_2019'THEN'WGEEL-2019-1'WHEN e.eel_datasource ='dc_2020'THEN'WGEEL-2020-1'WHEN e.eel_datasource ='dc_2021'THEN'WGEEL-2021-1'WHEN e.eel_datasource ='dc_2022'THEN'WGEEL-2022-1'WHEN e.eel_datasource ='dc_2023'THEN'WGEEL-2023-1'WHEN e.eel_datasource ='dc_2024'THEN'WGEEL-2024-1'WHEN e.eel_datasource ='wkemp_2025'THEN'WGEEL-2025-1'ELSE'TROUBLE AND THIS SHOULD FAIL'ENDAS sto_ver_codeFROM datwgeel.t_eelstock_eel e JOIN dateel.t_metadata_met m ON m.met_type::int= e.eel_typ_idWHERE eel_qal_id IN (0,1,2,3,4)AND eel_hty_code IN ('T') AND eel_typ_id !=16AND eel_missvaluequal !='ND' ; -- 12303------------------------------------------------------------------------------------------------------------------------------- Do we have MO data ? -----------------------------------------------------------------------------------------------------------------------------SELECT*FROM datwgeel.t_eelstock_eel WHERE eel_hty_code ='MO';--15600SELECT*FROM datwgeel.t_eelstock_eel WHERE eel_hty_code ='MO'and eel_value isnotNULLAND eel_qal_id in (1,2,3,4) ;--26 (typ 8 and 9 there are releases for the rhone, no marine division.-- So except for these 26 lines all data are MC.-- I asked to Guirec, he will fix this in the database. So there should no longer be any marine Open data in the DB.-- this is only for some data in MO (FR_Rhon) I'm inserting it nowSELECT*FROM datwgeel.t_eelstock_eel e JOIN dateel.t_metadata_met m ON m.met_type::int= e.eel_typ_idWHERE eel_qal_id IN (0,1,2,3,4)AND eel_hty_code IN ('MO') AND eel_value isnotNULLAND eel_missvaluequal !='ND';INSERTINTO dateel.t_stock_sto(sto_id, sto_met_var, sto_year, sto_spe_code, sto_value, sto_are_code, sto_cou_code, sto_lfs_code, sto_hty_code, sto_qal_code, sto_qal_comment, sto_comment, sto_datelastupdate, sto_mis_code, sto_dta_code, sto_wkg_code, sto_ver_code)SELECTeel_id AS sto_id, m.met_var AS sto_met_var, e.eel_year AS sto_year, 'ANG'AS sto_spe_code, e.eel_value AS sto_value, CASEWHEN eel_emu_nameshort ='FR_Rhon'THEN'37.1.2.7'ELSE'STOP'ENDAS sto_are_code, e.eel_cou_code AS sto_cou_code , e.eel_lfs_code AS sto_lfs_code, CASEWHEN e.eel_hty_code ='AL'THENNULLWHEN e.eel_hty_code ='F'THEN'FW'WHEN e.eel_hty_code ='MO'THEN'MO'WHEN e.eel_hty_code ='C'THEN'MC'WHEN e.eel_hty_code ='T'THEN'T'WHEN e.eel_hty_code ISNULLTHENNULLELSE'TROUBLE'ENDAS sto_hty_code--, NULL AS sto_fia_code -- fishing area, e.eel_qal_id AS sto_qal_code -- see later TO INSERT deprecated values, e.eel_qal_comment AS sto_qal_comment , e.eel_comment AS sto_comment, e.eel_datelastupdate AS sto_datelastupdate, e.eel_missvaluequal AS sto_mis_code, 'Public'AS sto_dta_code, 'WGEEL'AS sto_wkg_code, CASEWHEN e.eel_datasource ='wgeel_2016'THEN'WGEEL-2016-1'WHEN e.eel_datasource ='dc_2017'THEN'WGEEL-2017-1'WHEN e.eel_datasource ='weel_2017'THEN'WGEEL-2017-2'WHEN e.eel_datasource ='dc_2018'THEN'WGEEL-2018-1'WHEN e.eel_datasource ='dc_2019'THEN'WGEEL-2019-1'WHEN e.eel_datasource ='dc_2020'THEN'WGEEL-2020-1'WHEN e.eel_datasource ='dc_2021'THEN'WGEEL-2021-1'WHEN e.eel_datasource ='dc_2022'THEN'WGEEL-2022-1'WHEN e.eel_datasource ='dc_2023'THEN'WGEEL-2023-1'WHEN e.eel_datasource ='dc_2024'THEN'WGEEL-2024-1'WHEN e.eel_datasource ='wkemp_2025'THEN'WGEEL-2025-1'ELSE'TROUBLE AND THIS SHOULD FAIL'ENDAS sto_ver_codeFROM datwgeel.t_eelstock_eel e JOIN dateel.t_metadata_met m ON m.met_type::int= e.eel_typ_idWHERE eel_qal_id IN (0,1,2,3,4)AND eel_hty_code IN ('MO') AND eel_value isnotNULL; --26------------------------------------------------------------------------------------------------------------------------------- Coastal waters, in which case do we have more than one eel_area_division for one emu, one lifestage code, one type ?-----------------------------------------------------------------------------------------------------------------------------with dupl AS (SELECT*, count(eel_area_division) OVER (PARTITIONBY eel_typ_id, eel_emu_nameshort, eel_year, eel_lfs_code)FROM datwgeel.t_eelstock_eel WHERE eel_hty_code ='C'AND eel_value isnotNULLAND eel_qal_id in (1,2,3,4))SELECT*FROM dupl WHEREcount>1; --98-- OK so I have landings for SE_East, DK_Mari, and NO_total. In all those cases I can use the country level------------------------------------------------------------------------------------------------------------------------------- Coastal waters, in which case do we have one value per eel_area_division for one emu, one lifestage code, one type ?-- Are there countries where more than one EMU is reported ?-----------------------------------------------------------------------------------------------------------------------------with dupl AS (SELECT*, count(eel_area_division) OVER (PARTITIONBY eel_typ_id, eel_emu_nameshort, eel_year, eel_lfs_code)FROM datwgeel.t_eelstock_eel WHERE eel_hty_code ='C'AND eel_value isnotNULLAND eel_qal_id in (1,2,3,4)AND eel_typ_id !=16)SELECT*FROM dupl WHEREcount=1ORDERBY eel_emu_nameshort, eel_typ_id;-- BE_Sche is 27.4.c typ_id 6 (rec)-- DE_Eide is always 27.4.b, typ_id 4 (com) and 6 (rec)-- DE_Schl is always 27.3.b, c, typ id 4 6 and 9 (release OG and G)-- => DE_Warn is always 27.3.d except for habitat where it is reported as 27.3.b,c o I'm not importing typ_id 16 (habitat), typ_id 4 and 6-- DK_Inla 1 value in 2021 eel_id 569486, typ_id 4 Y dc_2024 => removed belowSELECT*FROM datwgeel.t_eelstock_eel WHERE eel_value isnotNULLAND eel_qal_id in (1,2,3,4)AND eel_typ_id =4AND eel_cou_code ='DK'AND eel_lfs_code ='Y'-- Dk_Mari is always 27.3.b, c, Y or S, typ_id 4-- DK_total is always 27.3.b, c typ_id 6, eel_lfs (Y, YS) , 2017-2022 -- EE_West is always 27.3.d, typ_id 4 (com) YS-- ES_Murc is always 37.1.1, typ_id 4 (com) YS-- !! ES_Vale On value G in, typ_id 4 in 2021 dc_2021 (OK should be T)SELECT*FROM datwgeel.t_eelstock_eel WHERE eel_value isnotNULLAND eel_qal_id in (1,2,3,4)AND eel_typ_id =4AND eel_emu_nameshort ='ES_Vale'AND eel_lfs_code ='G'-- FI_Finl is always 27.3.d typ_id 4, 6, 9-- GR_EaMT is always 37.3.1 -- GR_NorW is always 37.2.2-- GR_WePe is always 37.2.2 -- !! GR_total is reporting both with an without eel_area_division for GR_total => Mail sent-- LT_Lith / Lt_total change an make it consistent ? -- LV_latv is always 37.3.d 4, 6-- !! NL_Neth is always 27.4.c except for two lines where I have nulls, mail sent for check to Tessa-- !! NO_Total is always 27.7.a (wrong)-- except for 3 yellow lines in 2021-2023 where it becomes 37.3.a => mail sent-- PL_Oder and PL_Vist are all 37.3.d 4,8,9-- !! SE East is always reporting 27.3.d, 27.3b,c (Baltic this is consistent with emu_def ) but it is reporting 27.3.a which it shouldn't-- SE WE is always reporting 27.3.a -- Sl_total is always reporting 37.2.1-- TN_EC is always reporting 37.2.2 -- TN_NE is always reporting 37.1.3 -- TN_SO is always reporting 37.2.2-- Change for tunisia ? Should be Inland for the lagoons...; -- so Greece, Poland are reporting two rows with different EMUs. For Greece and Poland make the sum.-- Tunisia is also reporting more than one EMU for 37.2.2 but this ------------------------------------------------------- Coastal water not reported with eel_area_division-----------------------------------------------------SELECT*FROM datwgeel.t_eelstock_eel WHERE eel_hty_code ='C'AND eel_area_division ISNULLAND eel_value isnotNULLAND eel_qal_id in (1,2,3,4)AND eel_typ_id !=16ORDERBY eel_emu_nameshort, eel_typ_id, eel_lfs_code, eel_year; --1061-- DE_Eide 8 G 2020-2022 (value 0)-- DE_Eide 8 OG 1985-2022 (value 0)-- DE_Eide 8 Y 1985-2022 (value 0)-- DE_Eide 9 (same) should be 27.4.b-- DE_Schl 1985-2022 OG 0 and then values => Should be 27.3.b, c-- DE_Warn should be 27.3.d-- DK Mari 2016 2024 8 - 9 OGSELECT*FROM datwgeel.t_eelstock_eel WHERE eel_value isnotNULLAND eel_qal_id in (1,2,3,4)AND eel_typ_id IN (8,9)AND eel_cou_code ='DK'ORDERBY eel_emu_nameshort, eel_typ_id, eel_lfs_code, eel_year;-- DK total says ICES subdivision 21 22 23 24 (not tin the list) this comment shows that divisions reported were not division. I guess this is the Baltic sea... So I guess I could use 27.3.b, c-- Mail sent to Michael 25/07 for check...-- EE_West should always be 27.3.d-- missing values for 6 lines (4, 6) Mail sent to PaulSELECT*FROM datwgeel.t_eelstock_eel WHERE eel_value isnotNULLAND eel_qal_id in (1,2,3,4)AND eel_cou_code ='EE'ORDERBY eel_emu_nameshort, eel_typ_id, eel_lfs_code, eel_year;SELECT*FROM datwgeel.t_eelstock_eel WHERE eel_value isnotNULLAND eel_qal_id in (1,2,3,4)AND eel_cou_code ='EE'AND eel_hty_code ISNOTNULLAND eel_typ_id=11ORDERBY eel_emu_nameshort, eel_typ_id, eel_lfs_code, eel_year;-- remove duplicates for aquaculture (2002 to 2016) some qal_id 3, in fact data are entered with or without habitat, so we have duplicated values.-- SE Mail sent to Josefin and RobSELECT*FROM datwgeel.t_eelstock_eel WHERE eel_value isnotNULLAND eel_qal_id in (1,2,3,4)AND eel_hty_code ='C'AND eel_emu_nameshort ='SE_total'-- Check transitional waters 4, 6 in 2019 and 4 2020 2023 YS-- see database_edition_2025.sql in wgeel for querywith dupl AS (SELECT*, count(eel_area_division) OVER (PARTITIONBY eel_typ_id, eel_emu_nameshort, eel_year, eel_lfs_code)FROM datwgeel.t_eelstock_eel WHERE eel_hty_code ='T'AND eel_value isnotNULLAND eel_qal_id in (1,2,3,4))SELECT*FROM dupl WHEREcount>1; --2-- OK there is a duplicate with qal_id 3 for ES_Cata ES G T 37.1.1with dupl AS (SELECT*, count(eel_area_division) OVER (PARTITIONBY eel_typ_id, eel_emu_nameshort, eel_year, eel_lfs_code)FROM datwgeel.t_eelstock_eel WHERE eel_hty_code ='T'AND eel_value isnotNULLAND eel_qal_id in (1,2,3,4))SELECT*FROM dupl WHEREcount=1; --1254with dupl AS (SELECT*, count(eel_area_division) OVER (PARTITIONBY eel_typ_id, eel_emu_nameshort, eel_year, eel_lfs_code)FROM datwgeel.t_eelstock_eel WHERE eel_hty_code ='T'AND eel_value isnotNULLAND eel_qal_id in (1,2,3,4))SELECTDISTINCTON (eel_typ_id, eel_emu_nameshort, eel_lfs_code, eel_area_division) eel_typ_id, eel_emu_nameshort, eel_lfs_code, eel_area_division FROM dupl ; --1254 -------------------------------------------------------------------- insert coastal waters where eel_area_division is not NULL------------------------------------------------------------------DROPTABLE tempo.emu_div;CREATETABLE tempo.emu_div ASSELECTDISTINCTON (eel_cou_code, eel_emu_nameshort, eel_area_division) eel_cou_code, eel_emu_nameshort, eel_area_division, NULLAS area_codeFROM datwgeel.t_eelstock_eel WHERE eel_value isnotNULLAND eel_qal_id in (1,2,3,4)AND eel_area_division ISNOTNULLorderby (eel_emu_nameshort);--21UPDATE tempo.emu_div set area_code = eel_area_division WHERE eel_emu_nameshort IN (SELECT emu_nameshort from refwgeel.tr_emusplit_ems where emu_sea like'%A%'OR emu_sea ='N9');-- 38SELECT*FROM datwgeel.t_eelstock_eel WHERE eel_emu_nameshort='IT_Pugl'AND eel_area_division='37.2.2'SELECT*FROM datwgeel.t_eelstock_eel WHERE eel_emu_nameshort='NO_total'AND eel_area_division='27.7.a'DELETEFROM tempo.emu_div WHERE eel_emu_nameshort='IT_Pugl'AND eel_area_division='37.2.2'; -- just one line in T no pbUPDATE tempo.emu_divSET area_code='37.2.1.17'WHERE eel_emu_nameshort='AL_total'AND eel_area_division='37.2.2';UPDATE tempo.emu_divSET area_code='27.3.b, c'WHERE eel_emu_nameshort='DK_total'AND eel_area_division='27.3.b, c';UPDATE tempo.emu_divSET area_code='37.1.1.4'WHERE eel_emu_nameshort='DZ_total'AND eel_area_division='37.1.1';UPDATE tempo.emu_divSET area_code='37.3.2.26'WHERE eel_emu_nameshort='EG_total'AND eel_area_division='37.3.2';UPDATE tempo.emu_divSET area_code='37.3.1.22'WHERE eel_emu_nameshort='GR_EaMT'AND eel_area_division='37.3.1';UPDATE tempo.emu_divSET area_code='37.2.2.20'WHERE eel_emu_nameshort='GR_NorW'AND eel_area_division='37.2.2';UPDATE tempo.emu_divSET area_code='37.2.2.20'WHERE eel_emu_nameshort='GR_WePe'AND eel_area_division='37.2.2';UPDATE tempo.emu_divSET area_code='37.2.1.17'WHERE eel_emu_nameshort='HR_total'AND eel_area_division='37.2.1';UPDATE tempo.emu_divSET area_code='37.2.1.17'WHERE eel_emu_nameshort='IT_Emil'AND eel_area_division='37.2.1';UPDATE tempo.emu_divSET area_code='37.2.1.17'WHERE eel_emu_nameshort='IT_Frio'AND eel_area_division='37.2.1';UPDATE tempo.emu_divSET area_code='37.2.1.17'WHERE eel_emu_nameshort='IT_Lazi'AND eel_area_division='37.1.3';UPDATE tempo.emu_divSET area_code='37.2.1.17'WHERE eel_emu_nameshort='IT_Pugl'AND eel_area_division='37.2.1';UPDATE tempo.emu_divSET area_code='37.3.1.112'WHERE eel_emu_nameshort='IT_Sard'AND eel_area_division='37.1.3';UPDATE tempo.emu_divSET area_code='37.1.3.9'WHERE eel_emu_nameshort='IT_Tosc'AND eel_area_division='37.1.3';UPDATE tempo.emu_divSET area_code='37.2.1.17'WHERE eel_emu_nameshort='IT_Vene'AND eel_area_division='37.2.1';UPDATE tempo.emu_divSET area_code='37.2.1.17'WHERE eel_emu_nameshort='SI_total'AND eel_area_division='37.2.1';UPDATE tempo.emu_divSET area_code='37.2.2.13'WHERE eel_emu_nameshort='TN_EC'AND eel_area_division='37.2.2';UPDATE tempo.emu_divSET area_code='37.1.3.12'WHERE eel_emu_nameshort='TN_NE'AND eel_area_division='37.1.3';UPDATE tempo.emu_divSET area_code='37.1.3.12'WHERE eel_emu_nameshort='TN_Nor'AND eel_area_division='37.1.3';UPDATE tempo.emu_divSET area_code='37.2.2.14'WHERE eel_emu_nameshort='TN_SO'AND eel_area_division='37.2.2';DELETEFROM tempo.emu_divWHERE eel_emu_nameshort='ES_Mino'AND eel_area_division='37.1.1';DELETEFROM tempo.emu_divWHERE eel_emu_nameshort='ES_Vale'AND eel_area_division='37.1.2';DELETEFROM tempo.emu_divWHERE eel_emu_nameshort='IT_Pugl'AND eel_area_division='37.2.2';UPDATE tempo.emu_divSET area_code='37.1.1.5'WHERE eel_emu_nameshort='ES_Bale'AND eel_area_division='37.1.1';UPDATE tempo.emu_divSET area_code='37.1.1.6'WHERE eel_emu_nameshort='ES_Cata'AND eel_area_division='37.1.1';UPDATE tempo.emu_divSET area_code='27.9.a'WHERE eel_emu_nameshort='ES_Minh'AND eel_area_division='27.9.a';UPDATE tempo.emu_divSET area_code='27.9.a'WHERE eel_emu_nameshort='ES_Mino'AND eel_area_division='27.9.a';UPDATE tempo.emu_divSET area_code='37.1.1.6'WHERE eel_emu_nameshort='ES_Vale'AND eel_area_division='37.1.1';UPDATE tempo.emu_divSET area_code='37.1.1.1'WHERE eel_emu_nameshort='ES_Murc' ;UPDATE tempo.emu_divSET area_code='27.3.d'WHERE eel_emu_nameshort='LT_total'AND eel_area_division='27.3.d';UPDATE tempo.emu_divSET area_code='27.3.a'WHERE eel_emu_nameshort='NO_total'AND eel_area_division='27.3.a';UPDATE tempo.emu_divSET area_code='27.4.a'WHERE eel_emu_nameshort='NO_total'AND eel_area_division='27.4.a';UPDATE tempo.emu_divSET area_code='27.2.a'WHERE eel_emu_nameshort='NO_total'AND eel_area_division='27.7.a';UPDATE tempo.emu_divSET area_code='27.3.d'WHERE eel_emu_nameshort='PL_total'AND eel_area_division='27.3.d';UPDATE tempo.emu_divSET eel_area_division='27.9.a',area_code='27.9.a'WHERE eel_emu_nameshort='PT_total'AND eel_area_division='27.9.a';UPDATE tempo.emu_divSET area_code='27.3.d'WHERE eel_emu_nameshort='SE_Ea_o'AND eel_area_division='27.3.d';UPDATE tempo.emu_divSET area_code='27.3.d'WHERE eel_emu_nameshort='SE_So_o'AND eel_area_division='27.3.d';UPDATE tempo.emu_divSET area_code='37.3.1.22'WHERE eel_emu_nameshort='GR_total'AND eel_area_division='37.3.1' ;INSERTINTO tempo.emu_div (eel_cou_code,eel_emu_nameshort,area_code)VALUES ('EE','EE_West','27.3.d')INSERTINTO tempo.emu_div (eel_cou_code,eel_emu_nameshort,area_code)VALUES ('EE','EE_West','27.3.d') INSERTINTO dateel.t_stock_sto(sto_id, sto_met_var, sto_year, sto_spe_code, sto_value, sto_are_code, sto_cou_code, sto_lfs_code, sto_hty_code, sto_qal_code, sto_qal_comment, sto_comment, sto_datelastupdate, sto_mis_code, sto_dta_code, sto_wkg_code, sto_ver_code)SELECTeel_id AS sto_id, m.met_var AS sto_met_var, e.eel_year AS sto_year, 'ANG'AS sto_spe_code, e.eel_value AS sto_value, emu_div.area_code AS sto_are_code--, e.eel_area_division , e.eel_cou_code AS sto_cou_code , e.eel_lfs_code AS sto_lfs_code, CASEWHEN e.eel_hty_code ='AL'THENNULLWHEN e.eel_hty_code ='F'THEN'FW'WHEN e.eel_hty_code ='MO'THEN'MO'WHEN e.eel_hty_code ='C'THEN'MC'WHEN e.eel_hty_code ='T'THEN'T'WHEN e.eel_hty_code ISNULLTHENNULLELSE'TROUBLE'ENDAS sto_hty_code--, NULL AS sto_fia_code -- fishing area, e.eel_qal_id AS sto_qal_code , e.eel_qal_comment AS sto_qal_comment , e.eel_comment AS sto_comment, e.eel_datelastupdate AS sto_datelastupdate, e.eel_missvaluequal AS sto_mis_code, 'Public'AS sto_dta_code, 'WGEEL'AS sto_wkg_code, CASEWHEN e.eel_datasource ='wgeel_2016'THEN'WGEEL-2016-1'WHEN e.eel_datasource ='dc_2017'THEN'WGEEL-2017-1'WHEN e.eel_datasource ='weel_2017'THEN'WGEEL-2017-2'WHEN e.eel_datasource ='dc_2018'THEN'WGEEL-2018-1'WHEN e.eel_datasource ='dc_2019'THEN'WGEEL-2019-1'WHEN e.eel_datasource ='dc_2020'THEN'WGEEL-2020-1'WHEN e.eel_datasource ='dc_2021'THEN'WGEEL-2021-1'WHEN e.eel_datasource ='dc_2022'THEN'WGEEL-2022-1'WHEN e.eel_datasource ='dc_2023'THEN'WGEEL-2023-1'WHEN e.eel_datasource ='dc_2024'THEN'WGEEL-2024-1'WHEN e.eel_datasource ='wkemp_2025'THEN'WGEEL-2025-1'ELSE'TROUBLE AND THIS SHOULD FAIL'ENDAS sto_ver_codeFROM datwgeel.t_eelstock_eel e JOIN dateel.t_metadata_met m ON m.met_type::int= e.eel_typ_idLEFTJOIN tempo.emu_div ON (emu_div.eel_emu_nameshort,emu_div.eel_area_division) = (e.eel_emu_nameshort, e.eel_area_division)WHERE eel_qal_id IN (0,1,2,3,4)AND e.eel_hty_code ='C'AND e.eel_value ISNOTNULLAND e.eel_area_division ISNOTNULL; -- 1295---------------------------------------------------------- insert coastal waters where eel_area_division is NULL--------------------------------------------------------CREATETABLE tempo.emu_null ASSELECT*FROM tempo.emu_div WHEREeel_emu_nameshort IN (SELECTDISTINCT eel_emu_nameshort FROMdatwgeel.t_eelstock_eel e WHERE e.eel_qal_id IN (0,1,2,3,4)AND e.eel_hty_code ='C'AND e.eel_value ISNOTNULLAND e.eel_area_division ISNULL)-- See joplin, I have to make some choice, the best for SE_East, DK, and NO would be to split values per eel_hty-- and not have any null values.DELETEFROM tempo.emu_nullWHERE eel_emu_nameshort='DK_Mari'AND eel_area_division='27.3.a';DELETEFROM tempo.emu_nullWHERE eel_emu_nameshort='DK_Mari'AND eel_area_division='27.4.b';DELETEFROM tempo.emu_nullWHERE eel_emu_nameshort='DE_Warn'AND eel_area_division='27.3.b, c';DELETEFROM tempo.emu_nullWHERE eel_emu_nameshort='SE_East'AND eel_area_division='27.3.a';DELETEFROM tempo.emu_nullWHERE eel_emu_nameshort='SE_East'AND eel_area_division='27.3.b, c';DELETEFROM tempo.emu_nullWHERE eel_emu_nameshort='NO_total'AND eel_area_division='27.4.a';DELETEFROM tempo.emu_nullWHERE eel_emu_nameshort='NO_total'AND eel_area_division='27.7.a';INSERTINTO dateel.t_stock_sto(sto_id, sto_met_var, sto_year, sto_spe_code, sto_value, sto_are_code, sto_cou_code, sto_lfs_code, sto_hty_code, sto_qal_code, sto_qal_comment, sto_comment, sto_datelastupdate, sto_mis_code, sto_dta_code, sto_wkg_code, sto_ver_code)SELECTeel_id AS sto_id, m.met_var AS sto_met_var, e.eel_year AS sto_year, 'ANG'AS sto_spe_code, e.eel_value AS sto_value, emu_null.area_code AS sto_are_code--, e.eel_area_division --, e.eel_emu_nameshort, e.eel_cou_code AS sto_cou_code , e.eel_lfs_code AS sto_lfs_code, CASEWHEN e.eel_hty_code ='AL'THENNULLWHEN e.eel_hty_code ='F'THEN'FW'WHEN e.eel_hty_code ='MO'THEN'MO'WHEN e.eel_hty_code ='C'THEN'MC'WHEN e.eel_hty_code ='T'THEN'T'WHEN e.eel_hty_code ISNULLTHENNULLELSE'TROUBLE'ENDAS sto_hty_code--, NULL AS sto_fia_code -- fishing area, e.eel_qal_id AS sto_qal_code , e.eel_qal_comment AS sto_qal_comment , e.eel_comment AS sto_comment, e.eel_datelastupdate AS sto_datelastupdate, e.eel_missvaluequal AS sto_mis_code, 'Public'AS sto_dta_code, 'WGEEL'AS sto_wkg_code, CASEWHEN e.eel_datasource ='wgeel_2016'THEN'WGEEL-2016-1'WHEN e.eel_datasource ='dc_2017'THEN'WGEEL-2017-1'WHEN e.eel_datasource ='weel_2017'THEN'WGEEL-2017-2'WHEN e.eel_datasource ='dc_2018'THEN'WGEEL-2018-1'WHEN e.eel_datasource ='dc_2019'THEN'WGEEL-2019-1'WHEN e.eel_datasource ='dc_2020'THEN'WGEEL-2020-1'WHEN e.eel_datasource ='dc_2021'THEN'WGEEL-2021-1'WHEN e.eel_datasource ='dc_2022'THEN'WGEEL-2022-1'WHEN e.eel_datasource ='dc_2023'THEN'WGEEL-2023-1'WHEN e.eel_datasource ='dc_2024'THEN'WGEEL-2024-1'WHEN e.eel_datasource ='wkemp_2025'THEN'WGEEL-2025-1'ELSE'TROUBLE AND THIS SHOULD FAIL'ENDAS sto_ver_codeFROM datwgeel.t_eelstock_eel e JOIN dateel.t_metadata_met m ON m.met_type::int= e.eel_typ_idLEFTJOIN tempo.emu_null ON (emu_null.eel_emu_nameshort) = (e.eel_emu_nameshort)WHERE eel_qal_id IN (0,1,2,3,4)AND e.eel_hty_code ='C'AND e.eel_value ISNOTNULLAND e.eel_area_division ISNULLAND e. eel_emu_nameshort !='SE_total'; -- 1057SELECT*FROM datwgeel.t_eelstock_eel WHERE eel_id ='567218';SELECT*FROM datwgeel.t_eelstock_eel WHEREeel_qal_id IN (0,1,2,3,4)AND eel_hty_code ='C'AND eel_value ISNOTNULLAND eel_area_division ISNULLAND eel_emu_nameshort ='SE_total'; --4 lines-- TODO eel_percent-- TODO see later TO INSERT deprecated values
6 WGBAST
SQL code to create table datbast.t_metadata_met
DROPTABLEIFEXISTS datbast.t_metadata_met CASCADE;CREATETABLE datbast.t_metadata_met(CONSTRAINT t_metadata_met_pkey PRIMARYKEY(met_var, met_spe_code),CONSTRAINT fk_met_spe_code FOREIGNKEY (met_spe_code)REFERENCESref.tr_species_spe(spe_code) ONUPDATECASCADEONDELETERESTRICT,CONSTRAINT ck_met_spe_code CHECK (met_spe_code='SAL'OR met_spe_code='TRS'),CONSTRAINT fk_met_wkg_code FOREIGNKEY (met_wkg_code)REFERENCESref.tr_icworkinggroup_wkg(wkg_code) ONUPDATECASCADEONDELETERESTRICT,CONSTRAINT ck_met_wkg_code CHECK (met_wkg_code='WGBAST'),CONSTRAINT fk_met_ver_code FOREIGNKEY (met_ver_code)REFERENCES refbast.tr_version_ver(ver_code) ONUPDATECASCADEONDELETERESTRICT,CONSTRAINT fk_met_oty_code FOREIGNKEY (met_oty_code) REFERENCESref.tr_objecttype_oty (oty_code) ONUPDATECASCADEONDELETERESTRICT,CONSTRAINT fk_met_nim_code FOREIGNKEY (met_nim_code) REFERENCESref.tr_nimble_nim (nim_code) ONUPDATECASCADEONDELETERESTRICT, CONSTRAINT fk_met_mtr_code FOREIGNKEY (met_mtr_code)REFERENCESref.tr_metric_mtr(mtr_code)ONUPDATECASCADEONDELETERESTRICT,CONSTRAINT fk_met_uni_code FOREIGNKEY (met_uni_code)REFERENCESref.tr_units_uni(uni_code)ONUPDATECASCADEONDELETERESTRICT,CONSTRAINT fk_met_cat_code FOREIGNKEY (met_cat_code)REFERENCESref.tr_category_cat(cat_code)ONUPDATECASCADEONDELETERESTRICT,CONSTRAINT fk_met_des_code FOREIGNKEY (met_des_code)REFERENCESref.tr_destination_des(des_code)ONUPDATECASCADEONDELETERESTRICT)INHERITS (dat.t_metadata_met);-- COMMENTS FOR WGEELCOMMENTONTABLE datbast.t_metadata_met IS'Table (metadata) of each variable (parameter) in the wgeel database.';COMMENTONCOLUMN datbast.t_metadata_met.met_var IS'Variable code, primary key on both met_spe_code and met_var.';COMMENTONCOLUMN datbast.t_metadata_met.met_spe_code IS'Species, SAL OR TRS primary key on both met_spe_code and met_var.';COMMENTONCOLUMN datbast.t_metadata_met.met_ver_code IS'Code on the version of the model, see table refeel.tr_version_ver.';COMMENTONCOLUMN datbast.t_metadata_met.met_oty_code IS'Object type, single_value, vector, matrix see table tr_objecttype_oty.';COMMENTONCOLUMN datbast.t_metadata_met.met_nim_code IS'Nimble type, one of data, constant, output, other.';COMMENTONCOLUMN datbast.t_metadata_met.met_dim IS'Dimension of the Nimble variable, use {10, 100, 100} to insert the description of an array(10,100,100).';COMMENTONCOLUMN datbast.t_metadata_met.met_dimname IS'Dimension of the variable in Nimble, use {''year'', ''stage'', ''area''}.';COMMENTONCOLUMN datbast.t_metadata_met.met_modelstage IS'Currently one of fit, other, First year.';COMMENTONCOLUMN datbast.t_metadata_met.met_type IS'Type of data in the variable, homewatercatches, Initialisation first year,abundance ....';COMMENTONCOLUMN datbast.t_metadata_met.met_location IS'Describe process with geographical information';COMMENTONCOLUMN datbast.t_metadata_met.met_fishery IS'Description of the fishery.';COMMENTONCOLUMN datbast.t_metadata_met.met_des_code IS'Destination of the fish, e.g. Released (alive), Seal damage,Removed (from the environment), references table tr_destination_des., this is currently only used by WGBAST,so can be kept NULL';COMMENTONCOLUMN datbast.t_metadata_met.met_uni_code IS'Unit, datbasterences table tr_unit_uni.';COMMENTONCOLUMN datbast.t_metadata_met.met_cat_code IS'Broad category of data or parameter, catch, effort, biomass, mortality, count ...datbasterences table tr_category_cat.';COMMENTONCOLUMN datbast.t_metadata_met.met_mtr_code IS'Code of the metric, datbasterences tr_metric_mtr, Estimate, Bound, SD, CV ....';COMMENTONCOLUMN datbast.t_metadata_met.met_definition IS'Definition of the metric.';COMMENTONCOLUMN datbast.t_metadata_met.met_deprecatedIS'Is the variable still used ?';ALTERTABLE datbast.t_metadata_met OWNER TO diaspara_admin;GRANTSELECTON datbast.t_metadata_met TO diaspara_read;
An analysis of the WGBAST dataset for landings shows that it could follow the structure of the main t_stock_sto table, here is the list of changes needed.
gear. The gear must be added to the dimension of the t_stock_sto table, it is one dimension of the table.
Time period. The data are not always reported by YEAR, unlike in eel or WGNAS. Other types of time reporting e.g. Month, Half of year, Quarter need to be added to the t_stock_sto table, since this table is inherited in postgres and aready has one more column (to store some extra dimension) is WGNAS when compared to WGEEL, we need to do the same and allow for three additional columns, one for gear, one for time period type and one for time period.
The metadata will allow by a simple join to get back to F_type (stored in column met_type). It should also for a simple division according to the destination column, allowing to separate dead fish from the living ones.
Effort, Numbers and Weights. The database will be in long format while in the current structure, Effort, Weights and Numbers are reported in separate columns.A simple query will bring back the original format.
Effort is reported in geardays only for driftnet, longline and trapnet fisheries.
TODO CHECK WITH maria about the unit (effort gearxdays)
TODO Check ALV ALL in gears
TODO Check 138 rows without f_type, can these all be attributed to COMM
6.1 Create referential for versions WGBAST
Creating the version referential for WGBAST
DROPTABLEIFEXISTS refbast.tr_version_ver CASCADE;CREATETABLE refbast.tr_version_ver() inherits (ref.tr_version_ver);ALTERTABLE refbast.tr_version_ver ADDCONSTRAINT ver_code_pkey PRIMARYKEY (ver_code);ALTERTABLE refbast.tr_version_ver ADDCONSTRAINT fk_ver_spe_code FOREIGNKEY (ver_spe_code) REFERENCESref.tr_species_spe(spe_code)ONUPDATECASCADEONDELETECASCADE;COMMENTONTABLE refbast.tr_version_verIS'Table of data or variable version, essentially one datacall or advice, inherits ref.tr_version_ver';COMMENTONCOLUMN refbast.tr_version_ver.ver_code IS'Version code, stockkey-year-version.';COMMENTONCOLUMN refbast.tr_version_ver.ver_year IS'Year of assessement.';COMMENTONCOLUMN refbast.tr_version_ver.ver_spe_code IS'Species code left NULL for WGBAST as the data call references several species';COMMENTONCOLUMN refbast.tr_version_ver.ver_stockkeylabel IS'Ver_stockkeylabel e.g. ele.2737.nea.';COMMENTONCOLUMN refbast.tr_version_ver.ver_datacalldoi IS'Data call DOI, find a way to retrieve that information and update this comment';COMMENTONCOLUMN refbast.tr_version_ver.ver_version IS'Version code corresponding to numbering of the versions';COMMENTONCOLUMN refbast.tr_version_ver.ver_description IS'Description of the data call / version.';GRANTALLON refbast.tr_version_ver TO diaspara_admin;GRANTSELECTON refbast.tr_version_ver TO diaspara_read;
Code to insert values into the refbast.tr_version_ver table
tr_version_ver <-data.frame(ver_code =paste0("WGNAS-",2020:2024,"-1"),ver_year =2020:2024,ver_spe_code ="SAL",ver_wkg_code ="WGNAS",ver_datacalldoi=c(NA,NA,NA,NA,"https://doi.org/10.17895/ices.pub.25071005.v3"), ver_stockkeylabel =c("sal.neac.all"), # sugested by Hilaire. # TODO FIND other DOI (mail sent to ICES)ver_version=c(1,1,1,1,1), # TODO WGNAS check that there is just one version per yearver_description=c(NA,NA,NA,NA,NA)) # TODO WGNAS provide model descriptionDBI::dbWriteTable(con_diaspara_admin, "temp_tr_version_ver", tr_version_ver, overwrite =TRUE)dbExecute(con_diaspara_admin, "INSERT INTO refnas.tr_version_ver(ver_code, ver_year, ver_spe_code, ver_stockkeylabel, ver_datacalldoi, ver_version, ver_description, ver_wkg_code) SELECT ver_code, ver_year, ver_spe_code, ver_stockkeylabel, ver_datacalldoi, ver_version::integer, ver_description, ver_wkg_code FROM temp_tr_version_ver;") # 5DBI::dbExecute(con_diaspara_admin, "DROP TABLE temp_tr_version_ver;")tr_version_ver <-data.frame(ver_code =paste0("WGBAST-",2024:2025,"-1"),ver_year =2024:2025,ver_spe_code =NA,ver_wkg_code ="WGBAST",ver_datacalldoi=c("https://doi.org/10.17895/ices.pub.25071005.v3","https://doi.org/10.17895/ices.pub.28218932.v2"), ver_stockkeylabel =c("sal.27.22–31"), # TODO FIND other DOI (mail sent to ICES)ver_version=c(1,1), # TODO WGNAS check that there is just one version per yearver_description=c("Joint ICES Fisheries Data call for landings, discards, biological and effort data and other supporting information in support of the ICES fisheries advice in 2024.","Combined ICES Fisheries Data call for landings, discards, biological and effort data and other supporting information in support of the ICES fisheries advice in 2025.")) # TODO WGNAS provide model descriptionDBI::dbWriteTable(con_diaspara_admin, "temp_tr_version_ver", tr_version_ver, overwrite =TRUE)dbExecute(con_diaspara_admin, "INSERT INTO refbast.tr_version_ver(ver_code, ver_year, ver_spe_code, ver_stockkeylabel, ver_datacalldoi, ver_version, ver_description, ver_wkg_code) SELECT ver_code, ver_year, ver_spe_code, ver_stockkeylabel, ver_datacalldoi, ver_version::integer, ver_description, ver_wkg_code FROM temp_tr_version_ver;") # 2DBI::dbExecute(con_diaspara_admin, "DROP TABLE temp_tr_version_ver;")
Creating the estimation method referential for WGBAST
-- Table of estimation methods when databasis is EstimatedDROPTABLEIFEXISTS refbast.tr_estimationmethod_esm CASCADE;CREATETABLE refbast.tr_estimationmethod_esm () inherits (ref.tr_estimationmethod_esm);ALTERTABLE refbast.tr_estimationmethod_esm ALTERCOLUMN esm_wkg_code SETDEFAULT'WGBAST';ALTERTABLE refbast.tr_estimationmethod_esm ADDCONSTRAINT uk_esm_code UNIQUE (esm_code);COMMENTONTABLE refbast.tr_estimationmethod_esm IS'Table of table estimation method, provided when databasis (dtb_code) correspond to Estimated';COMMENTONCOLUMN refbast.tr_estimationmethod_esm.esm_code IS'Estimation method code';COMMENTONCOLUMN refbast.tr_estimationmethod_esm.esm_description IS'Estimation method description';COMMENTONCOLUMN refbast.tr_estimationmethod_esm.esm_icesvalue IS'Code (Key) of the Estimation method in ICES';COMMENTONCOLUMN refbast.tr_estimationmethod_esm.esm_icesguid IS'UUID (guid) of ICES ';COMMENTONCOLUMN refbast.tr_estimationmethod_esm.esm_icestablesource IS'Source table in ICES';GRANTALLON refbast.tr_estimationmethod_esm TO diaspara_admin;GRANTSELECTON refbast.tr_estimationmethod_esm TO diaspara_read;
Code to import estimation method codes
# esm <-data.frame(esm_id=1:8, esm_code =paste0("SmoltEst",1:8), esm_description =c("Estimate of smolt production from complete count of smolts.","Sampling of smolts and estimate of total smolt run size.","Estimate of smolt run from parr production by relation developed in the same river.","Estimate of smolt run from parr production by relation developed in another river.","Inference of smolt production from data derived from similar rivers in the region.","Estimate of smolt production from count of spawners.","Estimate of smolt production inferred from stocking of reared fish in the river.","Estimate of smolt production from salmon catch, exploitation and survival estimate."), esm_icesvalue =NA,esm_icesguid =NA,esm_icestablesource =NA)DBI::dbWriteTable(con_diaspara_admin, "temp_esmr", esm, overwrite =TRUE)DBI::dbExecute(con_diaspara_admin, "INSERT INTO refbast.tr_estimationmethod_esm(esm_id, esm_code, esm_description, esm_icesvalue, esm_icestablesource)SELECT esm_id, esm_code, esm_description, esm_icesvalue, esm_icestablesourceFROM temp_esmr")# 8DBI::dbExecute(con_diaspara_admin, "DROP table temp_esmr")
6.2 Create datbast.t_metadata_met
Note there is a slight different here, I need to add twice the variables for salmon, and then for trutta. These are no duplicates as the primary key is set on both TRS and SAL. Later on, there should be variables only with SAL (at the second step of the integration process.)
Code to import to metadata for wgbast.
# t_metadata_metdf_all <- readxl::read_xlsx(file.path(datawd, "WGBAST_2024_Catch_29-02-2024.xlsx"), sheet ="Catch data")df_all <- janitor::clean_names(df_all)# C. (Cedric) From there following henni's script : https://github.com/hennip/WGBAST/blob/main/02-data/catch-effort/CatchEffort.r# Comments with C. are added by Cedric, otherwise taken from github# quick fix to avoid logical I put char in subdiv_IC[1]df_all$subdiv_ic[1] <-NAdf_all <- df_all |>mutate(tp_type=ifelse(tp_type=="QRT", "QTR", tp_type), gear=ifelse(gear=="GNS", "MIS", gear), # Tapani commentw_type =ifelse(w_type %in%c('EXP','GST'), 'EXV', w_type),n_type =ifelse(n_type %in%c('EXP','GST'), 'EXV', n_type))# Gears#unique(df_all$gear)#NA "AN" "LLD" "GND" "MIS" "FYK" "All" "ALV"#table(df_all$gear)#All ALV AN FYK GND LLD MIS # 93 29 1597 3432 1013 1541 9122 # driftnet=GND, longline=LLD, trapnet=FYK, angling=AN, other=MIS, set gillnet (anchored, stationary)=GNSdf_all$gearICES <-case_when(df_all$gear =="AN"~"LHP", # CHECK THIS Handlines and hand-operated pole-and-lines df_all$gear =="LLD"~"LLD", df_all$gear =="GND"~"GND", df_all$gear =="MIS"~"MIS", df_all$gear =="FYK"~"FYK", df_all$gear =="ALV"~"LHP") # LV and FI, in river RECR# ALV: discarded alive, BMS: below minimum landing size (dead)# creating t_metadata_met# # commercial=COMM, recreational=RECR, discard=DISC, sealdamage=SEAL, unreported=UNRP, ALV=released alive back in water, BMS= Below minimum landings size, BROOD=broodstock fishery#table(df_all$f_type, useNA = "ifany")# ALV BMS BROOD COMM DISC RECR SEAL <NA> # 537 77 39 12920 334 2473 980 368# #table(df_all$w_type)# there are missing values for f_type, correspond to SAL FI/SE, 1972-1999# then SAL 2000 FI/SE, 24-31 logbooks weights# then SAL 2001 SE, 2000# 3000 logbooks weights# then 2 lines SAL TRS # then lines for LT or LV# # => I think all those lines are COMM, this would be consistent with f_type in scripts# where COMM is never used (the default)# #print(df_all[is.na(df_all$f_type), ], n ="Inf")df_all <-bind_rows( df_all |>filter(is.na(f_type)) |>mutate(tp_type=ifelse(fishery =="F", "REC", "COMM")), df_all |>filter(!is.na(f_type)))# EST EXP EXT EXV GST LOG # 893 28 495 1218 30 14188 # # EST EXP EXT EXV GST LOG # 944 28 335 1295 9 14117 # table(df_all$n_type, df_all$w_type, useNA = "ifany")# EST EXT EXV LOG <NA># EST 679 2 26 181 56# EXP 0 0 28 0 0# EXT 2 256 0 75 2# EXV 51 0 1210 0 34# GST 1 0 8 0 0# LOG 106 237 0 13704 70# <NA> 54 0 4 228 714# these are not used (f_type, w_type) => ignored or add to comments.# table(df_all$f_type, df_all$w_type, useNA ="ifany") #table(df_all$f_type)saveRDS(df_all, file="data/wgbast_landings_modified.Rds")# t_metadata_met <- dbGetQuery(con_diaspara, "SELECT * FROM datbast.t_metadata_met;")# clipr::write_clip(colnames(t_metadata_met))# head(t_metadata_met)uktyp <-unique(df_all$f_type)uktyp[is.na(uktyp)] <-"HIST"# historical data, check hopefully it's OKtyp <-outer(c("N","W","E"), paste0("_",uktyp ), FUN ="paste0")dim(typ) <-NULL#"N_HIST" "W_HIST" "E_HIST" "N_COMM" "W_COMM" "E_COMM" "N_ALV" "W_ALV" "E_ALV" "N_RECR" "W_RECR" "E_RECR" "N_DISC" #"W_DISC" "E_DISC" "N_SEAL" "W_SEAL" "E_SEAL" "N_BMS" "W_BMS" "E_BMS" "N_BROOD" "W_BROOD" "E_BROOD"#typ <- outer(typ, c("_SAL", "_TRS"), FUN = "paste0")#dim(typ) <- NULL#get the type backmet_type <-substring(typ, 3,nchar(typ)) #COMM COMM, ...., uni_code <-substring(typ, 1,1)uni_code <-case_when(uni_code =="E"~"nd", uni_code =="W"~"kg", uni_code =="N"~"nr") #see https://diaspara.bordeaux-aquitaine.inrae.fr/deliverables/wp3/p7/midb.html#unit-tr_units_uni# vector with SAL ... then TRS# The column species is repeated because the foreign key for t_stock_sto is on both TRS and SAL,# so for instance we'll have two lines one with COMM_N for TRS one for SAL.# It might seem weird but might allow for different metadata, and also most importantly# later on, in the model some variables will be specific to SAL# but when the variables are in common, then need to be repeated.t_metadata_met_TRS <-data.frame(met_var = typ,met_spe_code ="TRS",met_wkg_code ="WGBAST",met_ver_code ="WGBAST-2025-1", met_oty_code ="Single_value", # https://diaspara.bordeaux-aquitaine.inrae.fr/deliverables/wp3/p7/midb.html#object-type-tr_objectype_otymet_nim_code ="Data", # https://diaspara.bordeaux-aquitaine.inrae.fr/deliverables/wp3/p7/midb.html#type-of-parm-data-tr_nimble_nimmet_dim =paste0("{", 1, ",",0, ",",0, "}" ),met_dimname =paste0("{'NULL',NULL,NULL}" ),# Here unlike the eel, I cannot be sure the first dimension is year, might be MON, HYR ....met_modelstage =NA,met_type = met_type, # not a referential, used for legacy in WGNAS, # see https://diaspara.bordeaux-aquitaine.inrae.fr/deliverables/wp3/p4/wgnas_salmoglob_description.html#tbl-globaldata2-4met_location =NA, # something line bef. Fisheries Aft fisheries.... not a referentialmet_fishery =NA, # not a referentialmet_mtr_code =NA, # reference to tr_metrictype (bound, mean, SD, can be left empty)met_des_code =case_when( met_type =="COMM"~"Removed", met_type =="ALV"~"Released", met_type =="RECR"~"Removed", met_type =="DISC"~"Discarded", met_type =="BROOD"~"Removed", met_type =="SEAL"~"Seal damaged", met_type =="BMS"~"Discarded",.default =NA),# https://diaspara.bordeaux-aquitaine.inrae.fr/deliverables/wp3/p7/midb.html#destination-tr_destination_destmet_uni_code = uni_code,met_cat_code =case_when( met_type =="COMM"~"Catch", met_type =="ALV"~"Release", met_type =="RECR"~"Catch", met_type =="DISC"~"Catch", met_type =="BROOD"~"Other", met_type =="SEAL"~"Other", met_type =="BMS"~"Catch",.default =NA),met_definition ="TODO",met_deprecated =NA# not integrating any of the deprecated data)t_metadata_met_SAL <- t_metadata_met_TRSt_metadata_met_SAL$met_spe_code<-"SAL"t_metadata_met <-bind_rows(t_metadata_met_TRS,t_metadata_met_SAL)DBI::dbWriteTable(con_diaspara_admin, "temp_wgbast_t_metadata_met", t_metadata_met, overwrite =TRUE)DBI::dbExecute(con_diaspara_admin, "DELETE FROM datbast.t_metadata_met")DBI::dbExecute(con_diaspara_admin, "INSERT INTO datbast.t_metadata_met(met_var, met_spe_code, met_wkg_code, met_ver_code, met_oty_code, met_nim_code, met_dim, met_dimname, met_modelstage, met_type, met_location, met_fishery, met_mtr_code, met_des_code, met_uni_code, met_cat_code, met_definition, met_deprecated)SELECT met_var, met_spe_code, met_wkg_code, met_ver_code, met_oty_code, met_nim_code, met_dim::integer[], met_dimname::text[], met_modelstage, met_type, met_location, met_fishery, met_mtr_code, met_des_code, met_uni_code, met_cat_code, met_definition, met_deprecated FROM temp_wgbast_t_metadata_met") #48
Code to import to metadata for wgbast (variables model)
# sent by Beckyscalar <-read_csv("data/WGBAST scalars1.csv")scalar <- janitor::clean_names(scalar)array <-read_csv("data/WGBAST vectors_arrays1.csv")array <- janitor::clean_names(array)t_metadata_met_a <-data.frame(met_var = array$variable_name,met_spe_code ="SAL",met_wkg_code ="WGBAST",met_ver_code ="WGBAST-2025-1", met_oty_code =ifelse(is.na(array$dim2), "Vector",ifelse(is.na(array$dim3),"Matrix", "Array")), # Single_value Vector Matrix Array https://diaspara.bordeaux-aquitaine.inrae.fr/deliverables/wp3/p7/midb.html#object-type-tr_objectype_otymet_nim_code =ifelse(array$type =="stockastic", "Data", "Output"), #scenarios or stockastic TODO check consistency with WGNAS https://diaspara.bordeaux-aquitaine.inrae.fr/deliverables/wp3/p7/midb.html#type-of-parm-data-tr_nimble_nimmet_dim =paste0("{", array$dim1, ",",ifelse(is.na(array$dim2), 0,array$dim2), ",",ifelse(is.na(array$dim3), 0,array$dim3), "}" ),met_dimname =paste0("{",array$dim1_description,",", ifelse(array$dim2_description=="NA", NULL,array$dim2_description),",", ifelse(array$dim3_description=="NA",NULL,array$dim3_description),"}" ),# Here unlike the eel, I cannot be sure the first dimension is year, might be MON, HYR ....met_modelstage =NA,met_type =NA, # TODO# not a referential, used for legacy in WGNAS, # see https://diaspara.bordeaux-aquitaine.inrae.fr/deliverables/wp3/p4/wgnas_salmoglob_description.html#tbl-globaldata2-4met_location =NA, # something line bef. Fisheries Aft fisheries.... not a referentialmet_fishery =NA, # not a referentialmet_mtr_code =NA, # reference to tr_metrictype (bound, mean, SD, can be left empty)met_des_code =NA,# https://diaspara.bordeaux-aquitaine.inrae.fr/deliverables/wp3/p7/midb.html#destination-tr_destination_destmet_uni_code =NA,met_cat_code =NA, # TODOmet_definition ="TODO",met_deprecated =NA# not integrating any of the deprecated data)t_metadata_met_s <-data.frame(met_var = scalar$name,met_spe_code ="SAL",met_wkg_code ="WGBAST",met_ver_code ="WGBAST-2025-1", met_oty_code ="Single_value", met_nim_code =ifelse(scalar$type =="stochastic", "Data", "Output"), #scenarios or stochastic TODO check consistency with WGNAS https://diaspara.bordeaux-aquitaine.inrae.fr/deliverables/wp3/p7/midb.html#type-of-parm-data-tr_nimble_nimmet_dim =paste0("{", 1, ",",0, ",",0, "}" ),met_dimname =paste0("{'NULL',NULL,NULL}" ),# Here unlike the eel, I cannot be sure the first dimension is year, might be MON, HYR ....met_modelstage =NA,met_type =NA, # TODO# not a referential, used for legacy in WGNAS, # see https://diaspara.bordeaux-aquitaine.inrae.fr/deliverables/wp3/p4/wgnas_salmoglob_description.html#tbl-globaldata2-4met_location =NA, # something line bef. Fisheries Aft fisheries.... not a referentialmet_fishery =NA, # not a referentialmet_mtr_code =NA, # reference to tr_metrictype (bound, mean, SD, can be left empty)met_des_code =NA,# https://diaspara.bordeaux-aquitaine.inrae.fr/deliverables/wp3/p7/midb.html#destination-tr_destination_destmet_uni_code =NA,met_cat_code =NA, # TODOmet_definition ="TODO",met_deprecated =NA# not integrating any of the deprecated data)t_metadata_met<-bind_rows(t_metadata_met_s, t_metadata_met_a)DBI::dbWriteTable(con_diaspara_admin, "temp_wgbast_t_metadata_met", t_metadata_met, overwrite =TRUE)DBI::dbExecute(con_diaspara_admin, "INSERT INTO datbast.t_metadata_met(met_var, met_spe_code, met_wkg_code, met_ver_code, met_oty_code, met_nim_code, met_dim, met_dimname, met_modelstage, met_type, met_location, met_fishery, met_mtr_code, met_des_code, met_uni_code, met_cat_code, met_definition, met_deprecated)SELECT met_var, met_spe_code, met_wkg_code, met_ver_code, met_oty_code, met_nim_code, met_dim::integer[], met_dimname::text[], met_modelstage, met_type, met_location, met_fishery, met_mtr_code, met_des_code, met_uni_code, met_cat_code, met_definition, met_deprecated FROM temp_wgbast_t_metadata_met") #117
6.3 datbast.t_stock_sto
There are three additional column in databast.t_stock_sto when compared to dat.t_stock_sto, the table from which it inherits. This is similar to datnas.t_stock_sto where an additional column was created to handle the extra dimension for some arrays stored in WGNAS. The columns are :
sto_tip_code the time period, one of YR, HYR (half year), QTR (Quarter), MON (Month). A vocabulary has been created for checks on these time periods.
sto_timeperiod integer, the value of the time period. Note : a trigger has been created to handle different possible values for sto_tip_code (e.g. half of year can be 1 or 2 , and month between 1 and 12).
sto_datasourcecode. This column is not used in scripts, but discussion with Henni have shown that this remains important. It will be adapted to ICES vocab DataSource with additions for elements on the calculation of smolts in the Young fish database (see
.
SQL code to create table datbast.t_stock_sto
-- CREATE A TABLE INHERITED FROM dat.t_stock_sto.-- Table dat.stock_sto only gets data by inheritance.-- Here we have to build the constraints again.DROPTABLEIFEXISTS datbast.t_stock_sto;CREATETABLE datbast.t_stock_sto ( sto_gear_code text,CONSTRAINT fk_sto_gear_code FOREIGNKEY (sto_gear_code) REFERENCESref.tr_gear_gea(gea_code)ONUPDATECASCADEONDELETERESTRICT, sto_tip_code TEXT,CONSTRAINT fk_tip_code FOREIGNKEY (sto_tip_code)REFERENCESref.tr_timeperiod_tip(tip_code)ONUPDATECASCADEONDELETERESTRICT, sto_timeperiod integerNOTNULL, sto_dts_code TEXT,CONSTRAINT fk_sto_dts_code FOREIGNKEY (sto_dts_code) REFERENCESref.tr_datasource_dts(dts_code)ONUPDATECASCADEONDELETERESTRICT, sto_dtb_code TEXT,CONSTRAINT fk_sto_dtb_code FOREIGNKEY (sto_dtb_code) REFERENCESref.tr_databasis_dtb(dtb_code)ONUPDATECASCADEONDELETERESTRICT, sto_esm_code TEXT,CONSTRAINT fk_sto_esm_code FOREIGNKEY (sto_esm_code)REFERENCES refbast.tr_estimationmethod_esm(esm_code)ONUPDATECASCADEONDELETERESTRICT, CONSTRAINT fk_sto_met_var_met_spe_codeFOREIGNKEY (sto_met_var, sto_spe_code) REFERENCES datbast.t_metadata_met(met_var,met_spe_code)ONUPDATECASCADEONDELETERESTRICT,CONSTRAINT fk_sto_are_code FOREIGNKEY (sto_are_code)REFERENCES refbast.tr_area_are (are_code) ONUPDATECASCADEONDELETERESTRICT,CONSTRAINT fk_sto_cou_code FOREIGNKEY (sto_cou_code)REFERENCESref.tr_country_cou (cou_code)ONUPDATECASCADEONDELETERESTRICT,CONSTRAINT fk_sto_lfs_code_sto_spe_code FOREIGNKEY (sto_lfs_code, sto_spe_code)REFERENCESref.tr_lifestage_lfs (lfs_code, lfs_spe_code) ONUPDATECASCADEONDELETERESTRICT,CONSTRAINT fk_hty_code FOREIGNKEY (sto_hty_code)REFERENCESref.tr_habitattype_hty(hty_code) ONUPDATECASCADEONDELETERESTRICT,CONSTRAINT fk_sto_qal_code FOREIGNKEY (sto_qal_code)REFERENCESref.tr_quality_qal(qal_code)ONUPDATECASCADEONDELETERESTRICT,CONSTRAINT fk_sto_mis_code FOREIGNKEY (sto_mis_code)REFERENCESref.tr_missvalueqal_mis (mis_code)ONUPDATECASCADEONDELETERESTRICT,CONSTRAINT fk_dta_code FOREIGNKEY (sto_dta_code)REFERENCESref.tr_dataaccess_dta(dta_code) ONUPDATECASCADEONDELETERESTRICT, CONSTRAINT fk_sto_wkg_code FOREIGNKEY (sto_wkg_code)REFERENCESref.tr_icworkinggroup_wkg(wkg_code)ONUPDATECASCADEONDELETERESTRICT, CONSTRAINT c_uk_sto_id_sto_wkg_code UNIQUE (sto_id, sto_wkg_code),CONSTRAINT ck_notnull_value_and_mis_code CHECK ((((sto_mis_code ISNULL) AND (sto_value ISNOTNULL)) OR ((sto_mis_code ISNOTNULL) AND (sto_value ISNULL)))))inherits (dat.t_stock_sto) ;-- This table will always be for WGBASTALTERTABLE datbast.t_stock_sto ALTERCOLUMN sto_spe_code SETDEFAULTNULL;ALTERTABLE datbast.t_stock_sto ADDCONSTRAINT ck_spe_code CHECK (sto_spe_code='SAL'OR sto_spe_code='TRS');ALTERTABLE datbast.t_stock_sto ALTERCOLUMN sto_wkg_code SETDEFAULT'WGBAST';ALTERTABLE datbast.t_stock_sto ADDCONSTRAINT ck_wkg_code CHECK (sto_wkg_code='WGBAST');ALTERTABLE datbast.t_stock_sto OWNER TO diaspara_admin;GRANTALLONTABLE datbast.t_stock_sto TO diaspara_read;COMMENTONTABLE datbast.t_stock_sto IS'Table including the stock data in schema datbast.... This table feeds the dat.t_stock_sto table by inheritance. It correspondsto the catch excel table in the original WGBAST database.';COMMENTONCOLUMN datbast.t_stock_sto.sto_id IS'Integer serial identifying. Only unique in this tablewhen looking at the pair, sto_id, sto_wkg_code';COMMENTONCOLUMN datbast.t_stock_sto.sto_gear_code IS'Code of the gear used, this column is specific to WGBAST, e.g. it only appears in wgbast.t_stock_sto not in dat.t_stock_sto';COMMENTONCOLUMN datbast.t_stock_sto.sto_tip_code IS'Code of the time period used, one of "MON" = month,"HYR" = half of year,"QTR" = quarter,"YR" = Year this column is specific to WGBAST, e.g. it only appears in wgbast.t_stock_sto not in dat.t_stock_sto';COMMENTONCOLUMN datbast.t_stock_sto.sto_timeperiod IS'An integer giving the value of the time period used';COMMENTONCOLUMN datbast.t_stock_sto.sto_dts_code IS'Code of the data source one of Logb (logbook), Exprt (Expert) SampDS (Survey sampling), SampDC (Commercial sampling), ... see DataSource ICES Vocab;';COMMENTONCOLUMN datbast.t_stock_sto.sto_dtb_code IS'Code of the data basis, one of Estimated, Measured, NotApplicable, Official, Unknown from vocab DataBasis in ICES';COMMENTONCOLUMN datbast.t_stock_sto.sto_esm_code IS'Code of the estimation method, one of smolt1, ...';COMMENTONCOLUMN datbast.t_stock_sto.sto_met_var IS'Name of the variable in the database, this is a mixture for f_type, value type (effort E, Number N, Weight W), and species e.g. COMM_N_TRT, see databast.t_metadata_met.met_var, there is a unicity constraint basedon the pair of column sto_spe_code, sto_met_var';-- note if we end up with a single table, then the constraint will have to be set-- on sto_wkg_code, sto_spe_code and sto_met_code.COMMENTONCOLUMN datbast.t_stock_sto.sto_year IS'Year';COMMENTONCOLUMN datbast.t_stock_sto.sto_value IS'Value if null then provide a value in sto_mis_code to explain why not provided';COMMENTONCOLUMN datbast.t_stock_sto.sto_are_code IS'Code of the area, areas are geographical sector most often corresponding to stock units, see tr_area_are.';COMMENTONCOLUMN datbast.t_stock_sto.sto_cou_code IS'Code of the country see tr_country_cou, not null';COMMENTONCOLUMN datbast.t_stock_sto.sto_lfs_code IS'Code of the lifestage see tr_lifestage_lfs, Not null, the constraint is set on both lfs_code, and lfs_spe_code (as two species can have the same lifestage code.';COMMENTONCOLUMN datbast.t_stock_sto.sto_hty_code IS'Code of the habitat type, one of MO (marine open), MC (Marine coastal), T (Transitional water), FW (Freshwater), null accepted';COMMENTONCOLUMN datbast.t_stock_sto.sto_qal_code IS'Code of data quality (1 good quality, 2 modified by working group, 3 bad quality (not used), 4 dubious, 18, 19 ... historical data not used. Not null, Foreign key set to tr_quality_qal';COMMENTONCOLUMN datbast.t_stock_sto.sto_qal_comment IS'Comment for the quality, for instance explaining why a data is qualified as good or dubious.';COMMENTONCOLUMN datbast.t_stock_sto.sto_comment IS'Comment on the value';COMMENTONCOLUMN datbast.t_stock_sto.sto_datelastupdate IS'Last update of the data';COMMENTONCOLUMN datbast.t_stock_sto.sto_mis_code IS'When no value are given in sto_value, justify why with, NC (not collected), NP (Not pertinent), NR (Not reported),references table tr_missvalueqal_mis, should be null if value is provided (can''t have both).';COMMENTONCOLUMN datbast.t_stock_sto.sto_dta_code IS'Access to data, default is ''Public''';COMMENTONCOLUMN datbast.t_stock_sto.sto_wkg_code IS'Code of the working group, one ofWGBAST, WGEEL, WGNAS, WKTRUTTA';COMMENTONCOLUMN datbast.t_stock_sto.sto_ver_code IS'Version code, references refbast.tr_version_ver, code like WGBAST-2025-1, all historical data set to WGBAST-2024-1';-- trigger on dateDROPFUNCTIONIFEXISTS datbast.update_sto_datelastupdate CASCADE;CREATEORREPLACEFUNCTION datbast.update_sto_datelastupdate() RETURNS trigger LANGUAGE plpgsqlAS $function$BEGINNEW.sto_datelastupdate = now()::date;RETURNNEW; END;$function$;ALTERFUNCTION datbast.update_sto_datelastupdate() OWNER TO diaspara_admin;CREATETRIGGER update_sto_datelastupdate BEFOREINSERTORUPDATEON datbast.t_stock_sto FOREACHROWEXECUTEFUNCTION datbast.update_sto_datelastupdate();-- trigger to check consistency between sto_timeperiod and sto_tip_code-- MonCREATEORREPLACEFUNCTION datbast.check_time_period() RETURNS TRIGGER LANGUAGE plpgsqlAS $check_time_period$BEGIN-- sto_timeperiod is always positive or NULL-- if sto_tip_code = "YR" keep sto_timeperiod NULLIF (NEW.sto_tip_code ='Year'ANDNEW.sto_timeperiod >0) THEN RAISE EXCEPTION'sto_timeperiod should be 0 when the code for time period (sto_tip_code) is YR (year), the year is filled in column sto_year';ENDIF;-- if sto_tip_code = "QTR" check 1 2 3 or 4IF (NEW.sto_tip_code ='>Quarter'ANDNEW.sto_timeperiod >4) THEN RAISE EXCEPTION'sto_timeperiod should be 1, 2, 3 or 4 for quarters';ENDIF; -- half of year is one or two IF (NEW.sto_tip_code ='Half of Year'ANDNEW.sto_timeperiod >2) THEN RAISE EXCEPTION'sto_timeperiod should be 1 (first half) 2 (second half) when the code for time period (sto_tip_code) is HYR (half of year)' ;ENDIF;-- half of year is one or two IF (NEW.sto_tip_code ='Month'ANDNEW.sto_timeperiod >12) THEN RAISE EXCEPTION'sto_timeperiod should be 1 to 12 when the code for timeperiod (sto_tip_code) is MON (Month)';ENDIF;RETURNNEW; END;$check_time_period$;ALTERFUNCTION datbast.check_time_period() OWNER TO diaspara_admin;DROPTRIGGERIFEXISTS trg_check_time_period ON datbast.t_stock_sto ;CREATETRIGGER trg_check_time_period BEFOREINSERTORUPDATEON datbast.t_stock_sto FOREACHROWEXECUTEFUNCTION datbast.check_time_period();
Clearly the table of datasource will have to be revised and new methodologies added and
Code to import to t_stock_sto for wgbast
df_all <-readRDS(file="data/wgbast_landings_modified.Rds")# Modify some lines with comments (TO BE CHECKED BY WGBAST)df_all[df_all$sub_div =="21"&!is.na(df_all$sub_div) ,"Notes"] <-"ATTENTION THESE WERE MARKED AS 21 WHICH doesn't exist,They have been changed to 31, please check"#Inversion of tp_type and n_typedf_all[df_all$tp_type=='COMM'& df_all$time_period!=0,"tp_type"] <-"MON"# 4 lines where COMM is obvioulsy not YEAR# the other are yearid_err <-which(is.na(df_all$f_type)& df_all$tp_type=="COMM")df_all[id_err,"tp_type"] <-"YR"df_all[id_err,"f_type"] <-"COMM"#Year without 0 as time_period one line with 2 in Estonia all other have 0df_all[df_all$tp_type=='YR'& df_all$time_period!=0,"time_period"]<-0# Year should be YR in the initial datasetdf_all[df_all$tp_type=="Year"&!is.na(df_all$tp_type),"tp_type"] <-"YR"# missing tp_typedf_all[is.na(df_all$tp_type),"tp_type"] <-"YR"# 6 lines with historical data# in Estonia there are both SAL&TRS and NA, which correspond to sea damage unspecified.# I cannot have that, will report as Salmon, leave to the WGBAST to see how to handle this.df_all[!is.na(df_all$species) & df_all$species =="SAL&TRS","species"]<-"SAL"df_all[is.na(df_all$species) ,"species"]<-"SAL"df_all[df_all$species=="NA" ,"species"]<-"SAL"# create table of rivernames in WGBAST, do queries and manual search to join them# to our layer.# tt <- table(df_all$river)# tt <- tt[order(tt, decreasing =TRUE)]# tt <- as.data.frame(tt)# colnames(tt) <- c("riv_are_name", "number")# dbWriteTable(con_diaspara_admin, "landings_wbast_river_names", tt,overwrite = TRUE)# dbExecute(con_diaspara_admin, "ALTER TABLE landings_wbast_river_names set schema refbast;")# dbExecute(con_diaspara_admin, "ALTER TABLE refbast.landings_wbast_river_names ADD COLUMN riv_are_code TEXT;")# # For recreational fisheries, the river column is used.# It will be used as the hierarchy level to enter the datariv <-dbGetQuery(con_diaspara_admin, "SELECT * FROM refbast.landings_wbast_river_names JOIN refbast.tr_area_are on are_code = riv_are_code")# get the are_code...df_all <- df_all |>left_join(riv |>select(riv_are_name, riv_are_code), by =join_by(river == riv_are_name)) gear <-dbGetQuery(con_diaspara_admin, "SELECT * FROM ref.tr_gear_gea WHERE gea_icesvalue is NOT NULL")df_all <- df_all |>left_join(gear |>select(gea_code, gea_icesvalue), by =join_by(gearICES == gea_icesvalue)) # Insert Numbersdf_all_N <- df_all |>filter(!is.na(numb)) |>mutate(f_type =ifelse(is.na(f_type), "HIST", f_type)) |>mutate(sto_met_var =paste0("N_",f_type))# unit allows to avoid having NA in strings ... Here we put additional info in the comment from the contentdf_all_N$n_type2 <- df_all_N$n_typedf_all_N$n_type2[!is.na(df_all_N$n_type)]<-paste0("N_type=",df_all_N$n_type2[!is.na(df_all_N$n_type)])df_all_N$n_type2[!is.na(df_all_N$notes)] <-paste0(", ",df_all_N$n_type2[!is.na(df_all_N$notes)])df_all_N$n_type2[is.na(df_all_N$n_type)]<-""df_all_N$notes2 <- df_all_N$notesdf_all_N$notes2[is.na(df_all_N$notes2)] <-""df_all_N$notes2 <-paste0(df_all_N$notes2,df_all_N$n_type2)t_stock_sto_N =data.frame(sto_met_var = df_all_N$sto_met_var,sto_year = df_all_N$year,sto_spe_code = df_all_N$species,sto_value = df_all_N$numb,# if it's a river get the code of the river otherwise get other codes....sto_are_code =case_when(!is.na(df_all_N$river) ~ df_all_N$riv_are_code, df_all_N$sub_div =="22-32"~"27.3.d", # correct, 3 lines corresponding to national survey Estonia df_all_N$sub_div =="200"~"27.3.d.22-29", df_all_N$sub_div =="300"~"27.3.d.30-31", df_all_N$sub_div =="32"~"27.3.d.32", df_all_N$sub_div =="31"~"27.3.d.31", df_all_N$sub_div =="30"~"27.3.d.30", df_all_N$sub_div =="29"~"27.3.d.29", df_all_N$sub_div =="27"~"27.3.d.27", df_all_N$sub_div =="26"~"27.3.d.26", df_all_N$sub_div =="25"~"27.3.d.25", df_all_N$sub_div =="24"~"27.3.d.24", df_all_N$sub_div =="23"~"27.3.b.23", df_all_N$sub_div =="22"~"27.3.c.22", df_all_N$sub_div =="21"~"27.3.d.31",# 3 Lines for sweden comment added# here we allow for the two subdivision in the Baltic df_all_N$sub_div =="28"& df_all_N$subdiv_ic =='27.3.d.28.1'~'27.3.d.28.1', df_all_N$sub_div =="28"& df_all_N$subdiv_ic =='27.3.d.28.2'~'27.3.d.28.2', df_all_N$sub_div =="28"~"27.3.d.28",is.na(df_all_N$sub_div) ~"27.3.d"# 12 rows with with comments corresponds all catches of the country and year concerned ),sto_cou_code = df_all_N$country,sto_lfs_code ='A',sto_hty_code =case_when(df_all_N$fishery =="O"~"MO", df_all_N$fishery =="C"~"MC", df_all_N$fishery =="R"~"FW"),sto_qal_code =1,sto_comment = df_all_N$notes2,sto_datelastupdate =Sys.Date(),sto_mis_code =NA,sto_dta_code ="Public", # check thissto_wkg_code ="WGBAST",sto_ver_code ="WGBAST-2025-1",sto_gear_code = df_all_N$gea_code,sto_tip_code =case_when(df_all_N$tp_type =="YR"~"Year", df_all_N$tp_type =="HYR"~"Half of Year", df_all_N$tp_type =="MON"~"Month", df_all_N$tp_type =="MONTH"~"Month", df_all_N$tp_type =="QTR"~"Quarter", df_all_N$tp_type =="COMM"~"Quarter", # this is an erroris.na( df_all_N$tp_type) ~"Year",.default ="Troube this will fail at insertion"),sto_timeperiod = df_all_N$time_period,# in the notes some elements hint at surveys, but this will need a check up by WGBAST anyways.sto_dts_code =case_when(df_all_N$n_type =="LOG"~"Logb", df_all_N$n_type =="EXV"~"Exprt", df_all_N$n_type =="EST"& (grepl("survey",tolower(df_all_N$notes)) |grepl("question",tolower(df_all_N$notes)) |grepl("query", tolower(df_all_N$notes)) |grepl("web", tolower(df_all_N$notes))) ~"SampDS", df_all_N$n_type =="EXT"~NA),sto_dtb_code =case_when(df_all_N$n_type =="LOG"~"Official", df_all_N$n_type =="EXV"~"Estimated", df_all_N$n_type =="EST"~"Estimated", df_all_N$n_type =="EXT"~"Estimated",.default ="Unknown"),sto_esm_code =NA) #dbExecute(con_diaspara_admin, "drop table if exists temp_t_stock_sto_n")dbExecute(con_diaspara_local, "drop table if exists temp_t_stock_sto_n")system.time(dbWriteTable(con_diaspara_local, "temp_t_stock_sto_n", t_stock_sto_N)) # 27sdbExecute(con_diaspara_local, "DELETE FROM datbast.t_stock_sto")dbExecute(con_diaspara_local, "INSERT INTO datbast.t_stock_sto(sto_met_var, sto_year, sto_spe_code, sto_value, sto_are_code, sto_cou_code, sto_lfs_code, sto_hty_code, sto_qal_code, sto_comment, sto_datelastupdate, sto_mis_code, sto_dta_code, sto_wkg_code, sto_ver_code, sto_gear_code, sto_tip_code, sto_timeperiod, sto_dts_code, sto_dtb_code, sto_esm_code) SELECT sto_met_var, sto_year, sto_spe_code, sto_value, sto_are_code, sto_cou_code, sto_lfs_code, sto_hty_code, sto_qal_code, sto_comment, sto_datelastupdate, sto_mis_code, sto_dta_code, sto_wkg_code, sto_ver_code, sto_gear_code, sto_tip_code, sto_timeperiod, sto_dts_code, sto_dtb_code, sto_esm_code FROM temp_t_stock_sto_n") # 14402dbExecute(con_diaspara_local, "drop table temp_t_stock_sto_n")# Insert WEIGHTS-------------------------------------# df_all_W <- df_all |>filter(!is.na(weight)) |>mutate(f_type =ifelse(is.na(f_type), "HIST", f_type)) |>mutate(sto_met_var =paste0("W_",f_type))# unit allows to avoid having NA in strings ... Here we put additional info in the comment from the contentdf_all_W$w_type2 <- df_all_W$w_typedf_all_W$w_type2[!is.na(df_all_W$w_type)]<-paste0("W_type=",df_all_W$w_type2[!is.na(df_all_W$w_type)])df_all_N$w_type2[!is.na(df_all_N$notes)] <-paste0(", ",df_all_N$w_type2[!is.na(df_all_N$notes)])df_all_W$w_type2[is.na(df_all_W$w_type)]<-""df_all_W$notes2 <- df_all_W$notesdf_all_W$notes2[is.na(df_all_W$notes2)] <-""df_all_W$notes2<-paste0(df_all_W$notes2,df_all_W$w_type2)df_all_W$notes2[df_all_W$notes2==""] <-NAt_stock_sto_W =data.frame(sto_met_var = df_all_W$sto_met_var,sto_year = df_all_W$year,sto_spe_code = df_all_W$species,sto_value = df_all_W$weight,# if it's a river get the code of the river otherwise get other codes....sto_are_code =case_when(!is.na(df_all_W$river) ~ df_all_W$riv_are_code, df_all_W$sub_div =="22-32"~"27.3.d", # correct, 3 lines corresponding to national survey Estonia df_all_W$sub_div =="200"~"27.3.d.22-29", df_all_W$sub_div =="300"~"27.3.d.30-31", df_all_W$sub_div =="32"~"27.3.d.32", df_all_W$sub_div =="31"~"27.3.d.31", df_all_W$sub_div =="30"~"27.3.d.30", df_all_W$sub_div =="29"~"27.3.d.29", df_all_W$sub_div =="27"~"27.3.d.27", df_all_W$sub_div =="26"~"27.3.d.26", df_all_W$sub_div =="25"~"27.3.d.25", df_all_W$sub_div =="24"~"27.3.d.24", df_all_W$sub_div =="23"~"27.3.b.23", df_all_W$sub_div =="22"~"27.3.c.22", df_all_W$sub_div =="21"~"27.3.d.31",# 3 Lines for sweden comment added# here we allow for the two subdivision in the Baltic df_all_W$sub_div =="28"& df_all_W$subdiv_ic =='27.3.d.28.1'~'27.3.d.28.1', df_all_W$sub_div =="28"& df_all_W$subdiv_ic =='27.3.d.28.2'~'27.3.d.28.2', df_all_W$sub_div =="28"~"27.3.d.28",is.na(df_all_W$sub_div) ~"27.3.d"# 12 rows with with comments corresponds all catches of the country and year concerned ),sto_cou_code = df_all_W$country,sto_lfs_code ='A',sto_hty_code =case_when(df_all_W$fishery =="O"~"MO", df_all_W$fishery =="C"~"MC", df_all_W$fishery =="R"~"FW"),sto_qal_code =1,sto_comment = df_all_W$notes2,sto_datelastupdate =Sys.Date(),sto_mis_code =NA,sto_dta_code ="Public", # check thissto_wkg_code ="WGBAST",sto_ver_code ="WGBAST-2025-1",sto_gear_code = df_all_W$gea_code,sto_tip_code =case_when(df_all_W$tp_type =="YR"~"Year", df_all_W$tp_type =="HYR"~"Half of Year", df_all_W$tp_type =="MON"~"Month", df_all_W$tp_type =="MONTH"~"Month", df_all_W$tp_type =="QTR"~"Quarter", df_all_W$tp_type =="COMM"~"Quarter", # this is an erroris.na( df_all_W$tp_type) ~"Year",.default ="Troube this will fail at insertion"),sto_timeperiod = df_all_W$time_period,# in the notes some elements hint at surveys, but this will need a check up by WGBAST anyways.sto_dts_code =case_when(df_all_W$n_type =="LOG"~"Logb", df_all_W$n_type =="EXV"~"Exprt", df_all_W$n_type =="EST"& (grepl("survey",tolower(df_all_W$notes)) |grepl("question",tolower(df_all_W$notes)) |grepl("query", tolower(df_all_W$notes)) |grepl("web", tolower(df_all_W$notes))) ~"SampDS", df_all_W$n_type =="EXT"~NA),sto_dtb_code =case_when(df_all_W$n_type =="LOG"~"Official", df_all_W$n_type =="EXV"~"Estimated", df_all_W$n_type =="EST"~"Estimated", df_all_W$n_type =="EXT"~"Estimated",.default ="Unknown"),sto_esm_code =NA) #dbExecute(con_diaspara_admin, "drop table if exists temp_t_stock_sto_w")dbExecute(con_diaspara_local, "drop table if exists temp_t_stock_sto_w")system.time(dbWriteTable(con_diaspara_local, "temp_t_stock_sto_w", t_stock_sto_W)) # 0.14dbExecute(con_diaspara_local, "INSERT INTO datbast.t_stock_sto(sto_met_var, sto_year, sto_spe_code, sto_value, sto_are_code, sto_cou_code, sto_lfs_code, sto_hty_code, sto_qal_code, sto_comment, sto_datelastupdate, sto_mis_code, sto_dta_code, sto_wkg_code, sto_ver_code, sto_gear_code, sto_tip_code, sto_timeperiod, sto_dts_code, sto_dtb_code, sto_esm_code) SELECT sto_met_var, sto_year, sto_spe_code, sto_value, sto_are_code, sto_cou_code, sto_lfs_code, sto_hty_code, sto_qal_code, sto_comment, sto_datelastupdate, sto_mis_code, sto_dta_code, sto_wkg_code, sto_ver_code, sto_gear_code, sto_tip_code, sto_timeperiod, sto_dts_code, sto_dtb_code, sto_esm_code FROM temp_t_stock_sto_w") #17334dbExecute(con_diaspara_admin, "drop table temp_t_stock_sto_w")# Insert Effort# Insert N_CI# Insert W_CI
QUESTION WGBAST: corrections
3 lines with area 21 (which do not exists) => It’s in sweden for TRS is it correct to assign it to 31 ? To be checked during integration.
tp_type has 89 lines with COMM => Assigned to Year to be checked
QUESTION WGBAST: Would the data access be restricted
Data access can be Resticted or Public.
TODO WGBAST : n_type and w_type
Current we cannot easily translate all values LOG” “EST” “EXV” “EXT” values with ICES vocab. While Logbook is OK. We think that you will need to create a dictionary of possible estimation methods (we could have more), and then resubmit your data while screening for the correct type. For instance we don’t have an equivalent for EXT (extrapolated) so has not been translated, but the f_type and w_type are provided in the column comment. For “Est” when notes indicated “survey”, we have assessed it as SampDS. If you look at the tr_datasource_dts you will see a table of values in the ICES vocab. Among possible candidates are OthDF Other declarative forms (i.e. landing declarations and national declarative forms), or SampDC Commercial sampling data (sampling methodologies specific to each country). This refers to sampling in commercial vessels, not only for commercial species, or SampDS Survey sampling data (sampling methodologies specific to each country).
This document is still in construction
7 Acknowledgements
Data source : EuroGeographics and UN-FAO for countries
References
ICES. 2024a. “The Second ICES/NASCO Workshop on Salmon Mortality at Sea (WKSalmon2; Outputs from 2022 Meeting).” ICES Scientific Reports. https://doi.org/10.17895/ICES.PUB.22560790.