DIADROMOUS DATABASE

DIASPARA WP3.4 final version

DIADROMOUS FISH DATABASE : Scripts to create the diadromous database (import of data from WGNAS, WGEEL and WGBAST). Creation of referentials (dictionaries).
Author

Briand Cédric, Oliviero Jules, Helminen Jani

Published

13-02-2026

1 EXECUTIVE SUMMARY

The current poor status of several diadromous fish species, most notably the Atlantic salmon and the European eel, highlights the urgent need for effective management and scientifically robust assessment procedures. Achieving this requires high‑quality, coherent and accessible data, as conservation and management decisions can only be as reliable as the information on which they rely. Yet, despite the ecological and socio‑economic importance of these species, the data required to monitor their populations and pressures remain highly fragmented, scattered across institutions, stored in heterogeneous formats, and often maintained in locally developed systems. Such dispersion poses major limitations for transparency, reproducibility, long‑term maintenance, and ultimately for the provision of sound scientific advice. Atlantic salmon and European eel share life cycles that span both continental and marine ecosystems, inside and outside Europe. Although populations behave as relatively independent units in freshwater, they are biologically mixed during their marine phases, which requires coordination at regional and international scales for data collection, assessment, and management. Moreover, these species face multiple anthropogenic impacts, including fisheries, habitat degradation, and fragmentation caused by dams and hydropower plants, further emphasizing the need for robust and harmonized data systems.

In this context, the International Council for the Exploration of the Sea (ICES) plays a central role in providing independent, high‑quality scientific advice for fisheries management, coordinating international expert groups that evaluate stock status and develop methodologies to support evidence‑based decision making. However, current ICES working groups (WGEEL, WGNAS and WGBAST) rely on locally maintained, heterogeneous databases and spreadsheets, an approach that hampers operability, transparency and long‑term sustainability, and is incompatible with the future Transparent Assessment Framework (TAF) aspirations (an ICES methodology and platform developed by to ensure that scientific assessments of fishery resources are fully transparent, reproducible, and auditable). To address these challenges, DIASPARA has developed the DIASPARA Fish Stock Database (StockDB), a new standardized and centralized database designed to support the assessment of diadromous fish species. StockDB consolidates biological data, fisheries information, habitat descriptors, and impact metrics (including dam‑related pressures), integrating datasets from legacy ICES databases.

To do so, our work was carried out in different steps.

  • The first was to review the databases and working procedures of three ICES expert groups related to diadromous species were analyzed: WGNAS, WGBAST and WGTRUTTA. These analyses, carried out after contacting and holding meetings with the experts involved in these groups, resulted in three dedicated reports:WGNAS, WGBAST, WGTRUTTA. An analysis of the WGEEL database was not required, as the leaders of this work package have been directly involved in its development and maintenance, and therefore already have an in‑depth understanding of its structure and functioning.

  • The second phase consisted of finding a database structure suiting the needs of all expert groups. ICES could only maintain one common structure for all diadromous working group, so we needed to merge all datasets into one database. The main structure of the database was presented and discussed, including potential improvements, during an online DIASPARA meeting : database structure. This structure enables the efficient storage, harmonisation and retrieval of the data needed to run international stock assessment models used by the working groups responsible for producing advice or scientific reports on diadromous species. Its design builds on, and remains consistent with, the architectures previously developed for the WGEEL and WGNAS databases. The objective here was to remain as close to possible to the current working format of the different working groups, so as to be able to continue operating with the minimal changes on scripts and tools.

  • The third phase consisted in coding the whole database structure. It included referential tables (a set of standardized and controlled vocabularies) that would be compatible with vocabularies currently used in ICES. This part was done in constant contact with ICES data center to ensure the compatibility with ICES standards. Step by step we also tested that we could import all data into the stock database and ensuring that the resulting structure was fully operational and usable across all working groups, thereby complementing the earlier work of designing the database structure by validating it with real datasets and practical workflows. It’s only when trying to practically import the data that missing elements were found, and that the final database structure was validated.

  • At the end of this process, the diadromous fish database stores raw data (biometry, time series of abundance), preprocessed data used by models (e.g. landings at various scales, biomass …), model parameters and outputs.

For ease of use, the report is structured with four main parts.

  • The first describes some principle about the database and it’s structure.
  • The second creates all the vocabularies (standard set of code alongside with their description used as reference for stage, species). Think of them as “dictionaries” of possible words and that the database would only be able to use those words as standard and not invent new ones.
  • The third refers to the Stock and holds values aggregated at the scale of the assessment unit, or stock unit.
  • The fourth is the Series and Trait and allows to have time series of data, group and individual life history trait data. This was previously coded in a separate report which has been merged into this main DIADROMOUS DATABASE report at the end of the project for ease of reading.

Additionally, to accommodate both structures, a habitat database was created using a hierarchical structure of the habitat of the migratory fishes (see habitat report). The script to create this report can be found in diaspara github code of the report, the SQL codes are found in the following link SQL code.

All the code (R, SQL), reports (Quarto), and presentations (Quarto) were produced in DIASPARA migDB github repository

The code to this report is available here

The SQL code is here

All presentation, reports produced by WP3 are accessible online at the diaspara website for WP3

2 HIERARCHICAL STRUCTURE OF THE DATABASE

Tables are first created in a schema containing all tables, called ref or dat. From these tables, when necessary, working group specific tables will be created. They inherit from the mother table in the dat or ref schema. Querying a table in the refbast, or refnas schema will only return the data from the WGBAST, or WGNAS working group. But querying a “mother” table in the ref or dat schema will return data from WGNAS or WGBAST. Inheritance is a powerful to aggregate data, but requires caution when building tables, as the foreign keys (format links to other tables) need to be repeated across all inherited tables. A similar output will be obtained in SQL server in the future database by replacing the tables with views or partitioned views.

Code for SQL Server

SQL server used by ICES does not use inheritance, the same structure (schema) can be followed and the mother table will correspond to a view either as a UNION or JOIN of the tables

2.1 Referential tables (vocabularies)

ICES vocabularies refer to the controlled lists of codes, reference terms, and standardized definitions maintained by the International Council for the Exploration of the Sea to ensure consistency and interoperability across all datasets submitted to and managed by ICES. These vocabularies include reference codes for sampling stations, species metadata, and other key data elements used in marine research and assessment. They are hosted on the ICES Vocabulary Server, which acts as the central library linking all codes used in ICES data services and provides tools such as the Code Request application for users needing new reference codes. By enforcing standardized terminology and structured metadata, ICES vocabularies support high‑quality data integration, quality assurance, and harmonization across national and international monitoring programmes.

Within the project, referential tables are created for each data type, and sourced from ICES vocabularies. Checks are made to ensure that the existing vocabularies cover the needs of the working group and the different diadromous species.

The structure might be either a full vocabulary, common to all working groups, or a more complex structure, ensuring that different items are used by different working groups (for instance life stages are very different between salmon and eel and cannot be shared). In the latter case, having working-group-specific tables allows to easily set up foreign key to restrict the values used within each working group.

2.2 Unicity constraints

Another important aspect to consider is the implementation of unique constraints, especially since some fields may contain null values. To preserve data integrity, several levels of unique constraints—supported by indexes—should be defined. These may include combinations such as:

  • (year, age, area, parameter)

  • (year, age, parameter)

  • (year, area, parameter)

  • (year, parameter)

This flexibility is necessary because age is used in WGNAS and WGBAST but not in WGEEL, and because WGBAST includes two additional fields not present in other databases: period (e.g., month, half‑year) along with the associated value and the estimation method. Using different structures in the inherited tables allows each working group to manage its specific requirements while still maintaining a largely shared and consistent core schema. Within WGNAS, the presence of area × area matrices means that the area field may appear twice. This situation can be handled by introducing an additional column, needed for both WGNAS and WGBAST. In such cases, it may also be necessary to implement a trigger to enforce uniqueness on combinations such as (year, area, area, parameter) whenever duplicated area fields occur.

2.3 Convention for creating the diaspara database

Along this document, the database will be named DiadromousDB. The database is created with postgresSQL.

Some rules

  • By default, values are capitalised for the first letter e.g. Public for the code in dataaccess.

  • Codes are capitalized, e.g working group names WGEEL, WGNAS, or country codes.

  • Units are lowercase e.g. g, mm …

  • Column naming: all integer used for primary keys are called xxx_id all columns containing text used for primary keys are called xxx_code, the column with definition, or description is always called xxx_description where xxx is the three letter code for the table.

  • 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 dta_something

  • Referential tables or dictionaries are called tr_(sometable), tables build in conjunction from other tables and not in the dictionaries are called t_(sometable).

  • Foreign keys 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 keys are name fk_columnname where the column name is the name in the table

  • Primary keys are names tablename_pkey (with the constraint possibly refering to more than one column).

  • Other constraints are check constraints ck_columnname and unique constraints uk_columnname

  • All tables and columns have a definition, we will ask the working groups to check those.

  • Use of “snake_case”: 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). Some exceptions to this rule are made when the table was imported straight from ICES

2.4 Code to create the diaspara database

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.

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
DROP SCHEMA IF EXISTS dat CASCADE;
CREATE SCHEMA dat;
ALTER SCHEMA dat OWNER TO diaspara_admin;
COMMENT ON SCHEMA dat IS 'SCHEMA common to all migratory fish, filled by inheritance';

DROP SCHEMA IF EXISTS datang CASCADE;
CREATE SCHEMA datang;
ALTER SCHEMA datang OWNER TO diaspara_admin;
COMMENT ON SCHEMA datang IS 'SCHEMA for WGEEL';

DROP SCHEMA IF EXISTS datnas CASCADE;
CREATE SCHEMA datnas;
ALTER SCHEMA datnas OWNER TO diaspara_admin;
COMMENT ON SCHEMA datnas IS 'SCHEMA for WGNAS';

DROP SCHEMA IF EXISTS datbast CASCADE;
CREATE SCHEMA datbast;
ALTER SCHEMA datbast OWNER TO diaspara_admin;
COMMENT ON SCHEMA datbast IS 'SCHEMA for WGBAST';


DROP SCHEMA IF EXISTS dattrutta CASCADE;
CREATE SCHEMA dattrutta;
ALTER SCHEMA dattrutta OWNER TO diaspara_admin;
COMMENT ON SCHEMA dattrutta IS 'SCHEMA for WKTRUTTA';


ALTER TABLE area."ref-countries-2024-01m � CNTR_RG_01M_2024_4326" RENAME TO "ref-countries-2024-01m-4326";

The database has been created with different schemas (Figure 1). The main schema for dictionaries is ref, and a schema is created per working group for specific referential tables. The schema dat is the common schema for all data. For each working group, schema datbast, dateel, datnas are created. The tables are 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 that dat should not containt any data, but will hold all the views and inherited tables coming from the different schema.

3 CREATING REFERENTIALS

This script holds all referentials necessary for both the trait and the stock.

3.1 species (tr_species_spe)

The first thing is to create a referential table for species. At the moment the structure doesn’t integrate schema for Alosa and Lamprey, but the species have been created. There are no codes in ICES vocab for Alosa alosa, Alosa fallax, Petromyzon marinus, Lampetra fluviatilis.

Code used to create a referential table for species - code and queries to ICES
sp <- getCodeList("IC_species")

#The following lines show that there is no code in IC_species 
#grep("Lampetra", sp$description) # nothing
#grep("Petromyzon", sp$description) # nothing
#grep("Alosa",  sp$description) # nothing

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("127186", "126281", "127187", "126413", "126415", "101174", "101172"),
      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;
CREATE TABLE ref.tr_species_spe (
     spe_code CHARACTER VARYING(3) PRIMARY KEY,
     spe_commonnname TEXT,
     spe_scientificname TEXT,
     spe_codeaphia numeric NOT NULL,
     spe_description TEXT);
COMMENT ON TABLE ref.tr_species_spe IS 'Table of species code';
GRANT ALL ON TABLE ref.tr_species_spe to diaspara_admin;
GRANT SELECT ON TABLE ref.tr_species_spe to diaspara_read;

-- 19/12/2025 finally we need TO use AFIAID
-- we also remove TRT as a species 

DELETE FROM "ref".tr_species_spe  WHERE spe_code='TRT';


ALTER TABLE ref.tr_species_spe ALTER column spe_code type TEXT;


ALTER TABLE "ref"."tr_lifestage_lfs" ALTER COLUMN lfs_spe_code TYPE TEXT;

-- 19/12/2025 finally we need TO use AFIAID
-- we also remove TRT as a species 

ALTER TABLE dat.t_metadata_met ALTER COLUMN met_spe_code TYPE TEXT;

ALTER TABLE dat.t_stock_sto ALTER COLUMN sto_spe_code TYPE TEXT;

 ALTER TABLE datnas.t_metadata_met DROP
    CONSTRAINT ck_met_spe_code;
 
 ALTER TABLE datnas.t_stock_sto DROP CONSTRAINT 
ck_spe_code;

ALTER TABLE datbast.t_metadata_met DROP CONSTRAINT ck_met_spe_code;

ALTER TABLE dateel.t_metadata_met DROP CONSTRAINT ck_met_spe_code;

ALTER TABLE datnas.t_stock_sto DROP CONSTRAINT ck_spe_code;

ALTER TABLE dateel.t_stock_sto DROP CONSTRAINT ck_spe_code;

ALTER TABLE datbast.t_stock_sto DROP CONSTRAINT ck_spe_code;

UPDATE ref.tr_species_spe SET spe_code = spe_codeaphia; 


ALTER TABLE datnas.t_metadata_met ADD
    CONSTRAINT ck_met_spe_code   
    CHECK (met_spe_code='127186'); 

ALTER TABLE datnas.t_stock_sto ADD CONSTRAINT 
ck_sto_spe_code CHECK (sto_spe_code='127186');
  
ALTER TABLE datbast.t_metadata_met 
ADD CONSTRAINT ck_met_spe_code CHECK 
 (met_spe_code='127186' OR met_spe_code='127187');
 
 ALTER TABLE datbast.t_stock_sto ADD CONSTRAINT 
ck_sto_spe_code CHECK  (sto_spe_code='127186' OR sto_spe_code='127187');
 
ALTER TABLE dateel.t_metadata_met 
ADD CONSTRAINT ck_met_spe_code CHECK (met_spe_code='126281');

ALTER TABLE datbast.t_stock_sto 
ADD CONSTRAINT ck_spe_code 
CHECK (sto_spe_code='127186' OR sto_spe_code='127187');
 
COMMENT ON COLUMN datbast.t_metadata_met.met_spe_code 
IS 'Species aphiaID, text ''127186'' salmo salar OR ''127187'' for Salmo trutta primary key on both met_spe_code and met_var.';

COMMENT ON COLUMN dateel.t_metadata_met.met_spe_code 
IS 'Species, ''126281'' primary key on both met_spe_code and met_var.';

ALTER TABLE dateel.t_stock_sto ALTER COLUMN sto_spe_code SET DEFAULT '126281';
ALTER TABLE datnas.t_stock_sto ALTER COLUMN sto_spe_code SET DEFAULT '127186';
-- no default for datbast

COMMENT ON TABLE  ref.tr_species_spe IS 
'Table of fish species, spe_code using AphiaID as the reference with 
reference to ICES vocabularies.'
Creating a referential table for species - code and queries to ICES
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")#7
dbExecute(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 using AphiaID as the reference with 
reference to ICES vocabularies.'")
Table 2: Working groups table in the diaspara DB
spe_code spe_commonnname spe_scientificname spe_codeaphia spe_description
127186 Atlantic salmon Salmo salar 127186 NA
126413 Twait shad Alosa alosa 126413 NA
126415 Allis shad Alosa fallax 126415 NA
101174 Sea lamprey Petromyzon marinus 101174 NA
101172 European river lamprey Lampetra fluviatilis 101172 NA
126281 European eel Anguilla anguilla 126281 NA
127187 Sea trout Salmo trutta 127187 NA

3.2 Working group (tr_icworkinggroup_wkg)

Species is necessary to separate data within the same working group (WGBAST works on both Trout and Salmon). Furthermore, two working groups might be working on the same species. For this reason we need to have a “working group” entry in most of the tables. There is already a table for working group. The proposed table is Table 3.

NoteNote

WGEEL name needs to be updated to JOINT EIFAAC/ICES/GFCM WORKING GROUP ON EEL and WGTRUTTA is an expert group, and, therefore, needs to be added to the lit separately.

The working groups might change over time, referencing a working group there is probably not the best. > Added stockkeylabel, this table is necessary to aggregate data, as species is not enough.

SQL code to create table tr_icworkinggroup_wkg
--DROP TABLE IF EXISTS ref.tr_icworkinggroup_wkg CASCADE;

CREATE TABLE ref.tr_icworkinggroup_wkg (
wkg_code TEXT PRIMARY KEY,
wkg_description TEXT,
wkg_icesguid uuid,
wkg_stockkeylabel TEXT
);

COMMENT ON TABLE ref.tr_icworkinggroup_wkg 
IS 'Table corresponding to the IC_WorkingGroup referential;';
COMMENT ON COLUMN ref.tr_icworkinggroup_wkg.wkg_code IS 
'Working group code uppercase, WGEEL, WGNAS, WGBAST, WGTRUTTA';


GRANT ALL ON ref.tr_icworkinggroup_wkg TO diaspara_admin;
GRANT SELECT ON ref.tr_icworkinggroup_wkg TO diaspara_read;
Code to create reference table for working groups
# Using the jsonlite to download the guid also
tbl <- 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;") #4
dbExecute(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

3.3 Country (tr_country_cou)

Countries are taken from the WGEEL database, and streamlined with ICES to further integrate North 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
DROP TABLE IF EXISTS ref.tr_country_cou;
CREATE TABLE ref.tr_country_cou (
    cou_code character varying(2) NOT NULL,
    cou_country text NOT NULL,
    cou_order integer NOT NULL,
    geom public.geometry,
    cou_iso3code character varying(3)
);
COMMENT ON TABLE ref.tr_country_cou IS
          'Table of country codes source EuroGeographics and UN-FAO.';
ALTER TABLE ref.tr_country_cou 
          OWNER TO diaspara_admin;
GRANT SELECT ON TABLE ref.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 constraints
dbExecute(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_order
FROM  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_order
FROM  area.\"ref-countries-2024-01m-4326\"
WHERE \"CNTR_ID\" IN ('SJ');") #3

dbExecute(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 display current referental table.
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 background
crs_string <- "+proj=ortho +lon_0=-30 +lat_0=30"

# background for the globe - center buffered by earth radius
ocean <- 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 first
  geom_sf(aes(fill = cou_code), lwd = .1) + # now land over the oceans
  scale_fill_discrete(guide = "none") +
  theme_void()

# this part is used to avoid long computations
png(filename="images/fig-country.png", bg="transparent")
print(g)
dev.off()
Figure 4: Map of countries in the diaspara DB © EuroGeographics

3.4 Unit (tr_units_uni)

SQL code to create tables
--DROP TABLE IF EXISTS ref.tr_units_uni CASCADE;

CREATE TABLE ref.tr_units_uni (
  uni_code varchar(20) NOT NULL,
  uni_description text NOT NULL,
  uni_icesvalue character varying(4),  
  uni_icesguid uuid,
  uni_icestablesource text,
  CONSTRAINT t_units_uni_pkey PRIMARY KEY (uni_code),
  CONSTRAINT uk_uni_description UNIQUE (uni_description),
  CONSTRAINT uk_uni_icesguid UNIQUE (uni_icesguid),
  CONSTRAINT uk_uni_icesvalue UNIQUE (uni_icesvalue)
);
GRANT ALL ON ref.tr_units_uni TO diaspara_admin;
GRANT SELECT ON ref.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

To create the units table, we started from the existing WGEEL table, and we later added some elements for WGBAST. In addition, to standardize our table, all codes where checked againt several existing ICES vocabularies. We used the p06 as the most common source. The source code in ICES table, its id, and the source table are presented in the table.

Code to insert existing values from WGEEL
dbExecute(con_diaspara_admin,"INSERT INTO ref.tr_units_uni (
uni_code, uni_description)
SELECT * FROM refwgeel.tr_units_uni;")#25

dbExecute(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;") #16
dbExecute(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 AND
uni_icestablesource IS NULL;") # 16

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);", 
                 "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)
Code to show table
dbGetQuery(con_diaspara, "SELECT * FROM ref.tr_units_uni;")|> 
knitr::kable() |>
 kable_styling(bootstrap_options = c("striped", "hover", "condensed"))
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

ICES is modifying the code

Work is currently in progress to integrate the codes for unit in ICES. An issue is open and discussed in the ICES git Data Information Group. WGEEL: New MUNIT codes #737

3.5 Parameters

We need to store input or output parameters of the stock assessment models, these are often multidimensional arrays. To do so we use variables names that store 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 identifier of the variable will be used for all the lines necessary to store this dataset. When arrays have only two dimensions, then only two columns are used.

The values in some columns can also be left empty if it does not correspond to the actual dimension of the data, for instance some arrays have nothing to do with age, and in that case there is nothing to store. The parameters will be described by their metadata as illustrated in Figure 6

We can have a look at the metadata in the analysis done on the WGNAS database “Salmoglob” WGNAS description.

In Salmoglob, we had a problem with some columns holding data corresponding to different data types . For instance a column could hold either year, or age. Another issue was that some arrays integrated in the database have twice the same column reported (e.g. a matrix holding transition from an area to another area. This was solved by using an additional column where data can be of several types (see tg_additional_add in Section 4.1.5). The description could be used within a type array. But as SQL server does not work with arrays, and the SQL database will be stored in ICES, we chose not to use those arrays.

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')] |> kable
sd <- mapply(getSD, year= 2020:2024, SIMPLIFY=FALSE)
sd <- do.call(rbind,sd)
ww <- grepl('ele',sd$StockKeyLabel) | grepl('Salmo',sd$speciesScientificName)
sd[ww,] |> kable()

3.6 Object dimension (tr_objectdimension_odi)

Parameters can have different dimensions :

  • single value (scalar)
  • vector (1D)
  • matrix (2D)
  • arrays (3D)

These dimensions are specified in table Table 7, and later in this report used in metadata.

SQL code to create tables
DROP TABLE IF EXISTS ref.tr_objectdimension_odi CASCADE;
CREATE TABLE ref.tr_objectdimension_odi (
odi_code TEXT PRIMARY KEY,
odi_description TEXT
);

INSERT INTO ref.tr_objectdimension_odi VALUES ('Single_value', 'Single value');
INSERT INTO ref.tr_objectdimension_odi VALUES ('Vector', 'One dimension vector');
INSERT INTO ref.tr_objectdimension_odi VALUES ('Matrix', 'Two dimensions matrix');
INSERT INTO ref.tr_objectdimension_odi VALUES ('Array', 'Three dimensions array');

COMMENT ON TABLE ref.tr_objectdimension_odi IS 
'Table indicating the dimensions of the object stored in the model, 
single value, vector, matrix, array';

COMMENT ON COLUMN ref.tr_objectdimension_odi.odi_code IS 
'code of the object dimension, single_value, vector, ...';

COMMENT ON COLUMN ref.tr_objectdimension_odi.odi_code IS 'description of the object type';
GRANT ALL ON ref.tr_objectdimension_odi TO diaspara_admin;
GRANT SELECT ON ref.tr_objectdimension_odi TO diaspara_read;

/* fix from Hilaire's review


ALTER TABLE "ref".tr_objecttype_oty RENAME TO tr_objectdimension_odi;
ALTER TABLE "ref".tr_objectdimension_odi RENAME COLUMN oty_code TO odi_code;
ALTER TABLE "ref".tr_objectdimension_odi RENAME COLUMN oty_description TO odi_description;
ALTER TABLE "ref".tr_objectdimension_odi RENAME CONSTRAINT tr_objecttype_oty_pkey TO tr_objectdimension_odi_pkey;
ALTER TABLE dat.t_metadata_met RENAME COLUMN met_oty_code TO met_odi_code;
ALTER TABLE dat.t_metadata_met RENAME CONSTRAINT fk_met_oty_code TO fk_met_odi_code;
 */
Table 7: Object type
odi_code odi_description
Single_value Single value
Vector One dimension vector
Matrix Two dimensions matrix
Array Three dimensions array

3.7 Type of parm / data (tr_bayestype_bty)

The stock model use parameters as inputs and produce parameter outputs. Some paramaters are constants, some are considered as data entry, some are outputs, and some others are not necessarily used in the model itself but necessary for comparision or graphical purpose (e.g. Conservation Limits). In the salmoglob metadata (WGNAS), two tables hold similar information status and nimble. These entries have been grouped in the tr_bayestype_bty table.

SQL code to create tables
--nimble

DROP TABLE IF EXISTS ref.tr_bayestype_bty CASCADE;
CREATE TABLE ref.tr_bayestype_bty (
nim_code TEXT PRIMARY KEY,
nim_description TEXT
);

COMMENT ON TABLE ref.tr_bayestype_bty 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....

INSERT INTO ref.tr_bayestype_bty VALUES ('Data', 'Data entry to the model');
INSERT INTO ref.tr_bayestype_bty 
VALUES ('Parameter constant', 'Parameter input to the model');
INSERT INTO ref.tr_bayestype_bty 
VALUES ('Parameter estimate', 'Parameter input to the model');
INSERT INTO ref.tr_bayestype_bty 
VALUES ('Output', 'Output from the model, derived quantity');
-- Do we want another type here ?
--INSERT INTO ref.tr_bayestype_bty VALUES ('observation', 'Observation not used in the model');
INSERT INTO ref.tr_bayestype_bty 
VALUES ('Other', 'Applies currently to conservation limits');
GRANT ALL ON ref.tr_bayestype_bty TO diaspara_admin;
GRANT SELECT ON ref.tr_bayestype_bty TO diaspara_read;


/*
Hilaire review : remove "nimble" ...
ALTER TABLE "ref".tr_nimble_nim RENAME TO tr_bayestype_bty
ALTER TABLE "ref".tr_nimble_nim RENAME COLUMN nim_code TO bty_code;
ALTER TABLE "ref".tr_nimble_nim RENAME COLUMN nim_description TO bty_description;
ALTER TABLE "ref".tr_nimble_nim RENAME CONSTRAINT tr_nimble_nim_pkey TO tr_bayestype_bty_pkey;
ALTER INDEX "ref".tr_nimble_nim_pkey RENAME TO tr_bayestype_bty_pkey;
ALTER TABLE dat.t_metadata_met RENAME COLUMN met_nim_code TO met_bty_code;
ALTER TABLE dat.t_metadata_met RENAME CONSTRAINT fk_met_nim_code TO fk_met_bty_code;
ALTER TABLE dateel.t_metadata_met RENAME CONSTRAINT fk_met_nim_code TO fk_met_bty_code;
ALTER TABLE datnas.t_metadata_met RENAME CONSTRAINT fk_met_nim_code TO fk_met_bty_code;
ALTER TABLE datbast.t_metadata_met RENAME CONSTRAINT fk_met_nim_code TO fk_met_bty_code;
*/
Table 8: Nimble
bty_code bty_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

3.8 Version (tr_version_ver)

Currently in the salmoglob information about version only correspond to different versions of the same parameter see WGNAS analysis report. The database only contains the variables used to run the salmoglob model, at the time of the working group, any updated value is copied to the database_archive which then contains historical values. From this, it might be possible to rebuild historical states of the database but it is not straightforward, as the archive database can hold, for the same year, multiple values of the same variable, if the corrections or updates were made several times. The dates (column date_time) used in the database and database_archive give information about the latest update. An analysis with Pierre Yves Hernwann on unique values for tupples [version, year, type, age, area, location, metric, var_mod] shows that some duplicates are present in the archive database in 2021 and 2022, so by using the latest date in the year it is possible to reproduce the state of the database at the moment of the working group. Still it was agreed that a clear versioning would ease up the work (as in WGEEL). It was also agreed that metadata should also contain information about historical variables For instance we create a new variable, so we know when it was introduced. So the version column was added to we added to both metadata (t_metadata_met) table and stock table (t_stock_sto). Some variables might get deprecated over time.

TODO ICES

The DB will be held in ICES server. We will need a procedure to save the database at each working group to be able to run past versions of the model. This means keeping a database_archive for each working groups. It’s a straightforward copy of the t_stock_sto for each working group.

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 WGNAS
DROP TABLE IF EXISTS ref.tr_version_ver CASCADE;
CREATE TABLE ref.tr_version_ver(
ver_code TEXT PRIMARY KEY,
ver_year INTEGER NOT NULL,
ver_spe_code CHARACTER VARYING(3),
/*CONSTRAINT fk_ver_spe_code FOREIGN KEY (ver_spe_code) 
REFERENCES ref.tr_species_spe(spe_code)
ON UPDATE CASCADE ON DELETE RESTRICT,*/
ver_wkg_code TEXT NOT NULL,
CONSTRAINT fk_ver_wkg_code  FOREIGN KEY (ver_wkg_code)
REFERENCES ref.tr_icworkinggroup_wkg(wkg_code)
ON UPDATE CASCADE ON DELETE RESTRICT,
--ver_stockkey INTEGER NOT NULL, 
ver_stockkeylabel TEXT,
---ver_stockadvicedoi TEXT NOT NULL,
ver_datacalldoi TEXT NULL,
ver_version INTEGER NOT NULL,
ver_description TEXT
);
COMMENT ON TABLE ref.tr_version_ver
IS 'Table of data or variable version, essentially one datacall or advice.';
COMMENT ON COLUMN ref.tr_version_ver.ver_code 
IS 'Version code, stockkey-year-version.';
COMMENT ON COLUMN ref.tr_version_ver.ver_year 
IS 'Year of assessement.';
COMMENT ON COLUMN ref.tr_version_ver.ver_spe_code 
IS 'Species code e.g. ''Anguilla anguilla'' or ''Salmo salar,Salmo trutta'' the reference name should be in tr_species_spe, comma separated';
COMMENT ON COLUMN ref.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.';
COMMENT ON COLUMN ref.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().';
COMMENT ON COLUMN ref.tr_version_ver.ver_datacalldoi 
IS 'Data call DOI, find a way to retreive that information 
and update this comment';
COMMENT ON COLUMN ref.tr_version_ver.ver_version 
IS 'Version code in original database, eg 2,4 for wgnas, dc_2020 for wgeel.';
COMMENT ON COLUMN ref.tr_version_ver.ver_description 
IS 'Description of the data call / version.';

GRANT ALL ON ref.tr_version_ver TO diaspara_admin;
GRANT SELECT ON ref.tr_version_ver TO diaspara_read;


-- we need to allow several species separated by a comma (several species for a working group)
-- the 
ALTER TABLE ref.tr_version_ver DROP CONSTRAINT fk_ver_spe_code;
ALTER TABLE refnas.tr_version_ver DROP CONSTRAINT fk_ver_spe_code;
ALTER TABLE refeel.tr_version_ver DROP CONSTRAINT fk_ver_spe_code;
ALTER TABLE refbast.tr_version_ver DROP CONSTRAINT fk_ver_spe_code;
ALTER TABLE ref.tr_version_ver ALTER COLUMN 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 = "127186",
  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 year
  ver_description=c(NA,NA,NA,NA,NA)) # TODO WGNAS provide model description

DBI::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;") # 5
DBI::dbExecute(con_diaspara_admin, "DROP TABLE temp_tr_version_ver;")
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 Salmo salar sal.neac.all 1 NA WGNAS
WGNAS-2021-1 2021 Salmo salar sal.neac.all 1 NA WGNAS
WGNAS-2022-1 2022 Salmo salar sal.neac.all 1 NA WGNAS
WGNAS-2023-1 2023 Salmo salar sal.neac.all 1 NA WGNAS
WGNAS-2024-1 2024 Salmo salar sal.neac.all 1 NA WGNAS
DIASPARA-2025-1 2025 Salmo salar NA NA 1 WP2 data call for diaspara on LHT WGNAS
WGEEL-2023-1 2023 Anguilla anguilla ele 1 Joint EIFAAC/GFCM/ICES Eel Data Call 2023 WGEEL
WGEEL-2024-1 2024 Anguilla anguilla ele https://doi.org/10.17895/ices.pub.25816738.v2 1 Joint EIFAAC/GFCM/ICES Eel Data Call 2024 WGEEL
WGEEL-2025-1 2025 Anguilla anguilla ele https://doi.org/10.17895/ices.pub.25816738.v2 1 WKEMP 2025 special request WGEEL
WGEEL-2025-2 2025 Anguilla anguilla 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 Anguilla anguilla ele 1 Joint EIFAAC/GFCM/ICES Eel Data Call 2016 WGEEL
WGEEL-2017-2 2017 Anguilla anguilla 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 Anguilla anguilla ele 1 Data provided by wgeel 2016 WGEEL
WGEEL-2018-1 2018 Anguilla anguilla ele 1 Data provided by wgeel 2017 WGEEL
WGEEL-2019-1 2019 Anguilla anguilla ele 1 Joint EIFAAC/GFCM/ICES Eel Data Call 2019 WGEEL
WGEEL-2020-1 2020 Anguilla anguilla ele 1 Joint EIFAAC/GFCM/ICES Eel Data Call 2020 WGEEL
WGEEL-2021-1 2021 Anguilla anguilla ele 1 Joint EIFAAC/GFCM/ICES Eel Data Call 2021 WGEEL
WGEEL-2022-1 2022 Anguilla anguilla ele 1 Joint EIFAAC/GFCM/ICES Eel Data Call 2022 WGEEL
WGBAST-2024-1 2024 Salmo salar, Salmo trutta 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 Salmo salar, Salmo trutta 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

TODO ICES

datacall (see link in ICES webpage) are not yet part of a vocabulary accessible to external users in ICES. A demand had been made to make them public

3.9 Statistic (or metric) (tr_statistic_sta)

This table describes the type of statistic (or metric) returned by the parameter. The name metric has not been used to avoid confusion with the “metric DB”.

SQL code to create tables
-- metric 

DROP TABLE IF EXISTS  ref.tr_statistic_sta CASCADE;
CREATE TABLE ref.tr_statistic_sta(
sta_code TEXT PRIMARY KEY,
sta_description TEXT
);


INSERT INTO ref.tr_statistic_sta VALUES
('Estimate' , 'Estimate');
INSERT INTO ref.tr_statistic_sta VALUES
('Index', 'Index');
INSERT INTO ref.tr_statistic_sta VALUES
('Bound', 'Either min or max');
INSERT INTO ref.tr_statistic_sta VALUES
('Hyperparameter', 'Hyperparameter (prior)');
INSERT INTO ref.tr_statistic_sta VALUES
('SD', 'Standard deviation');
INSERT INTO ref.tr_statistic_sta VALUES
('CV', 'Coefficient of variation');
INSERT INTO ref.tr_statistic_sta VALUES
('Precision', 'Inverse of variance');
INSERT INTO ref.tr_statistic_sta VALUES
('Mean', 'Mean');
INSERT INTO ref.tr_statistic_sta VALUES 
('Min','Minimum');
INSERT INTO ref.tr_statistic_sta VALUES 
('Max','Maximum');

GRANT ALL ON ref.tr_statistic_sta TO diaspara_admin;
GRANT SELECT ON ref.tr_statistic_sta TO diaspara_read;
COMMENT ON TABLE ref.tr_statistic_sta IS 
'Table metric describe the type of statistic described by the parameter,  Index, Bound ...';

/*
ALTER TABLE "ref".tr_metric_mtr RENAME TO tr_statistic_sta;
ALTER TABLE "ref".tr_statistic_sta RENAME COLUMN mtr_code TO sta_code;
ALTER TABLE "ref".tr_statistic_sta RENAME COLUMN mtr_description TO sta_description;
ALTER TABLE "ref".tr_statistic_sta RENAME CONSTRAINT tr_metric_mtr_pkey TO tr_statistic_sta_pkey;
Table 10: Statistic (metric) possible value of parameters
sta_code sta_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 currenly correspond to the needs of both WGNAS and WGBAST. But the statistic can be NULL, for instance in case of a number of fish released, none of the above (Table 10) would apply.

3.10 Category (tr_category_cat)

Categories Table 11 were in the salmoglob metadata, here they were simplified to be able to get groups of parameters, for instance all parameters dealing with catch.

SQL code to create tables
-- tr_category_cat

DROP TABLE IF EXISTS ref.tr_category_cat CASCADE;
CREATE TABLE ref.tr_category_cat (
cat_code TEXT PRIMARY KEY,
cat_description TEXT
);

INSERT INTO ref.tr_category_cat VALUES 
('Catch', 'Catch, including recreational and commercial catch.');
INSERT INTO ref.tr_category_cat VALUES (
'Effort', 'Parameter measuring fishing effort.');
INSERT INTO ref.tr_category_cat VALUES (
'Biomass', 'Biomass of fish either in number or weight.');
INSERT INTO ref.tr_category_cat VALUES (
'Mortality', 'Mortality either expressed in year-1 (instantaneous rate) 
as F in exp(-FY) but can also be harvest rate.');
INSERT INTO ref.tr_category_cat VALUES (
'Release', 'Release or restocking.');
INSERT INTO ref.tr_category_cat VALUES (
'Density', 'Fish density.');
INSERT INTO ref.tr_category_cat VALUES (
'Count', 'Count or abundance or number of fish.');
INSERT INTO ref.tr_category_cat VALUES (
'Conservation limit', 'Limit of conservation in Number or Number of eggs.');
INSERT INTO ref.tr_category_cat VALUES (
'Life trait', 'Life trait parameterized in model, e.g. growth parameter, 
fecundity rate ...');
INSERT INTO ref.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....');
COMMENT ON TABLE ref.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.';

GRANT ALL ON ref.tr_category_cat TO diaspara_admin;
GRANT SELECT ON ref.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...

3.11 Destination (tr_destination_dest)

This table was added for WGBAST. The idea is “what becomes of this fish”. It allows to integrate discards, releases and seal damages.

SQL code to create tables
-- table ref.tr_destination_des

DROP TABLE IF EXISTS ref.tr_destination_des CASCADE;
CREATE TABLE ref.tr_destination_des (
des_code TEXT PRIMARY KEY,
des_description TEXT
);

COMMENT ON TABLE ref.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)'; 
INSERT INTO ref.tr_destination_des VALUES 
('Removed', 'Removed from the environment, e.g. caught and kept');
INSERT INTO ref.tr_destination_des VALUES (
'Seal damaged', 'Seal damage');
INSERT INTO ref.tr_destination_des VALUES (
'Discarded', 'Discards');
INSERT INTO ref.tr_destination_des VALUES (
'Released', 'Released alive');
INSERT INTO ref.tr_destination_des VALUES (
'Released ', 'Released alive');

GRANT ALL ON ref.tr_destination_des TO diaspara_admin;
GRANT SELECT ON ref.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

3.12 Habitat level (tr_habitatlevel_lev)

In the habitat database created by DIASPARA, various levels of regional aggregation have been used. They are embedded within each other like russian dolls. The habitat level correspond to the level of grouping, from stock(s) to river. Depending on the species habitat levels and their hierarchy can differ. An example for this difference is that for Salmon the stock is at the level of a river while the eel is a single stock distributed all over its geographic range. The levels used in the habitat database are described in table Table 13.

This table has been created in the habitat report.

SQL code to create tables
--DROP TABLE IF EXISTS ref.tr_habitatlevel_lev CASCADE;

CREATE TABLE ref.tr_habitatlevel_lev(
   lev_code TEXT PRIMARY KEY,
   lev_description TEXT  
);

COMMENT ON TABLE ref.tr_habitatlevel_lev 
IS 'Table of geographic levels stock, complex, country, region, basin, river,
the specific order depend according to working groups.';

GRANT ALL ON ref.tr_habitatlevel_lev TO diaspara_admin;
GRANT SELECT ON ref.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
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
Lagoons Shallow body of water seperated from a larger body of water by a narrow landform
Stock(s) This is the highest geographic level for assessement, stock level or pan Population, it correspond to a single stock for eel.
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 (substock) 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
Post_smolt_area Postsmolt areas from Olmos et al. (2021)
Substock Sub component of the stock, assessed in separate models as they are geographically isolated during part of their lifecycle

3.12.1 Area (tr_area_are)

This table has been created in the diadromous database as we needed reference for various geographical grouping used thoughout the different databases. However, most of the work was done in the habitat report for the full habitat referential creation.

SQL code to create tables
--DROP TABLE IF EXISTS ref.tr_area_are CASCADE;
CREATE TABLE ref.tr_area_are (
   are_id INTEGER PRIMARY KEY,
   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 FOREIGN KEY (are_are_id) 
  REFERENCES ref.tr_area_are (are_id) ON DELETE CASCADE
  ON UPDATE CASCADE,
  CONSTRAINT uk_are_code UNIQUE (are_code),
  CONSTRAINT fk_area_lev_code FOREIGN KEY (are_lev_code) REFERENCES
  ref.tr_habitatlevel_lev(lev_code) ON UPDATE CASCADE ON DELETE CASCADE,
  CONSTRAINT fk_area_wkg_code FOREIGN KEY (are_wkg_code) REFERENCES
  ref.tr_icworkinggroup_wkg(wkg_code) ON UPDATE CASCADE ON DELETE CASCADE
);

GRANT ALL ON ref.tr_area_are TO diaspara_admin;
GRANT SELECT ON ref.tr_area_are TO diaspara_read;

COMMENT ON TABLE ref.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)
ALTER TABLE "ref".tr_area_are RENAME COLUMN are_rivername TO are_name;





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
14 3 2 Western Bothnian Bay Assessment_unit WGBAST FALSE
17 3 5 Eastern Main Basin Assessment_unit WGBAST FALSE
18 3 6 Gulf of Finland Assessment_unit WGBAST FALSE
2 1 Baltic marine Stock(s) WGBAST TRUE
13 3 1 Northeastern Bothnian Bay Assessment_unit WGBAST FALSE
Figure 7: First concepts of the hierarchy, see habitat report for final hierarchies in each working group

NOTE DIASPARA

Areas are specific to each working group (see Figure 11)

Figure 8: WGBAST
Figure 9: WGNAS
Figure 10: WGEEL

3.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;
CREATE TABLE ref.tr_dataaccess_dta(
   dta_code TEXT PRIMARY KEY,
   dta_description TEXT  
);
GRANT ALL ON ref.tr_dataaccess_dta  TO diaspara_admin;
GRANT SELECT ON ref.tr_dataaccess_dta TO diaspara_read;
COMMENT ON TABLE ref.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
Table 15: Data access
dta_code dta_description
Public Public access according to ICES Data Policy
Restricted Restricted access (wgeel find a definition)

3.14 Missing data (tr_missvalueqal_mis)

SQL code to create tables
--DROP TABLE IF EXISTS ref.tr_missvalueqal_mis CASCADE;

CREATE TABLE ref.tr_missvalueqal_mis(
   mis_code TEXT PRIMARY KEY,
   mis_description TEXT NOT NULL,  
   mis_definition TEXT);
   
GRANT ALL ON ref.tr_missvalueqal_mis TO diaspara_admin;
GRANT SELECT ON ref.tr_missvalueqal_mis TO diaspara_read;

COMMENT ON TABLE ref.tr_missvalueqal_mis IS 'Table showing the qualification when value is missing, NC, NP, NR.';
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 16: 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).

TODO ICES

This is used in the t_stock_sto table by both WGEEL and WGBAST. Either a value is provided or this field has to be provided (conditional mandatory in the format).

3.15 Life stages (tr_lifestage_lfs)

Life stages cannot easily be shared among all species, they are species specific. Often similar between Sea trout and Salmon, but there is a large gap between a leptocephalus and a parr.

3.15.1 Considerations about the database structure

For life stage, unlike in other referentials, using working-group-specific life stages would lead to confusion. WGBAST and WGNAS would share the same stages for salmon. So unlike in many other tables, the referentials will not use inheritance (see paragraph Section 2 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.

3.15.2 The lifestages in working group databases

Stages use are described in WGNAS metadata paragraph life stage of the WGNAS description report and WGBAST reports (though for the WGBAST’s “young fish” -data this concept is mixed with age) paragraph life stage of the WGBAST description report. So they are not used as a separate column to describe the data. But in the eel database they are and so we will need to add this dimension to the table structure.

3.15.3 Simplifying the stage column in WGNAS

The work was initially done with the stage column in the WGNAS salmoglob database. In this column, the information relies on a combination of life stage and spatial location (e.g; post smolt and location at sea, returning adult in seawater, in freshwater…) ICES (2024b). To deal with these spatio-temporal elements that are not stages, we simplified the stages table, removed elements which are not stages. Parameters still hold the spatio temporal information in metadata. 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.

3.15.4 Some stages are a mixture of several stages.

In some cases, a 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.

Stages OG and QG for WGEEL

Ongrown eel (OG) and quarantined glass eel (QG) are used to describe the stages of glass eel or small yellow eels as they are released. They will be marked as deprecated for the stock, but they will probably be used in the release database that needs to be created for EDA.

3.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)

DROP TABLE IF EXISTS ref.tr_lifestage_lfs CASCADE;
CREATE TABLE ref.tr_lifestage_lfs (
  lfs_id SERIAL PRIMARY KEY,
  lfs_code TEXT NOT NULL UNIQUE,
  lfs_name TEXT NOT NULL,
  lfs_spe_code character varying(3) NOT  NULL,    
  lfs_description TEXT,
  lfs_icesvalue character varying(4),  
  lfs_icesguid uuid,
  lfs_icestablesource text,
CONSTRAINT fk_lfs_spe_code FOREIGN KEY (lfs_spe_code)
  REFERENCES ref.tr_species_spe(spe_code) 
  ON DELETE CASCADE
  ON UPDATE CASCADE,
CONSTRAINT uk_lfs UNIQUE (lfs_code, lfs_spe_code)
);

COMMENT ON TABLE ref.tr_lifestage_lfs IS 'Table of lifestages';
COMMENT ON COLUMN ref.tr_lifestage_lfs.lfs_id IS 'Integer, primary key of the table';
COMMENT ON COLUMN ref.tr_lifestage_lfs.lfs_code IS 'The code of lifestage';
COMMENT ON COLUMN ref.tr_lifestage_lfs.lfs_name IS 'The english name of lifestage';
COMMENT ON COLUMN ref.tr_lifestage_lfs.lfs_spe_code IS 'The code of the species referenced from
tr_species_spe : use aphiaID eg ''126281'' for eel ';
COMMENT ON COLUMN ref.tr_lifestage_lfs.lfs_description IS 'Definition of the lifestage';
COMMENT ON COLUMN ref.tr_lifestage_lfs.lfs_icesvalue IS 'Code for the lifestage in the ICES database';
COMMENT ON COLUMN ref.tr_lifestage_lfs.lfs_icesguid IS 'GUID in the ICES database';
COMMENT ON COLUMN ref.tr_lifestage_lfs.lfs_icestablesource IS 'Source table in ICES vocab';


GRANT ALL ON ref.tr_lifestage_lfs TO diaspara_admin;
GRANT SELECT ON ref.tr_lifestage_lfs TO diaspara_read;



3.15.6 Existing stages in ICES dictionaries

You can run the following code to see the candidate tables in ICES, in summary: none fitted and this part is skipped to shorten the report.

Table 17: ICES vocabularies for life stages
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 use
DevScale <- 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")) 

3.15.7 Importing the lifestages for Salmon

Some of the definitions come from Ontology portal.

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", "127186" , "In fish, the term egg usually refers to female haploid gametes.", 
  "E",   "0424ae90-03aa-4e73-8cda-e8745d0b8158", "TS_DevStage",
  "EE",   "Eyed egg", "127186" , "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", "127186" , "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", "127186" , "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", "127186", 
  "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", "127186", "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", "127186", "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", "127186", " 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", "127186", "All life stages are concerned.", NA, NA, NA,
  "_", "No life stage", "127186", "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;")#24
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, 
     lfs_spe_code,
     lfs_description,
     lfs_icesvalue, 
     lfs_icesguid::uuid, 
     lfs_icestablesource
     FROM temp_lfs;")
dbExecute(con_diaspara_admin, "DROP TABLE temp_lfs")

3.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 ='126281';")
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, '126281' 
FROM refwgeel.tr_lifestage_lfs ;") # 8

3.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, 
    '127187' AS lfs_spe_code,
    lfs_description,
    lfs_icesvalue, 
    lfs_icesguid::uuid, 
    lfs_icestablesource
    FROM ref.tr_lifestage_lfs WHERE lfs_spe_code = '127186';")

3.15.10 Content of the tr_lifestage_lfs table

Code
dbGetQuery(con_diaspara, "SELECT * FROM ref.tr_lifestage_lfs;") |> 
DT::datatable(rownames = FALSE,
  options = list(
    pageLength = 7,        
    scrollX= TRUE   
  ))
Tip

Follow up in ICES vocab

This issue has been created in ICES data governance : DIASPARA: Diadromous fish life stages #885

3.16 Maturity (ts_maturity_mat)

In Salmoglob, information about the stage mixes information on stage and maturity. The use of Universal sexual maturity scale for all fish (SMSF) vocabulary has been made mandatory for all working groups. For this reason a vocab on maturity was created. It will probably rarely be used in eel as all the eel caught even on their way to the ocean are always immature, the maturation occuring later during the spawning migration. However, this information is necessary for Salmon, for which both the location and the maturity will define the spatio temporal elements in life cycle, to be integrated as processes in the model. So for instance, some parameters will describe sexually mature individuals caught at sea, or in freshwater during their spawning migration.

SQL code to create table tr_maturity_mat
-- maturity table code


DROP TABLE IF EXISTS ref.tr_maturity_mat CASCADE;
CREATE TABLE ref.tr_maturity_mat (
  mat_id SERIAL PRIMARY KEY,
  mat_code TEXT NOT NULL CONSTRAINT uk_mat_code UNIQUE, 
  mat_description TEXT,
  mat_icesvalue character varying(4),  
  mat_icesguid uuid,
  mat_icestablesource text
);

COMMENT ON TABLE ref.tr_maturity_mat IS 'Table of maturity corresponding to the 6 stage scale of the ICES vocabulary';
COMMENT ON COLUMN ref.tr_maturity_mat.mat_id IS 'Integer, primary key of the table';
COMMENT ON COLUMN ref.tr_maturity_mat.mat_code IS 'The code of maturity stage';
COMMENT ON COLUMN ref.tr_maturity_mat.mat_description IS 'Definition of the maturity stage';
COMMENT ON COLUMN ref.tr_maturity_mat.mat_icesvalue IS 'Code (Key) of the maturity in ICES db';
COMMENT ON COLUMN ref.tr_maturity_mat.mat_icesguid IS 'UUID (guid) of ICES, you can access by pasting ';
COMMENT ON COLUMN ref.tr_maturity_mat.mat_icestablesource IS 'Source table in ICES';
GRANT ALL ON ref.tr_maturity_mat TO diaspara_admin;
GRANT SELECT ON ref.tr_maturity_mat TO diaspara_read;

since 2020 and WGBIOP (ICES 2024c) 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)
Bb. Developing and functionally mature
C. Spawning Ca. Actively spawning
Cb. Spawning
D. Regressing/Regenerating Da. Regressing
Db. Regenerating
E. Omitted spawning
F. Abnormal

Table SMSF (WKMATCH 2012 maturity scale revised). Source: [@ices_wbbiop_2024].

Of note the following comments by WGBIOP :

  • 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 (see table below) 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 18).

Code to import maturity from ICES.
maturity <- icesVocab::getCodeList('TS_MATURITY')

maturity <- maturity |> 
  rename("mat_icesguid"="GUID",  "mat_icesvalue" = "Key", "mat_description" = "Description") |> 
  select ( mat_icesvalue, mat_icesguid, mat_description) |>
  filter(mat_icesvalue %in% c("A","B","Ba","Bb","C","Ca","Cb","D","Da","Db","E", "F")) |>
  mutate(mat_icestablesource = "TS_MATURITY",
         mat_id = 1:12,
         mat_code = mat_icesvalue) |>
  select(mat_id, mat_code, mat_description, mat_icesvalue, mat_icesguid, mat_icestablesource)

DBI::dbWriteTable(con_diaspara_admin, "temp_maturity", maturity, overwrite = TRUE)


DBI::dbExecute(con_diaspara_admin, "INSERT INTO ref.tr_maturity_mat
(mat_id, mat_code, mat_description, mat_icesvalue, mat_icesguid, mat_icestablesource)
SELECT mat_id, mat_code, mat_description, mat_icesvalue, mat_icesguid::uuid, mat_icestablesource
FROM temp_maturity")# 12


DBI::dbExecute(con_diaspara_admin, "DROP table temp_maturity")
Code
dbGetQuery(con_diaspara, "SELECT * FROM ref.tr_maturity_mat;") |> 
  knitr::kable() |> 
  kable_styling(bootstrap_options = c("striped", "hover", "condensed"))
Table 18: Table of maturity codes
mat_id mat_code mat_description mat_icesvalue mat_icesguid mat_icestablesource
1 A Immature A a25f81c6-91af-47fe-b2a1-6f76a8643ac3 TS_MATURITY
2 B Developing B 62b08142-2f9d-4b8c-b53f-d9bce26b1c35 TS_MATURITY
3 Ba 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
CautionAdd maturity to metadata in WGNAS

We still have to modify the metadata in WGNAS, create a new column for maturity and link it. This has to be done by WGNAS : Metadata : integrate the maturity referential #27

3.17 Habitat type (tr_habitattype_hty)

This table (Table 19) is used in RDBES, and those stages are consistent with WGBAST and WGEEL. When creating habitat types 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.

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 19: 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
266932 976fc2af-a21c-47ad-820f-98b684e01bcd CL Coastal lagoons 2026-02-10T10:02:49.497 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

3.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 vocab


DROP TABLE IF EXISTS ref.tr_habitattype_hty CASCADE;
CREATE TABLE ref.tr_habitattype_hty (
  hty_id SERIAL PRIMARY KEY,
  hty_code TEXT NOT NULL UNIQUE,
  hty_description TEXT,
  hty_icesvalue character varying(4),  
  hty_icesguid uuid,
  hty_icestablesource text
);

COMMENT ON TABLE ref.tr_habitattype_hty IS 'Table of habitat types, takes from the WLTYP vocab';
COMMENT ON COLUMN ref.tr_habitattype_hty.hty_id IS 'Integer, primary key of the table';
COMMENT ON COLUMN ref.tr_habitattype_hty.hty_code IS 'The code of the habitat';
COMMENT ON COLUMN ref.tr_habitattype_hty.hty_description IS 'Definition of the lifestage';
COMMENT ON COLUMN ref.tr_habitattype_hty.hty_icesvalue IS 'Code for the lifestage in the ICES database';
COMMENT ON COLUMN ref.tr_habitattype_hty.hty_icesguid IS 'GUID in the ICES database';
COMMENT ON COLUMN ref.tr_habitattype_hty.hty_icestablesource IS 'Source table in ICES vocab';


GRANT ALL ON ref.tr_habitattype_hty TO diaspara_admin;
GRANT SELECT ON ref.tr_habitattype_hty TO diaspara_read;

3.17.2 Import the habitat type

The codes are imported in Table Table 20.

Code to import habitat from ICES.
habitat <- icesVocab::getCodeList('WLTYP')

habitat <- habitat |> 
  rename("hty_icesguid"="GUID",  "hty_icesvalue" = "Key", "hty_description" = "Description") |> 
  select ( hty_icesvalue, hty_icesguid, hty_description) |>
  filter(hty_icesvalue %in% c("MC","MO","FW","T")) |>
  mutate(hty_icestablesource = "TS_habitat",
         hty_id = 1:4,
         hty_code = hty_icesvalue) |>
  select(hty_id, hty_code, hty_description, hty_icesvalue, hty_icesguid, hty_icestablesource)

DBI::dbWriteTable(con_diaspara_admin, "temp_habitat", habitat, overwrite = TRUE)


DBI::dbExecute(con_diaspara_admin, "INSERT INTO ref.tr_habitattype_hty
(hty_id, hty_code, hty_description, hty_icesvalue, hty_icesguid, hty_icestablesource)
SELECT hty_id, hty_code, hty_description, hty_icesvalue, hty_icesguid::uuid, hty_icestablesource
FROM temp_habitat")# 4


DBI::dbExecute(con_diaspara_admin, "DROP table temp_habitat")
  • The following table is proposed (Table Table 20).
Code
dbGetQuery(con_diaspara, "SELECT * FROM ref.tr_habitattype_hty;") |> 
  knitr::kable() |> 
  kable_styling(bootstrap_options = c("striped", "hover", "condensed"))
Table 20: Table of habitat types
hty_id hty_code hty_description hty_icesvalue hty_icesguid hty_icestablesource
1 FW Fresh water FW eb979616-8b95-4c1b-92e8-b5f8d8bf1b96 TS_habitat
2 MC Marine water (coast) MC b51355b0-b905-4b4e-ab12-98d9b47d7752 TS_habitat
3 MO Marine water (open sea) MO a75522ef-5e4a-4e2d-8550-38091cb6c994 TS_habitat
4 T WFD Transitional water - implies reduced salinity T 1c792737-6f55-422a-b709-88af2d78c4ea TS_habitat

3.18 Quality (tr_quality_qal)

3.18.0.1 Quality and Archiving Procedures Across Working Groups

The Working Group on Eel (WGEEL) employs a dedicated quality‑coding system to document both the reliability of submitted data and any modifications applied during processing. This system, implemented through the table tbl‑tr_quality_qalwgeel, enables the group to flag records as high quality, modified, subject to warnings, missing, or otherwise problematic. It also serves as a mechanism for retaining historical information associated with each data point. In contrast, ICES does not routinely retain archived versions of submitted datasets. The Working Group on North Atlantic Salmon (WGNAS) adopts a different approach: elements from each annual assessment are systematically copied into an archive table, while only the most up‑to‑date data are maintained in the active database used for current analyses. Consequently, the SalmoGlob database—constructed from WGNAS data—contains exclusively the records relevant to the current assessment year. A structured comparison between the active and archived datasets is conducted within the WGNAS Shiny visualisation tool. This comparison is used to identify variables that are missing or that exhibit substantial deviations from the previous year’s values. The results provide an essential quality‑control checkpoint, ensuring the consistency and reliability of input data prior to executing the more complex modelling procedures.

Table 21

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

Considering the heavy reliance of WGEEL on the quality flag, and the importance of an archive database for WGNAS processes, it was decided to keep both but to shift to the quality flag code a standard vocabulary from ICES seadatanet. This shift from the working group format to the new format implies breaking changes summarized below.

  • 0 in wgeel becomes 9
  • 1 is OK
  • 2 becomes 5
  • 3 becomes 4
  • 4 becomes 3

Values other than 0 1 2 3 4 will have to be ignored and considered as historical. Note that currently those are still kept in the database, but in the future we’ll copy them in another table for archive data. Figure Figure 14 shows which tables will be updated after the change.

3.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 quality

DROP TABLE IF EXISTS ref.tr_quality_qal CASCADE;
CREATE  TABLE ref.tr_quality_qal (
  qal_code int4 NOT NULL,
  qal_description text NULL,
  qal_definition text NULL,
  qal_kept bool  NULL,
    CONSTRAINT tr_quality_qal_pkey PRIMARY KEY (qal_code)
);
COMMENT ON TABLE ref.tr_quality_qal IS 'Table of quality rating, 1 = good quality, 2 = modified 4 = warnings, 0 = missing, 18 , 19 ... deprecated data in 2018, 2019 ...';
COMMENT ON COLUMN ref.tr_quality_qal.qal_code IS 'Data quality code';
COMMENT ON COLUMN ref.tr_quality_qal.qal_description IS 'Data quality description';
COMMENT ON COLUMN ref.tr_quality_qal.qal_definition IS 'Definition of the quality code';
COMMENT ON COLUMN ref.tr_quality_qal.qal_kept IS 'Are the data with this score kept for analysis';

GRANT ALL ON ref.tr_quality_qal TO diaspara_admin;
GRANT SELECT ON ref.tr_quality_qal TO diaspara_read;


3.18.2 Import the quality code

The codes are imported in Table 22 using the following code :

Code to import quality from WGEEL and SeaDataNet flags
 SDN_FLAGS<- icesVocab::getCodeList('SDN_FLAGS')
dbWriteTable(conn = con_diaspara,name = "temp_sdn_flags", value = SDN_FLAGS) 
# old code deprecated, see next sql
# dbExecute(con_diaspara_admin,"DELETE FROM ref.tr_quality_qal;")
# dbExecute(con_diaspara, "ALTER TABLE ref.tr")
# 
# 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 wgeel
# dbExecute(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")
SQL code to modify table tr_quality_qal
-- See report following Maria's comment there is a referential, here is the script to adapt the table

ALTER TABLE ref.tr_quality_qal  ADD COLUMN qal_icesvalue CHARACTER VARYING (4);
ALTER TABLE ref.tr_quality_qal  ADD COLUMN qal_icesguid uuid ;
ALTER TABLE ref.tr_quality_qal  ADD COLUMN qal_icestablesource TEXT ;

-- table public.temp_sdn_flags has been inserted in R
-- see report https://diaspara.bordeaux-aquitaine.inrae.fr/deliverables/wp3/p7stock/stockdb.html#quality-tr_quality_qal


/*
 * 0 has been removed from the table
 */

SELECT * FROM public.temp_sdn_flags WHERE "Key" = '9';
DELETE FROM  ref.tr_quality_qal WHERE qal_code = 9;
INSERT INTO ref.tr_quality_qal (qal_code, qal_description, qal_definition,
qal_kept, qal_icesvalue, qal_icesguid, qal_icestablesource)
 SELECT "Key"::integer AS qal_code,
  'Missing' AS qal_description,
 "Description" AS qal_definition,
 FALSE AS qal_kept,
 "Key" AS qal_icesvalue,
 "Guid"::UUID AS qal_icesguid, 
 'SDN_FLAGS' AS qal_icestablesource 
 FROM public.temp_sdn_flags WHERE "Key" = '9'; --1
 
 
 /*
  * 1 is OK
  */
 
SELECT * FROM public.temp_sdn_flags WHERE "Key" = '1';
UPDATE ref.tr_quality_qal SET (qal_description, qal_definition, qal_kept,
qal_icesvalue, qal_icesguid, qal_icestablesource) =
(s.qal_description, s.qal_definition, s.qal_kept, s.qal_icesvalue, 
s.qal_icesguid, s.qal_icestablesource)
FROM (
 SELECT
  'Good quality' AS qal_description,
 "Description" AS qal_definition,
 TRUE AS qal_kept,
 "Key" AS qal_icesvalue,
 "Guid"::UUID AS qal_icesguid, 
 'SDN_FLAGS' AS qal_icestablesource 
 FROM public.temp_sdn_flags WHERE "Key" = '1') AS s
 WHERE qal_code = 1;
 
  /*
  * 2 becomes 5
  */
DELETE FROM  ref.tr_quality_qal WHERE qal_code = 5;
UPDATE ref.tr_quality_qal SET (qal_code, qal_description, qal_definition, 
qal_kept, qal_icesvalue, qal_icesguid, qal_icestablesource) =
(s.qal_code, s.qal_description, s.qal_definition, s.qal_kept, 
s.qal_icesvalue, s.qal_icesguid, s.qal_icestablesource)
 FROM (
 SELECT
  "Key"::integer AS qal_code,
  'Modified' AS qal_description,
 "Description"|| '. Warning this was 2 previously in the WGEEL database.' AS qal_definition,
 TRUE AS qal_kept,
 "Key" AS qal_icesvalue,
 "Guid"::UUID AS qal_icesguid, 
 'SDN_FLAGS' AS qal_icestablesource 
 FROM public.temp_sdn_flags WHERE "Key" = '5') AS s
 WHERE tr_quality_qal.qal_code = 2; --1
 
   /*
  * 3 becomes 100
  * 4 becomes 3
  * 100 becomes 4
  */
 

 
 UPDATE ref.tr_quality_qal SET (qal_code, qal_description, qal_definition, 
qal_kept, qal_icesvalue, qal_icesguid, qal_icestablesource) =
(s.qal_code, s.qal_description, s.qal_definition, s.qal_kept, 
s.qal_icesvalue, s.qal_icesguid, s.qal_icestablesource)
FROM
(SELECT 
100 AS qal_code,
 qal_description, 
 "Description"||'. Previously 3 in WGEEL with definition:  '||qal_definition AS qal_definition, 
 qal_kept, 
 "Key" AS qal_icesvalue,
 "Guid"::UUID AS qal_icesguid, 
 'SDN_FLAGS' AS qal_icestablesource 
 FROM ref.tr_quality_qal, temp_sdn_flags 
 WHERE qal_code = 3 AND  "Key" = '4')s
 WHERE tr_quality_qal.qal_code = 3;
 
 
 UPDATE ref.tr_quality_qal SET (qal_code, qal_description, qal_definition, 
qal_kept, qal_icesvalue, qal_icesguid, qal_icestablesource) =
(s.qal_code, s.qal_description, s.qal_definition, s.qal_kept, 
s.qal_icesvalue, s.qal_icesguid, s.qal_icestablesource)
FROM
(SELECT 
 3 AS qal_code,
 qal_description, 
 "Description"||'. Previously 4 in WGEEL with definition: '||qal_definition AS qal_definition, 
 qal_kept, "Key" AS qal_icesvalue,
 "Guid"::UUID AS qal_icesguid, 
 'SDN_FLAGS' AS qal_icestablesource 
 FROM ref.tr_quality_qal, temp_sdn_flags 
 WHERE qal_code = 4 AND  "Key" = '3')s
 WHERE tr_quality_qal.qal_code = 4;

 
 UPDATE ref.tr_quality_qal SET qal_code = 4 WHERE qal_code =100;
 
 
 
 
  /*
  * Insert values 2, 6, 7, 8 (I'm not using letters) as qal_code is an integer
  */

 
 INSERT INTO ref.tr_quality_qal (qal_code, qal_description, qal_definition,
qal_kept, qal_icesvalue, qal_icesguid, qal_icestablesource)
 SELECT "Key"::integer AS qal_code,
  'Missing' AS qal_description,
 "Description" AS qal_definition,
 TRUE AS qal_kept,
 "Key" AS qal_icesvalue,
 "Guid"::UUID AS qal_icesguid, 
 'SDN_FLAGS' AS qal_icestablesource 
 FROM public.temp_sdn_flags WHERE "Key" in ('2', '6', '7', '8'); --4
 
UPDATE "ref".tr_quality_qal
  SET qal_description='probably good'
  WHERE qal_code=2;
UPDATE "ref".tr_quality_qal
  SET qal_description='below detection'
  WHERE qal_code=6;
UPDATE "ref".tr_quality_qal
  SET qal_description='above detection'
  WHERE qal_code=7;
UPDATE "ref".tr_quality_qal
  SET qal_description='interpolated'
  WHERE qal_code=8;
Code
dbGetQuery(con_diaspara, "SELECT * FROM ref.tr_quality_qal;") |> 
  knitr::kable() |> 
  kable_styling(bootstrap_options = c("striped", "hover", "condensed"))
Table 22: Table of quality
qal_code qal_description qal_definition qal_kept qal_icesvalue qal_icesguid qal_icestablesource
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 NA NA NA
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 NA NA NA
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 NA NA NA
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 NA NA NA
-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 NA NA NA
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 NA NA NA
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 NA NA NA
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 NA NA NA
9 Missing Missing value. The data value is missing. Any accompanying value will be a magic number representing absent data. FALSE 9 e61462dc-09e4-45ae-8d62-b9b85ce363a7 SDN_FLAGS
1 Good quality Good value. Good quality data value that is not part of any identified malfunction and has been verified as consitent with real phenomena during the quality control process. TRUE 1 6da55b2a-7565-4cd9-aae8-c192f0e7645a SDN_FLAGS
5 Modified Changed value. Data value adjusted during quality control. Best practice strongly recommends that the value before the change be preserved in the data or its accompanying metadata.. Warning this was 2 previously in the WGEEL database. TRUE 5 7586c1e9-d89f-4902-bc2f-d79f69ac92cd SDN_FLAGS
7 Above detection Value in excess. The level of the measured phenomena was too large to be quantified by the technique employed to measure it. The accompanying value is the measurement limit for the technique. TRUE 7 a8fdd6ba-c389-4509-a049-3f88f291f392 SDN_FLAGS
8 Interpolated Interpolated value. This value has been derived by interpolation from other values in the data object. TRUE 8 6c8f2885-d786-4467-bee0-28baf558fc35 SDN_FLAGS
3 Warnings Probably bad value. Data value recognised as unusual during quality control that forms part of a feature that is probably inconsistent with real phenomena.. Previously 4 in WGEEL with definition: The data is used by the wgeel, but there are warnings on its quality (see comments) TRUE 3 fe08b67a-d1ed-4f29-9fca-764e885692b7 SDN_FLAGS
4 Bad quality Bad value. An obviously erroneous data value.. Previously 3 in WGEEL with definition: The data has been judged of too poor quality to be used by the wgeel, it is not used TRUE 4 59d2158e-1108-4872-b32e-ca65f7365995 SDN_FLAGS
2 Probably good Probably good value. Data value that is probably consistent with real phenomena but this is unconfirmed or data value forming part of a malfunction that is considered too small to affect the overall quality of the data object of which it is a part. TRUE 2 8f73d75e-dda2-4345-886c-ab816c73ed20 SDN_FLAGS
6 Below detection Value below detection. The level of the measured phenomena was too small to be quantified by the technique employed to measure it. The accompanying value is the detection limit for the technique. TRUE 6 1634bec4-65b3-4172-b9d0-5092cea78b6e SDN_FLAGS

3.19 Age (tr_age_age)

The code for creating tr_age_age (Table Table 23) 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)

DROP TABLE IF EXISTS ref.tr_age_age;
CREATE TABLE ref.tr_age_age (
age_value INTEGER,
age_envir TEXT NOT NULL,
CONSTRAINT ck_age_envir CHECK (age_envir='Seawater' OR age_envir='Freshwater'),
age_code varchar(3) PRIMARY KEY,
age_description TEXT,
age_definition TEXT,
age_icesvalue character varying(4),  
age_icesguid uuid,
age_icestablesource text);

ALTER TABLE ref.tr_age_age OWNER TO diaspara_admin;
GRANT SELECT ON ref.tr_age_age  TO diaspara_read;


INSERT INTO ref.tr_age_age VALUES (0, 'Freshwater', '0FW', '0 year in freshwater','Age of juvenile fish in their first year in Freshwater');
INSERT INTO ref.tr_age_age VALUES (1, 'Freshwater', '1FW', '1 year in freshwater',NULL);
INSERT INTO ref.tr_age_age VALUES (2, 'Freshwater', '2FW', '2 years in freshwater',NULL);
INSERT INTO ref.tr_age_age VALUES (3, 'Freshwater', '3FW', '3 years in freshwater',NULL);
INSERT INTO ref.tr_age_age VALUES (4, 'Freshwater', '4FW', '4 years in freshwater',NULL);
INSERT INTO ref.tr_age_age VALUES (5, 'Freshwater', '5FW', '5 years in freshwater',NULL);
INSERT INTO ref.tr_age_age VALUES (6, 'Freshwater', '6FW', '6 years in freshwater',NULL);
INSERT INTO ref.tr_age_age VALUES (1, 'Seawater', '1SW', '1 year in seawater',NULL);
INSERT INTO ref.tr_age_age VALUES (2, 'Seawater', '2SW', '2 years in seawater',NULL);
INSERT INTO ref.tr_age_age VALUES (NULL, 'Seawater', 'MSW', 'Two years or more in seawater',NULL);
INSERT INTO ref.tr_age_age VALUES (NULL, 'Seawater', 'MSW', 'Two years or more in seawater',NULL);
INSERT INTO "ref".tr_age_age (age_envir,age_code,age_description,age_definition)
  VALUES ('Freshwater','1+','Older than one year in freshwater','Groups all fishes older than one year in freshwater');


COMMENT ON TABLE ref.tr_age_age IS 'Table of ages for salmonids';
COMMENT ON COLUMN ref.tr_age_age.age_value IS 'Integer, value of the age as integer';
COMMENT ON COLUMN ref.tr_age_age.age_envir IS 'Freshwater or Seawater';
COMMENT ON COLUMN ref.tr_age_age.age_code IS '1FW to 6FW and 1SW to 2SW';
COMMENT ON COLUMN ref.tr_age_age.age_description IS 'Description of the age';
COMMENT ON COLUMN ref.tr_age_age.age_definition IS 'Definition of the age';
COMMENT ON COLUMN ref.tr_age_age.age_icesvalue IS 'Code for the age in the ICES database';
COMMENT ON COLUMN ref.tr_age_age.age_icesguid IS 'GUID in the ICES database';
COMMENT ON COLUMN ref.tr_age_age.age_icestablesource IS 'Source table in ICES vocab';
Code
dbGetQuery(con_diaspara, "SELECT * FROM ref.tr_age_age;") |> 
  knitr::kable() |> 
  kable_styling(bootstrap_options = c("striped", "hover", "condensed"))
Table 23: Table of age
age_value age_envir age_code age_description age_definition age_icesvalue age_icesguid age_icestablesource
1 Freshwater 0FW 0 year in freshwater 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
NA Freshwater 1+ Older than one year in freshwater Groups all fishes older than one year in freshwater NA NA NA

3.20 Sex (tr_sex_sex)

There is a referential about sex in ICES see Table Table 24.

Code
TS_SEXCO <- icesVocab::getCodeList('SEXCO')
kable(TS_SEXCO, caption = "TS_SEXCO") |> kable_styling(bootstrap_options = c("striped", "hover", "condensed")) 
Table 24: ICES vocabularies for sex
TS_SEXCO
Id Guid Key Description LongDescription Modified Deprecated CodeTypeID CodeTypeGUID
26730 57201ebe-e901-41b9-9939-f54cadb83ebb F Female 2024-10-22T01:08:06.437 FALSE 45 4efe3145-65ee-46c7-bca1-3ce9f10101de
26731 dba034ab-7e05-4332-8586-f1b33e4c2093 H Hermaphrodite 2023-02-08T11:30:06.04 FALSE 45 4efe3145-65ee-46c7-bca1-3ce9f10101de
26732 48dabe79-03f3-4fc2-ab66-cb1cc52cc735 I 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
DROP TABLE IF EXISTS ref.tr_sex_sex CASCADE;
CREATE TABLE ref.tr_sex_sex (
  sex_id SERIAL PRIMARY KEY,
  sex_code TEXT NOT NULL CONSTRAINT uk_sex_code UNIQUE, 
  sex_description TEXT,
  sex_icesvalue character varying(4),  
  sex_icesguid uuid,
  sex_icestablesource text
);

COMMENT ON TABLE ref.tr_sex_sex IS 'Table of possible sex values corresponding to the 7 scale of the ICES vocabulary';
COMMENT ON COLUMN ref.tr_sex_sex.sex_id IS 'Integer, primary key of the table';
COMMENT ON COLUMN ref.tr_sex_sex.sex_code IS 'The code of sex';
COMMENT ON COLUMN ref.tr_sex_sex.sex_description IS 'Definition of the sex nature';
COMMENT ON COLUMN ref.tr_sex_sex.sex_icesvalue IS 'Code (Key) of the sex in ICES db';
COMMENT ON COLUMN ref.tr_sex_sex.sex_icesguid IS 'UUID (guid) of ICES, you can access by pasting ';

GRANT ALL ON ref.tr_sex_sex TO diaspara_admin;
GRANT SELECT ON ref.tr_sex_sex TO diaspara_read;
Code to import sex codes from ICES.
sex <- icesVocab::getCodeList('SEXCO')

sex <- sex |> 
  rename("sex_icesguid"="GUID",  "sex_icesvalue" = "Key", "sex_description" = "Description") |> 
  select ( sex_icesvalue, sex_icesguid, sex_description) |>
  mutate(sex_icestablesource = "SEXCO",
         sex_id = 1:7,
         sex_code = sex_icesvalue) |>
  select(sex_id, sex_code, sex_description, sex_icesvalue, sex_icesguid, sex_icestablesource)

DBI::dbWriteTable(con_diaspara_admin, "temp_sex", sex, overwrite = TRUE)


DBI::dbExecute(con_diaspara_admin, "INSERT INTO ref.tr_sex_sex
(sex_id, sex_code, sex_description, sex_icesvalue, sex_icesguid, sex_icestablesource)
SELECT sex_id, sex_code, sex_description, sex_icesvalue, sex_icesguid::uuid, sex_icestablesource
FROM temp_sex")# 4


DBI::dbExecute(con_diaspara_admin, "DROP table temp_sex")
Code
dbGetQuery(con_diaspara, "SELECT * FROM ref.tr_sex_sex;") |> 
  knitr::kable() |> 
  kable_styling(bootstrap_options = c("striped", "hover", "condensed"))
Table 25: Table of sex
sex_id sex_code sex_description sex_icesvalue sex_icesguid sex_icestablesource
1 F Female F 57201ebe-e901-41b9-9939-f54cadb83ebb SEXCO
2 H Hermaphrodite H dba034ab-7e05-4332-8586-f1b33e4c2093 SEXCO
3 I 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

3.21 Gear (ref.tr_gear_gea)

The gears dictionary 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
DROP TABLE IF EXISTS ref.tr_gear_gea;
CREATE TABLE ref.tr_gear_gea (
  gea_id serial4 NOT NULL,
  gea_code text NOT NULL,
  gea_description text NULL,
  gea_icesvalue varchar(4) NULL,
  gea_icesguid uuid NULL,
  gea_icestablesource text NULL,
  CONSTRAINT tr_gear_gea_pkey PRIMARY KEY (gea_id),
  CONSTRAINT uk_gea_code UNIQUE (gea_code)
);
COMMENT ON TABLE ref.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';
COMMENT ON COLUMN ref.tr_gear_gea.gea_id IS 'Id of the gear internal serial';
COMMENT ON COLUMN ref.tr_gear_gea.gea_issscfg_code IS 'Isssfg code of the gear';
COMMENT ON COLUMN ref.tr_gear_gea.gea_description IS 'English name of the gear';
COMMENT ON COLUMN ref.tr_maturity_mat.mat_icesvalue IS 'Code (Key) of the maturity in ICES db';
COMMENT ON COLUMN ref.tr_maturity_mat.mat_icesguid IS 'UUID (guid) of ICES, you can access by pasting ';
GRANT ALL ON ref.tr_gear_gea TO diaspara_admin;
GRANT SELECT ON ref.tr_gear_gea TO diaspara_read;





-- manual code to merge tr_gear_with ICES DB


UPDATE ref.tr_gear_gea
  SET gea_icestablesource='GearType',gea_icesvalue='PS'
  WHERE gea_id=1;
UPDATE ref.tr_gear_gea
  SET gea_icestablesource='GearType',gea_icesvalue='SB'
  WHERE gea_id=4;
UPDATE ref.tr_gear_gea
  SET gea_icestablesource='GearType',gea_icesvalue='SBV'
  WHERE gea_id=5;
UPDATE ref.tr_gear_gea
  SET gea_icestablesource='GearType',gea_icesvalue='TBB'
  WHERE gea_id=7;
UPDATE ref.tr_gear_gea
  SET gea_icestablesource='GearType',gea_icesvalue='LLS'
  WHERE gea_id=45;
UPDATE ref.tr_gear_gea
  SET gea_icestablesource='GearType',gea_icesvalue='LLD'
  WHERE gea_id=46;
UPDATE ref.tr_gear_gea
  SET gea_icestablesource='GearType',gea_icesvalue='LTL'
  WHERE gea_id=49;
UPDATE ref.tr_gear_gea
  SET gea_icestablesource='GearType',gea_icesvalue='LX'
  WHERE gea_id=50;
UPDATE ref.tr_gear_gea
  SET gea_icestablesource='GearType',gea_icesvalue='MIS'
  WHERE gea_id=59;
UPDATE "ref".tr_gear_gea
 SET gea_icestablesource='GearType',gea_icesvalue='HMD'
 WHERE gea_id=20;
UPDATE "ref".tr_gear_gea
 SET gea_icestablesource='GearType',gea_icesvalue='LA'
 WHERE gea_id=27;
UPDATE "ref".tr_gear_gea
 SET gea_icestablesource='GearType',gea_icesvalue='GND'
 WHERE gea_id=30;
UPDATE "ref".tr_gear_gea
 SET gea_icestablesource='GearType',gea_icesvalue='GNC'
 WHERE gea_id=31;
UPDATE "ref".tr_gear_gea
 SET gea_icestablesource='GearType',gea_icesvalue=''
 WHERE gea_id=32;
UPDATE "ref".tr_gear_gea
 SET gea_icestablesource='GearType',gea_icesvalue='GRT'
 WHERE gea_id=33;
UPDATE "ref".tr_gear_gea
 SET gea_icestablesource='GearType',gea_icesvalue='GTN'
 WHERE gea_id=34;
UPDATE "ref".tr_gear_gea
 SET gea_icestablesource='GearType',gea_icesvalue='FPO'
 WHERE gea_id=37;
UPDATE "ref".tr_gear_gea
 SET gea_icestablesource='GearType',gea_icesvalue='FYK'
 WHERE gea_id=38;
UPDATE "ref".tr_gear_gea
 SET gea_icestablesource='GearType',gea_icesvalue='LHP'
 WHERE gea_id=43;
UPDATE "ref".tr_gear_gea
 SET gea_icestablesource='GearType'
 WHERE gea_id=1;
UPDATE "ref".tr_gear_gea
 SET gea_icestablesource='GearType'
 WHERE gea_id=4;
UPDATE "ref".tr_gear_gea
 SET gea_icestablesource='GearType'
 WHERE gea_id=5;
UPDATE "ref".tr_gear_gea
 SET gea_icestablesource='GearType'
 WHERE gea_id=7;
UPDATE "ref".tr_gear_gea
 SET gea_icestablesource='GearType'
 WHERE gea_id=45;
UPDATE "ref".tr_gear_gea
   SET gea_icestablesource='GearType'
   WHERE gea_id=46;
UPDATE "ref".tr_gear_gea
   SET gea_icestablesource='GearType'
   WHERE gea_id=49;
UPDATE "ref".tr_gear_gea
   SET gea_icestablesource='GearType'
   WHERE gea_id=50;
UPDATE "ref".tr_gear_gea
   SET gea_icestablesource='GearType'
   WHERE gea_id=59; --28
UPDATE "ref".tr_gear_gea
  SET gea_icestablesource='GearType'
  WHERE gea_id=7;
UPDATE "ref".tr_gear_gea
  SET gea_icestablesource='GearType',gea_icesvalue='OTB'
  WHERE gea_id=8;
UPDATE "ref".tr_gear_gea
  SET gea_icestablesource='GearType',gea_icesvalue='OTT'
  WHERE gea_id=10;
UPDATE "ref".tr_gear_gea
  SET gea_icestablesource='GearType',gea_icesvalue='PTB'
  WHERE gea_id=11;
UPDATE "ref".tr_gear_gea
  SET gea_icestablesource='GearType',gea_icesvalue='OTM'
  WHERE gea_id=13;


ALTER TABLE tr_gear_gea SET gea_code 
Code to import gear codes from WGEEL
gea <- dbGetQuery(con_wgeel_distant, "SELECT * FROM ref.tr_gear_gea")

gea <- gea |> 
  rename("gea_code"="gea_issscfg_code",  "gea_description" = "gea_name_en") |> 
  select(-gea_id) |>
  arrange(gea_code) |>
  mutate(gea_icestablesource = NA,
         gea_icesvalue = NA,
         gea_icesguid = as.character(NA),
         gea_id = 1:nrow(gea)
  ) |>
  select(gea_id, gea_code, gea_description, gea_icesvalue, gea_icesguid, gea_icestablesource)

DBI::dbWriteTable(con_diaspara_admin, "temp_gear", gea, overwrite = TRUE)


DBI::dbExecute(con_diaspara_admin, "INSERT INTO ref.tr_gear_gea
(gea_id, gea_code, gea_description, gea_icesvalue, gea_icesguid, gea_icestablesource)
SELECT gea_id, gea_code, gea_description, gea_icesvalue, gea_icesguid::uuid, gea_icestablesource
FROM temp_gear")# 60


DBI::dbExecute(con_diaspara_admin, "DROP table temp_gear")
Code
dbGetQuery(con_diaspara, "SELECT * FROM ref.tr_gear_gea;") |> 
  knitr::kable() |> 
  kable_styling(bootstrap_options = c("striped", "hover", "condensed"))
Table 26: Table of gears
gea_id gea_code gea_description gea_icesvalue gea_icesguid gea_icestablesource
2 01.2 Surrounding nets without purse lines NA NA NA
3 01.9 Surrounding nets (nei) NA NA NA
6 02.9 Seine nets (nei) NA NA NA
9 03.13 Twin bottom otter trawls NA NA NA
12 03.19 Bottom trawls (nei) NA NA NA
14 03.22 Midwater pair trawls NA NA NA
15 03.29 Midwater trawls (nei) NA NA NA
16 03.3 Semipelagic trawls NA NA NA
17 03.9 Trawls (nei) NA NA NA
18 04.1 Towed dredges NA NA NA
19 04.2 Hand dredges NA NA NA
21 04.9 Dredges (nei) NA NA NA
22 05.1 Portable lift nets NA NA NA
23 05.2 Boat-operated lift nets NA NA NA
24 05.3 Shore-operated stationary lift nets NA NA NA
25 05.9 Lift nets (nei) NA NA NA
26 06.1 Cast nets NA NA NA
28 06.9 Falling gear (nei) NA NA NA
29 07.1 Set gillnets (anchored) NA NA NA
35 07.9 Gillnets and entangling nets (nei) NA NA NA
36 08.1 Stationary uncovered pound nets NA NA NA
39 08.4 Stow nets NA NA NA
40 08.5 Barriers, fences, weirs, etc. NA NA NA
41 08.6 Aerial traps NA NA NA
42 08.9 Traps (nei) NA NA NA
44 09.2 Mechanized lines and pole-and-lines NA NA NA
47 09.39 Longlines (nei) NA NA NA
48 09.4 Vertical lines NA NA NA
51 10.1 Harpoons NA NA NA
52 10.2 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
TipOther 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

TipOther source of definition (if needed)

Method used to monitor eel in the Mediterranean are referenced in detail in this report.

3.22 ICES areas

We have create entries in the table `tr_fishingarea_fia for FAO major fishing area (27, 21, 37, 34, 31).

  • 27 Atlantic, Northeast
  • 21 Atlantic, Northwest
  • 37 Mediterranean and Black Sea
  • 34 Atlantic Eastern Central
  • 31 Atlantic, Western Central

source : GFCM geographical subareas https://www.fao.org/gfcm/data/maps/gsas/fr/ https://gfcmsitestorage.blob.core.windows.net/website/5.Data/ArcGIS/GSAs_simplified_updated_division%20(2).zip

source : NAFO divisions https://www.nafo.int/Data/GIS https://www.nafo.int/Portals/0/GIS/Divisions.zip

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 world was found on a computer. Cannot trace the source: it’s exactly the same for NAFO but changed in the Med and ICES. For some reason, it was not complete in the 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, wk
dbExecute(con_diaspara_admin, "INSERT INTO ref.tr_fishingarea_fia
SELECT
   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 ices
dbExecute(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 GFCM
dbExecute(con_diaspara_admin, "INSERT INTO ref.tr_fishingarea_fia
SELECT 
'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,
geom
FROM area.\"GSAs_simplified_division\";") # 32

dbExecute(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 geometry
details 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 computations
png(filename="images/fig-fishingareas_major.png",width=600, height=600, res=300, bg="transparent")
print(g)
dev.off()
Figure 15: 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 ortho

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")  +
  scale_fill_discrete(guide = "none")  +
  theme_void()

# this part is used to avoid long computations
png(filename="images/fig-fishingareas_subarea.png", bg="transparent")
print(g)
dev.off()
Figure 16: Map of ICES fishing areas at Subarea level, source NAFO, FAO, ICES, GFCM.
Code to create a map of fishing areas at Division level
if (file.exists("data/fishingareas_division.Rdata")) load("data/fishingareas_division.Rdata") else {
  fishing_areas_division <- sf::st_read(con_diaspara,
                                        query = "SELECT fia_code, ST_MakeValid(geom) 
                          from ref.tr_fishingarea_fia
                          WHERE fia_level = 'Division'") |>
    sf::st_transform(4326) 
  save(fishing_areas_division, file="data/fishing_areas_division.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_division |> 
  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")  +
  scale_fill_discrete(guide = "none") +
  theme_void()

png(filename="images/fig-fishingareas_division.png", bg="transparent")
print(g)
dev.off() 
Figure 17: Map of ICES fishing areas at division level, source NAFO, FAO, ICES, GFCM.
Code to create a map of fishing areas at subdivision level
if (file.exists("data/fishingareas_subdivision.Rdata")) load("data/fishingareas_subdivision.Rdata") else {
  fishing_areas_subdivision <- sf::st_read(con_diaspara,
                                           query = "SELECT fia_code, ST_MakeValid(geom) 
                          from ref.tr_fishingarea_fia
                          WHERE fia_level = 'Subdivision'") |>
    sf::st_transform(4326) 
  save(fishing_areas_subdivision, file="data/fishing_areas_subdivision.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_subdivision |> 
  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")  +
  scale_fill_discrete(guide = "none") +
  theme_void()

png(filename="images/fig-fishingareas_subdivision.png", bg="transparent")
print(g)
dev.off() 
Figure 18: Map of ICES fishing areas at subdivision level, source NAFO, FAO, ICES, GFCM.

3.23 Time period (ref.tr_timeperiod_tip)

WGBAST reports data per month, quarter, or half year. There is a vocabulary for quarters but not yet for half of year.

SQL code to create table tr_timeperiod_tip
-- maturity table code


DROP TABLE IF EXISTS ref.tr_timeperiod_tip CASCADE;
CREATE TABLE  ref.tr_timeperiod_tip (
  tip_id SERIAL PRIMARY KEY,
  tip_code TEXT NOT NULL CONSTRAINT uk_tip_code UNIQUE, 
  tip_description TEXT,
  tip_icesvalue TEXT,  
  tip_icesguid uuid,
  tip_icestablesource text
);

COMMENT ON TABLE ref.tr_timeperiod_tip IS 'Table of time periods';
COMMENT ON COLUMN ref.tr_timeperiod_tip.tip_id IS 'Integer, primary key of the table';
COMMENT ON COLUMN ref.tr_timeperiod_tip.tip_code IS 'The code of time period';
COMMENT ON COLUMN ref.tr_timeperiod_tip.tip_description IS 'Definition of the time period';
COMMENT ON COLUMN ref.tr_timeperiod_tip.tip_icesvalue IS 'Code (Key) of the time period in ICES db';
COMMENT ON COLUMN ref.tr_timeperiod_tip.tip_icesguid IS 'UUID (guid) of ICES, you can access by pasting ';
COMMENT ON COLUMN ref.tr_timeperiod_tip.tip_icestablesource IS 'Source table in ICES';
GRANT ALL ON ref.tr_timeperiod_tip TO diaspara_admin;
GRANT SELECT ON ref.tr_timeperiod_tip TO diaspara_read;
Code to import timeperiod codes
tp <- icesVocab::getCodeList('IC_SeasonType')
#I don't want this I want a code
tip <- 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_icestablesource
FROM temp_tipr")# 4
DBI::dbExecute(con_diaspara_admin, "DROP table temp_tipr")
Code
dbGetQuery(con_diaspara, "SELECT * FROM ref.tr_timeperiod_tip;") |> 
  knitr::kable() |> 
  kable_styling(bootstrap_options = c("striped", "hover", "condensed"))
Table 27: Table of gears
tip_id tip_code tip_description tip_icesvalue tip_icesguid tip_icestablesource
1 Month Monthly data, from 1 to 12 Month 60eecbb5-c253-4d19-826e-a1126e329b92 IC_SeasonType
2 Quarter Quarterly data from 1 to 4 Quarter 7aeb3bd1-cabe-48e4-b941-997e4337c33e IC_SeasonType
3 Year 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
WarningOnly in WGBAST

Currently the time period are not used in WGEEL and WGNAS (where time period is always year), the referential is only used in WGBAST.

3.24 Data source (ref.tr_datasource_dts)

The source of data is included in WGBAST see: WBAST description. The vocab described here adapts this vocab to ICES DataSource vocab and proposes new entries from WGBAST.

ICES data centre indicated that the current way of handling estimated data is to separate the source of data and the type of estimation. For instance, this structure is followed currently in RDBES. So a catch can come from logbook: it is estimated, and when estimated, a method must be provided (estimation method).

SQL code to create table tr_datasource_dts
-- Table for quality

DROP TABLE IF EXISTS ref.tr_datasource_dts CASCADE;
CREATE  TABLE ref.tr_datasource_dts (
  dts_id int4 PRIMARY KEY,
  dts_code TEXT NOT NULL CONSTRAINT uk_dts_code UNIQUE, 
  dts_description text NULL,
  dts_icesvalue TEXT,  
  dts_icesguid uuid,
  dts_icestablesource text
);
COMMENT ON TABLE ref.tr_datasource_dts IS 'Table of data source values, e.g. logbooks, Expert value ...';
COMMENT ON COLUMN ref.tr_datasource_dts.dts_code IS 'Data srouce code';
COMMENT ON COLUMN ref.tr_datasource_dts.dts_description IS 'Data source description';
COMMENT ON COLUMN ref.tr_datasource_dts.dts_icesvalue IS 'Code (Key) of the time period in ICES db';
COMMENT ON COLUMN ref.tr_datasource_dts.dts_icesguid IS 'UUID (guid) of ICES, you can access by pasting ';
COMMENT ON COLUMN ref.tr_datasource_dts.dts_icestablesource IS 'Source table in ICES';

GRANT ALL ON ref.tr_datasource_dts TO diaspara_admin;
GRANT SELECT ON ref.tr_datasource_dts TO diaspara_read;

Code to import datasource codes
dts <- icesVocab::getCodeList('DataSource')
# 
dts <- dts |>
  rename("dts_icesguid"="Guid",  "dts_code" = "Key", "dts_description" = "Description") |> 
  select ( dts_code, dts_icesguid, dts_description)  |>
  mutate(dts_icestablesource = "DataSource",
         dts_id = 1:nrow(dts),
         dts_icesvalue = dts_code) |>
  select(dts_id, dts_code, dts_description, dts_icesvalue, dts_icesguid, dts_icestablesource)



DBI::dbWriteTable(con_diaspara_admin, "temp_dtsr", dts, overwrite = TRUE)
DBI::dbExecute(con_diaspara_admin, "DELETE FROM ref.tr_datasource_dts")
DBI::dbExecute(con_diaspara_admin, "INSERT INTO ref.tr_datasource_dts
(dts_id, dts_code, dts_description, dts_icesvalue, dts_icesguid, dts_icestablesource)
SELECT dts_id, dts_code, dts_description, dts_icesvalue, dts_icesguid::uuid, dts_icestablesource
FROM temp_dtsr")# 14
DBI::dbExecute(con_diaspara_admin, "DROP table temp_dtsr")
DBI::dbExecute(con_diaspara_admin, "INSERT INTO ref.tr_datasource_dts (dts_id,dts_code,dts_description)
    VALUES (15,'Smolt','Smolt count');")
DBI::dbExecute(con_diaspara_admin, "INSERT INTO ref.tr_datasource_dts (dts_id,dts_code,dts_description)
    VALUES (16,'Parr','Parr densities (electrofishing)');")
DBI::dbExecute(con_diaspara_admin, "INSERT INTO ref.tr_datasource_dts (dts_id,dts_code,dts_description)
    VALUES (17,'Spawner','Spawner count');")
DBI::dbExecute(con_diaspara_admin, "INSERT INTO ref.tr_datasource_dts (dts_id,dts_code,dts_description)
    VALUES (18,'Stocking','Stocking data');")
Code
dbGetQuery(con_diaspara, "SELECT * FROM ref.tr_datasource_dts;") |> 
  knitr::kable() |> 
  kable_styling(bootstrap_options = c("striped", "hover", "condensed"))
Table 28: 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

3.25 Data basis (ref.tr_databasis_dtb)

SQL code to create table tr_databasis_dtb
-- Table of estimation methods when databasis is Estimated

DROP TABLE IF EXISTS ref.tr_databasis_dtb CASCADE;
CREATE  TABLE ref.tr_databasis_dtb (
  dtb_id int4 PRIMARY KEY,
  dtb_code TEXT NOT NULL CONSTRAINT uk_dtb_code UNIQUE, 
  dtb_description text NULL,
  dtb_icesvalue TEXT,  
  dtb_icesguid uuid,
  dtb_icestablesource text
);
COMMENT ON TABLE ref.tr_databasis_dtb IS 'Table of data basis';
COMMENT ON COLUMN ref.tr_databasis_dtb.dtb_code IS 'Data basis  code';
COMMENT ON COLUMN ref.tr_databasis_dtb.dtb_description IS 'Data basis description';
COMMENT ON COLUMN ref.tr_databasis_dtb.dtb_icesvalue IS 'Code (Key) of the Data basis in ICES';
COMMENT ON COLUMN ref.tr_databasis_dtb.dtb_icesguid IS 'UUID (guid) of ICES ';
COMMENT ON COLUMN ref.tr_databasis_dtb.dtb_icestablesource IS 'Source table in ICES';

GRANT ALL ON ref.tr_databasis_dtb TO diaspara_admin;
GRANT SELECT ON ref.tr_databasis_dtb TO diaspara_read;

Code to import databasis codes
dtb <- icesVocab::getCodeList('DataBasis')
# 
dtb <- dtb |>
  rename("dtb_icesguid"="Guid",  "dtb_code" = "Key", "dtb_description" = "Description") |> 
  select ( dtb_code, dtb_icesguid, dtb_description)  |>
  mutate(dtb_icestablesource = "DataBasis",
         dtb_id = 1:nrow(dtb),
         dtb_icesvalue = dtb_code) |>
  select(dtb_id, dtb_code, dtb_description, dtb_icesvalue, dtb_icesguid, dtb_icestablesource)



DBI::dbWriteTable(con_diaspara_admin, "temp_dtbr", dtb, overwrite = TRUE)
DBI::dbExecute(con_diaspara_admin, "INSERT INTO ref.tr_databasis_dtb
(dtb_id, dtb_code, dtb_description, dtb_icesvalue, dtb_icesguid, dtb_icestablesource)
SELECT dtb_id, dtb_code, dtb_description, dtb_icesvalue, dtb_icesguid::uuid, dtb_icestablesource
FROM temp_dtbr")# 5
DBI::dbExecute(con_diaspara_admin, "DROP table temp_dtbr")

3.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’.

  1. Complete count of smolts.
  2. Sampling of smolts and estimate of total smolt run size.
  3. Estimate of smolt run from parr production by relation developed in the same river.
  4. Estimate of smolt run from parr production by relation developed in another river.
  5. Inference of smolt production from data derived from similar rivers in the region.
  6. Count of spawners.
  7. Estimate inferred from stocking of reared fish in the river.
  8. Salmon catch, exploitation and survival estimate.
SQL code to create table ref.tr_estimationmethod_esm
-- Table of estimation methods when databasis is Estimated

DROP TABLE IF EXISTS ref.tr_estimationmethod_esm CASCADE;
CREATE  TABLE ref.tr_estimationmethod_esm (
  esm_id int4 PRIMARY KEY,
  esm_code TEXT NOT NULL CONSTRAINT uk_esm_code UNIQUE, 
  esm_description text NULL,
  esm_wkg_code TEXT NOT NULL,
CONSTRAINT fk_esm_wkg_code  FOREIGN KEY (esm_wkg_code)
REFERENCES ref.tr_icworkinggroup_wkg(wkg_code)
ON UPDATE CASCADE ON DELETE RESTRICT,
  esm_icesvalue TEXT,  
  esm_icesguid uuid,
  esm_icestablesource text
);
COMMENT ON TABLE ref.tr_estimationmethod_esm IS 'Table of table estimation method, provided when databasis (dtb_code) correspond to Estimated';
COMMENT ON COLUMN ref.tr_estimationmethod_esm.esm_code IS 'Estimation method code';
COMMENT ON COLUMN ref.tr_estimationmethod_esm.esm_description IS 'Estimation method  description';
COMMENT ON COLUMN ref.tr_estimationmethod_esm.esm_icesvalue IS 'Code (Key) of the Estimation method in ICES';
COMMENT ON COLUMN ref.tr_estimationmethod_esm.esm_icesguid IS 'UUID (guid) of ICES ';
COMMENT ON COLUMN ref.tr_estimationmethod_esm.esm_icestablesource IS 'Source table in ICES';
COMMENT ON COLUMN ref.tr_estimationmethod_esm.esm_wkg_code 
IS 'Code of the working group, one of WGBAST, WGEEL, WGNAS, WKTRUTTA';
GRANT ALL ON ref.tr_estimationmethod_esm TO diaspara_admin;
GRANT SELECT ON ref.tr_estimationmethod_esm TO diaspara_read;

WarningThis data type is currently only used in WGBAST

Currently the estimation method has only been used in WGBAST. Maybe it could be extended by creating a similar table in the WGNAS in the future.

NoteNote

The estimation method are inherited, so there is a common table and estimation methods are created in daughter tables in each working group, they are inherited. See Section 4.4

3.27 Station (and ICES related vocabs)

The trait data need to be related to sampling stations. These rely on a set of vocabularies (EDMO, PRGOV, …) liseted hereafter. To include the stations, we need two referential tables: the first one is the Station dictionary and the second is the relation Dictionary (which relates stations together). Both are maintained at ICES. The following vocabs existing in ICES have been integrated in the diadromous DB to ensure standardisation with ICES vocabs.

3.27.1 SemanticRelation

Code to show SemanticRelation.
SemanticRelation <- getCodeList("SemanticRelation")
knitr::kable(SemanticRelation)|>
  kable_styling(bootstrap_options = c("striped", "hover", "condensed"))
Table 29: Semantic relation
Id Guid Key Description LongDescription Modified Deprecated CodeTypeID CodeTypeGUID
169652 83921b19-6958-4619-b941-55fb3f207b8d 1 Broader 2017-02-27T12:33:33.203 FALSE 1495 816acef1-a7cd-44a7-a24a-ee3a65241024
169651 3420f8cf-1090-4810-80ee-7a144c26d3bb 2 Narrower 2017-02-27T12:33:13.493 FALSE 1495 816acef1-a7cd-44a7-a24a-ee3a65241024
169653 1d8976e7-7fb6-4dac-9b70-b282788e57c6 3 Related 2017-02-27T12:31:35.25 FALSE 1495 816acef1-a7cd-44a7-a24a-ee3a65241024
196324 4c8a38b4-2609-4a0a-aa49-b05148b1f315 4 SameAs 2018-05-30T13:44:10.893 FALSE 1495 816acef1-a7cd-44a7-a24a-ee3a65241024
196325 8c7c8ae7-1942-432e-9646-db0aef26498b 5 IsReplacedBy 2018-07-11T11:05:44.437 FALSE 1495 816acef1-a7cd-44a7-a24a-ee3a65241024
196764 d6d94c4f-d888-4a72-8152-16986a72d86d 6 Replaces 2018-07-11T11:05:56.097 FALSE 1495 816acef1-a7cd-44a7-a24a-ee3a65241024
Code to import relation.
dbWriteTable(con_diaspara, "SemanticRelation", PRGOV)
dbExecute(con_diaspara, 'ALTER TABLE "SemanticRelation" SET SCHEMA ref;') 
dbExecute(con_diaspara,
          'ALTER TABLE ref."SemanticRelation" ADD CONSTRAINT semanticrelation_pkey PRIMARY KEY ("Key");') 

3.27.2 PRGOV

Code to show PRGOV.
PRGOV <- getCodeList("PRGOV")
knitr::kable(PRGOV)|>
  kable_styling(bootstrap_options = c("striped", "hover", "condensed"))
Table 30: Program Governance for the Station Dictionary (10 first lines)
Id Guid Key Description LongDescription Modified Deprecated CodeTypeID CodeTypeGUID
156691 47a15656-9a4c-4edc-9013-aeb76fc4405f A AMAP Program Governance for the Station Dictionary. Designations with funding first, then project 2024-11-27T09:31:28.347 FALSE 1473 dc896ec4-e236-4a4c-a900-e4bcafcf0cde
196223 28a85b12-c702-40b9-a79c-6010184a7ba7 ASMT-MIME Assessment Grouping for OSPAR MIME Program Governance for the Station Dictionary. Designations with funding first, then project 2019-03-06T17:56:24.277 FALSE 1473 dc896ec4-e236-4a4c-a900-e4bcafcf0cde
156746 34f8c0f8-c096-45ed-a2c6-dfad117b44aa BO BONUS Program Governance for the Station Dictionary. Designations with funding first, then project 2016-07-12T13:00:53.21 FALSE 1473 dc896ec4-e236-4a4c-a900-e4bcafcf0cde
156745 1cb8b3d2-6a52-4d6c-9e71-59170afbf035 BO1 BONUS Beast Program Governance for the Station Dictionary. Designations with funding first, then project 2016-07-12T13:06:48.253 FALSE 1473 dc896ec4-e236-4a4c-a900-e4bcafcf0cde
156722 bcdd09de-b915-4f10-97a1-d094f9544d44 FP7J FP7 - Jericho Program Governance for the Station Dictionary. Designations with funding first, then project 2016-07-12T13:08:19.653 FALSE 1473 dc896ec4-e236-4a4c-a900-e4bcafcf0cde
156689 83052fb7-d4e1-482f-a947-801e2273f478 H HELCOM Program Governance for the Station Dictionary. Designations with funding first, then project 2025-02-05T10:55:23.333 FALSE 1473 dc896ec4-e236-4a4c-a900-e4bcafcf0cde
156742 24f1673d-d7e1-4501-8104-665d4bf2fd93 H1 HELCOM BMP Program Governance for the Station Dictionary. Designations with funding first, then project 2018-05-16T16:46:13.95 FALSE 1473 dc896ec4-e236-4a4c-a900-e4bcafcf0cde
156743 d29af7d1-4cc1-42ac-aea4-4c253ac0f139 H2 HELCOM COMBINE Program Governance for the Station Dictionary. Designations with funding first, then project 2025-01-08T13:09:53.477 FALSE 1473 dc896ec4-e236-4a4c-a900-e4bcafcf0cde
202517 6ef57389-8fbe-4cd3-8bc7-660c77d84199 H3 HELCOM Continuous Underwater Noise monitoring Program Governance for the Station Dictionary. Designations with funding first, then project 2025-04-08T08:52:43.98 FALSE 1473 dc896ec4-e236-4a4c-a900-e4bcafcf0cde
156690 e14c46d5-b1b0-48c7-89ef-ac8da49f4e0f ICES ICES Program Governance for the Station Dictionary. Designations with funding first, then project 2025-01-08T13:09:58.03 FALSE 1473 dc896ec4-e236-4a4c-a900-e4bcafcf0cde
156860 6e18b63f-3105-4c21-b741-fa44b2a9be84 MP MEDPOL Mediterranean Pollution and Research Programme Program Governance for the Station Dictionary. Designations with funding first, then project 2021-10-01T00:08:39.66 FALSE 1473 dc896ec4-e236-4a4c-a900-e4bcafcf0cde
261196 4af03f7e-aa21-41d0-99fe-a71a3839f621 MSFD Marine Strategy Framework Directive Program Governance for the Station Dictionary. Designations with funding first, then project 2025-02-06T15:26:37.893 FALSE 1473 dc896ec4-e236-4a4c-a900-e4bcafcf0cde
169793 e2f717e3-c74f-4d84-b6bc-237c9bed7cfa MSFD-10 Marine Strategy Framework Directive - Descriptor 10 Litter (do not use) Program Governance for the Station Dictionary. Designations with funding first, then project 2025-01-06T11:14:48.58 TRUE 1473 dc896ec4-e236-4a4c-a900-e4bcafcf0cde
232239 bf985b9c-e5f9-4d38-ac5e-84781a0d9e77 MSFD-8 Marine Strategy Framework Directive - Descriptor 8 Contaminants (do not use) Program Governance for the Station Dictionary. Designations with funding first, then project 2025-01-07T10:41:28.523 TRUE 1473 dc896ec4-e236-4a4c-a900-e4bcafcf0cde
194868 26a82124-3a54-46e4-8637-b9671ee936c4 MSFD-9 Marine Strategy Framework Directive - Descriptor 9 Contaminants in seafood destined for human consumption (do not use) Program Governance for the Station Dictionary. Designations with funding first, then project 2025-01-07T10:41:50.66 TRUE 1473 dc896ec4-e236-4a4c-a900-e4bcafcf0cde
156687 745bad18-04de-4053-a752-48003d53dd38 NTL National Program Governance for the Station Dictionary. Designations with funding first, then project 2025-07-07T06:34:44.657 FALSE 1473 dc896ec4-e236-4a4c-a900-e4bcafcf0cde
156688 35b9d6b2-f4b5-4cac-9e5f-df038848c45d O OSPAR Program Governance for the Station Dictionary. Designations with funding first, then project 2025-07-07T18:19:52.437 FALSE 1473 dc896ec4-e236-4a4c-a900-e4bcafcf0cde
156740 84f3e3f0-a432-4264-b27a-8963b0f79c2f O1 OSPAR JMP Program Governance for the Station Dictionary. Designations with funding first, then project 2025-01-06T13:40:45.833 FALSE 1473 dc896ec4-e236-4a4c-a900-e4bcafcf0cde
156741 6bf2bb6d-5e90-4ab2-9b57-4d573ad6d491 O2 OSPAR CEMP Program Governance for the Station Dictionary. Designations with funding first, then project 2025-01-06T13:40:42.767 FALSE 1473 dc896ec4-e236-4a4c-a900-e4bcafcf0cde
156744 2f5b26a2-1a19-47e9-a56a-8f7e57cf6b3a SDN SeaDataNet Program Governance for the Station Dictionary. Designations with funding first, then project 2016-07-12T13:01:50.12 FALSE 1473 dc896ec4-e236-4a4c-a900-e4bcafcf0cde
156692 533f3f8f-df60-47fb-a2a8-74ebc0afb1e0 WFD Water Framework Directive Program Governance for the Station Dictionary. Designations with funding first, then project 2025-02-06T15:30:06.833 FALSE 1473 dc896ec4-e236-4a4c-a900-e4bcafcf0cde
Code to import PRGOV.
dbWriteTable(con_diaspara, "PRGOV", PRGOV)
dbExecute(con_diaspara, 'ALTER TABLE "PRGOV" SET SCHEMA ref;') 
dbExecute(con_diaspara, 
          'ALTER TABLE ref."PRGOV" ADD CONSTRAINT prgov_pkey PRIMARY KEY ("Key");') 

3.27.3 EDMO

Table 31: European Directory of Marine Organisations (EDMO)
Code to show EDMO.
EDMO <- getCodeList("EDMO")|>slice_head(n=10)  |>
  knitr::kable() |>
  kable_styling(bootstrap_options = c("striped", "hover", "condensed"))
TipAddings institutions to the EDMO

To request a new EDMO, an organisation needs to send an email to info@maris.nl

Code to import EDMO.
dbWriteTable(con_diaspara, "EDMO", EDMO)
dbExecute(con_diaspara, 'ALTER TABLE "EDMO" SET SCHEMA ref;')  
dbExecute(con_diaspara, 
          'ALTER TABLE ref."EDMO" ADD CONSTRAINT edmo_pkey PRIMARY KEY ("Key");')  

3.27.4 PURPM

Code to show PURPM.
PURPM <- getCodeList("PURPM")
knitr::kable(PURPM)|>
  kable_styling(bootstrap_options = c("striped", "hover", "condensed"))
Table 32: Purpose of Monitoring
Id Guid Key Description LongDescription Modified Deprecated CodeTypeID CodeTypeGUID
261197 21c70853-68e1-4c05-94fc-02c04c431011 8 MSFD Descriptior 8 - Contaminants 2025-01-07T10:41:56.963 FALSE 42 83c14aa4-133b-49bc-8a32-107047146848
261198 b5758296-3a14-452f-aaa3-4d9367377b67 9 MSFD Descriptior 9 - Contaminants in seafood destined for human consumption 2025-01-07T10:41:58.863 FALSE 42 83c14aa4-133b-49bc-8a32-107047146848
26936 0eed054b-b478-4c6e-b448-51a58c6ec967 B Biological effects monitoring 2025-07-07T18:20:57.213 FALSE 42 83c14aa4-133b-49bc-8a32-107047146848
26937 b677e830-34f8-4eaf-88e3-3377d726d209 E Eutrophication effects monitoring 2025-07-07T18:20:58.913 FALSE 42 83c14aa4-133b-49bc-8a32-107047146848
140653 18ad665b-1597-4cab-90ba-84445678ef14 F Fishery trawl surveys 2016-08-14T10:36:24.617 FALSE 42 83c14aa4-133b-49bc-8a32-107047146848
26938 3f0310df-3a9c-48fb-a1e3-8a47a918f1aa H Human health risk assessment 2025-01-07T10:41:40.53 FALSE 42 83c14aa4-133b-49bc-8a32-107047146848
140654 89cd9460-1d43-4fd0-b658-7619a97bb864 L Litter 2025-01-21T14:00:33.483 FALSE 42 83c14aa4-133b-49bc-8a32-107047146848
26939 2451faa3-831b-43c6-9aff-939c701d864c N No specific purpose 2021-04-06T16:57:06.723 FALSE 42 83c14aa4-133b-49bc-8a32-107047146848
137083 e01f97eb-6e49-4741-bc75-4ff29407584a O Ocean acidification 2025-03-05T11:55:50.7 FALSE 42 83c14aa4-133b-49bc-8a32-107047146848
51445 f02b4faa-d081-4061-b8c8-81b339b6da2e R Research 2025-03-05T11:57:31.303 FALSE 42 83c14aa4-133b-49bc-8a32-107047146848
26940 49df3df6-f880-4330-9707-a276eb92b4f2 S Spatial (geographical) distribution monitoring 2025-07-07T06:35:55.053 FALSE 42 83c14aa4-133b-49bc-8a32-107047146848
26941 562ae8f8-e175-4f07-ae92-a5af7b32539d T Temporal trend monitoring 2025-07-07T18:21:00.377 FALSE 42 83c14aa4-133b-49bc-8a32-107047146848
198772 9efdc23c-153b-44bf-a978-55a406384eb2 U Underwater noise monitoring 2025-04-08T08:52:49.863 FALSE 42 83c14aa4-133b-49bc-8a32-107047146848
Code to import PURPM.
dbWriteTable(con_diaspara, "PURPM", PURPM)
dbExecute(con_diaspara, 'ALTER TABLE "PURPM" SET SCHEMA ref;')
dbExecute(con_diaspara, 
          'ALTER TABLE ref."PURPM" ADD CONSTRAINT purm_pkey PRIMARY KEY ("Key");')    

3.27.5 DTYPE

Code to show icesStation_DTYPE.
Station_DTYPE <- getCodeList("Station_DTYPE")
knitr::kable(Station_DTYPE)|>
  kable_styling(bootstrap_options = c("striped", "hover", "condensed"))
Table 33: Station dictionary data type
Id Guid Key Description LongDescription Modified Deprecated CodeTypeID CodeTypeGUID
156767 9ae94eaa-67f5-4499-9fec-9c753d454d8b BP Bacterioplankton 2018-05-24T00:40:34.24 FALSE 1400 111d1f9c-6352-47ec-98f5-bc2cb60bcb55
148249 0a1d0292-367b-48f8-bfe4-d53c460c59b1 CF Contaminants/hazardous substances in biota 2025-07-07T18:15:36.883 FALSE 1400 111d1f9c-6352-47ec-98f5-bc2cb60bcb55
148250 da00a888-4d78-40f3-bc37-3b2575f75f7b CS Contaminants/hazardous substances in sediment 2025-05-23T09:48:25.073 FALSE 1400 111d1f9c-6352-47ec-98f5-bc2cb60bcb55
202489 e03228f9-9f70-46b7-899f-226b02054f2b CUWN Continuous underwater noise 2025-04-08T08:52:36.057 FALSE 1400 111d1f9c-6352-47ec-98f5-bc2cb60bcb55
148251 8655c1bd-330a-4f7a-812c-f6cc0bd8f5a2 CW Contaminants/hazardous substances in water 2025-07-07T18:21:01.82 FALSE 1400 111d1f9c-6352-47ec-98f5-bc2cb60bcb55
148256 85103227-9697-4487-a874-053e9d88de5d DF Disease in biota 2025-07-07T18:15:40.493 FALSE 1400 111d1f9c-6352-47ec-98f5-bc2cb60bcb55
148252 185f5a57-72e1-419b-b4ab-2a0b2aa0f899 EF Biological effects in biota 2025-07-07T18:15:38.633 FALSE 1400 111d1f9c-6352-47ec-98f5-bc2cb60bcb55
148253 8bdccd4f-f0b7-401f-be43-9533a3fd72bf ES Biological effects in sediment 2025-04-23T11:35:22.617 FALSE 1400 111d1f9c-6352-47ec-98f5-bc2cb60bcb55
156766 6583e8b5-5d79-4ba2-94cb-099dd745e8eb EU Eutrophication effects 2025-07-07T18:21:46.69 FALSE 1400 111d1f9c-6352-47ec-98f5-bc2cb60bcb55
148254 8a758bca-6647-4b47-94a6-7d85ea48a29b EW Biological effects in water 2025-07-07T18:21:45.353 FALSE 1400 111d1f9c-6352-47ec-98f5-bc2cb60bcb55
148263 3edfcdff-974f-47fe-be3a-8f742fb5b0a7 HY Physico-chemical parameters in water 2022-10-21T20:41:44.293 FALSE 1400 111d1f9c-6352-47ec-98f5-bc2cb60bcb55
148258 fad0afaa-28e9-40b5-ac9c-1b1a06f82bc5 LT Litter data 2025-01-06T11:15:11.02 FALSE 1400 111d1f9c-6352-47ec-98f5-bc2cb60bcb55
148255 ba545513-a5dc-4087-bd05-71c28da65f54 NU Nutrients in water 2022-12-15T10:13:18.09 FALSE 1400 111d1f9c-6352-47ec-98f5-bc2cb60bcb55
148257 3768b56d-d6c7-48cf-9056-4c03a33e233d OA Ocean acidification 2025-07-07T18:22:22.77 FALSE 1400 111d1f9c-6352-47ec-98f5-bc2cb60bcb55
148259 3ba04e2e-025d-45d1-abd9-71fdd3508793 PB Phytobenthos 2024-04-11T17:22:13.513 FALSE 1400 111d1f9c-6352-47ec-98f5-bc2cb60bcb55
148260 5fb5a8fb-cfce-4bda-9335-825071df513d PP Phytoplankton 2025-07-07T18:17:13.433 FALSE 1400 111d1f9c-6352-47ec-98f5-bc2cb60bcb55
156768 fc02fa31-489b-4205-9dcf-bef7a1c9aded PR Primary production 2020-07-06T12:38:11.193 FALSE 1400 111d1f9c-6352-47ec-98f5-bc2cb60bcb55
148262 8f667c67-b741-4ee8-a363-51327e9b4799 ZB Zoobenthos 2025-07-07T06:34:49.877 FALSE 1400 111d1f9c-6352-47ec-98f5-bc2cb60bcb55
148261 e5278079-7d6a-46b4-b844-4be4e4c0d344 ZP Zooplankton 2025-07-07T18:17:15.013 FALSE 1400 111d1f9c-6352-47ec-98f5-bc2cb60bcb55
Code to import icesStation_DTYPE.
dbWriteTable(con_diaspara, "Station_DTYPE", Station_DTYPE)
dbExecute(con_diaspara, 'ALTER TABLE "Station_DTYPE" SET SCHEMA ref;')  
dbExecute(con_diaspara, 
          'ALTER TABLE ref."Station_DTYPE" ADD CONSTRAINT station_dtype_pkey PRIMARY KEY ("Key");') 

3.27.6 WLTYP

Code to show ices WLTYP.
WLTYP <- getCodeList("WLTYP")
knitr::kable(WLTYP)|>
  kable_styling(bootstrap_options = c("striped", "hover", "condensed"))
Table 34: Water and Land Station Type
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
266932 976fc2af-a21c-47ad-820f-98b684e01bcd CL Coastal lagoons 2026-02-10T10:02:49.497 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
Code to import ices WLTYP.
dbExecute(con_diaspara, 'DROP TABLE IF EXISTS ref."WLTYP";')
WLTYP$Key[is.na(WLTYP$Key)] <- "NA"
dbWriteTable(con_diaspara, "WLTYP", WLTYP)
dbExecute(con_diaspara, 
          'ALTER TABLE "WLTYP" SET SCHEMA ref;') 
dbExecute(con_diaspara, 
          'ALTER TABLE ref."WLTYP" ADD CONSTRAINT wltype_pkey PRIMARY KEY ("Key");') 

3.27.7 MSTAT

Code to show ices MSTAT.
MSTAT <- getCodeList("MSTAT")
knitr::kable(MSTAT)|>
  kable_styling(bootstrap_options = c("striped", "hover", "condensed"))
Table 35: Type of monitoring station
Id Guid Key Description LongDescription Modified Deprecated CodeTypeID CodeTypeGUID
51864 35cd7508-3e7b-47a9-9b5d-ba043280e22e B WFD B - Baseline/Reference station 2024-11-28T09:24:46.697 FALSE 177 358203dc-6df5-4bc0-9da5-328f98fd618a
53326 00b2cc8b-aefa-4823-bbfc-6e6710f2a5c8 ID Impacted directly from disruptions such as dredging or trawling 2025-04-07T14:18:53.457 FALSE 177 358203dc-6df5-4bc0-9da5-328f98fd618a
53325 57914639-50a3-4d7c-8fbd-cfd662ad76e9 IH WFD I(HZ) - Impacted directly by discharges containing hazardous substances 2024-11-28T07:51:56.923 FALSE 177 358203dc-6df5-4bc0-9da5-328f98fd618a
53810 fb7f3e57-3392-4b55-8077-5b3da96d7900 IH-A where impact is aluminum industry (primary) (nature of the industry, not to the impacted area) 2006-10-23T12:00:00 FALSE 177 358203dc-6df5-4bc0-9da5-328f98fd618a
53811 7931ff8a-4257-4d19-a8e5-8bdf2060db93 IH-C where impact is chemical/pharmaceutical industry 2021-09-20T11:45:40.753 FALSE 177 358203dc-6df5-4bc0-9da5-328f98fd618a
54097 1bdcff7c-10b3-4c71-b6fd-87cd51ac9e26 IH-D dock where impact is antifoulants, fuel oil/petroleum products 2024-08-26T12:34:32.227 FALSE 177 358203dc-6df5-4bc0-9da5-328f98fd618a
53814 7774858e-2b82-4457-b5a3-cb07a613fba9 IH-E where impact is surface treatment/electroplating 2006-10-23T12:00:00 FALSE 177 358203dc-6df5-4bc0-9da5-328f98fd618a
53815 c14296ec-08ea-443d-8128-077f53bde913 IH-F where impact is phosphogypsum-fertilizers 2006-10-23T12:00:00 FALSE 177 358203dc-6df5-4bc0-9da5-328f98fd618a
54098 28ccc88f-0f1e-4557-989e-21a097203f6d IH-H harbour where impact is antifoulants, fuel oil/petroleum products 2023-08-30T06:25:25.753 FALSE 177 358203dc-6df5-4bc0-9da5-328f98fd618a
53816 a6f885b4-87b3-4bee-b4c0-4822fd459699 IH-I where impact is iron and steel industry (primary) (nature of the industry, not to the impacted area) 2022-01-06T13:08:53.717 FALSE 177 358203dc-6df5-4bc0-9da5-328f98fd618a
53817 27eca6da-1b91-47b3-8758-3622b40dcf38 IH-M where impact is metal industry (non-ferrous) 2016-08-14T01:52:44.027 FALSE 177 358203dc-6df5-4bc0-9da5-328f98fd618a
53818 98d3b8cd-0ea4-407d-bee4-28938d432c51 IH-O where impact is oil/gas exploration/production platform 2023-01-27T03:30:16.64 FALSE 177 358203dc-6df5-4bc0-9da5-328f98fd618a
53819 6bd5f9c1-46cc-47b7-b151-f9590a1c9862 IH-P where impact is paper and pulp industry 2019-10-23T11:15:03.78 FALSE 177 358203dc-6df5-4bc0-9da5-328f98fd618a
53820 9a3e08c1-ecee-48ad-97bd-d94af2fa6603 IH-S where impact is iron and steel industry (secondary) (nature of the industry, not to the impacted area) 2006-10-23T12:00:00 FALSE 177 358203dc-6df5-4bc0-9da5-328f98fd618a
54099 6544bdd0-a2c6-45ae-bf9f-dbe1ab63319d IH-W where impact is from diffuse emissions from waste incineration 2017-04-03T20:51:30.467 FALSE 177 358203dc-6df5-4bc0-9da5-328f98fd618a
51865 74356f36-785b-454b-b83a-7aa6a102ae3a IP WFD I(PHY) - Impacted directly by discharges affecting physico-chemical conditions 2019-10-23T11:14:12.907 FALSE 177 358203dc-6df5-4bc0-9da5-328f98fd618a
53822 3ab88ae3-e7f4-424b-89bb-d1fe8c57753e IP-B where impact is fossil fuel burning/non-nuclear power plant 2016-08-14T01:52:43.363 FALSE 177 358203dc-6df5-4bc0-9da5-328f98fd618a
53823 a92b6a9a-d5f2-4d78-b37b-eaa996c10f3c IP-N where impact is nuclear power plant 2006-10-23T12:00:00 FALSE 177 358203dc-6df5-4bc0-9da5-328f98fd618a
53824 75b8b6e4-7a79-4367-9094-648740baa137 IP-T where impact is municipal waste water treatment plant 2024-11-28T07:58:57.637 FALSE 177 358203dc-6df5-4bc0-9da5-328f98fd618a
53324 ceb0b857-171a-49cc-84c6-49aa38e09590 RH WFD R(HZ) - Representative of general conditions in terms of hazardous substances 2025-07-07T18:15:43.513 FALSE 177 358203dc-6df5-4bc0-9da5-328f98fd618a
53289 08354400-b079-4773-af80-134243623425 RP WFD R(PHY) - Representative of general conditions for nutrients/organic matter 2025-07-07T06:33:52.457 FALSE 177 358203dc-6df5-4bc0-9da5-328f98fd618a
Code to import ices MSTAT.
dbWriteTable(con_diaspara, "MSTAT", MSTAT)
dbExecute(con_diaspara, 
          'ALTER TABLE ref."MSTAT" ADD CONSTRAINT mstat_pkey PRIMARY KEY ("Key");')   

3.27.8 Deprecated

Code to show ices Deprecated.
Deprecated <- getCodeList("Deprecated")
knitr::kable(Deprecated)|>
  kable_styling(bootstrap_options = c("striped", "hover", "condensed"))
Table 36: Deprecated
Id Guid Key Description LongDescription Modified Deprecated CodeTypeID CodeTypeGUID
169654 1f2a621c-b427-4aea-b66a-03437d3217bd False Not deprecated 2017-02-27T14:50:59.863 FALSE 1496 078d2a29-4f05-44a7-b115-743b2ed7ee4c
169655 0e88dd12-78b0-4ec6-a3e1-2178e0b22f2a True Deprecated 2017-02-27T14:50:38.56 FALSE 1496 078d2a29-4f05-44a7-b115-743b2ed7ee4c

3.28 Fishway type ref.tr_fishway_fiw

Exchanges with ICES on the development of a format for the trait dataset have shown the need to either standardize the content of some of the columns describing the series. This has been done either through removing some columns in the table describing the location, or protocols and replacing them with a writted document attached with a DOI (a reference to a document online on the ICES website describing each of the series). Other elements, like fishway have been standardised.

SQL code to create table tr_fishway_fiw
-- this is a new referential

DROP TABLE IF EXISTS ref.tr_fishway_fiw;
CREATE TABLE ref.tr_fishway_fiw (
fiw_code TEXT PRIMARY KEY,
fiw_description TEXT,
fiw_definition TEXT,
fiw_icesvalue character varying(4),  
fiw_icesguid uuid,
fiw_icestablesource text);
DELETE FROM ref.tr_fishway_fiw;
INSERT INTO ref.tr_fishway_fiw (fiw_code, fiw_description, fiw_definition)
VALUES('VS', 
'Vertical slot fishway', 
'Vertical Slot Fishways have top-to-bottom opening (slot) in the cross-wall by which water flows between pools, they are adapted to wide variations in water level.');
INSERT INTO ref.tr_fishway_fiw (fiw_code, fiw_description, fiw_definition)
VALUES('PO', 
'Pool', 
'A pool pass consists of a stepped channel divided by cross-walls that form a series of pools, where water flows through submerged or surface openings, allowing fish to rest between short bursts through higher-velocity zones. The rough bottom and calm pools make it especially suitable for both swimming and bottom-dwelling species.');
INSERT INTO ref.tr_fishway_fiw (fiw_code, fiw_description, fiw_definition)
VALUES('FL', 
'Fish lock', 
'A fish lock, similar in structure to a ship lock, uses a lock chamber with inlet and outlet gates to help fish ascend past barriers; unlike ship locks, it is specifically designed to support fish migration by addressing issues like turbulence, timing, and the need for a guiding current. While ship locks generally cannot replace fish passes, they can sometimes be adapted during peak migration seasons to aid species like salmon or glass eels.');
INSERT INTO ref.tr_fishway_fiw (fiw_code, fiw_description, fiw_definition)
VALUES('D', 
'Denil pass', 
'compact, steeply sloped fish pass featuring angled baffles that create backflows to reduce water velocity, enabling fish to ascend over moderate height differences. Its prefabricated design and efficient energy dissipation make it ideal for retrofitting existing dams with limited space, with the standard U-shaped baffle version now widely used.');
INSERT INTO ref.tr_fishway_fiw (fiw_code, fiw_description, fiw_definition)
VALUES('RR', 
'Rock ramp', 
'Close-to_nature type, gently sloped rough-surfaced sill spanning the river width with a gentle slope, designed to overcome riverbed level differences; it may include stabilizing structures like weirs if they share similar sloped, loose construction.');
INSERT INTO ref.tr_fishway_fiw (fiw_code, fiw_description, fiw_definition)
VALUES('ER', 
'Eel ramp', 
'Eel ladders/ramps, e.g., pipe-based systems laid through weirs and filled with baffles or brushwood to slow flow, shallow channels fitted with brush or gravel structures that help eels ascend while offering better visibility, maintenance, and protection from predators.');
INSERT INTO ref.tr_fishway_fiw (fiw_code, fiw_description, fiw_definition)
VALUES('LA', 
'Lateral canal', 
'Bybass channel that uses lateral canals');
INSERT INTO ref.tr_fishway_fiw (fiw_code, fiw_description, fiw_definition)
VALUES('AR', 
'Artificial river', 
'Human-made channel designed to mimic the characteristics of a natural stream, allowing fish to bypass barriers like dams. These fishways typically feature a gentle slope, varied flow conditions, resting areas, and natural substrates (like gravel and rocks, trees, bushes, etc.)');
INSERT INTO ref.tr_fishway_fiw (fiw_code, fiw_description, fiw_definition)
VALUES('UN', 
'Unknown', 
'Unknown type fish passage');
INSERT INTO ref.tr_fishway_fiw (fiw_code, fiw_description, fiw_definition)
VALUES('S', 
'Sluice', 
'Periodically opening sluice gates that creates a strong, directed flow that attracts and allows fish to pass. ');
INSERT INTO ref.tr_fishway_fiw (fiw_code, fiw_description, fiw_definition)
VALUES('HL', 
'Hydraulic lift', 
'A type of fish elevator that uses hydraulic mechanisms—such as pumps, valves, and water pressure—to move fish over high barriers like dams.');


ALTER TABLE ref.tr_fishway_fiw OWNER TO diaspara_admin;
GRANT SELECT ON ref.tr_fishway_fiw  TO diaspara_read;


COMMENT ON TABLE ref.tr_fishway_fiw IS 'Table of fishway type';
COMMENT ON COLUMN ref.tr_fishway_fiw.fiw_code IS 'Code for fishway type';
COMMENT ON COLUMN ref.tr_fishway_fiw.fiw_description IS 'Description of the fishway';
COMMENT ON COLUMN ref.tr_fishway_fiw.fiw_definition IS 'Definition of the fishway';
COMMENT ON COLUMN ref.tr_fishway_fiw.fiw_icesvalue IS 'Code for the fishwat in the ICES database';
COMMENT ON COLUMN ref.tr_fishway_fiw.fiw_icesguid IS 'GUID in the ICES database';
Code to show fishway table (to be imported in ICES vocab).
habitat <- dbGetQuery(con_diaspara, "SELECT * FROM ref.tr_fishway_fiw;")
knitr::kable(habitat)|>
  kable_styling(bootstrap_options = c("striped", "hover", "condensed"))
Table 37: Fishway vocab proposed to ICES.
fiw_code fiw_description fiw_definition fiw_icesvalue fiw_icesguid fiw_icestablesource
VS Vertical slot fishway Vertical Slot Fishways have top-to-bottom opening (slot) in the cross-wall by which water flows between pools, they are adapted to wide variations in water level. NA NA NA
PO Pool A pool pass consists of a stepped channel divided by cross-walls that form a series of pools, where water flows through submerged or surface openings, allowing fish to rest between short bursts through higher-velocity zones. The rough bottom and calm pools make it especially suitable for both swimming and bottom-dwelling species. NA NA NA
FL Fish lock A fish lock, similar in structure to a ship lock, uses a lock chamber with inlet and outlet gates to help fish ascend past barriers; unlike ship locks, it is specifically designed to support fish migration by addressing issues like turbulence, timing, and the need for a guiding current. While ship locks generally cannot replace fish passes, they can sometimes be adapted during peak migration seasons to aid species like salmon or glass eels. NA NA NA
D Denil pass compact, steeply sloped fish pass featuring angled baffles that create backflows to reduce water velocity, enabling fish to ascend over moderate height differences. Its prefabricated design and efficient energy dissipation make it ideal for retrofitting existing dams with limited space, with the standard U-shaped baffle version now widely used. NA NA NA
RR Rock ramp Close-to_nature type, gently sloped rough-surfaced sill spanning the river width with a gentle slope, designed to overcome riverbed level differences; it may include stabilizing structures like weirs if they share similar sloped, loose construction. NA NA NA
ER Eel ramp Eel ladders/ramps, e.g., pipe-based systems laid through weirs and filled with baffles or brushwood to slow flow, shallow channels fitted with brush or gravel structures that help eels ascend while offering better visibility, maintenance, and protection from predators. NA NA NA
LA Lateral canal Bybass channel that uses lateral canals NA NA NA
AR Artificial river Human-made channel designed to mimic the characteristics of a natural stream, allowing fish to bypass barriers like dams. These fishways typically feature a gentle slope, varied flow conditions, resting areas, and natural substrates (like gravel and rocks, trees, bushes, etc.) NA NA NA
UN Unknown Unknown type fish passage NA NA NA
S Sluice Periodically opening sluice gates that creates a strong, directed flow that attracts and allows fish to pass. NA NA NA
HL Hydraulic lift A type of fish elevator that uses hydraulic mechanisms—such as pumps, valves, and water pressure—to move fish over high barriers like dams. NA NA NA

3.29 Fish migration monitoring ref.tr_monitoring_mon

A monitoring device can be a trap or a camera in a fishway, or any tools used to sample or monitor the migration. If the migration is monitored as part of a fishing operation (sampling on a barrier or fyke net used for commercial fishery), then it is possible to use the gear type column and ignore the monitoring column. The monitoring device are attached to scientific monitoring, mostly in fishways, but devices likes accoustic sonars make exception.

SQL code to create table tr_monitoring_mon
-- this is a new referential

DROP TABLE IF EXISTS ref.tr_monitoring_mon;
CREATE TABLE ref.tr_monitoring_mon (
mon_code TEXT PRIMARY KEY,
mon_description TEXT,
mon_definition TEXT,
mon_icesvalue character varying(4),  
mon_icesguid uuid,
mon_icestablesource text);
DELETE FROM ref.tr_monitoring_mon;
INSERT INTO ref.tr_monitoring_mon (mon_code, mon_description, mon_definition)
VALUES('SO', 
'Sonar HF', 
'Multibeam, high frequency sonar used to monitor fish migration, e.g. Didson, Aris, Blueview, Occulus ....');
INSERT INTO ref.tr_monitoring_mon (mon_code, mon_description, mon_definition)
VALUES('TR', 
'Trap', 
'Trap used to catch a part or the whole run. Fish can be directed towards the trap with a system of grids,
or within a fishway. The fishes are counted and measured and then released, most often to continue their migration,
upstream or downstream from the trap.');
INSERT INTO ref.tr_monitoring_mon (mon_code, mon_description, mon_definition)
VALUES('VR', 
'Video recording', 
'Video recording of the fish used to make specific identification, and measure the length and direction of passage.
The video is often located in a narrow passage within a fishway, often also with light set in the background.');
INSERT INTO ref.tr_monitoring_mon (mon_code, mon_description, mon_definition)
VALUES('RC', 
'Resistivity counter', 
'Resistivity counters monitor the resistance between electrodes to detect the passage of a fish.
The lower resistance of the fish compared to the water is used to detect the passage. 
A series of submerged electrodes are used to detect the direction. Automatic
adjustment of the sensitivity of the counter ensures that the sizes into which fish are
classified remains consistent.');
INSERT INTO ref.tr_monitoring_mon (mon_code, mon_description, mon_definition)
VALUES('AC', 
'Telemetry', 
'e.g., Acoustic, PIT, or radiotelemetry receivers are use in fish tracking to detect and decode transmissions from fish tags');
INSERT INTO ref.tr_monitoring_mon (mon_code, mon_description, mon_definition)
VALUES('IR', 
'Infrared counter', 
'Counter that uses infrared, e.g., Vaki Riverwatcher');






ALTER TABLE ref.tr_monitoring_mon OWNER TO diaspara_admin;
GRANT SELECT ON ref.tr_monitoring_mon  TO diaspara_read;


COMMENT ON TABLE ref.tr_monitoring_mon IS 'Table of monitoring devices. 
A monitoring device is used to monitor fish passage. It can be attached to a fishway. 
A fishway can have several monitoring devices, e.g. a trap and a video recording. 
A monitoring device can also be placed without fishway , e.g. a sonar, an accoustic receiver.';
COMMENT ON COLUMN ref.tr_monitoring_mon.mon_code IS 'Code for monitoring type';
COMMENT ON COLUMN ref.tr_monitoring_mon.mon_description IS 'Description of the monitoring device';
COMMENT ON COLUMN ref.tr_monitoring_mon.mon_definition IS 'Definition of the monitoring device';
COMMENT ON COLUMN ref.tr_monitoring_mon.mon_icesvalue IS 'Code for the fishwat in the ICES database';
COMMENT ON COLUMN ref.tr_monitoring_mon.mon_icesguid IS 'GUID in the ICES database';
Code to show fishway table (to be imported in ICES vocab).
habitat <- dbGetQuery(con_diaspara, 
                      "SELECT * FROM ref.tr_monitoring_mon;")
knitr::kable(habitat)|>
  kable_styling(bootstrap_options = c("striped", "hover", "condensed"))
Table 38: Fishway vocab proposed to ICES.
mon_code mon_description mon_definition mon_icesvalue mon_icesguid mon_icestablesource
SO Sonar HF Multibeam, high frequency sonar used to monitor fish migration, e.g. Didson, Aris, Blueview, Occulus .... NA NA NA
TR Trap Trap used to catch a part or the whole run. Fish can be directed towards the trap with a system of grids, or within a fishway. The fishes are counted and measured and then released, most often to continue their migration, upstream or downstream from the trap. |NA |NA |NA
VR Video recording Video recording of the fish used to make specific identification, and measure the length and direction of passage. The video is often located in a narrow passage within a fishway, often also with light set in the background. |NA |NA |NA
RC Resistivity counter Resistivity counters monitor the resistance between electrodes to detect the passage of a fish. The lower resistance of the fish compared to the water is used to detect the passage. A series of submerged electrodes are used to detect the direction. Automatic adjustment of the sensitivity of the counter ensures that the sizes into which fish are classified remains cons stent. |NA |NA |NA
AC Telemetry e.g., Acoustic, PIT, or radiotelemetry receivers are use in fish tracking to detect and decode transmissions from fish tags NA NA NA
IR Infrared counter Counter that uses infrared, e.g., Vaki Riverwatcher NA NA NA
OC Other catching methods Any other type of fish catching method than a trap. E.g. rod, gillnet, etc. NA NA NA
VC Visual count Visual fish counting methods, not including with the use of cameras NA NA NA
IQ Interview or questionnaire Interview or questionnaire of e.g. recreational fishers or other parties NA NA NA
MK Mark and Recapture Mark and recapture methods NA NA NA
CD Catch data Recreational or commercial fisheries catch data NA NA NA

3.30 Fish Traits ref.tr_trait_tra

Trait is referring to a characteristics of a fish (there are different method, or different measurements for different species). The trait can be, either qualitative or quantitative. The trait is measured by a method, the measure (either categorical eg. sex = ‘Male’) or quantitative e.g. (length_mm = 150) might be accompanied by a method. For instance a fish is measured for length as fork length or total length, in the individual_trait table, the fish will be related to three columns, the code of the length parameter in the trait table, the quantitative value, and the method used.

SQL code to create tables ref.tr_trait_tra and refeel.tg_trait_tra
-- DROP TABLE ref.tr_trait_tra CASCADE;

CREATE TABLE ref.tr_trait_tra (
  tra_id integer PRIMARY KEY,
  tra_code text NOT NULL,
  tra_description text NULL, 
  tra_wkg_code TEXT NOT NULL,  
  CONSTRAINT fk_tra_wkg_code  FOREIGN KEY (tra_wkg_code)
  REFERENCES ref.tr_icworkinggroup_wkg(wkg_code)
  ON UPDATE CASCADE ON DELETE RESTRICT,
  tra_spe_code TEXT NOT NULL,  
  CONSTRAINT fk_tra_spe_code  FOREIGN KEY (tra_spe_code)
  REFERENCES ref.tr_species_spe(spe_code)
  ON UPDATE CASCADE ON DELETE RESTRICT,
  tra_indivorgroup text NULL,
  CONSTRAINT ck_tra_indivorgroup CHECK (((tra_indivorgroup = 'Individual'::text) 
  OR (tra_indivorgroup = 'Group'::text) 
  OR (tra_indivorgroup = 'Both'::text))),
  tra_qualitativeornumeric TEXT,
  CONSTRAINT ck_tra_qualitativeornumeric CHECK ((tra_qualitativeornumeric = 'Qualitative'::text) 
  OR (tra_qualitativeornumeric = 'Numeric'::text)),
  CONSTRAINT uk_tra_code UNIQUE (tra_code)
);


COMMENT ON COLUMN ref.tr_trait_tra.tra_id IS 
'Integer, id of the trait';
COMMENT ON COLUMN ref.tr_trait_tra.tra_code IS
 'Name of the trait';
COMMENT ON COLUMN ref.tr_trait_tra.tra_description IS
 'Description of the fish trait';
COMMENT ON COLUMN ref.tr_trait_tra.tra_indivorgroup IS 
'Is the metric a group metric (group), or individual metric (individual) or can be used in both tables (both) ?';
COMMENT ON COLUMN ref.tr_trait_tra.tra_qualitativeornumeric IS
 'Indicate variable type, either Qualitative or Numeric';
COMMENT ON COLUMN ref.tr_trait_tra.tra_spe_code IS
 'AphiaID of the species code TEXT (e.g''127186'' Salmo salar )';


GRANT ALL ON ref.tr_trait_tra TO diaspara_admin;
GRANT SELECT ON ref.tr_trait_tra TO diaspara_read; 

/*
note The refeel.tg_trait_tra actually contains physically all parms and that's not the case of
ref.tr_trait_tra which only gets those by inheritance.
refeel.tg_trait_tra must be created after insertion in tr_traitnumeric_trn
and tr_traitqualitative_trq
*/

CREATE TABLE refeel.tg_trait_tra AS (
SELECT  
  tra_id,
  tra_code,
  tra_description, 
  tra_wkg_code,  
  tra_spe_code , 
  tra_indivorgroup,
  tra_qualitativeornumeric FROM 
  refeel.tr_traitnumeric_trn
UNION
SELECT  
  tra_id,
  tra_code,
  tra_description, 
  tra_wkg_code,  
  tra_spe_code , 
  tra_indivorgroup,
  tra_qualitativeornumeric FROM 
  refeel.tr_traitqualitative_trq);
ALTER TABLE refeel.tg_trait_tra 
ADD  CONSTRAINT uk_tra_code UNIQUE (tra_code);

3.31 Numeric fish trait (tr_traitnumeric_trn)

Trait can be either qualitative or quantitative (numeric). Both tables are inherited from tr_trait_tra.

SQL code to create tables ref.tr_traitnumeric_trn and refeel.tr_traitnumeric_trn
-- DROP TABLE IF EXISTS ref.tr_traitnumeric_trn;
CREATE TABLE ref.tr_traitnumeric_trn(  
trn_uni_code varchar(20) NULL,
trn_minvalue NUMERIC,
trn_maxvalue NUMERIC,
  CONSTRAINT fk_tra_wkg_code  FOREIGN KEY (tra_wkg_code)
  REFERENCES ref.tr_icworkinggroup_wkg(wkg_code)
  ON UPDATE CASCADE ON DELETE RESTRICT,
  CONSTRAINT fk_tra_spe_code  FOREIGN KEY (tra_spe_code)
  REFERENCES ref.tr_species_spe(spe_code)
  ON UPDATE CASCADE ON DELETE RESTRICT, 
  CONSTRAINT fk_trn_uni_code FOREIGN KEY (trn_uni_code) 
  REFERENCES ref.tr_units_uni(uni_code)   ON UPDATE CASCADE ON DELETE CASCADE,
  CONSTRAINT uk_trn_code UNIQUE (tra_code)
) INHERITS  (ref.tr_trait_tra);

COMMENT ON COLUMN ref.tr_traitnumeric_trn.tra_id IS
 'Integer, id of the trait';
COMMENT ON COLUMN ref.tr_traitnumeric_trn.tra_code IS
 'Name of the trait';
COMMENT ON COLUMN ref.tr_traitnumeric_trn.tra_description IS
 'Description of the fish trait';
COMMENT ON COLUMN ref.tr_traitnumeric_trn.tra_indivorgroup IS
 'Is the metric a Group metric (group), or Individual metric (individual) or can be used in both tables (both) ?';
COMMENT ON COLUMN ref.tr_traitnumeric_trn.trn_uni_code IS
 'Unit used, references tr_unit_uni';
COMMENT ON COLUMN ref.tr_traitnumeric_trn.trn_minvalue IS
 'Minimum allowed value';
COMMENT ON COLUMN ref.tr_traitnumeric_trn.trn_maxvalue IS
 'Maximum allowed value';


GRANT ALL ON ref.tr_traitnumeric_trn TO diaspara_admin;
GRANT SELECT ON ref.tr_traitnumeric_trn TO diaspara_read; 


DROP TABLE IF EXISTS refeel.tr_traitnumeric_trn;
CREATE TABLE refeel.tr_traitnumeric_trn(  
  CONSTRAINT uk_refeel_tra_id UNIQUE (tra_id),
  CONSTRAINT uk_refell_tra_code UNIQUE(tra_code),
  CONSTRAINT fk_tra_wkg_code  FOREIGN KEY (tra_wkg_code)
  REFERENCES ref.tr_icworkinggroup_wkg(wkg_code)
  ON UPDATE CASCADE ON DELETE RESTRICT,
  CONSTRAINT fk_tra_spe_code  FOREIGN KEY (tra_spe_code)
  REFERENCES ref.tr_species_spe(spe_code)
  ON UPDATE CASCADE ON DELETE RESTRICT, 
  CONSTRAINT fk_trn_uni_code FOREIGN KEY (trn_uni_code) 
  REFERENCES ref.tr_units_uni(uni_code)  
  ON UPDATE CASCADE ON DELETE CASCADE,
  CONSTRAINT uk_trn_code UNIQUE (tra_code)
) INHERITS  (ref.tr_traitnumeric_trn);

COMMENT ON COLUMN refeel.tr_traitnumeric_trn.tra_id IS
 'Integer, id of the trait';
COMMENT ON COLUMN refeel.tr_traitnumeric_trn.tra_code IS 
'Name of the trait';
COMMENT ON COLUMN refeel.tr_traitnumeric_trn.tra_description IS
 'Description of the fish trait';
COMMENT ON COLUMN refeel.tr_traitnumeric_trn.tra_indivorgroup IS
 'Is the metric a Group metric (group), or Individual metric (individual) or can be used in both tables (both) ?';
COMMENT ON COLUMN refeel.tr_traitnumeric_trn.trn_uni_code IS
 'Unit used, references tr_unit_uni';
COMMENT ON COLUMN refeel.tr_traitnumeric_trn.trn_minvalue IS
 'Minimum allowed value';
COMMENT ON COLUMN refeel.tr_traitnumeric_trn.trn_maxvalue IS 
'Maximum allowed value';


GRANT ALL ON refeel.tr_traitnumeric_trn TO diaspara_admin;
GRANT SELECT ON refeel.tr_traitnumeric_trn TO diaspara_read; 
Code to import numeric trait.
tra <- dbGetQuery(con_wgeel_local, "SELECT * FROM ref.tr_traittype_mty ;")
# we will include group trait names later
tra <- tra[(!grepl("mean", tra$mty_name) | 
              tra$mty_name =='eye_diam_meanmm' |
              tra$mty_name == 'teq'),]
# we will also include method later
tra <- tra[!grepl("method", tra$mty_name),]
res <- dbGetQuery(con_diaspara, "SELECT * FROM ref.tr_trait_tra")
#clipr::write_clip(colnames(res))
tranum <- data.frame(
  "tra_id" = tra$mty_id,
  "tra_code" = stringi::stri_trans_totitle(tra$mty_name),
  "tra_description" = tra$mty_description,
  "tra_wkg_code" = 'WGEEL',
  "Tra_spe_code" = 'ANG',
  "trn_uni_code" = tra$mty_uni_tra_indivorgroup"=stringi::stri_trans_totitle(tra$mty_group),
  "tra_qualitativeornumeric"='Numeric',
  "trn_minvalue" = tra$mty_min,
  "trn_maxvalue" = tra$mty_max)


# the proportions will be numeric for group and qualitative for individual (
# e.g. evex presence)

tranum$tra_indivorgroup=="Both" & grepl("proportion",tranum$tra_code),
  tra_indivorgroup")] <- "Group"


# view(tranum)
# fix names
tranum$tra_description[tranum$tra_code=="Lengthmm"] <-
  'Total body length in millimeters (mm) or mean total body length for group'
tranum$tra_description[tranum$tra_code=="Differentiated_proportion"] <-
  'Proportion of differentiated eel (between 0 and 1)'

tranum$tra_description[tranum$tra_code=="Female_proportion"] <-
  'Female proportion in the population female/(male+female) for group (between 0 and 1)'
tranum$tra_description[tranum$tra_code=="Anguillicola_proportion"] <-
  'Prevalence of Anguillicola in proportion in group (between 0 and 1)'
tranum$tra_description[tranum$tra_code=="Evex_proportion"] <-
  'EVE and EVEX proportion in the group (between 0 and 1)'
tranum$tra_description[tranum$tra_code=="Hva_proportion"] <-
  'HVA proportion in the group (between 0 and 1)'
# duplicated, now two methods
tranum <- tranum[tranum$tra_id!=11,] 
tranum$tra_description[tranum$tra_id==10] <-
  "Lipid percentage or mean muscle lipid percentage for group"
tranum[tranum$tra_id==10,"tra_code"] <- "Muscle_lipid"

dbWriteTable(con_diaspara_admin, "tr_traitnumeric_trn_temp", tranum, overwrite =TRUE)
dbExecute(con_diaspara_admin, "DELETE FROM refeel.tr_traitnumeric_trn")
dbExecute(con_diaspara_admin, "INSERT INTO refeel.tr_traitnumeric_trn(
tra_id,
tra_code,
tra_wkg_code,
tra_spe_code,
tra_descritra_indivorgroup,
trn_uni_code,
tra_qualitativeornumeric,
trn_minvalue,
trn_maxvalue)
SELECT 
tra_id,
tra_code,
'WGEEL',
'ANG',
tra_descritra_indivorgroup,
trn_uni_code,
tra_qualitativeornumeric,
trn_minvalue,
trn_maxvalue
 FROM tr_traitnumeric_trn_temp") #18


dbExecute(con_diaspara_admin, 
          "INSERT INTO refeel.tr_traitnumeric_trn (tra_id,tra_code,tra_description,
 tra_wkg_code,tra_stra_indivorgroup,
 tra_qualitativeornumeric,
 trn_uni_code,trn_minvalue,trn_maxvalue)
    VALUES (27,'Eye_diam_vert_mm','Eye diameter (vertical) in mm','WGEEL',
  'ANG','Individual','Numeric','mm',1,15);
INSERT INTO refeel.tr_traitnumeric_trn (tra_id,tra_code,tra_description,
tra_wkg_code,tra_stra_indivorgroup,tra_qualitativeornumeric,
trn_uni_code,trn_minvalue,trn_maxvalue)
    VALUES (28,'Eye_diam_horiz_mm','Eye diameter (horizontal) in mm',
  'WGEEL','ANG','Individual','Numeric','mm',1,15);
") #18


dbExecute(con_diaspara_admin,  "UPDATE refeel.tr_traitnumeric_trn
    SET tra_code='Eye_diam_mean_mm'
    WHERE tra_id=4;")
Table 39: Quantitative parameters parameters
tra_id tra_code tra_description tra_wkg_code tra_spe_code tra_indivorgroup tra_qualitativeornumeric trn_uni_code trn_minvalue trn_maxvalue
1 Lengthmm Total body length in millimeters (mm) or mean total body length for group WGEEL 126281 Both Numeric mm 50.0 1500
2 Weightg Weight (g) or mean weight for group WGEEL 126281 Both Numeric g 0.1 3000
3 Ageyear Age (year) or mean age for group WGEEL 126281 Both Numeric nr year 0.0 75
5 Pectoral_lengthmm Pectoral fin length (mm) WGEEL 126281 Individual Numeric mm 3.0 54
7 Differentiated_proportion Proportion of differentiated eel (between 0 and 1) WGEEL 126281 Group Numeric wo 0.0 1
9 Anguillicola_intensity A. crassus intensity or mean A. crassus intensity for group WGEEL 126281 Both Numeric nr 0.0 NA
10 Muscle_lipid Lipid percentage or mean muscle lipid percentage for group WGEEL 126281 Both Numeric percent 0.0 NA
12 Sum_6_pcb Sum of six PCBs or mean sum of six PCBs for groups WGEEL 126281 Both Numeric ng/g 0.0 NA
13 Evex_proportion EVE and EVEX proportion in the group (between 0 and 1) WGEEL 126281 Group Numeric wo 0.0 1
14 Hva_proportion HVA proportion in the group (between 0 and 1) WGEEL 126281 Group Numeric wo 0.0 1
15 Pb Lead (Pb) concentration or mean lead (Pb) concentration WGEEL 126281 Both Numeric ng/g 0.0 NA
16 Hg Mercury (Hg) concentration or mean lead (Pb) concentration for group WGEEL 126281 Both Numeric ng/g 0.0 NA
17 Cd Cadmium (Cd) concentration or mean cadmium concentration for group WGEEL 126281 Both Numeric ng/g 0.0 NA
24 G_in_gy_proportion Proportion of glass eel in number during the season when the series is a grouping of glass and yellow eels WGEEL 126281 Group Numeric wo 0.0 1
25 S_in_ys_proportion Proportion of silver eel in number in the group WGEEL 126281 Group Numeric wo 0.0 1
26 Teq Sum TEQ of measured dioxin-like PCBs or mean sum TEQ of measured dioxin-like PCBs WGEEL 126281 Both Numeric ng/g 0.0 NA
6 Female_proportion Female proportion in the population female/(male+female) for group (between 0 and 1) WGEEL 126281 Group Numeric wo 0.0 1
8 Anguillicola_proportion Prevalence of Anguillicola in proportion in group (between 0 and 1) WGEEL 126281 Group Numeric wo 0.0 1
27 Eye_diam_vert_mm Eye diameter (vertical) in mm WGEEL 126281 Individual Numeric mm 1.0 15
28 Eye_diam_horiz_mm Eye diameter (horizontal) in mm WGEEL 126281 Individual Numeric mm 1.0 15
4 Eye_diam_mean_mm Eye diameter, or average of vertical and horizontal diameter (mm) WGEEL 126281 Individual Numeric mm 1.0 15

3.32 Qualitative fish trait (tr_traitqualitative_trq)

SQL code to create table ref.tr_traitqualitative_trq and refeel.tr_traitqualitative_trq
-- DROP TABLE IF EXISTS ref.tr_traitqualitative_trq CASCADE;

CREATE TABLE ref.tr_traitqualitative_trq (
  CONSTRAINT fk_tra_wkg_code  FOREIGN KEY (tra_wkg_code)
  REFERENCES ref.tr_icworkinggroup_wkg(wkg_code)
  ON UPDATE CASCADE ON DELETE RESTRICT,
  CONSTRAINT fk_tra_spe_code  FOREIGN KEY (tra_spe_code)
  REFERENCES ref.tr_species_spe(spe_code)
  ON UPDATE CASCADE ON DELETE RESTRICT,
  CONSTRAINT uk_trq_code UNIQUE (tra_code)
  ) INHERITS (ref.tr_trait_tra);


COMMENT ON TABLE ref.tr_traitqualitative_trq IS 
'Table of qualitative trait parameters';

GRANT ALL ON ref.tr_traitqualitative_trq TO diaspara_admin;
GRANT SELECT ON ref.tr_traitqualitative_trq TO diaspara_read; 

DROP TABLE IF EXISTS refeel.tr_traitqualitative_trq;
CREATE TABLE refeel.tr_traitqualitative_trq (
  CONSTRAINT uk_refeel_tra_id UNIQUE (tra_id),
  CONSTRAINT uk_refeel_tra_code UNIQUE(tra_code),
  CONSTRAINT fk_tra_wkg_code  FOREIGN KEY (tra_wkg_code)
  REFERENCES ref.tr_icworkinggroup_wkg(wkg_code)
  ON UPDATE CASCADE ON DELETE RESTRICT,
  CONSTRAINT fk_tra_spe_code  FOREIGN KEY (tra_spe_code)
  REFERENCES ref.tr_species_spe(spe_code)
  ON UPDATE CASCADE ON DELETE RESTRICT
  ) INHERITS (ref.tr_traitqualitative_trq);


COMMENT ON TABLE refeel.tr_traitqualitative_trq IS 
'Table of qualitative trait parameters';

GRANT ALL ON refeel.tr_traitqualitative_trq TO diaspara_admin;
GRANT SELECT ON refeel.tr_traitqualitative_trq TO diaspara_read; 

Code to import qualitative table.
tra <- dbGetQuery(con_wgeel_local, "SELECT * FROM ref.tr_traittype_mty ;")
# we will include group trait names later
tra <- tra[grepl("is_", tra$mty_individual_name) |
             grepl("presence", tra$mty_individual_name),]
# we will also include method later

#clipr::write_clip(colnames(res))
traqal <- data.frame(
  "tra_id" = tra$mty_id,
  "tra_code" = stringi::stri_trans_totitle(tra$mty_individual_name),
  "tra_description" = tra$mty_description,
  "tra_wkg_code" = 'WGEEL',
  "Tra_spe_code" = 'ANG',
  "tra_uni_code" = tra$mty_uni_code,
  "tra_typemetric"='Individual',
  "tra_qualitativeornumeric"='Qualitative'
)


# the proportions will be numeric for group and qualitative for individual (
# e.g. evex presence)

traqal$tra_code <- gsub("\\s*_\\([^\\)]+\\)", "", traqal$tra_code)
traqal$tra_code[traqal$tra_code=="Is_female"] <- "Sex"
traqal$tra_individualname <- traqal$tra_code

# fix names

traqal$tra_description[traqal$tra_code=="Is_differentiated"] <- 
  'Is the eel differentiated (Y Yes, N No, NA Not applicable,P probable, U Unknown)'
traqal$tra_description[traqal$tra_code=="Sex"] <-
  'Sex (F Female,
 H Hermaphordite,
I Immature attempt made,M Male, 
T Transitional, 
U Undetermined no attempt made, 
X Mixed)'
traqal$tra_description[traqal$tra_code=="Anguillicola_presence"] <-
  'Presence of Anguillicola (Y Yes, N No, NA Not applicable,P probable, U Unknown)'
traqal$tra_description[traqal$tra_code=="Evex_presence"] <-
  'EVE or EVEX presence (Y Yes, N No, NA Not applicable,P probable, U Unknown)'
traqal$tra_description[traqal$tra_code=="Hva_presence"] <-
  'HVA presence (Y Yes, N No, NA Not applicable,P probable, U Unknown)'
# view(traqal)

dbWriteTable(con_diaspara_admin, "tr_traitqualitative_trq_temp",
             traqal, overwrite =TRUE)
dbExecute(con_diaspara_admin, "DELETE FROM refeel.tr_traitqualitative_trq");
dbExecute(con_diaspara_admin, "INSERT INTO refeel.tr_traitqualitative_trq(
tra_id,
tra_code,
tra_wkg_code,
tra_spe_code,
tra_description,
tra_indivorgroup,
tra_qualitativeornumeric)
SELECT 
tra_id,
tra_code,
'WGEEL',
'ANG',
tra_description,
tra_indivorgroup,
tra_qualitativeornumeric
 FROM tr_traitqualitative_trq_temp") #5
# TODO add group name


dbExecute(con_diaspara_admin, "INSERT INTO refeel.tr_traitqualitative_trq(
tra_id,
tra_code,
tra_wkg_code,
tra_spe_code,
tra_description,
tra_indivorgroup,
tra_qualitativeornumeric)
SELECT 
29,
'Pigment_stage',
'WGEEL',
'ANG',
'Pigmentation stage according to Elie, 1982',
'Individual',
'Qualitative'") 
# duplicated for variables which were both group and 
dbExecute(con_diaspara_admin,
          "UPDATE refeel.tr_traitqualitative_trq SET tra_id = 34 
 WHERE tra_code='Hva_presence';")
dbExecute(con_diaspara_admin, 
          "UPDATE refeel.tr_traitqualitative_trq SET tra_id = 33 
WHERE tra_code='Evex_presence';")
dbExecute(con_diaspara_admin, 
          "UPDATE refeel.tr_traitqualitative_trq SET tra_id= 32 
WHERE tra_code='Anguillicola_presence';")
dbExecute(con_diaspara_admin, 
          "UPDATE refeel.tr_traitqualitative_trq SET tra_id= 31 
WHERE tra_code='Is_differentiated'")
dbExecute(con_diaspara_admin,
          "UPDATE refeel.tr_traitqualitative_trq SET tra_id= 30 
 WHERE tra_code='Sex';")
Table 40: Qualitative parameters
tra_id tra_code tra_description tra_wkg_code tra_spe_code tra_indivorgroup tra_qualitativeornumeric
29 Pigment_stage Pigmentation stage according to Elie, 1982 WGEEL 126281 Individual Qualitative
34 Hva_presence HVA presence (Y Yes, N No, NA Not applicable,P probable, U Unknown) WGEEL 126281 Individual Qualitative
33 Evex_presence EVE or EVEX presence (Y Yes, N No, NA Not applicable,P probable, U Unknown) WGEEL 126281 Individual Qualitative
32 Anguillicola_presence Presence of Anguillicola (Y Yes, N No, NA Not applicable,P probable, U Unknown) WGEEL 126281 Individual Qualitative
31 Is_differentiated Is the eel differentiated (Y Yes, N No, NA Not applicable,P probable, U Unknown) WGEEL 126281 Individual Qualitative
30 Sex Sex (F Female,H Hermaphordite, I Immature attempt made, M Male, T Transitional, U Undetermined no attempt made, X Mixed) WGEEL 126281 Individual Qualitative

3.33 Values of Qualitative fish trait (tr_traitvaluequal_trv)

The qualitative traits have a limited set of discrete values, this table contains the discrete values.

SQL code to create tables ref.tr_traitqualvalue_trv and refeel.tr_traitqualvalue_trv
-- DROP TABLE IF EXISTS ref.tr_traitvaluequal_trv CASCADE;

CREATE TABLE ref.tr_traitvaluequal_trv(
  trv_id INTEGER,
  trv_trq_code TEXT NOT NULL,
  CONSTRAINT fk_trv_trq_code 
  FOREIGN KEY (trv_trq_code)
  REFERENCES ref.tr_traitqualitative_trq(tra_code)
  ON UPDATE CASCADE ON DELETE CASCADE,
  trv_code text NOT NULL ,
  trv_description text NULL,
  trv_spe_code TEXT NOT NULL,
  CONSTRAINT fk_trv_spe_code  FOREIGN KEY (trv_spe_code)
  REFERENCES ref.tr_species_spe(spe_code)
  ON UPDATE CASCADE ON DELETE RESTRICT,
  trv_wkg_code TEXT NOT NULL,
  CONSTRAINT fk_trv_wkg_code  FOREIGN KEY (trv_wkg_code)
  REFERENCES ref.tr_icworkinggroup_wkg(wkg_code)
  ON UPDATE CASCADE ON DELETE RESTRICT,  
  CONSTRAINT uk_trv_code UNIQUE (trv_code, trv_trq_code,trv_wkg_code)
);


COMMENT ON COLUMN ref.tr_traitvaluequal_trv.trv_id IS
 'Integer, id of the qualitative used';
COMMENT ON COLUMN ref.tr_traitvaluequal_trv.trv_code IS
 'Code of the qualitative trait';
COMMENT ON COLUMN ref.tr_traitvaluequal_trv.trv_description IS
 'Description of the method';

GRANT ALL ON ref.tr_traitvaluequal_trv TO diaspara_admin;
GRANT SELECT ON ref.tr_traitvaluequal_trv TO diaspara_read; 

DROP TABLE IF EXISTS refeel.tr_traitvaluequal_trv CASCADE;
CREATE TABLE refeel.tr_traitvaluequal_trv(
  CONSTRAINT uk_trv_id UNIQUE (trv_id),
  CONSTRAINT fk_trv_trq_code 
  FOREIGN KEY (trv_trq_code)
    REFERENCES refeel.tr_traitqualitative_trq(tra_code)
      ON UPDATE CASCADE ON DELETE CASCADE,
  CONSTRAINT uk_refeel_trv_code UNIQUE (trv_code, trv_trq_code)
) INHERITS (ref.tr_traitvaluequal_trv);


COMMENT ON COLUMN refeel.tr_traitvaluequal_trv.trv_id IS
 'Integer, id of the qualitative used';
COMMENT ON COLUMN refeel.tr_traitvaluequal_trv.trv_code IS
 'Code of the qualitative trait';
COMMENT ON COLUMN refeel.tr_traitvaluequal_trv.trv_description IS
 'Description of the method';

GRANT ALL ON refeel.tr_traitvaluequal_trv TO diaspara_admin;
GRANT SELECT ON refeel.tr_traitvaluequal_trv TO diaspara_read; 
Table 41: Table of possible qualitative trait values
Code to import trait values for qualitative parm.
trv <- dbGetQuery(con_diaspara, "SELECT * FROM refeel.tr_traitvaluequal_trv;")
trq <- dbGetQuery(con_diaspara, "SELECT * FROM refeel.tr_traitqualitative_trq;")
#clipr::write_clip(colnames(trv))
trq <- data.frame(
  "trv_id"=1:(13+5*4+7),
  "trv_trq_code"=c(
    rep(trq$tra_code[1],13),
    rep(trq$tra_code[2],5),
    rep(trq$tra_code[3],5),
    rep(trq$tra_code[4],5),
    rep(trq$tra_code[5],5),
    rep(trq$tra_code[6],7)),
  "trv_code"=c(c("VA","VB","VIA0","VIA1","VIA2",
                 "VIA3","VIA4","VIB","VII", "mix_VIA1_VIA4",
                 "mix_VA_VB", "U","NA"),
               rep(c("N","NA","U","Y","P"),4),
               c("F","I","M","T","U","X","H")),
  "trv_description" = c(
    "No pigmentation except a spot on the caudal fin",
    "Early development of the pigmentation on the skull,
   no superficial piment beyond the cerebral spot.",
   "Development of dorsal pigmentation along the base of dorsal fin",
   "The dosal pigmentation is complete from head to tail",
   "Presence of medio lateral pigmentation but
   it does not reach the beginning of the dorsal fin",
   "The medio-lateral pigmentation reaches the beginning of the dorsal fin",
   "Ventro lateral pigmentation distributed along the myosepta. 
  Pigments are still distinct.",
  "Pigments are no longer distinct in the ventro lateral region",
  "Loss of transparency, the abdominal cavity takes a silvery color.
  Generalised development of yellow eel pigment cells",
  "Development of surface and branchiostegal pigmentation",
  "No or early pigmentation",
  "Glass eels, but pigmentation stage is unknown",
  "Not available",
  rep(c("No","Not Applicable", "Unknown","Yes", "Probable"), 4),
  "Female", "Immature - attempt made but sex could not be destinguished",
  "Male", "Transitional", "Undetermined - no attempt made", "Mixed",
  "Hermaphrodite"
  ))
dbWriteTable(con_diaspara_admin, "tr_traitvaluequal_trv_temp", trq,
             overwrite =TRUE)
dbExecute(con_diaspara_admin, "DELETE FROM refeel.tr_traitvaluequal_trv");
dbExecute(con_diaspara_admin, "INSERT INTO refeel.tr_traitvaluequal_trv
SELECT 
trv_id,
trv_trq_code,
trv_code,
trv_description,
'WGEEL',
'ANG'
 FROM tr_traitvaluequal_trv_temp;") #40
Code to show trait value table.
dbGetQuery(con_diaspara, "SELECT * FROM refeel.tr_traitvaluequal_trv;") |>
  knitr::kable() |>
  kable_styling(bootstrap_options = c("striped", "hover", "condensed"))
Table 42: Values for qualitative parameters
trv_id trv_trq_code trv_code trv_description trv_spe_code trv_wkg_code
1 Pigment_stage VA No pigmentation except a spot on the caudal fin WGEEL ANG
2 Pigment_stage VB Early development of the pigmentation on the skull, no superficial piment beyond the cerebral spot. WGEEL ANG
3 Pigment_stage VIA0 Development of dorsal pigmentation along the base of dorsal fin WGEEL ANG
4 Pigment_stage VIA1 The dosal pigmentation is complete from head to tail WGEEL ANG
5 Pigment_stage VIA2 Presence of medio lateral pigmentation but it does not reach the beginning of the dorsal fin WGEEL ANG
6 Pigment_stage VIA3 The medio-lateral pigmentation reaches the beginning of the dorsal fin WGEEL ANG
7 Pigment_stage VIA4 Ventro lateral pigmentation distributed along the myosepta. Pigments are still distinct. WGEEL ANG
8 Pigment_stage VIB Pigments are no longer distinct in the ventro lateral region WGEEL ANG
9 Pigment_stage VII Loss of transparency, the abdominal cavity takes a silvery color. Generalised development of yellow eel pigment cells WGEEL ANG
10 Pigment_stage mix_VIA1_VIA4 Development of surface and branchiostegal pigmentation WGEEL ANG
11 Pigment_stage mix_VA_VB No or early pigmentation WGEEL ANG
12 Pigment_stage U Glass eels, but pigmentation stage is unknown WGEEL ANG
13 Pigment_stage NA Not available WGEEL ANG
15 Hva_presence NA Not Applicable WGEEL ANG
16 Hva_presence U Unknown WGEEL ANG
17 Hva_presence Y Yes WGEEL ANG
18 Hva_presence P Probable WGEEL ANG
20 Evex_presence NA Not Applicable WGEEL ANG
21 Evex_presence U Unknown WGEEL ANG
22 Evex_presence Y Yes WGEEL ANG
23 Evex_presence P Probable WGEEL ANG
25 Anguillicola_presence NA Not Applicable WGEEL ANG
26 Anguillicola_presence U Unknown WGEEL ANG
27 Anguillicola_presence Y Yes WGEEL ANG
28 Anguillicola_presence P Probable WGEEL ANG
30 Is_differentiated NA Not Applicable WGEEL ANG
31 Is_differentiated U Unknown WGEEL ANG
32 Is_differentiated Y Yes WGEEL ANG
33 Is_differentiated P Probable WGEEL ANG
34 Sex F Female WGEEL ANG
35 Sex I Immature - attempt made but sex could not be destinguished WGEEL ANG
36 Sex M Male WGEEL ANG
37 Sex T Transitional WGEEL ANG
38 Sex U Undetermined - no attempt made WGEEL ANG
39 Sex X Mixed WGEEL ANG
40 Sex H Hermaphrodite WGEEL ANG
14 Hva_presence N No WGEEL ANG
19 Evex_presence N No WGEEL ANG
29 Is_differentiated N No WGEEL ANG
24 Anguillicola_presence N No WGEEL ANG

3.34 Fish trait measurement method

Currently in the wgeel database, the traits table value contains one column for value which can store numeric or integer. When it is integer, then, the trait id (mty_id) refers either to a category (e.g sex, or is differenciated), or a method (sexed using size, sexed after gonadal inspection). In the new database, the method will be stored in a different column in the group or individual traits. This table references the methods proposed. Again these methods will be working group specific so we create an inherited table.

SQL code to create tables ref.tr_traitmethod_trm and refeel.tr_traitmethod_trm
-- DROP TABLE ref.tr_traitmethod_trm;

CREATE TABLE ref.tr_traitmethod_trm (
  trm_id integer PRIMARY KEY,
  trm_code text NOT NULL,
  trm_wkg_code TEXT NOT NULL,  
  CONSTRAINT fk_trm_wkg_code  FOREIGN KEY (trm_wkg_code)
  REFERENCES ref.tr_icworkinggroup_wkg(wkg_code)
  ON UPDATE CASCADE ON DELETE RESTRICT,
  trm_spe_code TEXT NOT NULL,  
  CONSTRAINT fk_trm_spe_code  FOREIGN KEY (trm_spe_code)
  REFERENCES ref.tr_species_spe(spe_code)
  ON UPDATE CASCADE ON DELETE RESTRICT,
  trm_description text NULL,
  CONSTRAINT uk_trm_code UNIQUE (trm_code)
);


COMMENT ON TABLE ref.tr_traitmethod_trm IS 
'Table of method used to obtain a trait metric';
COMMENT ON COLUMN ref.tr_traitmethod_trm.trm_id IS 
'Integer, id of the method used';
COMMENT ON COLUMN ref.tr_traitmethod_trm.trm_code IS 
'Name of the method used';
COMMENT ON COLUMN ref.tr_traitmethod_trm.trm_wkg_code IS 
'Working group code';
COMMENT ON COLUMN ref.tr_traitmethod_trm.trm_spe_code IS 
'Species code';
COMMENT ON COLUMN ref.tr_traitmethod_trm.trm_description IS 
'Description of the method';



GRANT ALL ON ref.tr_traitmethod_trm TO diaspara_admin;
GRANT SELECT ON ref.tr_traitmethod_trm TO diaspara_read; 

DROP TABLE IF EXISTS refeel.tr_traitmethod_trm;
CREATE TABLE refeel.tr_traitmethod_trm (
  CONSTRAINT uk_refeel_tm_id UNIQUE (trm_id),
  CONSTRAINT uk_refeel_tm_code UNIQUE (trm_code),
  CONSTRAINT fk_trm_wkg_code  FOREIGN KEY (trm_wkg_code)
  REFERENCES ref.tr_icworkinggroup_wkg(wkg_code)
  ON UPDATE CASCADE ON DELETE RESTRICT,
  CONSTRAINT fk_trm_spe_code  FOREIGN KEY (trm_spe_code)
  REFERENCES ref.tr_species_spe(spe_code)
  ON UPDATE CASCADE ON DELETE RESTRICT,
  CONSTRAINT uk_trm_code UNIQUE (trm_code)
) INHERITS (ref.tr_traitmethod_trm);


COMMENT ON TABLE refeel.tr_traitmethod_trm IS 
'Table of method used to obtain a trait metric';
COMMENT ON COLUMN refeel.tr_traitmethod_trm.trm_id IS 
'Integer, id of the method used';
COMMENT ON COLUMN refeel.tr_traitmethod_trm.trm_code IS 
'Name of the method used';
COMMENT ON COLUMN refeel.tr_traitmethod_trm.trm_wkg_code IS 
'Working group code';
COMMENT ON COLUMN refeel.tr_traitmethod_trm.trm_spe_code IS 
'Species code';
COMMENT ON COLUMN refeel.tr_traitmethod_trm.trm_description IS 
'Description of the method';



GRANT ALL ON refeel.tr_traitmethod_trm TO diaspara_admin;
GRANT SELECT ON refeel.tr_traitmethod_trm TO diaspara_read; 
Code to import traitmethod table.
tra <- dbGetQuery(con_wgeel_local, "SELECT * FROM ref.tr_metrictype_mty ;")
tra <- tra[grepl("method", tra$mty_name), ]
res <- dbGetQuery(con_diaspara, "SELECT * FROM ref.tr_traitmethod_trm")
clipr::write_clip(colnames(res))
traitmethod <- data.frame(
  "trm_id" = 1:6,
  "trm_tra_code" = c(
    "Gonadal_inspection",
    "Length_based_sex",
    "Anguillicola_stereomicroscope_count",
    "Anguillicola_visual_count",       
    "Muscle_lipid_fatmeter",
    "Muscle_lipid_gravimeter"
  ),
  "trm_wkg_code" = rep("WGEEL", 6),
  "trm_spe_code" = rep("ANG", 6),
  "trm_description" = c(
    "The eel is dissected and the gonads are inpected, 
    In males, the testes  appear as thin, ribbon-like, whitish structures. 
    In females, the ovaries are larger, lobed, and more granular,
     often yellowish or pinkish depending on maturity. 
     Many eels pass through an intersexual phase
      (Here refered as Mixed to align with ICES Vocab), 
      where gonads show both ovarian and testicular tissue. 
      This is part of their natural development", # nolint
    "The size at silvering of eels depends on the sex. 
    Males are found within the 25-45 cm range, and females are found over 45 cm.
     There is an overlap of sexes arround ",# nolint
    "Anguillicola count using a dissecting microscope,
     this allows to detect early-stage infections or small larvae",
    "Anguillicola visual count",
    "Non invasive estimation of the fat content 
    by measuring the dielectric properties of tissues, 
    this method requires a calibration.",# nolint
    "Gravimeter, muscle tissues are dried and the lipids 
    are extracted using solvents, the extracted fat is dried and weighted" # nolint
  )
)

dbWriteTable(con_diaspara_admin, "tr_traitmethod_trm_temp", traitmethod, overwrite = TRUE)
dbExecute(con_diaspara_admin, "DELETE FROM refeel.tr_traitmethod_trm")
dbExecute(con_diaspara_admin, "INSERT INTO refeel.tr_traitmethod_trm
SELECT
trm_id,
trm_tra_code,
trm_wkg_code,
trm_spe_code,
trm_description
 FROM tr_traitmethod_trm_temp") # 6
Code to show trait measurement method table.
trm <- dbGetQuery(con_diaspara, "SELECT * FROM ref.tr_traitmethod_trm;")
knitr::kable(trm)|>
  kable_styling(bootstrap_options = c("striped", "hover", "condensed"))
Table 43: Trait table, check how this will be imported …
trm_id trm_code trm_wkg_code trm_spe_code trm_description
1 Gonadal_inspection WGEEL 126281 The eel is dissected and the gonads are inpected, In males, the testes appear as thin, ribbon-like, whitish structures. In females, the ovaries are larger, lobed, and more granular, often yellowish or pinkish depending on maturity. Many eels pass through an intersexual phase (Here refered as Mixed to align with ICES Vocab), where gonads show both ovarian and testicular tissue. This is part of their natural development
2 Length_based_sex WGEEL 126281 The size at silvering of eels depends on the sex. Males are found within the 25-45 cm range, and females are found over 45 cm. There is an overlap of sexes arround
3 Anguillicola_stereomicroscope_count WGEEL 126281 Anguillicola count using a dissecting microscope, this allows to detect early-stage infections or small larvae
5 Muscle_lipid_fatmeter WGEEL 126281 Non invasive estimation of the fat content by measuring the dielectric properties of tissues, this method requires a calibration.
6 Muscle_lipid_gravimeter WGEEL 126281 Gravimeter, muscle tissues are dried and the lipids are extracted using solvents, the extracted fat is dried and weighted
4 Anguillicola_visual_count WGEEL 126281 Anguillicola visual count

4 STOCK

The stock data structure contains elements that will be used to support the working group stock assessment. It stores population‑level information such as abundance, recruitment, landings, or parameters allowing to run the stock assessment models in WGBAST or WGNAS. These data are aggregated at the regional level, most often the assessment unit used in the models (#fig-diad1).

Figure 19: Conceptual illustration of the content of the stock database, data pertaining to the stock unit level

The following section demonstrates the use of the DIADROMOUS database by testing the integration of stock data from three diadroumous working groups.

4.1 WGNAS

The first attempt to create the stock data structure was based on WGNAS, it was further validated with WGEEL and WGBAST. Hence, the code to create the “core” or “mother” tables used for inheritance is done in the WGNAS section. The WGNAS database is created in schemas refnas and datnas (see Section 2). This section contains the code to import WGNAS to the DIADROMOUS DB.

4.1.1 Metadata (dat.t_metadata_met) (all groups)

Metatadata is a working group specific table describing the parameters used as entry in the stock table. One parameter refers to a quantity or model variable. This quantity is generally assessed at the regional scale (Stock unit (WGNAS), Stock assessment unit WGBAST, EMU or in the future stock subunit or region (WGEEL). The metadata table aims at providing a full description of this parameter, including its dimension, the stage, maturity, age, etc. Using parameters and metadata allow to handle the complexity, and the diversity of model elements, while providing a common structure for all data between the different working groups (Figure 20).

Figure 20: Conceptual illustration of the variables contained in metadata

One table is created as a template for all tables in the different working groups. The code used to create metadata is listed below.

SQL code to create table dat.t_metadata_met

DROP TABLE IF EXISTS dat.t_metadata_met CASCADE;
CREATE TABLE dat.t_metadata_met (
  met_var TEXT NOT NULL,
  met_spe_code character varying(3) NOT  NULL,
  met_wkg_code TEXT NOT NULL,
  met_ver_code TEXT NULL,
  met_odi_code TEXT NOT NULL,
  met_bty_code TEXT NOT NULL,
  met_dim integer ARRAY,
  met_dimname TEXT ARRAY,
  met_modelstage TEXT NULL, 
  met_type TEXT NULL,
  met_location TEXT NULL,
  met_fishery TEXT NULL,
  met_sta_code TEXT NULL,
  met_des_code TEXT NULL,
  met_uni_code TEXT NULL,
  met_cat_code TEXT NULL,
  met_definition TEXT NULL, 
  met_deprecated BOOLEAN DEFAULT FALSE,
  CONSTRAINT t_metadata_met_pkey PRIMARY KEY(met_var, met_spe_code),
  CONSTRAINT fk_met_spe_code FOREIGN KEY (met_spe_code)
  REFERENCES ref.tr_species_spe(spe_code) 
  ON DELETE CASCADE
  ON UPDATE CASCADE,
    CONSTRAINT fk_met_wkg_code FOREIGN KEY (met_wkg_code)
  REFERENCES ref.tr_icworkinggroup_wkg(wkg_code) 
  ON DELETE CASCADE
  ON UPDATE CASCADE,
  CONSTRAINT fk_met_ver_code FOREIGN KEY (met_ver_code)
  REFERENCES ref.tr_version_ver(ver_code) 
  ON DELETE CASCADE
  ON UPDATE CASCADE,
  CONSTRAINT fk_met_odi_code FOREIGN KEY (met_odi_code) 
  REFERENCES ref.tr_objectdimension_odi (odi_code) ON DELETE CASCADE
  ON UPDATE CASCADE,
  CONSTRAINT fk_met_bty_code FOREIGN KEY (met_bty_code) 
  REFERENCES ref.tr_bayestype_bty (nim_code) ON DELETE CASCADE
  ON UPDATE CASCADE,  
  CONSTRAINT fk_met_sta_code FOREIGN KEY (met_sta_code)
  REFERENCES ref.tr_statistic_sta(sta_code)
  ON DELETE CASCADE
  ON UPDATE CASCADE,
  CONSTRAINT fk_met_uni_code FOREIGN KEY (met_uni_code)
  REFERENCES ref.tr_units_uni(uni_code)
  ON DELETE CASCADE
  ON UPDATE CASCADE,
  CONSTRAINT fk_met_cat_code FOREIGN KEY (met_cat_code)
  REFERENCES ref.tr_category_cat(cat_code)
  ON DELETE CASCADE
  ON UPDATE CASCADE,
  CONSTRAINT fk_met_des_code FOREIGN KEY (met_des_code)
  REFERENCES ref.tr_destination_des(des_code)
  ON DELETE CASCADE
  ON UPDATE CASCADE
);
COMMENT ON TABLE dat.t_metadata_met IS 
'Table (metadata) of each variable (parameter) in the database.';
COMMENT ON COLUMN dat.t_metadata_met.met_var 
IS 'Variable code, primary key on both met_spe_code and met_var.';
COMMENT ON COLUMN dat.t_metadata_met.met_spe_code 
IS 'Species, ''127186'' (Salmo salar), ''127187'' (Salmo trutta), ''126281'' (Anguilla anguilla)  ... primary key on both met_spe_code and met_var.';
COMMENT ON COLUMN dat.t_metadata_met.met_ver_code 
IS 'Code on the version of the model, see table tr_version_ver.';
COMMENT ON COLUMN dat.t_metadata_met.met_odi_code 
IS 'Object type, single_value, vector, matrix see table tr_objectdimension_odi.';
COMMENT ON COLUMN dat.t_metadata_met.met_bty_code 
IS 'Nimble type, one of data, constant, output, other.';
COMMENT ON COLUMN 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).';
COMMENT ON COLUMN dat.t_metadata_met.met_dimname 
IS 'Dimension of the variable in Nimble, use {''year'', ''stage'', ''area''}.';
COMMENT ON COLUMN dat.t_metadata_met.met_modelstage 
IS 'Currently one of fit, other, First year.';
COMMENT ON COLUMN dat.t_metadata_met.met_type 
IS 'Type of data in the variable, homewatercatches, InitialISation first year,
abundance ....';
COMMENT ON COLUMN dat.t_metadata_met.met_location 
IS 'Describe process at sea, e.g. Btw. FAR - GLD fisheries, or Aft. Gld fISheries.';
COMMENT ON COLUMN dat.t_metadata_met.met_fishery 
IS 'Description of the fishery.';
COMMENT ON COLUMN 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.';
COMMENT ON COLUMN dat.t_metadata_met.met_uni_code 
IS 'Unit, references table tr_unit_uni.';
COMMENT ON COLUMN dat.t_metadata_met.met_cat_code 
IS 'Broad category of data or parameter, 
catch, effort, biomass, mortality, count ...references table tr_category_cat.';
COMMENT ON COLUMN dat.t_metadata_met.met_sta_code 
IS 'Code of the metric, references tr_statistic_sta, Estimate, Bound, SD, CV ....';
COMMENT ON COLUMN dat.t_metadata_met.met_definition 
IS 'Definition of the metric.';
COMMENT ON COLUMN dat.t_metadata_met.met_deprecated
IS'Is the variable still used ?';

GRANT ALL ON dat.t_metadata_met TO diaspara_admin;
GRANT SELECT ON dat.t_metadata_met TO diaspara_read;




/*
SELECT * FROM refsalmoglob."database" JOIN
datnas.t_metadata_met AS tmm ON tmm.met_var = var_mod
WHERE "year" IS NULL
*/
Table 44: metadata

4.1.2 Create and import the metadata table from WGNAS

Creating the referential for WGNAS






DROP TABLE IF EXISTS datnas.t_metadata_met;

CREATE TABLE datnas.t_metadata_met(met_oldversion numeric)
INHERITS (ref.t_metadata_met);


-- ADDING CONSTRAINTS

ALTER TABLE datnas.t_metadata_met ADD
 CONSTRAINT t_metadata_met_pkey PRIMARY KEY(met_var, met_spe_code);
 
ALTER TABLE datnas.t_metadata_met ADD 
  CONSTRAINT fk_met_spe_code FOREIGN KEY (met_spe_code)
  REFERENCES ref.tr_species_spe(spe_code) 
  ON DELETE CASCADE
  ON UPDATE CASCADE;

 ALTER TABLE datnas.t_metadata_met ADD
    CONSTRAINT ck_met_spe_code CHECK (met_spe_code='127186'); 

 ALTER TABLE datnas.t_metadata_met ADD
    CONSTRAINT fk_met_wkg_code FOREIGN KEY (met_wkg_code)
  REFERENCES ref.tr_icworkinggroup_wkg(wkg_code) 
  ON DELETE CASCADE
  ON UPDATE CASCADE;

ALTER TABLE datnas.t_metadata_met ADD
    CONSTRAINT ck_met_wkg_code CHECK (met_wkg_code='WGNAS');

ALTER TABLE datnas.t_metadata_met ADD
  CONSTRAINT fk_met_ver_code FOREIGN KEY (met_ver_code)
  REFERENCES refnas.tr_version_ver(ver_code) 
  ON DELETE CASCADE
  ON UPDATE CASCADE;

ALTER TABLE datnas.t_metadata_met ADD
  CONSTRAINT fk_met_odi_code FOREIGN KEY (met_odi_code) 
  REFERENCES ref.tr_objectdimension_odi (odi_code) ON DELETE CASCADE
  ON UPDATE CASCADE;

ALTER TABLE datnas.t_metadata_met ADD
  CONSTRAINT fk_met_bty_code FOREIGN KEY (met_bty_code) 
  REFERENCES ref.tr_bayestype_bty (nim_code) ON DELETE CASCADE
  ON UPDATE CASCADE;

ALTER TABLE datnas.t_metadata_met ADD  
  CONSTRAINT fk_met_sta_code FOREIGN KEY (met_sta_code)
  REFERENCES ref.tr_statistic_sta(sta_code)
  ON DELETE CASCADE
  ON UPDATE CASCADE;

ALTER TABLE datnas.t_metadata_met ADD
  CONSTRAINT fk_met_uni_code FOREIGN KEY (met_uni_code)
  REFERENCES ref.tr_units_uni(uni_code)
  ON DELETE CASCADE
  ON UPDATE CASCADE;

ALTER TABLE datnas.t_metadata_met ADD
  CONSTRAINT fk_met_cat_code FOREIGN KEY (met_cat_code)
  REFERENCES ref.tr_category_cat(cat_code)
  ON DELETE CASCADE
  ON UPDATE CASCADE;

ALTER TABLE datnas.t_metadata_met ADD
  CONSTRAINT fk_met_des_code FOREIGN KEY (met_des_code)
  REFERENCES ref.tr_destination_des(des_code)
  ON DELETE CASCADE
  ON UPDATE CASCADE;
--  COMMENTS FOR WGNAS


COMMENT ON TABLE datnas.t_metadata_met IS 
'Table (metadata) of each variable (parameter) in the wgnas database.';
COMMENT ON COLUMN refnas.t_metadata_met.met_var 
IS 'Variable code, primary key on both met_spe_code and met_var.';
COMMENT ON COLUMN refnas.t_metadata_met.met_spe_code 
IS 'Species, 127186 primary key on both met_spe_code and met_var.';
COMMENT ON COLUMN refnas.t_metadata_met.met_ver_code 
IS 'Code on the version of the model, see table tr_version_ver.';
COMMENT ON COLUMN refnas.t_metadata_met.met_odi_code 
IS 'Object type, single_value, vector, matrix see table tr_objectdimension_odi.';
COMMENT ON COLUMN refnas.t_metadata_met.met_bty_code 
IS 'Nimble type, one of data, constant, output, other.';
COMMENT ON COLUMN 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).';
COMMENT ON COLUMN refnas.t_metadata_met.met_dimname 
IS 'Dimension of the variable in Nimble, use {''year'', ''stage'', ''area''}.';
COMMENT ON COLUMN refnas.t_metadata_met.met_modelstage 
IS 'Currently one of fit, other, First year.';
COMMENT ON COLUMN refnas.t_metadata_met.met_type 
IS 'Type of data in the variable, homewatercatches, InitialISation first year,
abundance ....';
COMMENT ON COLUMN refnas.t_metadata_met.met_location 
IS 'Describe process at sea, e.g. Btw. FAR - GLD fisheries, or Aft. Gld fISheries.';
COMMENT ON COLUMN refnas.t_metadata_met.met_fishery 
IS 'Description of the fishery.';
COMMENT ON COLUMN 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';
COMMENT ON COLUMN refnas.t_metadata_met.met_uni_code 
IS 'Unit, refnaserences table tr_unit_uni.';
COMMENT ON COLUMN refnas.t_metadata_met.met_cat_code 
IS 'Broad category of data or parameter, 
catch, effort, biomass, mortality, count ...refnaserences table tr_category_cat.';
COMMENT ON COLUMN refnas.t_metadata_met.met_sta_code 
IS 'Code of the metric, refnaserences tr_statistic_sta, Estimate, Bound, SD, CV ....';
COMMENT ON COLUMN refnas.t_metadata_met.met_definition 
IS 'Definition of the metric.';
COMMENT ON COLUMN refnas.t_metadata_met.met_deprecated
IS'Is the variable still used ?';


ALTER TABLE datnas.t_metadata_met OWNER TO diaspara_admin;
GRANT SELECT ON datnas.t_metadata_met TO diaspara_read;



  
    
Code to import metadata to datnas …
# t_metadata_met

metadata <- dbGetQuery(con_salmoglob, "SELECT * FROM metadata")

res <- dbGetQuery(con_diaspara, "SELECT * FROM datnas.t_metadata_met;")
#clipr::write_clip(colnames(res))

# unique(metadata$metric)
# dbGetQuery(con_diaspara, "SELECT * FROM ref.tr_statistic_sta")

t_metadata_met <-
  data.frame(
    met_var = metadata$var_mod,
    met_spe_code = "127186",
    met_wkg_code = "WGNAS",
    met_ver_code = "SAL-2024-1", # no data on version in metadata
    met_odi_code = metadata$type_object,
    met_bty_code =  case_when(
      "Data_nimble"== metadata$nimble ~ "Data",
      "Const_nimble" == metadata$nimble ~ "Parameter constant",
      "Output" == metadata$nimble ~ "Output",
      "other" == metadata$nimble ~ "Other",
      .default = NA),
    met_dim = paste0(
      "{", metadata$dim1, ",",
      replace_na(metadata$dim2, 0), ",",
      replace_na(metadata$dim3, 0), "}"
    ),
    met_dimname = paste0(
      "{'", metadata$name_dim1, "',",
      ifelse(metadata$name_dim2 == "", "NULL", paste0("'", metadata$name_dim2, "'")), ",",
      ifelse(metadata$name_dim3 == "", "NULL", paste0("'", metadata$name_dim3, "'")), "}"
    ),
    met_modelstage = metadata$model_stage,
    met_type = metadata$type,
    met_location = metadata$locations,
    met_fishery = metadata$fishery,
    met_sta_code = case_when(metadata$metric == "Standard deviation" ~ "SD",
                             metadata$metric == "Coefficient of variation" ~ "CV",
                             .default = metadata$metric
    ),
    met_des_code = NA,
    met_uni_code = NA, # (TODO)
    met_cat_code = case_when(
      grepl("Origin distribution in sea catches", metadata$type) ~ "Other",
      grepl("catch", metadata$type) ~ "Catch",
      grepl("harvest rates", metadata$type) ~ "Mortality",
      grepl("Survival rate", metadata$type) ~ "Mortality",
      grepl("Returns", metadata$type) ~ "Count",
      grepl("Fecundity", metadata$type) ~ "Life trait",
      grepl("Sex ratio", metadata$type) ~ "Life trait",
      grepl("Maturation rate", metadata$type) ~ "Life trait",
      grepl("Proportion", metadata$type) ~ "Other",
      grepl("Stocking", metadata$type) ~ "Count",
      grepl("Smolt age structure", metadata$type) ~ "Life trait",
      grepl("Time spent", metadata$type) ~ "Life trait",
      grepl("Conservation limits", metadata$type) ~ "Conservation limit",
      grepl("Abundance", metadata$type) ~ "Count",
      grepl("Demographic transitions", metadata$type) ~ "Other",
      grepl("year", metadata$type) ~ "Other",
      grepl("Number of SU", metadata$type) ~ "Other",
      grepl("Prior", metadata$type) ~ "Other",
      grepl("Number of SU", metadata$type) ~ "Other",
      .default = NA
    ),
    met_definition = metadata$definition,
    met_deprecated = NA
    
  )

res <- dbWriteTable(con_diaspara_admin, "t_metadata_met_temp", 
                    t_metadata_met, overwrite = TRUE)
dbExecute(con_diaspara_admin, "INSERT INTO datnas.t_metadata_met 
SELECT 
 met_var,
 met_spe_code,
 met_wkg_code,
 met_ver_code,
 upper(substring(met_odi_code from 1 for 1)) ||
          substring(met_odi_code from 2 for length(met_odi_code)), 
 met_bty_code,
 met_dim::INTEGER[], 
 met_dimname::TEXT[], 
 met_modelstage, 
 met_type,
 met_location, 
 met_fishery, 
 met_sta_code, 
 met_des_code, 
 met_uni_code,
 met_cat_code, 
 met_definition, 
 met_deprecated
FROM t_metadata_met_temp")

dbExecute(con_diaspara_admin, "DROP TABLE t_metadata_temp CASCADE;")

After integration, the table of metadata from WGNAS is not changed much, apart from adapting to the new referentials. The table is shown in Table 45 below.

table metadata
dbGetQuery(con_diaspara, "SELECT * FROM datnas.t_metadata_met limit 10;")|> knitr::kable() |> kable_styling(bootstrap_options = c("striped", "hover", "condensed"))
Table 45: Content of the datnas metadata table
met_var met_spe_code met_wkg_code met_ver_code met_odi_code met_bty_code met_dim met_dimname met_modelstage met_type met_location met_fishery met_sta_code met_des_code met_uni_code met_cat_code met_definition met_deprecated met_oldversion
log_C5_NAC_1_lbnf_sd 127186 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 early Newfoundland fishery NA NA
log_C5_NAC_2_lbnf_lab_sd 127186 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 127186 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 127186 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 127186 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 127186 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 127186 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 127186 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
CV_hw 127186 WGNAS WGNAS-2024-1 Single_value Parameter constant {1,0,0} {'CV_hw',NULL,NULL} Fit Homewater catches _ NA CV NA NA Catch Standard-deviation for catches in home waters NA NA
log_C8_NAC_4_lbnf_oth_sd 127186 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

4.1.3 Create specific referential for WGNAS

Some of the referentials, particularly version, are specific to each working group.

Creating the referential for WGNAS

DROP TABLE IF EXISTS refnas.tr_version_ver CASCADE;
CREATE TABLE refnas.tr_version_ver() inherits (ref.tr_version_ver);

ALTER TABLE refnas.tr_version_ver ADD CONSTRAINT ver_code_pkey PRIMARY KEY (ver_code);
ALTER TABLE refnas.tr_version_ver ADD CONSTRAINT  fk_ver_spe_code FOREIGN KEY (ver_spe_code) 
REFERENCES ref.tr_species_spe(spe_code)
ON UPDATE CASCADE ON DELETE CASCADE;

COMMENT ON TABLE refnas.tr_version_ver
IS 'Table of data or variable version, essentially one datacall or advice, inherits ref.tr_version_ver';

COMMENT ON COLUMN refnas.tr_version_ver.ver_code 
IS 'Version code, stockkey-year-version.';
COMMENT ON COLUMN refnas.tr_version_ver.ver_year 
IS 'Year of assessement.';
COMMENT ON COLUMN refnas.tr_version_ver.ver_spe_code 
IS 'Species code e.g. ''127186'' references tr_species_spe.';
COMMENT ON COLUMN refnas.tr_version_ver.ver_stockkeylabel 
IS 'Ver_stockkeylabel e.g. ele.2737.nea.';
COMMENT ON COLUMN refnas.tr_version_ver.ver_datacalldoi 
IS 'Data call DOI, find a way to retrieve that information 
and update this comment';
COMMENT ON COLUMN refnas.tr_version_ver.ver_version 
IS 'Version code in original database, eg 2,4 for wgnas, dc_2020 for wgeel.';
COMMENT ON COLUMN refnas.tr_version_ver.ver_description 
IS 'Description of the data call / version.';
GRANT ALL ON refnas.tr_version_ver TO diaspara_admin;
GRANT SELECT ON refnas.tr_version_ver TO diaspara_read;


4.1.4 The stock table

The following scripts create the “mother” dat.t_stock_sto table used as the basis for all working groups. It futher imports the database table from the salmoglob (WGNAS) database. The stock table is intended to stock multidimensional data for each of the variables (Figure 21)

Figure 21: Conceptual illustration of the dimensions used in the stock table, some dimensions are only used by specific working groups while other are common
SQL code to create tables
-- before working there should have been these constraints in the salmoglob DB

 ALTER TABLE "database" 
ADD CONSTRAINT c_uk_area_varmod_year_location_age UNIQUE  (area, var_mod, "year", "location", age);
ALTER TABLE "database_archive" ADD CONSTRAINT 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 values

SELECT DISTINCT met_bty_code FROM datnas.t_metadata_met
JOIN refsalmoglob."database" ON var_mod = met_var
WHERE  met_cat_code ='Other'


SELECT * FROM datnas.t_metadata_met WHERE met_var LIKE '%mu%'
SELECT DISTINCT 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 valeus


DROP TABLE IF EXISTS dat.t_stock_sto CASCADE;
CREATE TABLE dat.t_stock_sto (
  sto_id SERIAL NOT NULL,
  sto_met_var TEXT NOT NULL, 
  sto_year INT4 NULL,
  sto_spe_code VARCHAR(3) NOT NULL,
  CONSTRAINT fk_sto_met_var_met_spe_code
    FOREIGN KEY (sto_met_var, sto_spe_code) REFERENCES dat.t_metadata_met(met_var,met_spe_code) 
    ON UPDATE CASCADE ON DELETE RESTRICT,
  sto_value NUMERIC NULL,
  sto_are_code TEXT NOT NULL,
  CONSTRAINT fk_sto_are_code FOREIGN KEY (sto_are_code)
    REFERENCES "ref".tr_area_are (are_code) 
    ON UPDATE CASCADE ON DELETE RESTRICT,
  -- 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 FOREIGN KEY (sto_cou_code)
    REFERENCES "ref".tr_country_cou (cou_code)
    ON UPDATE CASCADE ON DELETE RESTRICT,
  sto_lfs_code TEXT NOT NULL,
  CONSTRAINT fk_sto_lfs_code_sto_spe_code FOREIGN KEY (sto_lfs_code, sto_spe_code)
    REFERENCES "ref".tr_lifestage_lfs (lfs_code, lfs_spe_code) 
    ON UPDATE CASCADE ON DELETE RESTRICT,  
  sto_hty_code VARCHAR(2) NULL, 
  CONSTRAINT fk_hty_code FOREIGN KEY (sto_hty_code)
    REFERENCES "ref".tr_habitattype_hty(hty_code) 
    ON UPDATE CASCADE ON DELETE RESTRICT,
  --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 NOT NULL,
  CONSTRAINT fk_sto_qal_code FOREIGN KEY (sto_qal_code)
    REFERENCES "ref".tr_quality_qal(qal_code)
    ON UPDATE CASCADE ON DELETE RESTRICT,
  sto_qal_comment TEXT NULL,
  sto_comment TEXT NULL,
  sto_datelastupdate date NULL,
  sto_mis_code VARCHAR(2) NULL,
  CONSTRAINT fk_sto_mis_code FOREIGN KEY (sto_mis_code)
  REFERENCES "ref".tr_missvalueqal_mis (mis_code)
  ON UPDATE CASCADE ON DELETE RESTRICT,
  sto_dta_code TEXT DEFAULT 'Public' NULL,
  CONSTRAINT fk_dta_code FOREIGN KEY (sto_dta_code)
  REFERENCES "ref".tr_dataaccess_dta(dta_code) 
  ON UPDATE CASCADE ON DELETE RESTRICT,
  sto_wkg_code TEXT NOT NULL,  
  CONSTRAINT fk_sto_wkg_code  FOREIGN KEY (sto_wkg_code)
  REFERENCES "ref".tr_icworkinggroup_wkg(wkg_code)
  ON UPDATE CASCADE ON DELETE RESTRICT, 
  CONSTRAINT uk_sto_id_sto_wkg_code UNIQUE (sto_id, sto_wkg_code),
  CONSTRAINT ck_notnull_value_and_mis_code CHECK ((((sto_mis_code IS NULL) AND (sto_value IS NOT NULL)) OR 
  ((sto_mis_code IS NOT NULL) AND (sto_value IS NULL)))),
  sto_ver_code TEXT ,
  CONSTRAINT fk_sto_ver_code FOREIGN KEY (sto_ver_code)
  REFERENCES ref.tr_version_ver (ver_code)
  ON UPDATE CASCADE ON DELETE RESTRICT
  -- 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])))),
);



COMMENT ON TABLE 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';
COMMENT ON COLUMN dat.t_stock_sto.sto_id IS 'Integer serial identifying. Only unique in this table
when looking at the pair, sto_id, sto_wkg_code';
COMMENT ON COLUMN dat.t_stock_sto.sto_met_var IS 'Name of the variable in the database, this was previously named
var_mod in the salmoglob database and eel_typ_id in the wgeel database, there is a unicity constraint based
on 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.
COMMENT ON COLUMN dat.t_stock_sto.sto_year IS 'Year';
COMMENT ON COLUMN dat.t_stock_sto.sto_value IS 'Value if null then provide a value in sto_mis_code to explain why not provided';
COMMENT ON COLUMN 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.';
COMMENT ON COLUMN dat.t_stock_sto.sto_cou_code IS 'Code of the country see tr_country_cou, not null';
COMMENT ON COLUMN 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.';
COMMENT ON COLUMN 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';
COMMENT ON COLUMN 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';
COMMENT ON COLUMN dat.t_stock_sto.sto_qal_comment IS 'Comment for the quality, for instance explaining why a data is qualified as good or dubious.';
COMMENT ON COLUMN dat.t_stock_sto.sto_comment IS 'Comment on the value';
COMMENT ON COLUMN dat.t_stock_sto.sto_datelastupdate IS 'Last update of the data';
COMMENT ON COLUMN 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).';
COMMENT ON COLUMN dat.t_stock_sto.sto_dta_code IS 'Access to data, default is ''Public''';
COMMENT ON COLUMN dat.t_stock_sto.sto_wkg_code IS 'Code of the working group, one of
WGBAST, WGEEL, WGNAS, WKTRUTTA';
COMMENT ON COLUMN dat.t_stock_sto.sto_spe_code IS 'Code of the species';
COMMENT ON COLUMN dat.t_stock_sto.sto_ver_code IS 'Code of the version';

ALTER TABLE dat.t_stock_sto OWNER TO diaspara_admin;
GRANT SELECT ON dat.t_stock_sto  TO diaspara_read;


-- trigger on date
DROP FUNCTION dat.update_sto_datelastupdate;
CREATE OR REPLACE FUNCTION dat.update_sto_datelastupdate()
 RETURNS trigger
 LANGUAGE plpgsql
AS $function$
BEGIN
    NEW.sto_datelastupdate = now()::date;
    RETURN NEW; 
END;
$function$
;
ALTER FUNCTION dat.update_sto_datelastupdate() OWNER TO diaspara_admin;

CREATE TRIGGER update_sto_datelastupdate BEFORE
INSERT
    OR
UPDATE
    ON
    dat.t_stock_sto FOR EACH ROW EXECUTE FUNCTION dat.update_sto_datelastupdate();

/*
 * 
 * TODO CHECK THOSE TRIGGERS FOR WGEEL
 */
  
  /*
CREATE TRIGGER trg_check_no_ices_area AFTER
INSERT
    OR
UPDATE
    ON
    datawg.t_eelstock_eel FOR EACH ROW EXECUTE FUNCTION datawg.check_no_ices_area();
CREATE TRIGGER trg_check_the_stage AFTER
INSERT
    OR
UPDATE
    ON
    datawg.t_eelstock_eel FOR EACH ROW EXECUTE FUNCTION datawg.check_the_stage();

CREATE TRIGGER trg_check_emu_whole_aquaculture AFTER
INSERT
    OR
UPDATE
    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 127186 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.

DROP TABLE IF EXISTS datnas.t_stock_sto;
CREATE TABLE datnas.t_stock_sto (
   sto_add_code TEXT NULL,
   CONSTRAINT fk_sto_add_code FOREIGN KEY (sto_add_code) 
   REFERENCES refnas.tg_additional_add (add_code), 
  CONSTRAINT fk_sto_met_var_met_spe_code
    FOREIGN KEY (sto_met_var, sto_spe_code) 
    REFERENCES datnas.t_metadata_met(met_var,met_spe_code) 
    ON UPDATE CASCADE ON DELETE RESTRICT,
  CONSTRAINT fk_sto_are_code FOREIGN KEY (sto_are_code)
    REFERENCES refnas.tr_area_are (are_code) 
    ON UPDATE CASCADE ON DELETE RESTRICT,
  CONSTRAINT fk_sto_cou_code FOREIGN KEY (sto_cou_code)
    REFERENCES ref.tr_country_cou (cou_code)
    ON UPDATE CASCADE ON DELETE RESTRICT,
  CONSTRAINT fk_sto_lfs_code_sto_spe_code FOREIGN KEY (sto_lfs_code, sto_spe_code)
    REFERENCES ref.tr_lifestage_lfs (lfs_code, lfs_spe_code) 
    ON UPDATE CASCADE ON DELETE RESTRICT,
  CONSTRAINT fk_hty_code FOREIGN KEY (sto_hty_code)
    REFERENCES ref.tr_habitattype_hty(hty_code) 
    ON UPDATE CASCADE ON DELETE RESTRICT,
--  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 FOREIGN KEY (sto_qal_code)
    REFERENCES ref.tr_quality_qal(qal_code)
    ON UPDATE CASCADE ON DELETE RESTRICT,
  CONSTRAINT fk_sto_mis_code FOREIGN KEY (sto_mis_code)
  REFERENCES ref.tr_missvalueqal_mis (mis_code)
  ON UPDATE CASCADE ON DELETE RESTRICT,
  CONSTRAINT fk_dta_code FOREIGN KEY (sto_dta_code)
  REFERENCES ref.tr_dataaccess_dta(dta_code) 
  ON UPDATE CASCADE ON DELETE RESTRICT, 
  CONSTRAINT fk_sto_wkg_code  FOREIGN KEY (sto_wkg_code)
  REFERENCES ref.tr_icworkinggroup_wkg(wkg_code)
  ON UPDATE CASCADE ON DELETE RESTRICT, 
  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 IS NULL) AND (sto_value IS NOT NULL)) OR 
  ((sto_mis_code IS NOT NULL) AND (sto_value IS NULL))))
)
inherits (dat.t_stock_sto) ;

-- This table will always be for SALMON and WGNAS

ALTER TABLE datnas.t_stock_sto ALTER COLUMN sto_spe_code SET DEFAULT '127186';
ALTER TABLE datnas.t_stock_sto ADD CONSTRAINT ck_spe_code CHECK (sto_spe_code='127186');
ALTER TABLE datnas.t_stock_sto ALTER COLUMN sto_wkg_code SET DEFAULT 'WGNAS';
ALTER TABLE datnas.t_stock_sto ADD CONSTRAINT ck_wkg_code CHECK (sto_wkg_code='WGNAS');



ALTER TABLE datnas.t_stock_sto OWNER TO diaspara_admin;
GRANT ALL ON TABLE datnas.t_stock_sto TO diaspara_read;







COMMENT ON TABLE 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 corresponds
to the database table in the original WGNAS database.';
COMMENT ON COLUMN datnas.t_stock_sto.sto_id IS 'Integer serial identifying. Only unique in this table
when looking at the pair, sto_id, sto_wkg_code';
COMMENT ON COLUMN datnas.t_stock_sto.sto_met_var IS 'Name of the variable in the database, this was previously named
var_mod in the salmoglob database and eel_typ_id in the wgeel database, there is a unicity constraint based
on 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.
COMMENT ON COLUMN datnas.t_stock_sto.sto_spe_code IS 'Species default ''127186'' Salmo salar, check always equal to ''127186''';
COMMENT ON COLUMN datnas.t_stock_sto.sto_year IS 'Year';
COMMENT ON COLUMN datnas.t_stock_sto.sto_value IS 'Value if null then provide a value in sto_mis_code to explain why not provided';
COMMENT ON COLUMN 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.';
COMMENT ON COLUMN datnas.t_stock_sto.sto_cou_code IS 'Code of the country see tr_country_cou, not null';
COMMENT ON COLUMN 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.';
COMMENT ON COLUMN 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';
COMMENT ON COLUMN 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';
COMMENT ON COLUMN datnas.t_stock_sto.sto_qal_comment IS 'Comment for the quality, for instance explaining why a data is qualified as good or dubious.';
COMMENT ON COLUMN datnas.t_stock_sto.sto_comment IS 'Comment on the value';
COMMENT ON COLUMN datnas.t_stock_sto.sto_datelastupdate IS 'Last update of the data';
COMMENT ON COLUMN 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).';
COMMENT ON COLUMN datnas.t_stock_sto.sto_dta_code IS 'Access to data, default is ''Public''';
COMMENT ON COLUMN datnas.t_stock_sto.sto_wkg_code IS 'Code of the working group, one of
WGBAST, WGEEL, WGNAS, WKTRUTTA';
COMMENT ON COLUMN 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 date
DROP FUNCTION IF EXISTS datnas.update_sto_datelastupdate;
CREATE OR REPLACE FUNCTION datnas.update_sto_datelastupdate()
 RETURNS trigger
 LANGUAGE plpgsql
AS $function$
BEGIN
    NEW.sto_datelastupdate = now()::date;
    RETURN NEW; 
END;
$function$
;
ALTER FUNCTION datnas.update_sto_datelastupdate() OWNER TO diaspara_admin;

CREATE TRIGGER update_sto_datelastupdate BEFORE
INSERT
    OR
UPDATE
    ON
    datnas.t_stock_sto FOR EACH ROW EXECUTE FUNCTION datnas.update_sto_datelastupdate();


-- fix after change in wgeel
/*
SELECT * FROM refnas.tr_version_ver
UPDATE datnas.t_stock_sto SET sto_ver_code = 'WGNAS-2024-1'; -- 45076
*/
Cautionduplicated values in archive

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.1.5 Table of grouping for area and age : datnas.tg_additional_add

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.

This will be for parameter omega see location paragraph in WGNAS database description.

Another problem is the age column. When looking at the analysis see age in WGNAS database description

Only the variables eggs, p_smolt, p_smolt_pr and prop_female need an age.

This was solved using the tg_additional_add column. The stucture for WGBAST indicates that they too could use this additional column to store some of the matrix output.

SQL code to create tables
DROP TABLE IF EXISTS refnas.tg_additional_add;
CREATE TABLE refnas.tg_additional_add AS
SELECT are_code AS add_code, 'Area' AS add_type FROM refnas.tr_area_are
UNION
SELECT age_code AS add_code, 'Age' AS add_type FROM "ref".tr_age_age; --80
ALTER TABLE refnas.tg_additional_add ADD CONSTRAINT 
uk_add_code UNIQUE (add_code);


ALTER TABLE refnas.tg_additional_add OWNER TO diaspara_admin;
GRANT ALL ON TABLE refnas.tg_additional_add TO diaspara_read;




COMMENT ON TABLE 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 corresponds
to the database table in the original WGNAS database.';
COMMENT ON COLUMN refnas.tg_additional_add.add_code IS 'Code coming from are_code in
table refnas.tr_area_are or age_code in table ref.tr_age_age';
COMMENT ON COLUMN refnas.tg_additional_add.add_type IS 'One of Area or Age';
Table 46: 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.1.6 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
, '127186' 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_code
FROM refsalmoglob.database d JOIN
refsalmoglob.metadata m ON m.var_mod = d.var_mod; ")# 45076

4.1.6.1 structure of the table datnas.t_stock_sto

datnas.t_stock_sto table
dbGetQuery(con_diaspara, "SELECT * FROM datnas.t_stock_sto limit 10;")|> 
  knitr::kable() |> 
  kable_styling(bootstrap_options = c("striped", "hover", "condensed"))
Table 47: Content of the refnas t_stock_sto table
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 sto_ver_code
21254 E_theta1 2014 127186 0.007 QC NA E NA 1 NA NA 2025-12-19 NA Public WGNAS NA WGNAS-2024-1
21255 E_theta1 2013 127186 0.007 QC NA E NA 1 NA NA 2025-12-19 NA Public WGNAS NA WGNAS-2024-1
21256 E_theta1 2012 127186 0.007 QC NA E NA 1 NA NA 2025-12-19 NA Public WGNAS NA WGNAS-2024-1
21257 E_theta1 2011 127186 0.007 QC NA E NA 1 NA NA 2025-12-19 NA Public WGNAS NA WGNAS-2024-1
21258 E_theta1 2010 127186 0.007 QC NA E NA 1 NA NA 2025-12-19 NA Public WGNAS NA WGNAS-2024-1
21259 E_theta1 2009 127186 0.007 QC NA E NA 1 NA NA 2025-12-19 NA Public WGNAS NA WGNAS-2024-1
21260 E_theta1 2008 127186 0.007 QC NA E NA 1 NA NA 2025-12-19 NA Public WGNAS NA WGNAS-2024-1
21261 E_theta1 2007 127186 0.007 QC NA E NA 1 NA NA 2025-12-19 NA Public WGNAS NA WGNAS-2024-1
21262 E_theta1 2006 127186 0.007 QC NA E NA 1 NA NA 2025-12-19 NA Public WGNAS NA WGNAS-2024-1
21263 E_theta1 2005 127186 0.007 QC NA E NA 1 NA NA 2025-12-19 NA Public WGNAS NA WGNAS-2024-1

4.2 WGEEL

The main difficulty in transfering the WGEEL database to the DIADROMOUS database lies in the way the data are linked to areas in the marine habitat. Currently we have kept all historical data with the “historical” EMU as the reference. This might change once we start to build the model. If the data remain stuctured by EMU, then perhaps a data flow from the EMU might be used to aggregate / transfer data from EMUs to the stockunit. See habitat DB for the structure of eel habitat

4.2.1 Version (refeel.tr_version_ver)

See metricDB report

4.2.2 Metadata (dateel.t_metadata_met)

SQL code to create table dateel.t_metadata_met

DROP TABLE IF EXISTS dateel.t_metadata_met;

CREATE TABLE dateel.t_metadata_met(
 CONSTRAINT t_metadata_met_pkey PRIMARY KEY(met_var, met_wkg_code),
 CONSTRAINT fk_met_spe_code FOREIGN KEY (met_spe_code)
  REFERENCES ref.tr_species_spe(spe_code) 
  ON UPDATE CASCADE ON DELETE RESTRICT,
 CONSTRAINT ck_met_spe_code CHECK (met_spe_code='126281'),
 CONSTRAINT fk_met_wkg_code FOREIGN KEY (met_wkg_code)
  REFERENCES ref.tr_icworkinggroup_wkg(wkg_code) 
  ON UPDATE CASCADE ON DELETE RESTRICT,
  CONSTRAINT ck_met_wkg_code CHECK (met_wkg_code='WGEEL'),
  CONSTRAINT fk_met_ver_code FOREIGN KEY (met_ver_code)
  REFERENCES refeel.tr_version_ver(ver_code) 
  ON UPDATE CASCADE ON DELETE RESTRICT,
  CONSTRAINT fk_met_odi_code FOREIGN KEY (met_odi_code) 
  REFERENCES ref.tr_objectdimension_odi (odi_code) 
  ON UPDATE CASCADE ON DELETE RESTRICT,
  CONSTRAINT fk_met_bty_code FOREIGN KEY (met_bty_code) 
  REFERENCES ref.tr_bayestype_bty (nim_code) 
  ON UPDATE CASCADE ON DELETE RESTRICT,  
  CONSTRAINT fk_met_sta_code FOREIGN KEY (met_sta_code)
  REFERENCES ref.tr_statistic_sta(sta_code)
  ON UPDATE CASCADE ON DELETE RESTRICT,
  CONSTRAINT fk_met_uni_code FOREIGN KEY (met_uni_code)
  REFERENCES ref.tr_units_uni(uni_code)
  ON UPDATE CASCADE ON DELETE RESTRICT,
  CONSTRAINT fk_met_cat_code FOREIGN KEY (met_cat_code)
  REFERENCES ref.tr_category_cat(cat_code)
  ON UPDATE CASCADE ON DELETE RESTRICT,
  CONSTRAINT fk_met_des_code FOREIGN KEY (met_des_code)
  REFERENCES ref.tr_destination_des(des_code)
  ON UPDATE CASCADE ON DELETE RESTRICT
)
INHERITS (dat.t_metadata_met);



--  COMMENTS FOR WGEEL

COMMENT ON TABLE dateel.t_metadata_met IS 
'Table (metadata) of each variable (parameter) in the wgeel database.';
COMMENT ON COLUMN dateel.t_metadata_met.met_var 
IS 'Variable code, primary key on both met_spe_code and met_var.';
COMMENT ON COLUMN dateel.t_metadata_met.met_spe_code 
IS 'Species, ''126281'' primary key on both met_spe_code and met_var.';
COMMENT ON COLUMN dateel.t_metadata_met.met_ver_code 
IS 'Code on the version of the model, see table refeel.tr_version_ver.';
COMMENT ON COLUMN dateel.t_metadata_met.met_odi_code 
IS 'Object type, single_value, vector, matrix see table tr_objectdimension_odi.';
COMMENT ON COLUMN dateel.t_metadata_met.met_bty_code 
IS 'Nimble type, one of data, constant, output, other.';
COMMENT ON COLUMN 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).';
COMMENT ON COLUMN dateel.t_metadata_met.met_dimname 
IS 'Dimension of the variable in Nimble, use {''year'', ''stage'', ''area''}.';
COMMENT ON COLUMN dateel.t_metadata_met.met_modelstage 
IS 'Currently one of fit, other, First year.';
COMMENT ON COLUMN dateel.t_metadata_met.met_type 
IS 'Type of data in the variable, homewatercatches, InitialISation first year,
abundance ....';
COMMENT ON COLUMN dateel.t_metadata_met.met_location 
IS 'Describe process with geographical information';
COMMENT ON COLUMN dateel.t_metadata_met.met_fishery 
IS 'Description of the fishery.';
COMMENT ON COLUMN 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';
COMMENT ON COLUMN dateel.t_metadata_met.met_uni_code 
IS 'Unit, dateelerences table tr_unit_uni.';
COMMENT ON COLUMN dateel.t_metadata_met.met_cat_code 
IS 'Broad category of data or parameter, 
catch, effort, biomass, mortality, count ...dateelerences table tr_category_cat.';
COMMENT ON COLUMN dateel.t_metadata_met.met_sta_code 
IS 'Code of the metric, dateelerences tr_statistic_sta, Estimate, Bound, SD, CV ....';
COMMENT ON COLUMN dateel.t_metadata_met.met_definition 
IS 'Definition of the metric.';
COMMENT ON COLUMN dateel.t_metadata_met.met_deprecated
IS'Is the variable still used ?';



ALTER TABLE dateel.t_metadata_met OWNER TO diaspara_admin;
GRANT SELECT ON dateel.t_metadata_met TO diaspara_read;



type is not a referential, but used for legacy in WGNAS see type table so it’s currently empty in the table

Code to import to metadata for eel work in progress …
# t_metadata_met

eelstock <- dbGetQuery(con_diaspara_admin, "SELECT * FROM datwgeel.t_eelstock_eel WHERE eel_qal_id in (0,1,2,3,4) ")
nrow(eelstock) # 73730
unique(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 database
typ <- typ[!typ$typ_id %in% c(1,2,3),]  # remove series
typ <- typ[!typ$typ_id %in% c(16),]  # potential_availabe_habitat_production_ha
typ <- typ[!typ$typ_id %in% c(5, 7),]  # com_catch and rec_catch
typ <- typ[!typ$typ_id %in% c(26:31),]  # silver eel equivalents (deprecated)
# unique(metadata$metric)
# dbGetQuery(con_diaspara, "SELECT * FROM ref.tr_statistic_sta")
View(typ)
t_metadata_met <-
  data.frame(
    met_var = typ$typ_name,
    met_spe_code = "126281",
    met_wkg_code = "WGEEL",
    met_ver_code = "WGEEL-2025-1", 
    met_odi_code = "Single_value", # https://diaspara.bordeaux-aquitaine.inrae.fr/deliverables/wp3/p7stock/midb.html#object-type-tr_objectype_oty
    met_bty_code =  case_when(    
      typ$typ_id %in% c(4:12,32,33)   ~ "Data",
      .default = "Output"), # https://diaspara.bordeaux-aquitaine.inrae.fr/deliverables/wp3/p7stock/midb.html#type-of-parm-data-tr_bayestype_bty
    met_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-4
    met_location = NA, # something line bef. Fisheries Aft fisheries.... not a referential
    met_fishery = NA, # not a referential
    met_sta_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_odi_code, 
 met_bty_code,
 met_dim::INTEGER[], 
 met_dimname::TEXT[], 
 met_modelstage, 
 met_type,
 met_location, 
 met_fishery, 
 met_sta_code, 
 met_des_code, 
 met_uni_code,
 met_cat_code, 
 met_definition, 
 met_deprecated
FROM t_metadata_met_wgeel_temp") # 22

dbExecute(con_diaspara_admin, "DROP TABLE t_metadata_met_wgeel_temp CASCADE;")

4.2.3 Stock (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.

DROP TABLE IF EXISTS dateel.t_stock_sto;
CREATE TABLE dateel.t_stock_sto (
  CONSTRAINT fk_sto_met_var_met_spe_code
    FOREIGN KEY (sto_met_var, sto_spe_code) REFERENCES dateel.t_metadata_met(met_var,met_spe_code) 
    ON UPDATE CASCADE ON DELETE RESTRICT,
  CONSTRAINT fk_sto_are_code FOREIGN KEY (sto_are_code)
    REFERENCES refeel.tr_area_are (are_code) 
    ON UPDATE CASCADE ON DELETE RESTRICT,
  CONSTRAINT fk_sto_cou_code FOREIGN KEY (sto_cou_code)
    REFERENCES ref.tr_country_cou (cou_code)
    ON UPDATE CASCADE ON DELETE RESTRICT,
  CONSTRAINT fk_sto_lfs_code_sto_spe_code FOREIGN KEY (sto_lfs_code, sto_spe_code)
    REFERENCES ref.tr_lifestage_lfs (lfs_code, lfs_spe_code) 
    ON UPDATE CASCADE ON DELETE RESTRICT,
  CONSTRAINT fk_hty_code FOREIGN KEY (sto_hty_code)
    REFERENCES ref.tr_habitattype_hty(hty_code) 
    ON UPDATE CASCADE ON DELETE RESTRICT,
  --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 FOREIGN KEY (sto_qal_code)
    REFERENCES ref.tr_quality_qal(qal_code)
    ON UPDATE CASCADE ON DELETE RESTRICT,
  CONSTRAINT fk_sto_mis_code FOREIGN KEY (sto_mis_code)
  REFERENCES ref.tr_missvalueqal_mis (mis_code)
  ON UPDATE CASCADE ON DELETE RESTRICT,
  CONSTRAINT fk_dta_code FOREIGN KEY (sto_dta_code)
  REFERENCES ref.tr_dataaccess_dta(dta_code) 
  ON UPDATE CASCADE ON DELETE RESTRICT, 
  CONSTRAINT fk_sto_wkg_code  FOREIGN KEY (sto_wkg_code)
  REFERENCES ref.tr_icworkinggroup_wkg(wkg_code)
  ON UPDATE CASCADE ON DELETE RESTRICT, 
  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 IS NULL) AND (sto_value IS NOT NULL)) OR 
  ((sto_mis_code IS NOT NULL) AND (sto_value IS NULL))))
)
inherits (dat.t_stock_sto) ;

-- This table will always be for EEL (ang) and WGEEL

ALTER TABLE dateel.t_stock_sto ALTER COLUMN sto_spe_code SET DEFAULT '126281';
ALTER TABLE dateel.t_stock_sto ADD CONSTRAINT ck_spe_code CHECK (sto_spe_code='126281');
ALTER TABLE dateel.t_stock_sto ALTER COLUMN sto_wkg_code SET DEFAULT 'WGEEL';
ALTER TABLE dateel.t_stock_sto ADD CONSTRAINT ck_wkg_code CHECK (sto_wkg_code='WGEEL');



ALTER TABLE dateel.t_stock_sto OWNER TO diaspara_admin;
GRANT ALL ON TABLE dateel.t_stock_sto TO diaspara_read;







COMMENT ON TABLE 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 corresponds
to the t_eelstock_eel table in the original WGEEL database.';
COMMENT ON COLUMN dateel.t_stock_sto.sto_id IS 'Integer serial identifying. Only unique in this table
when looking at the pair, sto_id, sto_wkg_code';
COMMENT ON COLUMN dateel.t_stock_sto.sto_met_var IS 'Name of the variable in the database, this was previously named
eel_typ_name in the eel database, there is a unicity constraint based
on 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.
COMMENT ON COLUMN dateel.t_stock_sto.sto_year IS 'Year';
COMMENT ON COLUMN dateel.t_stock_sto.sto_value IS 'Value if null then provide a value in sto_mis_code to explain why not provided';
COMMENT ON COLUMN 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.';
COMMENT ON COLUMN dateel.t_stock_sto.sto_cou_code IS 'Code of the country see tr_country_cou, not null';
COMMENT ON COLUMN 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.';
COMMENT ON COLUMN 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';
COMMENT ON COLUMN dateel.t_stock_sto.sto_fia_code IS 'For marine area, code of the ICES area (table tr_fishingarea_fia), Null accepted';
COMMENT ON COLUMN 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';
COMMENT ON COLUMN dateel.t_stock_sto.sto_qal_comment IS 'Comment for the quality, for instance explaining why a data is qualified as good or dubious.';
COMMENT ON COLUMN dateel.t_stock_sto.sto_comment IS 'Comment on the value';
COMMENT ON COLUMN dateel.t_stock_sto.sto_datelastupdate IS 'Last update of the data';
COMMENT ON COLUMN 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).';
COMMENT ON COLUMN dateel.t_stock_sto.sto_dta_code IS 'Access to data, default is ''Public''';
COMMENT ON COLUMN dateel.t_stock_sto.sto_wkg_code IS 'Code of the working group, one of
WGBAST, WGEEL, WGNAS, WKTRUTTA';
COMMENT ON COLUMN dateel.t_stock_sto.sto_ver_code IS 'Version code, references refeel. tr_version_ver, code like WGEEL-2025-1';

-- trigger on date
DROP FUNCTION IF EXISTS dateel.update_sto_datelastupdate CASCADE;
CREATE OR REPLACE FUNCTION dateel.update_sto_datelastupdate()
 RETURNS trigger
 LANGUAGE plpgsql
AS $function$
BEGIN
    NEW.sto_datelastupdate = now()::date;
    RETURN NEW; 
END;
$function$
;
ALTER FUNCTION dateel.update_sto_datelastupdate() OWNER TO diaspara_admin;


CREATE TRIGGER update_sto_datelastupdate BEFORE
INSERT
    OR
UPDATE
    ON
    dateel.t_stock_sto FOR EACH ROW EXECUTE FUNCTION dateel.update_sto_datelastupdate();





SQL code to insert values in table dateel.t_stock_sto
DELETE FROM dateel.t_stock_sto;
INSERT INTO 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)
SELECT
eel_id AS  sto_id
, m.met_var AS sto_met_var
, e.eel_year AS sto_year
, '127186' AS  sto_spe_code
, e.eel_value AS sto_value
, CASE WHEN e.eel_emu_nameshort ilike '%total' THEN eel_cou_code
       WHEN e.eel_emu_nameshort IS NULL THEN eel_cou_code 
ELSE e.eel_emu_nameshort END AS sto_are_code
, e.eel_cou_code AS sto_cou_code 
, e.eel_lfs_code  AS sto_lfs_code
, CASE 
      WHEN e.eel_hty_code = 'AL' THEN NULL
      WHEN 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 IS NULL THEN NULL
      ELSE 'TROUBLE' END AS 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
, CASE
     WHEN 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' END AS sto_ver_code
FROM datwgeel.t_eelstock_eel e 
JOIN dateel.t_metadata_met m ON m.met_type::int = e.eel_typ_id
WHERE eel_qal_id IN (0,1,2,3,4)
AND eel_hty_code NOT IN ('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 T
 
 
INSERT INTO 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)
SELECT
eel_id AS sto_id
, m.met_var AS sto_met_var
, e.eel_year AS sto_year
, '127186' AS  sto_spe_code
, e.eel_value AS sto_value
, CASE WHEN e.eel_emu_nameshort ilike '%total' THEN eel_cou_code
       WHEN e.eel_emu_nameshort IS NULL THEN eel_cou_code 
ELSE e.eel_emu_nameshort END AS sto_are_code
, e.eel_cou_code AS sto_cou_code 
, e.eel_lfs_code  AS sto_lfs_code
, CASE 
      WHEN e.eel_hty_code = 'AL' THEN NULL
      WHEN 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 IS NULL THEN NULL
      ELSE 'TROUBLE' END AS 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
, CASE
     WHEN 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' END AS sto_ver_code
FROM datwgeel.t_eelstock_eel e 
JOIN dateel.t_metadata_met m ON m.met_type::int = e.eel_typ_id
WHERE eel_qal_id IN (0,1,2,3,4)
AND eel_hty_code IN ('T') 
AND  eel_typ_id != 16 
AND eel_missvaluequal != 'ND' ; -- 12303


-----------------------------------------------------------------------------------------------------------------------------
 -- Do we have MO data ? 
 -----------------------------------------------------------------------------------------------------------------------------
SELECT * FROM  datwgeel.t_eelstock_eel  WHERE eel_hty_code = 'MO';--15600
SELECT * FROM  datwgeel.t_eelstock_eel  WHERE eel_hty_code = 'MO' and eel_value is not NULL
AND 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 now
SELECT *
FROM datwgeel.t_eelstock_eel e 
JOIN dateel.t_metadata_met m ON m.met_type::int = e.eel_typ_id
WHERE eel_qal_id IN (0,1,2,3,4)
AND eel_hty_code IN ('MO') 
AND eel_value is not NULL 
AND eel_missvaluequal != 'ND';
 
INSERT INTO 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)
SELECT
eel_id AS sto_id
, m.met_var AS sto_met_var
, e.eel_year AS sto_year
, '127186' AS  sto_spe_code
, e.eel_value AS sto_value
, CASE WHEN eel_emu_nameshort = 'FR_Rhon' THEN '37.1.2.7' 
  ELSE 'STOP' END AS sto_are_code
, e.eel_cou_code AS sto_cou_code 
, e.eel_lfs_code  AS sto_lfs_code
, CASE 
      WHEN e.eel_hty_code = 'AL' THEN NULL
      WHEN 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 IS NULL THEN NULL
      ELSE 'TROUBLE' END AS 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
, CASE
     WHEN 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' END AS sto_ver_code
FROM datwgeel.t_eelstock_eel e 
JOIN dateel.t_metadata_met m ON m.met_type::int = e.eel_typ_id
WHERE eel_qal_id IN (0,1,2,3,4)
AND eel_hty_code IN ('MO') 
AND eel_value is not NULL; --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 (PARTITION BY eel_typ_id, eel_emu_nameshort,  eel_year, eel_lfs_code)
 FROM  datwgeel.t_eelstock_eel 
  WHERE eel_hty_code = 'C' 
  AND eel_value is not NULL
  AND eel_qal_id in (1,2,3,4))
  SELECT * FROM dupl WHERE count>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 (PARTITION BY eel_typ_id, eel_emu_nameshort,  eel_year, eel_lfs_code)
 FROM  datwgeel.t_eelstock_eel 
  WHERE eel_hty_code = 'C' 
  AND eel_value is not NULL
  AND eel_qal_id in (1,2,3,4)
  AND eel_typ_id !=16)
  SELECT * FROM dupl WHERE count=1
  ORDER BY 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 below
SELECT * FROM datwgeel.t_eelstock_eel 
  WHERE 
  eel_value is not NULL
  AND eel_qal_id in (1,2,3,4)
  AND eel_typ_id = 4
  AND 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 is not NULL
  AND eel_qal_id in (1,2,3,4)
  AND eel_typ_id = 4
  AND 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 IS NULL
  AND eel_value is not NULL
  AND eel_qal_id in (1,2,3,4)
  AND eel_typ_id !=16
   ORDER BY 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 OG

SELECT * 
 FROM  datwgeel.t_eelstock_eel 
  WHERE eel_value is not NULL
  AND eel_qal_id in (1,2,3,4)
  AND eel_typ_id IN (8,9)
  AND eel_cou_code = 'DK'
   ORDER BY 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 Paul
SELECT * 

 FROM  datwgeel.t_eelstock_eel 
  WHERE eel_value is not NULL
  AND eel_qal_id in (1,2,3,4)
  AND eel_cou_code = 'EE'  
   ORDER BY eel_emu_nameshort, eel_typ_id, eel_lfs_code, eel_year;
 
 SELECT * FROM  datwgeel.t_eelstock_eel 
  WHERE eel_value is not NULL
  AND eel_qal_id in (1,2,3,4)
  AND eel_cou_code = 'EE'  
  AND eel_hty_code IS NOT NULL
  AND eel_typ_id= 11
  ORDER BY 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 Rob

SELECT * FROM 
 datwgeel.t_eelstock_eel 
  WHERE eel_value is not NULL
  AND 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 query
  


  



with dupl AS (
SELECT *, count(eel_area_division)  OVER (PARTITION BY eel_typ_id, eel_emu_nameshort,  eel_year, eel_lfs_code)
 FROM  datwgeel.t_eelstock_eel 
  WHERE eel_hty_code = 'T'   
  AND eel_value is not NULL
  AND eel_qal_id in (1,2,3,4))
  SELECT * FROM dupl WHERE count>1; --2

-- OK there is a duplicate with qal_id 3 for ES_Cata ES G T 37.1.1

with dupl AS (
SELECT *, count(eel_area_division)  OVER (PARTITION BY eel_typ_id, eel_emu_nameshort,  eel_year, eel_lfs_code)
 FROM  datwgeel.t_eelstock_eel 
  WHERE eel_hty_code = 'T'   
  AND eel_value is not NULL
  AND eel_qal_id in (1,2,3,4))
  SELECT * FROM dupl WHERE count=1; --1254

with dupl AS (
SELECT *, count(eel_area_division)  OVER (PARTITION BY eel_typ_id, eel_emu_nameshort,  eel_year, eel_lfs_code)
 FROM  datwgeel.t_eelstock_eel 
  WHERE eel_hty_code = 'T'   
  AND eel_value is not NULL
  AND eel_qal_id in (1,2,3,4))
  SELECT DISTINCT ON (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
 ------------------------------------------------------------------
 
 DROP TABLE tempo.emu_div;
 CREATE TABLE tempo.emu_div AS 
 SELECT DISTINCT ON (eel_cou_code, eel_emu_nameshort, eel_area_division) 
 eel_cou_code, eel_emu_nameshort, 
  eel_area_division,   
  NULL AS area_code
 FROM  datwgeel.t_eelstock_eel 
  WHERE eel_value is not NULL
  AND eel_qal_id in (1,2,3,4)
  AND eel_area_division IS NOT NULL
  order by (eel_emu_nameshort);--21
  UPDATE 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');-- 38


  SELECT * 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'  
DELETE FROM tempo.emu_div WHERE eel_emu_nameshort='IT_Pugl' AND eel_area_division='37.2.2'; -- just one line in T no pb
UPDATE tempo.emu_div
  SET area_code='37.2.1.17'
  WHERE eel_emu_nameshort='AL_total' AND eel_area_division='37.2.2';
UPDATE tempo.emu_div
  SET area_code='27.3.b, c'
  WHERE eel_emu_nameshort='DK_total' AND eel_area_division='27.3.b, c';
UPDATE tempo.emu_div
  SET area_code='37.1.1.4'
  WHERE eel_emu_nameshort='DZ_total' AND eel_area_division='37.1.1';
UPDATE tempo.emu_div
  SET area_code='37.3.2.26'
  WHERE eel_emu_nameshort='EG_total' AND eel_area_division='37.3.2';
UPDATE tempo.emu_div
  SET area_code='37.3.1.22'
  WHERE eel_emu_nameshort='GR_EaMT' AND eel_area_division='37.3.1';
UPDATE tempo.emu_div
  SET area_code='37.2.2.20'
  WHERE eel_emu_nameshort='GR_NorW' AND eel_area_division='37.2.2';
UPDATE tempo.emu_div
  SET area_code='37.2.2.20'
  WHERE eel_emu_nameshort='GR_WePe' AND eel_area_division='37.2.2';
UPDATE tempo.emu_div
  SET area_code='37.2.1.17'
  WHERE eel_emu_nameshort='HR_total' AND eel_area_division='37.2.1';
UPDATE tempo.emu_div
  SET area_code='37.2.1.17'
  WHERE eel_emu_nameshort='IT_Emil' AND eel_area_division='37.2.1';
UPDATE tempo.emu_div
  SET area_code='37.2.1.17'
  WHERE eel_emu_nameshort='IT_Frio' AND eel_area_division='37.2.1';
UPDATE tempo.emu_div
  SET area_code='37.2.1.17'
  WHERE eel_emu_nameshort='IT_Lazi' AND eel_area_division='37.1.3';
UPDATE tempo.emu_div
  SET area_code='37.2.1.17'
  WHERE eel_emu_nameshort='IT_Pugl' AND eel_area_division='37.2.1';
UPDATE tempo.emu_div
  SET area_code='37.3.1.112'
  WHERE eel_emu_nameshort='IT_Sard' AND eel_area_division='37.1.3';
UPDATE tempo.emu_div
  SET area_code='37.1.3.9'
  WHERE eel_emu_nameshort='IT_Tosc' AND eel_area_division='37.1.3';
UPDATE tempo.emu_div
  SET area_code='37.2.1.17'
  WHERE eel_emu_nameshort='IT_Vene' AND eel_area_division='37.2.1';
UPDATE tempo.emu_div
  SET area_code='37.2.1.17'
  WHERE eel_emu_nameshort='SI_total' AND eel_area_division='37.2.1';
UPDATE tempo.emu_div
  SET area_code='37.2.2.13'
  WHERE eel_emu_nameshort='TN_EC' AND eel_area_division='37.2.2';
UPDATE tempo.emu_div
  SET area_code='37.1.3.12'
  WHERE eel_emu_nameshort='TN_NE' AND eel_area_division='37.1.3';
UPDATE tempo.emu_div
  SET area_code='37.1.3.12'
  WHERE eel_emu_nameshort='TN_Nor' AND eel_area_division='37.1.3';
UPDATE tempo.emu_div
  SET area_code='37.2.2.14'
  WHERE eel_emu_nameshort='TN_SO' AND eel_area_division='37.2.2';

DELETE FROM tempo.emu_div
  WHERE eel_emu_nameshort='ES_Mino' AND eel_area_division='37.1.1';
DELETE FROM tempo.emu_div
  WHERE eel_emu_nameshort='ES_Vale' AND eel_area_division='37.1.2';
DELETE FROM tempo.emu_div
  WHERE eel_emu_nameshort='IT_Pugl' AND eel_area_division='37.2.2';
UPDATE tempo.emu_div
  SET area_code='37.1.1.5'
  WHERE eel_emu_nameshort='ES_Bale' AND eel_area_division='37.1.1';
UPDATE tempo.emu_div
  SET area_code='37.1.1.6'
  WHERE eel_emu_nameshort='ES_Cata' AND eel_area_division='37.1.1';
UPDATE tempo.emu_div
  SET area_code='27.9.a'
  WHERE eel_emu_nameshort='ES_Minh' AND eel_area_division='27.9.a';
UPDATE tempo.emu_div
  SET area_code='27.9.a'
  WHERE eel_emu_nameshort='ES_Mino' AND eel_area_division='27.9.a';
UPDATE tempo.emu_div
  SET area_code='37.1.1.6'
  WHERE eel_emu_nameshort='ES_Vale' AND eel_area_division='37.1.1';
UPDATE tempo.emu_div
  SET area_code='37.1.1.1'
  WHERE eel_emu_nameshort='ES_Murc' ;
UPDATE tempo.emu_div
  SET area_code='27.3.d'
  WHERE eel_emu_nameshort='LT_total' AND eel_area_division='27.3.d';
UPDATE tempo.emu_div
  SET area_code='27.3.a'
  WHERE eel_emu_nameshort='NO_total' AND eel_area_division='27.3.a';
UPDATE tempo.emu_div
  SET area_code='27.4.a'
  WHERE eel_emu_nameshort='NO_total' AND eel_area_division='27.4.a';
UPDATE tempo.emu_div
  SET area_code='27.2.a'
  WHERE eel_emu_nameshort='NO_total' AND eel_area_division='27.7.a';
UPDATE tempo.emu_div
  SET area_code='27.3.d'
  WHERE eel_emu_nameshort='PL_total' AND eel_area_division='27.3.d';
UPDATE tempo.emu_div
  SET 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_div
  SET area_code='27.3.d'
  WHERE eel_emu_nameshort='SE_Ea_o' AND eel_area_division='27.3.d';
UPDATE tempo.emu_div
  SET area_code='27.3.d'
  WHERE eel_emu_nameshort='SE_So_o' AND eel_area_division='27.3.d';
UPDATE tempo.emu_div
  SET area_code='37.3.1.22'
  WHERE eel_emu_nameshort='GR_total' AND eel_area_division='37.3.1' ;
  

 
 

  

  
  
INSERT INTO tempo.emu_div (eel_cou_code,eel_emu_nameshort,area_code)
  VALUES ('EE','EE_West','27.3.d')
INSERT INTO tempo.emu_div (eel_cou_code,eel_emu_nameshort,area_code)
  VALUES ('EE','EE_West','27.3.d')  

INSERT INTO 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)
SELECT
eel_id AS sto_id
, m.met_var AS sto_met_var
, e.eel_year AS sto_year
, '127186' 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
, CASE 
      WHEN e.eel_hty_code = 'AL' THEN NULL
      WHEN 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 IS NULL THEN NULL
      ELSE 'TROUBLE' END AS 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
, CASE
     WHEN 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' END AS sto_ver_code
FROM datwgeel.t_eelstock_eel e 
JOIN dateel.t_metadata_met m ON m.met_type::int = e.eel_typ_id
LEFT JOIN 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 IS NOT NULL
AND e.eel_area_division IS NOT NULL; -- 1295

--------------------------------------------------------
-- insert coastal waters where eel_area_division is NULL
--------------------------------------------------------

CREATE TABLE tempo.emu_null AS SELECT * FROM tempo.emu_div WHERE
eel_emu_nameshort IN (SELECT DISTINCT eel_emu_nameshort FROM
datwgeel.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 IS NOT NULL
AND e.eel_area_division IS NULL)

-- 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.
DELETE FROM tempo.emu_null
  WHERE eel_emu_nameshort='DK_Mari' AND eel_area_division='27.3.a';
DELETE FROM tempo.emu_null
  WHERE eel_emu_nameshort='DK_Mari' AND eel_area_division='27.4.b';
DELETE FROM tempo.emu_null
  WHERE eel_emu_nameshort='DE_Warn' AND eel_area_division='27.3.b, c';
DELETE FROM tempo.emu_null
  WHERE eel_emu_nameshort='SE_East' AND eel_area_division='27.3.a';
DELETE FROM tempo.emu_null
  WHERE eel_emu_nameshort='SE_East' AND eel_area_division='27.3.b, c';
DELETE FROM tempo.emu_null
  WHERE eel_emu_nameshort='NO_total' AND eel_area_division='27.4.a';
DELETE FROM tempo.emu_null
  WHERE eel_emu_nameshort='NO_total' AND eel_area_division='27.7.a';



INSERT INTO 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)
SELECT
eel_id AS sto_id
, m.met_var AS sto_met_var
, e.eel_year AS sto_year
, '127186' 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
, CASE 
      WHEN e.eel_hty_code = 'AL' THEN NULL
      WHEN 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 IS NULL THEN NULL
      ELSE 'TROUBLE' END AS 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
, CASE
     WHEN 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' END AS sto_ver_code
FROM datwgeel.t_eelstock_eel e 
JOIN dateel.t_metadata_met m ON m.met_type::int = e.eel_typ_id
LEFT JOIN 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 IS NOT NULL
AND e.eel_area_division IS NULL
AND e. eel_emu_nameshort != 'SE_total'; -- 1057

SELECT * FROM datwgeel.t_eelstock_eel WHERE eel_id ='567218';

SELECT * FROM datwgeel.t_eelstock_eel WHERE 
eel_qal_id IN (0,1,2,3,4)
AND eel_hty_code ='C'
AND eel_value IS NOT NULL
AND eel_area_division IS NULL
AND eel_emu_nameshort = 'SE_total'; --4 lines


-- TODO eel_percent
-- TODO see later TO INSERT deprecated values

The full WGEEL database was imported in 2025. In 2026 there will be one last datacall using the previous database and shiny interface before switching to the new format.

The remaining issues are here :

Integrate the latest version of WGEEL database #29

4.3 WGBAST

4.3.1 Metadata (datbast.t_metadata_met)

SQL code to create table datbast.t_metadata_met
DROP TABLE IF EXISTS datbast.t_metadata_met CASCADE;

CREATE TABLE datbast.t_metadata_met(
 CONSTRAINT t_metadata_met_pkey PRIMARY KEY(met_var, met_spe_code),
 CONSTRAINT fk_met_spe_code FOREIGN KEY (met_spe_code)
  REFERENCES ref.tr_species_spe(spe_code) 
  ON UPDATE CASCADE ON DELETE RESTRICT,
 CONSTRAINT ck_met_spe_code CHECK 
 (met_spe_code='127186' OR met_spe_code='127187'),
 CONSTRAINT fk_met_wkg_code FOREIGN KEY (met_wkg_code)
  REFERENCES ref.tr_icworkinggroup_wkg(wkg_code) 
  ON UPDATE CASCADE ON DELETE RESTRICT,
  CONSTRAINT ck_met_wkg_code CHECK (met_wkg_code='WGBAST'),
  CONSTRAINT fk_met_ver_code FOREIGN KEY (met_ver_code)
  REFERENCES refbast.tr_version_ver(ver_code) 
  ON UPDATE CASCADE ON DELETE RESTRICT,
  CONSTRAINT fk_met_odi_code FOREIGN KEY (met_odi_code) 
  REFERENCES ref.tr_objectdimension_odi (odi_code) 
  ON UPDATE CASCADE ON DELETE RESTRICT,
  CONSTRAINT fk_met_bty_code FOREIGN KEY (met_bty_code) 
  REFERENCES ref.tr_bayestype_bty (nim_code) 
  ON UPDATE CASCADE ON DELETE RESTRICT,  
  CONSTRAINT fk_met_sta_code FOREIGN KEY (met_sta_code)
  REFERENCES ref.tr_statistic_sta(sta_code)
  ON UPDATE CASCADE ON DELETE RESTRICT,
  CONSTRAINT fk_met_uni_code FOREIGN KEY (met_uni_code)
  REFERENCES ref.tr_units_uni(uni_code)
  ON UPDATE CASCADE ON DELETE RESTRICT,
  CONSTRAINT fk_met_cat_code FOREIGN KEY (met_cat_code)
  REFERENCES ref.tr_category_cat(cat_code)
  ON UPDATE CASCADE ON DELETE RESTRICT,
  CONSTRAINT fk_met_des_code FOREIGN KEY (met_des_code)
  REFERENCES ref.tr_destination_des(des_code)
  ON UPDATE CASCADE ON DELETE RESTRICT
)
INHERITS (dat.t_metadata_met);


--  COMMENTS FOR WGEEL

COMMENT ON TABLE datbast.t_metadata_met IS 
'Table (metadata) of each variable (parameter) in the wgeel database.';
COMMENT ON COLUMN datbast.t_metadata_met.met_var 
IS 'Variable code, primary key on both met_spe_code and met_var.';
COMMENT ON COLUMN datbast.t_metadata_met.met_spe_code 
IS 'Species aphiaID, text ''127186'' salmo salar OR ''127187'' for Salmo trutta primary key on both met_spe_code and met_var.';
COMMENT ON COLUMN datbast.t_metadata_met.met_ver_code 
IS 'Code on the version of the model, see table refeel.tr_version_ver.';
COMMENT ON COLUMN datbast.t_metadata_met.met_odi_code 
IS 'Object type, single_value, vector, matrix see table tr_objectdimension_odi.';
COMMENT ON COLUMN datbast.t_metadata_met.met_bty_code 
IS 'Nimble type, one of data, constant, output, other.';
COMMENT ON COLUMN 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).';
COMMENT ON COLUMN datbast.t_metadata_met.met_dimname 
IS 'Dimension of the variable in Nimble, use {''year'', ''stage'', ''area''}.';
COMMENT ON COLUMN datbast.t_metadata_met.met_modelstage 
IS 'Currently one of fit, other, First year.';
COMMENT ON COLUMN datbast.t_metadata_met.met_type 
IS 'Type of data in the variable, homewatercatches, Initialisation first year,
abundance ....';
COMMENT ON COLUMN datbast.t_metadata_met.met_location 
IS 'Describe process with geographical information';
COMMENT ON COLUMN datbast.t_metadata_met.met_fishery 
IS 'Description of the fishery.';
COMMENT ON COLUMN 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';
COMMENT ON COLUMN datbast.t_metadata_met.met_uni_code 
IS 'Unit, datbasterences table tr_unit_uni.';
COMMENT ON COLUMN datbast.t_metadata_met.met_cat_code 
IS 'Broad category of data or parameter, 
catch, effort, biomass, mortality, count ...datbasterences table tr_category_cat.';
COMMENT ON COLUMN datbast.t_metadata_met.met_sta_code 
IS 'Code of the metric, datbasterences tr_statistic_sta, Estimate, Bound, SD, CV ....';
COMMENT ON COLUMN datbast.t_metadata_met.met_definition 
IS 'Definition of the metric.';
COMMENT ON COLUMN datbast.t_metadata_met.met_deprecated
IS'Is the variable still used ?';



ALTER TABLE datbast.t_metadata_met OWNER TO diaspara_admin;
GRANT SELECT ON 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. The table is inherited in postgres and will have 3 more columns that the mother table. This is already the case for the WGNAS stock table which has one more column (to store some extra dimension) than WGEEL. The three additional columns will be 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.

  • When the data will be resubmitted in the final format (in a future data call) the following elements will require attention from WGBAST. There is an ALV ALL in gears, which is probably an error, and there are 138 rows without f_type we need to check that they can be attributed to COMM

4.3.2 Version (refbast.tr_version_ver)

Creating the version referential for WGBAST

DROP TABLE IF EXISTS refbast.tr_version_ver CASCADE;
CREATE TABLE refbast.tr_version_ver() inherits (ref.tr_version_ver);

ALTER TABLE refbast.tr_version_ver ADD CONSTRAINT ver_code_pkey PRIMARY KEY (ver_code);
ALTER TABLE refbast.tr_version_ver ADD CONSTRAINT  fk_ver_spe_code FOREIGN KEY (ver_spe_code) 
REFERENCES ref.tr_species_spe(spe_code)
ON UPDATE CASCADE ON DELETE CASCADE;

COMMENT ON TABLE refbast.tr_version_ver
IS 'Table of data or variable version, essentially one datacall or advice, inherits ref.tr_version_ver';

COMMENT ON COLUMN refbast.tr_version_ver.ver_code 
IS 'Version code, stockkey-year-version.';
COMMENT ON COLUMN refbast.tr_version_ver.ver_year 
IS 'Year of assessement.';
COMMENT ON COLUMN refbast.tr_version_ver.ver_spe_code 
IS 'Species code left NULL for WGBAST as the data call references several species';
COMMENT ON COLUMN refbast.tr_version_ver.ver_stockkeylabel 
IS 'Ver_stockkeylabel e.g. ele.2737.nea.';
COMMENT ON COLUMN refbast.tr_version_ver.ver_datacalldoi 
IS 'Data call DOI, find a way to retrieve that information 
and update this comment';
COMMENT ON COLUMN refbast.tr_version_ver.ver_version 
IS 'Version code corresponding to numbering of the versions';
COMMENT ON COLUMN refbast.tr_version_ver.ver_description 
IS 'Description of the data call / version.';
GRANT ALL ON refbast.tr_version_ver TO diaspara_admin;
GRANT SELECT ON 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 = "127186",
  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 year
  ver_description=c(NA,NA,NA,NA,NA)) # TODO WGNAS provide model description

DBI::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;") # 5
DBI::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 year
  ver_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 description

DBI::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;") # 2
DBI::dbExecute(con_diaspara_admin, "DROP TABLE temp_tr_version_ver;")

4.4 Estimation method (datbast.tr_estimationmethod_esm)

The development of referentials for datasource, databasis, and estimation method is explained in the referential part. Here we provide the code for the estimation method table specific to WGBAST.

Creating the estimation method referential for WGBAST
-- Table of estimation methods when databasis is Estimated

DROP TABLE IF EXISTS refbast.tr_estimationmethod_esm CASCADE;
CREATE  TABLE refbast.tr_estimationmethod_esm () inherits (ref.tr_estimationmethod_esm);
ALTER TABLE refbast.tr_estimationmethod_esm ALTER COLUMN esm_wkg_code SET DEFAULT 'WGBAST';
ALTER TABLE refbast.tr_estimationmethod_esm ADD CONSTRAINT uk_esm_code UNIQUE (esm_code);
COMMENT ON TABLE refbast.tr_estimationmethod_esm IS 'Table of table estimation method, provided when databasis (dtb_code) correspond to Estimated';
COMMENT ON COLUMN refbast.tr_estimationmethod_esm.esm_code IS 'Estimation method code';
COMMENT ON COLUMN refbast.tr_estimationmethod_esm.esm_description IS 'Estimation method  description';
COMMENT ON COLUMN refbast.tr_estimationmethod_esm.esm_icesvalue IS 'Code (Key) of the Estimation method in ICES';
COMMENT ON COLUMN refbast.tr_estimationmethod_esm.esm_icesguid IS 'UUID (guid) of ICES ';
COMMENT ON COLUMN refbast.tr_estimationmethod_esm.esm_icestablesource IS 'Source table in ICES';

GRANT ALL ON refbast.tr_estimationmethod_esm TO diaspara_admin;
GRANT SELECT ON 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_icestablesource
FROM temp_esmr")# 8
DBI::dbExecute(con_diaspara_admin, "DROP table temp_esmr")

4.4.1 Create datbast.t_metadata_met

Note that there is a slight difference between the metadata table between WGBAST and the two other working groups. We indeed need to integrate the same variables twice, first for salmon, and then for trutta. These are no duplicates as the primary key is set on both 127187 (Salmo trutta) and 127186 (Salmon salar).

Code to import to metadata for wgbast.
# t_metadata_met


df_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] <- NA
df_all <- df_all |>
  mutate(tp_type=ifelse(tp_type=="QRT", "QTR", tp_type), 
         gear=ifelse(gear=="GNS", "MIS", gear), # Tapani comment
         w_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)=GNS

df_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 OK
typ <- 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 back
met_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/p7stock/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 = "127187",
    met_wkg_code = "WGBAST",
    met_ver_code = "WGBAST-2025-1", 
    met_odi_code = "Single_value", #  https://diaspara.bordeaux-aquitaine.inrae.fr/deliverables/wp3/p7stock/midb.html#object-type-tr_objectype_oty
    met_bty_code =  "Data", # https://diaspara.bordeaux-aquitaine.inrae.fr/deliverables/wp3/p7stock/midb.html#type-of-parm-data-tr_bayestype_bty
    met_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-4
    met_location = NA, # something line bef. Fisheries Aft fisheries.... not a referential
    met_fishery = NA, # not a referential
    met_sta_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/p7stock/midb.html#destination-tr_destination_dest
    met_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_TRS
t_metadata_met_SAL$met_spe_code<- "127186"


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_odi_code, met_bty_code, met_dim, met_dimname, met_modelstage, met_type, met_location, met_fishery, met_sta_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_odi_code, met_bty_code, met_dim::integer[], met_dimname::text[], met_modelstage, met_type, met_location, met_fishery, met_sta_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 Becky
scalar <- 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 = "127186",
    met_wkg_code = "WGBAST",
    met_ver_code = "WGBAST-2025-1", 
    met_odi_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/p7stock/midb.html#object-type-tr_objectype_oty
    met_bty_code =  ifelse(array$type == "stockastic", "Data", "Output"), #scenarios or stockastic TODO check consistency with WGNAS https://diaspara.bordeaux-aquitaine.inrae.fr/deliverables/wp3/p7stock/midb.html#type-of-parm-data-tr_bayestype_bty
    met_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-4
    met_location = NA, # something line bef. Fisheries Aft fisheries.... not a referential
    met_fishery = NA, # not a referential
    met_sta_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/p7stock/midb.html#destination-tr_destination_dest
    met_uni_code = NA,
    met_cat_code = NA, # TODO
met_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 = "127186",
    met_wkg_code = "WGBAST",
    met_ver_code = "WGBAST-2025-1", 
    met_odi_code =  "Single_value",  
    met_bty_code =  ifelse(scalar$type == "stochastic", "Data", "Output"), #scenarios or stochastic TODO check consistency with WGNAS https://diaspara.bordeaux-aquitaine.inrae.fr/deliverables/wp3/p7stock/midb.html#type-of-parm-data-tr_bayestype_bty
    met_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-4
    met_location = NA, # something line bef. Fisheries Aft fisheries.... not a referential
    met_fishery = NA, # not a referential
    met_sta_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/p7stock/midb.html#destination-tr_destination_dest
    met_uni_code = NA,
    met_cat_code = NA, # TODO
met_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_odi_code, met_bty_code, met_dim, met_dimname, met_modelstage, met_type, met_location, met_fishery, met_sta_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_odi_code, met_bty_code, met_dim::integer[], met_dimname::text[], met_modelstage, met_type, met_location, met_fishery, met_sta_code, met_des_code, met_uni_code, met_cat_code, met_definition, met_deprecated FROM temp_wgbast_t_metadata_met") #117

4.4.2 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
  1. .
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.
-- delete from datbast.t_stock_sto;
DROP TABLE IF EXISTS datbast.t_stock_sto;
CREATE TABLE datbast.t_stock_sto (
    sto_gear_code text,
  CONSTRAINT fk_sto_gear_code FOREIGN KEY (sto_gear_code) 
    REFERENCES  ref.tr_gear_gea(gea_code)
    ON UPDATE CASCADE ON DELETE RESTRICT,  
    sto_tip_code TEXT,
  CONSTRAINT fk_tip_code FOREIGN KEY (sto_tip_code)
    REFERENCES  ref.tr_timeperiod_tip(tip_code)
    ON UPDATE CASCADE ON DELETE RESTRICT,  
    sto_timeperiod integer NOT NULL,
    sto_dts_code TEXT,
  CONSTRAINT fk_sto_dts_code FOREIGN KEY (sto_dts_code) 
    REFERENCES ref.tr_datasource_dts(dts_code)
    ON UPDATE CASCADE ON DELETE RESTRICT,
   sto_dtb_code TEXT,
  CONSTRAINT fk_sto_dtb_code FOREIGN KEY (sto_dtb_code) 
    REFERENCES ref.tr_databasis_dtb(dtb_code)
    ON UPDATE CASCADE ON DELETE RESTRICT, 
  sto_esm_code TEXT,
  CONSTRAINT fk_sto_esm_code FOREIGN KEY (sto_esm_code)
    REFERENCES refbast.tr_estimationmethod_esm(esm_code)
    ON UPDATE CASCADE ON DELETE RESTRICT,   
  CONSTRAINT fk_sto_met_var_met_spe_code
    FOREIGN KEY (sto_met_var, sto_spe_code) 
    REFERENCES datbast.t_metadata_met(met_var,met_spe_code)
    ON UPDATE CASCADE ON DELETE RESTRICT,
  CONSTRAINT fk_sto_are_code FOREIGN KEY (sto_are_code)
    REFERENCES refbast.tr_area_are (are_code) 
    ON UPDATE CASCADE ON DELETE RESTRICT,
  CONSTRAINT fk_sto_cou_code FOREIGN KEY (sto_cou_code)
    REFERENCES ref.tr_country_cou (cou_code)
    ON UPDATE CASCADE ON DELETE RESTRICT,
  CONSTRAINT fk_sto_lfs_code_sto_spe_code FOREIGN KEY (sto_lfs_code, sto_spe_code)
    REFERENCES ref.tr_lifestage_lfs (lfs_code, lfs_spe_code) 
    ON UPDATE CASCADE ON DELETE RESTRICT,
  CONSTRAINT fk_hty_code FOREIGN KEY (sto_hty_code)
    REFERENCES ref.tr_habitattype_hty(hty_code) 
    ON UPDATE CASCADE ON DELETE RESTRICT,
  CONSTRAINT fk_sto_qal_code FOREIGN KEY (sto_qal_code)
    REFERENCES ref.tr_quality_qal(qal_code)
    ON UPDATE CASCADE ON DELETE RESTRICT,
  CONSTRAINT fk_sto_mis_code FOREIGN KEY (sto_mis_code)
  REFERENCES ref.tr_missvalueqal_mis (mis_code)
  ON UPDATE CASCADE ON DELETE RESTRICT,
  CONSTRAINT fk_dta_code FOREIGN KEY (sto_dta_code)
  REFERENCES ref.tr_dataaccess_dta(dta_code) 
  ON UPDATE CASCADE ON DELETE RESTRICT, 
  CONSTRAINT fk_sto_wkg_code  FOREIGN KEY (sto_wkg_code)
  REFERENCES ref.tr_icworkinggroup_wkg(wkg_code)
  ON UPDATE CASCADE ON DELETE RESTRICT, 
  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 IS NULL) AND (sto_value IS NOT NULL)) OR 
  ((sto_mis_code IS NOT NULL) AND (sto_value IS NULL))))

)
inherits (dat.t_stock_sto) ;

-- This table will always be for WGBAST

ALTER TABLE datbast.t_stock_sto ALTER COLUMN sto_spe_code SET DEFAULT NULL;
ALTER TABLE datbast.t_stock_sto ADD CONSTRAINT ck_spe_code CHECK (sto_spe_code='127186' OR sto_spe_code='127187');
ALTER TABLE datbast.t_stock_sto ALTER COLUMN sto_wkg_code SET DEFAULT 'WGBAST';
ALTER TABLE datbast.t_stock_sto ADD CONSTRAINT ck_wkg_code CHECK (sto_wkg_code='WGBAST');



ALTER TABLE datbast.t_stock_sto OWNER TO diaspara_admin;
GRANT ALL ON TABLE datbast.t_stock_sto TO diaspara_read;




COMMENT ON TABLE 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 corresponds
to the catch excel table in the original WGBAST database.';
COMMENT ON COLUMN datbast.t_stock_sto.sto_id IS 'Integer serial identifying. Only unique in this table
when looking at the pair, sto_id, sto_wkg_code';
COMMENT ON COLUMN 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';
COMMENT ON COLUMN 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';
COMMENT ON COLUMN datbast.t_stock_sto.sto_timeperiod IS 'An integer giving the value of the time period used';
COMMENT ON COLUMN 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;';
COMMENT ON COLUMN 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';
COMMENT ON COLUMN datbast.t_stock_sto.sto_esm_code IS 'Code of the estimation method, one of smolt1, ...';
COMMENT ON COLUMN 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 based
on 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.
COMMENT ON COLUMN datbast.t_stock_sto.sto_year IS 'Year';
COMMENT ON COLUMN datbast.t_stock_sto.sto_value IS 'Value if null then provide a value in sto_mis_code to explain why not provided';
COMMENT ON COLUMN 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.';
COMMENT ON COLUMN datbast.t_stock_sto.sto_cou_code IS 'Code of the country see tr_country_cou, not null';
COMMENT ON COLUMN 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.';
COMMENT ON COLUMN 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';
COMMENT ON COLUMN 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';
COMMENT ON COLUMN datbast.t_stock_sto.sto_qal_comment IS 'Comment for the quality, for instance explaining why a data is qualified as good or dubious.';
COMMENT ON COLUMN datbast.t_stock_sto.sto_comment IS 'Comment on the value';
COMMENT ON COLUMN datbast.t_stock_sto.sto_datelastupdate IS 'Last update of the data';
COMMENT ON COLUMN 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).';
COMMENT ON COLUMN datbast.t_stock_sto.sto_dta_code IS 'Access to data, default is ''Public''';
COMMENT ON COLUMN datbast.t_stock_sto.sto_wkg_code IS 'Code of the working group, one of
WGBAST, WGEEL, WGNAS, WKTRUTTA';
COMMENT ON COLUMN 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 date
DROP FUNCTION IF EXISTS datbast.update_sto_datelastupdate CASCADE;
CREATE OR REPLACE FUNCTION datbast.update_sto_datelastupdate()
 RETURNS trigger
 LANGUAGE plpgsql
AS $function$
BEGIN
    NEW.sto_datelastupdate = now()::date;
    RETURN NEW; 
END;
$function$
;

ALTER FUNCTION datbast.update_sto_datelastupdate() OWNER TO diaspara_admin;


CREATE TRIGGER update_sto_datelastupdate BEFORE
INSERT
    OR
UPDATE
    ON
    datbast.t_stock_sto FOR EACH ROW EXECUTE FUNCTION datbast.update_sto_datelastupdate();



-- trigger to check consistency between sto_timeperiod and sto_tip_code
-- Mon
CREATE OR REPLACE FUNCTION datbast.check_time_period()
 RETURNS TRIGGER 
 LANGUAGE plpgsql
AS $check_time_period$
BEGIN
   -- sto_timeperiod is always positive or NULL
   -- if sto_tip_code = "YR" keep sto_timeperiod NULL
    IF (NEW.sto_tip_code = 'Year' AND NEW.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';
    END IF;
     -- if sto_tip_code = "QTR" check 1 2 3 or 4
    IF (NEW.sto_tip_code = '>Quarter' AND NEW.sto_timeperiod > 4) THEN
    RAISE EXCEPTION 'sto_timeperiod should be 1, 2, 3 or 4 for quarters';
    END IF; 
    -- half of year is one or two        
    IF (NEW.sto_tip_code = 'Half of Year' AND NEW.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)' ;
    END IF;
    -- half of year is one or two        
    IF (NEW.sto_tip_code = 'Month' AND NEW.sto_timeperiod > 12) THEN
    RAISE EXCEPTION 'sto_timeperiod should be 1 to 12 when the code for timeperiod (sto_tip_code) is MON (Month)';
    END IF;
    RETURN NEW; 
END;
$check_time_period$;

ALTER FUNCTION datbast.check_time_period() OWNER TO diaspara_admin;

DROP TRIGGER IF EXISTS trg_check_time_period ON datbast.t_stock_sto ;
CREATE TRIGGER trg_check_time_period BEFORE
INSERT
    OR
UPDATE
    ON
    datbast.t_stock_sto FOR EACH ROW EXECUTE FUNCTION 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_type
df_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 year
id_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 0
df_all[df_all$tp_type=='YR'& df_all$time_period!=0,"time_period"]<- 0 
# Year should be YR in the initial dataset
df_all[df_all$tp_type=="Year" & !is.na(df_all$tp_type),"tp_type"] <- "YR"
# missing tp_type
df_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"]<- "127186"
df_all[is.na(df_all$species) ,"species"]<- "127186"
df_all[df_all$species=="NA" ,"species"]<- "127186"





# 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 data
riv <- 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 Numbers
df_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 content
df_all_N$n_type2 <- df_all_N$n_type
df_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$notes
df_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 this
  sto_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 error
                            is.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)) # 27s
dbExecute(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") # 14402
dbExecute(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 content
df_all_W$w_type2 <- df_all_W$w_type
df_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_W$w_type2[!is.na(df_all_W$notes)] <- paste0(", ",df_all_W$w_type2[!is.na(df_all_W$notes)])
df_all_W$w_type2[is.na(df_all_W$w_type)]<- ""
df_all_W$notes2 <- df_all_W$notes
df_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==""] <- NA

t_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 this
  sto_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 error
                            is.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.14
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_w") #17334
dbExecute(con_diaspara_local, "drop table temp_t_stock_sto_w")

# Insert Effort


df_all_e <- df_all |>
  filter(!is.na(effort)) |>
  mutate(f_type = ifelse(is.na(f_type), "HIST", f_type)) |>
  mutate(sto_met_var = paste0("E_",f_type))

# unit allows to avoid having NA in strings ... Here we put additional info in the comment from the content
df_all_e$w_type2 <- df_all_e$w_type
df_all_e$w_type2[!is.na(df_all_e$w_type)]<-paste0("W_type=",df_all_e$w_type2[!is.na(df_all_e$w_type)])
df_all_e$w_type2[!is.na(df_all_e$notes)] <-paste0(", ",df_all_e$w_type2[!is.na(df_all_e$notes)])
df_all_e$w_type2[is.na(df_all_e$w_type)]<- ""
df_all_e$notes2 <- df_all_e$notes
df_all_e$notes2[is.na(df_all_e$notes2)] <- ""
df_all_e$notes2<- paste0(df_all_e$notes2,df_all_e$w_type2)
df_all_e$notes2[df_all_e$notes2==""] <- NA

t_stock_sto_e = data.frame(
  sto_met_var = df_all_e$sto_met_var,
  sto_year = df_all_e$year,
  sto_spe_code = df_all_e$species,
  sto_value = df_all_e$effort,
  # if it's a river get the code of the river otherwise get other codes....
  sto_are_code = case_when(!is.na(df_all_e$river) ~ df_all_e$riv_are_code,
                           df_all_e$sub_div == "22-32" ~ "27.3.d", # correct, 3 lines corresponding to national survey Estonia
                           df_all_e$sub_div == "200" ~ "27.3.d.22-29",
                           df_all_e$sub_div == "300" ~ "27.3.d.30-31",
                           df_all_e$sub_div == "32"  ~  "27.3.d.32",
                           df_all_e$sub_div == "31"  ~  "27.3.d.31",
                           df_all_e$sub_div == "30"  ~  "27.3.d.30",
                           df_all_e$sub_div == "29"  ~  "27.3.d.29",
                           df_all_e$sub_div == "27"  ~  "27.3.d.27",
                           df_all_e$sub_div == "26"  ~  "27.3.d.26",
                           df_all_e$sub_div == "25"  ~  "27.3.d.25",
                           df_all_e$sub_div == "24"  ~  "27.3.d.24",
                           df_all_e$sub_div == "23"  ~  "27.3.b.23",
                           df_all_e$sub_div == "22"  ~  "27.3.c.22",
                           df_all_e$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_e$sub_div == "28" & df_all_e$subdiv_ic == '27.3.d.28.1' ~ '27.3.d.28.1',
                           df_all_e$sub_div == "28" & df_all_e$subdiv_ic == '27.3.d.28.2' ~ '27.3.d.28.2',
                           df_all_e$sub_div == "28"  ~  "27.3.d.28",
                           is.na(df_all_e$sub_div)   ~   "27.3.d" # 12 rows with with comments corresponds all catches of the country and year concerned
                           ),
  sto_cou_code = df_all_e$country,
  sto_lfs_code = 'A',
  sto_hty_code = case_when(df_all_e$fishery == "O" ~ "MO",
                           df_all_e$fishery == "C"~  "MC",
                           df_all_e$fishery == "R" ~ "FW"),
  sto_qal_code = 1,
  sto_comment = df_all_e$notes2,
  sto_datelastupdate = Sys.Date(),
  sto_mis_code = NA,
  sto_dta_code = "Public", # check this
  sto_wkg_code = "WGBAST",
  sto_ver_code = "WGBAST-2025-1",
  sto_gear_code  = df_all_e$gea_code,
  sto_tip_code  = case_when(df_all_e$tp_type == "YR" ~"Year",
                            df_all_e$tp_type == "HYR" ~ "Half of Year",
                            df_all_e$tp_type == "MON" ~ "Month",
                            df_all_e$tp_type == "MONTH" ~ "Month",
                            df_all_e$tp_type == "QTR" ~ "Quarter",
                            df_all_e$tp_type == "COMM" ~ "Quarter", # this is an error
                            is.na( df_all_e$tp_type) ~ "Year",
                            .default = "Troube this will fail at insertion"),
  sto_timeperiod = df_all_e$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_e$n_type == "LOG" ~ "Logb",
                                 df_all_e$n_type == "EXV" ~ "Exprt",
                                 df_all_e$n_type == "EST" & (grepl("survey",tolower(df_all_e$notes)) | 
                                                           grepl("question",tolower(df_all_e$notes)) |
                                                           grepl("query", tolower(df_all_e$notes)) |
                                                           grepl("web", tolower(df_all_e$notes))) ~ "SampDS", 
                                df_all_e$n_type == "EXT" ~ NA),
  sto_dtb_code = case_when(df_all_e$n_type == "LOG" ~ "Official",
                           df_all_e$n_type == "EXV"  ~  "Estimated",
                           df_all_e$n_type == "EST" ~ "Estimated",
                           df_all_e$n_type == "EXT" ~ "Estimated",
                           .default =  "Unknown"),
  sto_esm_code = NA
)  

#dbExecute(con_diaspara_admin, "drop table if exists temp_t_stock_sto_e")
dbExecute(con_diaspara_local, "drop table if exists temp_t_stock_sto_e")
system.time(dbWriteTable(con_diaspara_local, "temp_t_stock_sto_e", t_stock_sto_e)) # 0.14
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_e") #17334
dbExecute(con_diaspara_local, "drop table temp_t_stock_sto_e")


# Insert N_CI

# This is a bit too difficult, it's not always consistent. Could do when values are sepearated by a dash,
# but it's not always the case. There aren't that many values, should be checked.

# Insert W_CI

## WGBAST corrections made to the dataset 
#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 (it should be a time period) => Assigned to Year, please check

## TODO WGBAST : n_type and w_type
# Currently, 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).

5 SERIES AND TRAITS

Alongside the Stock, another data structure was initially developped by WGEEL and called the Metrics Database. It stores information about time series of abundance, recruitment or escapement data collected at individual locations (or group of locations). Its purpose is to store biological traits and individual‑ or group‑level measurements, which are required to interpret population patterns and to support analyses of life‑history processes. In DIASPARA, these metrics include the Life History Traits (LHT) defined in WP2, but the scope is broader: the Metrics DB also holds biological data associated with monitoring activities typically undertaken in WGEEL and WGBAST. For instance, trap operations or parr surveys not only produce abundance indices (stored in the Stock DB) but also generate biological measurements—size, condition, sex, contaminant levels, parasite presence which belong in the Metrics DB (Figure 19).

Figure 22: Conceptual illustration of the content of the metric database, basically a sampling site with data on series, average biological data attached to the annual data at the site (group traits) and individual trait data.

In the wgeel database, two different data structure coexisted.

The first was developed initially to store data about the series used in recruitment data. In practice, it consisted of three tables, the t_series_ser (Figure Figure 23 - top in blue) table contains series id and description, with columns describing the sampling details, the stage used, the method… This was the main identifier of the series which was be used as a reference in all dependent tables. The second t_dataseries_das table (Figure Figure 23 - on the right) held data about annual values in series. These were typically annual counts for recruitment, along with additional effort data. Linked to these were group metric series used to describe the series, mean age of eel, mean size, proportion of glass eel among the yellow eels, proportion of females … (Figure Figure 23 - in orange) Finally, individual metrics were all details for one fish. And they concerned metrics like size, weight, sex, but also can hold data about quality, contamination. So these are in essence the Life History traits analysed by WP2 in DIASPARA (Figure Figure 23 - in pink).

The second type of data was developed to hold the data collected from the DCF. These were metrics collected from landings, data coming from the analysis of electrofishing data, or other experimental sampling that are not reported as series. Currently, sampling of commercial fisheries should be held in the RDBES, and any commercial sampling data in the WGEEL will be removed and replaced by a data streaming from RDBES. The way to collect these data from the RDBES, and merge them with the actual trait data needs to be worked out in the future.

Figure 24: Diagram for sampling

The difference in table structure is illustrated below in tables highlighted in yellow (Figure Figure 24).

In the WGEEL database, the two structures for series and sampling were very close, the only difference was that there was no annual number linked to the sampling data, and that they were not linked to a stage in the first table. Since the two structures were very close, it was decided to merge them in a single dataset, thereby simplifying the structure of the database for WGEEL. From this basis, the inclusion of data from the Trutta, and WP2 has been tested. So in practise, future data calls could support salmon data for the series and trait part of the database.

5.1 Creating the station table

The trait data need to be related to sampling stations. See #

SQL code to create tables

/*
 * 
 * Note since the api retrieves a one to many relationship
 * in the foreign tables I need to drop foreign keys
 */

DROP TABLE IF EXISTS "ref"."StationDictionary" CASCADE;
CREATE TABLE "ref"."StationDictionary"(
"Definition" TEXT NOT NULL DEFAULT 'Station',
"HeaderRecord" TEXT NOT NULL DEFAULT 'Record',
"Station_Code" INTEGER PRIMARY KEY,
"Station_Country" TEXT NOT NULL,
--CONSTRAINT  fk_station_country 
--FOREIGN KEY ("Station_Country")
--REFERENCES ref.tr_country_cou(cou_code)
--ON UPDATE CASCADE ON DELETE CASCADE, -- possible problem here AS I don't have ALL the countries...
"Station_Name" TEXT NOT NULL,
"Station_LongName" TEXT NULL,
"Station_ActiveFromDate" CHARACTER VARYING (10) NULL, -- CHANGE I don't have that FROM the API
"Station_ActiveUntilDate" CHARACTER VARYING (10) NULL,
"Station_ProgramGovernance" TEXT  NULL,
--CONSTRAINT fk_station_programgovernance
--FOREIGN KEY ("Station_ProgramGovernance") 
--REFERENCES "ref"."PRGOV"("Key") 
--ON UPDATE CASCADE ON DELETE CASCADE,
"Station_StationGovernance" TEXT  NULL,
--CONSTRAINT fk_station_stationgovernance 
--FOREIGN KEY ("Station_StationGovernance") 
--REFERENCES "ref"."EDMO"("Key") 
--ON UPDATE CASCADE ON DELETE CASCADE,
"Station_PURPM" TEXT NULL, -- FAILS WITH NOT NULL
--CONSTRAINT fk_station
--FOREIGN KEY ("Station_PURPM") 
--REFERENCES "ref"."PURPM"("Key")
--ON UPDATE CASCADE ON DELETE CASCADE,
"Station_Latitude" NUMERIC NULL,
"Station_LatitudeRange" NUMERIC NULL,
"Station_Longitude" NUMERIC NULL,
"Station_LongitudeRange" NUMERIC NULL,
"Station_Geometry" geometry,
--CONSTRAINT ck_geom_or_latlon 
--CHECK ("Station_Geometry" IS NOT NULL 
--OR "Station_Latitude" IS NOT NULL
--OR "Station_LatitudeRange" IS NOT NULL),
"Station_DataType" TEXT NULL,
--CONSTRAINT fk_station_datatype 
--FOREIGN KEY ("Station_DataType") REFERENCES
--"ref"."Station_DTYPE"("Key")
--ON UPDATE CASCADE ON DELETE CASCADE,
"Station_WLTYP" TEXT,
--CONSTRAINT fk_station_wltype 
--FOREIGN KEY ("Station_WLTYP") 
--REFERENCES "ref"."WLTYP"("Key")
--ON UPDATE CASCADE ON DELETE CASCADE,
"Station_MSTAT" TEXT,
-- CONSTRAINT fk_station_msat
--FOREIGN KEY ("Station_MSTAT") 
--REFERENCES "ref"."MSTAT"("Key")
--ON UPDATE CASCADE ON DELETE CASCADE,
"Station_Notes" TEXT,
"Station_Deprecated" TEXT,
FOREIGN KEY ("Station_Deprecated") 
REFERENCES "ref"."Deprecated"("Key")
ON UPDATE CASCADE ON DELETE CASCADE
);

-- Not sure I'll ever need that one .....
DROP TABLE IF EXISTS "ref"."Relation";
CREATE TABLE "ref"."Relation"(
"Definiton" TEXT NOT NULL DEFAULT 'Relation',
"HeaderRecord" TEXT  NOT NULL DEFAULT 'Record',
"Relation_Code" INTEGER NOT NULL,
CONSTRAINT fk_relation_code FOREIGN KEY ("Relation_Code")
REFERENCES "ref"."StationDictionary"("Station_Code") 
ON UPDATE CASCADE ON DELETE CASCADE,
"Relation_Country" TEXT NOT NULL,
CONSTRAINT fk_relation_country 
 FOREIGN KEY ("Relation_Country")
REFERENCES ref.tr_country_cou(cou_code)
ON UPDATE CASCADE ON DELETE CASCADE,
"Relation_Name" CHARACTER VARYING(50) NOT NULL,
"Relation_ActiveFromDate" CHARACTER VARYING(10) NOT NULL,
"Relation_RelatedCode" INTEGER NOT NULL,
CONSTRAINT fk_relation_relatedCode 
FOREIGN KEY ("Relation_RelatedCode")
REFERENCES "ref"."StationDictionary"("Station_Code") 
ON UPDATE CASCADE ON DELETE CASCADE,
"Relation_RelatedCountry" TEXT NOT NULL,
CONSTRAINT fk_relation_related_country
FOREIGN KEY  ("Relation_RelatedCountry")
REFERENCES ref.tr_country_cou(cou_code)
ON UPDATE CASCADE ON DELETE CASCADE,
"Relation_RelatedName" CHARACTER VARYING(50) NOT NULL,
"Relation_RelatedActiveFromDate" CHARACTER VARYING (10) NOT NULL,
"Relation_RelationType" TEXT NOT NULL);



COMMENT ON TABLE ref."WLTYP" IS 'Water and land station type';
COMMENT ON TABLE ref."PRGOV" IS 'Program Governance referential';
COMMENT ON TABLE ref."PURPM" IS 'Purpose of monitoring';
COMMENT ON TABLE ref."MSTAT" IS 'Purpose of monitoring';
COMMENT ON TABLE ref."EDMO" IS 'European Directory of Marine Organisations (EDMO)';

Some of the constraints were adapted to enable the current loading of stations (issue 27)[https://github.com/ices-tools-prod/icesVocab/issues/27]. The following chunk creates a vocab with 14086 stations.

Code to import station
# tested 28/05/2025

library(icesStation)
system.time(
  station <- getListStation())
# user     system      spent
#    268.09        9.06     1402.47 
save(station, file = "data/station.Rdata")
# load(file = "data/station.Rdata")
initcap <- function(X) paste0(substring(X,1,1),tolower(substring(X,2, length(X))))


station <- station[station$Station_Name != 'TestBulkUload1',]
station$Station_Deprecated<- initcap(as.character(station$Station_Deprecated))

dbWriteTable(con_diaspara_admin, "temp_station", station, overwrite = TRUE)
dbExecute(con_diaspara_admin,'DELETE FROM "ref"."StationDictionary"')
dbExecute(con_diaspara_admin,'INSERT INTO "ref"."StationDictionary"
("Definition", 
"HeaderRecord", 
"Station_Code",
 "Station_Country",
 "Station_Name",
 "Station_LongName", 
"Station_ActiveFromDate", 
"Station_ActiveUntilDate",
 "Station_ProgramGovernance",
 "Station_StationGovernance", 
"Station_PURPM",
 "Station_DataType",
 "Station_WLTYP",
 "Station_MSTAT", 
"Station_Notes", 
"Station_Deprecated")
SELECT
"Definition", 
"HeaderRecord", 
"Station_Code"::INTEGER,
 "Station_Country",
 "Station_Name",
 "Station_LongName", 
"Station_ActiveFromDate", 
"Station_ActiveUntilDate",
 "Station_ProgramGovernance",
 "Station_StationGovernance", 
"Station_PURPM",
 "Station_DataType",
 "Station_WLTYP",
 "Station_MSTAT", 
"Station_Notes", 
"Station_Deprecated" 
 FROM temp_station') #14086
dbExecute(con_diaspara_admin, "DROP TABLE if exists temp_station")
Code to import station
# tested 28/05/2025

library(icesStation)
system.time(
  station <- getListStation())
#      user     system      spent
#    268.09        9.06     1402.47 
save(station, file = "data/station.Rdata")
# load(file = "data/station.Rdata")
initcap <- function(X) paste0(substring(X,1,1),tolower(substring(X,2, length(X))))


station <- station[station$Station_Name != 'TestBulkUload1',]
station$Station_Deprecated<- initcap(as.character(station$Station_Deprecated))

dbWriteTable(con_diaspara_admin, "temp_station", station, overwrite = TRUE)
dbExecute(con_diaspara_admin,'DELETE FROM "ref"."StationDictionary"')
dbExecute(con_diaspara_admin,'INSERT INTO "ref"."StationDictionary"
("Definition", 
"HeaderRecord", 
"Station_Code",
 "Station_Country",
 "Station_Name",
 "Station_LongName", 
"Station_ActiveFromDate", 
"Station_ActiveUntilDate",
 "Station_ProgramGovernance",
 "Station_StationGovernance", 
"Station_PURPM",
 "Station_DataType",
 "Station_WLTYP",
 "Station_MSTAT", 
"Station_Notes", 
"Station_Deprecated")
SELECT
"Definition", 
"HeaderRecord", 
"Station_Code"::INTEGER,
 "Station_Country",
 "Station_Name",
 "Station_LongName", 
"Station_ActiveFromDate", 
"Station_ActiveUntilDate",
 "Station_ProgramGovernance",
 "Station_StationGovernance", 
"Station_PURPM",
 "Station_DataType",
 "Station_WLTYP",
 "Station_MSTAT", 
"Station_Notes", 
"Station_Deprecated" 
 FROM temp_station') #14086
dbExecute(con_diaspara_admin, "DROP TABLE if exists temp_station")
ImportantComment on Station import

Even though a table station exists in WGEEL, it really contains no actual code from ICES. To insert data into stations, the data providers will have to check that they have an EDMO code, and then we will have to bulk load stations.

5.2 Creating the version table refeel.tr_version_ver

SQL code to create table refeel.tr_version_ver
DROP TABLE IF EXISTS refeel.tr_version_ver CASCADE;
CREATE TABLE refeel.tr_version_ver(
CONSTRAINT ver_code_pkey PRIMARY KEY (ver_code),
 CONSTRAINT  fk_ver_spe_code FOREIGN KEY (ver_spe_code) 
REFERENCES ref.tr_species_spe(spe_code)
ON UPDATE CASCADE ON DELETE CASCADE,
) inherits (ref.tr_version_ver);

COMMENT ON TABLE refeel.tr_version_ver
IS 'Table of data or variable version, essentially one datacall or advice, inherits ref.tr_version_ver';
ALTER TABLE refeel.tr_version_ver ALTER COLUMN ver_wkg_code 
SET DEFAULT 'WGEEL';

COMMENT ON TABLE refeel.tr_version_ver
IS 'Table of data or variable version, essentially one datacall or advice, inherits ref.tr_version_ver';

COMMENT ON COLUMN refeel.tr_version_ver.ver_version 
IS 'Version code, wkg-year-version.';
COMMENT ON COLUMN refeel.tr_version_ver.ver_year 
IS 'Year of assessement.';
COMMENT ON COLUMN refeel.tr_version_ver.ver_spe_code 
IS 'Species code e.g. ''127186'' Anguilla anguilla references tr_species_spe.';
COMMENT ON COLUMN refeel.tr_version_ver.ver_wkg_code 
IS 'Code of the working group,  WGEEL';
COMMENT ON COLUMN refeel.tr_version_ver.ver_stockkeylabel 
IS 'Ver_stockkeylabel e.g. ele.2737.nea.';
COMMENT ON COLUMN refeel.tr_version_ver.ver_datacalldoi 
IS 'Data call DOI, find a way to retrieve that information 
and update this comment';
COMMENT ON COLUMN refeel.tr_version_ver.ver_version 
IS 'Version code in original database, eg 2,4 for wgnas, dc_2020 for wgeel.';
COMMENT ON COLUMN refeel.tr_version_ver.ver_description 
IS 'Description of the data call / version.';
GRANT ALL ON refeel.tr_version_ver TO diaspara_admin;
GRANT SELECT ON refeel.tr_version_ver TO diaspara_read;

This table is the same as in wgnas, it is inherited from ref. Currently working with inherited table will allow for more flexibility along the working groups, as foreign keys are refering to different tables - for instance stages for Salmon will be different from stages for eel.

Code to insert values into the tr_version_ver table
# get the latest version from the server
ver <- dbGetQuery(con_wgeel_distant, "select * from ref.tr_datasource_dts")
save(ver, file= "data/tr_datasource_dts.Rdata")
ver <- ver[ver$dts_datasource != 'test',]
dc <- ver[grepl("dc", ver$dts_datasource), "dts_datasource"]
dcyear <- as.integer(lapply(strsplit(dc,"_"), function(X)X[2]))
wgeel <- ver[grepl("wgeel", ver$dts_datasource), "dts_datasource"]
wgeelyear <- as.integer(lapply(strsplit(wgeel,"_"), function(X)X[2]))
tr_version_ver <- data.frame(
  ver_code = paste0(rep("ANG-", 11),
                    c(wgeelyear, dcyear, 2025),c("-1","-2",rep("-1", 9))),
  ver_year = c(wgeelyear, dcyear, 2025,2025),
  ver_spe_code = "ANG",
  ver_datacalldoi=c(rep(NA, 10), 
                    "https://doi.org/10.17895/ices.pub.25816738.v2",
                    "https://doi.org/10.17895/ices.pub.25816738.v2",
                    "https://doi.org/10.17895/ices.pub.29254589"), 
  ver_stockkeylabel =c("ele.2737.nea"), 
  ver_version=c(1,2,rep(1,19),2), 
  ver_description=ver$dts_description) # 

DBI::dbWriteTable(con_diaspara_admin, "temp_tr_version_ver", tr_version_ver, 
                  overwrite = TRUE)
dbExecute(con_diaspara_admin, 
          "INSERT INTO refeel.tr_version_ver(ver_code,ver_year,ver_spe_code,
 ver_datacalldoi,ver_stockkeylabel,ver_version, ver_description) 
 SELECT ver_code,ver_year,ver_spe_code, ver_datacalldoi,
 ver_stockkeylabel,ver_version, ver_descriptio FROM temp_tr_version_ver;") # 5
DBI::dbExecute(con_diaspara_admin, "DROP TABLE temp_tr_version_ver;")
Table 48: Version
ver_code ver_year ver_spe_code ver_stockkeylabel ver_datacalldoi ver_version ver_description ver_wkg_code
WGEEL-2023-1 2023 Anguilla anguilla ele 1 Joint EIFAAC/GFCM/ICES Eel Data Call 2023 WGEEL
WGEEL-2024-1 2024 Anguilla anguilla ele https://doi.org/10.17895/ices.pub.25816738.v2 1 Joint EIFAAC/GFCM/ICES Eel Data Call 2024 WGEEL
WGEEL-2025-1 2025 Anguilla anguilla ele https://doi.org/10.17895/ices.pub.25816738.v2 1 WKEMP 2025 special request WGEEL
WGEEL-2025-2 2025 Anguilla anguilla 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 Anguilla anguilla ele 1 Joint EIFAAC/GFCM/ICES Eel Data Call 2016 WGEEL
WGEEL-2017-2 2017 Anguilla anguilla 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 Anguilla anguilla ele 1 Data provided by wgeel 2016 WGEEL
WGEEL-2018-1 2018 Anguilla anguilla ele 1 Data provided by wgeel 2017 WGEEL
WGEEL-2019-1 2019 Anguilla anguilla ele 1 Joint EIFAAC/GFCM/ICES Eel Data Call 2019 WGEEL
WGEEL-2020-1 2020 Anguilla anguilla ele 1 Joint EIFAAC/GFCM/ICES Eel Data Call 2020 WGEEL
WGEEL-2021-1 2021 Anguilla anguilla ele 1 Joint EIFAAC/GFCM/ICES Eel Data Call 2021 WGEEL
WGEEL-2022-1 2022 Anguilla anguilla ele 1 Joint EIFAAC/GFCM/ICES Eel Data Call 2022 WGEEL

5.3 series table t_series_ser

5.3.1 Creating series main table for series

SQL code to create table dat.t_series_ser
--DROP TABLE IF EXISTS dat.t_series_ser CASCADE;

CREATE TABLE dat.t_series_ser (
  ser_id uuid PRIMARY KEY,
  ser_code text NOT NULL,
  CONSTRAINT uk_ser_code UNIQUE (ser_code),
  ser_name TEXT NOT NULL,
  --CONSTRAINT uk_ser_name UNIQUE (ser_name),
  ser_spe_code TEXT NULL,
  CONSTRAINT fk_ser_spe_code FOREIGN KEY (ser_spe_code) 
  REFERENCES "ref".tr_species_spe(spe_code) 
  ON UPDATE CASCADE ON DELETE RESTRICT ,
  ser_lfs_code TEXT NULL,
  CONSTRAINT fk_ser_lfs_code_ser_spe_code FOREIGN KEY (ser_lfs_code, ser_spe_code)
  REFERENCES "ref".tr_lifestage_lfs (lfs_code, lfs_spe_code) 
  ON UPDATE CASCADE ON DELETE RESTRICT,  
  ser_are_code TEXT NOT NULL,
  CONSTRAINT fk_ser_are_code FOREIGN KEY (ser_are_code)
  REFERENCES "ref".tr_area_are (are_code) 
  ON UPDATE CASCADE ON DELETE RESTRICT,
  ser_wkg_code TEXT NOT NULL,  
  CONSTRAINT fk_ser_wkg_code  FOREIGN KEY (ser_wkg_code)
  REFERENCES "ref".tr_icworkinggroup_wkg(wkg_code),
  ser_ver_code TEXT NOT NULL,
  CONSTRAINT fk_ser_ver_code FOREIGN KEY (ser_ver_code)
  REFERENCES ref.tr_version_ver(ver_code),   
  ser_cou_code TEXT NOT NULL,
  CONSTRAINT fk_ser_cou_code FOREIGN KEY (ser_cou_code)
  REFERENCES ref.tr_country_cou(cou_code)
  ON UPDATE CASCADE ON DELETE RESTRICT,
  CONSTRAINT fk_ser_wltyp_code FOREIGN KEY( ser_wltyp_code)
  REFERENCES ref."WLTYP"("Key") 
  ON UPDATE CASCADE ON DELETE RESTRICT,
  ser_hab_code TEXT NULL,
  CONSTRAINT fk_ser_habitat_code FOREIGN KEY(ser_hab_code)
  REFERENCES ref.tr_habitat_hab (hab_code)
  ON UPDATE CASCADE ON DELETE RESTRICT, 
  ser_gea_code TEXT NULL,
  CONSTRAINT fk_ser_gea_code FOREIGN KEY (ser_gea_code)
  REFERENCES ref.tr_gear_gea(gea_code)
  ON UPDATE CASCADE ON DELETE CASCADE,  
  ser_fiw_code TEXT,
  CONSTRAINT fk_ser_fiw_code FOREIGN KEY (ser_fiw_code)
  REFERENCES ref.tr_fishway_fiw(fiw_code)
  ON UPDATE CASCADE ON DELETE CASCADE,  
  ser_mon_code TEXT,
  CONSTRAINT fk_ser_mon_code FOREIGN KEY (ser_mon_code)
  REFERENCES ref.tr_monitoring_mon(mon_code)
  ON UPDATE CASCADE ON DELETE CASCADE,  
  ser_uni_code varchar(20), 
  CONSTRAINT fk_ser_uni_code FOREIGN KEY (ser_uni_code)
  REFERENCES ref.tr_units_uni(uni_code)
  ON DELETE CASCADE ON UPDATE CASCADE,
  ser_effort_uni_code varchar(20),
  CONSTRAINT fk_ser_effort_uni_code FOREIGN KEY (ser_effort_uni_code)
  REFERENCES ref.tr_units_uni(uni_code)
  ON DELETE CASCADE  ON UPDATE CASCADE,
  ser_description TEXT NULL,
  ser_locationdescription TEXT NULL,
  ser_wltyp_code TEXT NULL,
  ser_stocking boolean NULL,
  ser_stockingcomment TEXT NULL,
  ser_protocol TEXT NULL,
  ser_samplingstrategy TEXT NULL,  
  ser_datarightsholder TEXT NULL,
  ser_datelastupdate DATE NOT NULL,
  geom geometry NULL);

COMMENT ON TABLE dat.t_series_ser IS 
'Table of time series, or sampling data identifier. This corresponds to a multi-annual data collection design.
It can correspond to time series data or individual metrics collection or both. This table is inherited. It means that the data in ref is fed by
the content of the tables in refeel, refnas, refbast... Note this table is joined to  StationDictionary, which contains elements about monitoring purpose (PURMP), stationGovernance, ProgramGovernance, 
station_activefromdate, stationactiveuntildate, latitude, latituderange, longitude, longituderange, MSAT. Check that the table content is consistent';
COMMENT ON COLUMN dat.t_series_ser.ser_id IS 
'UUID, identifier of the series, primary key';
COMMENT ON COLUMN dat.t_series_ser.ser_code IS 
'Code of the series';
COMMENT ON COLUMN dat.t_series_ser.ser_name IS 
'Name of the series';
COMMENT ON COLUMN dat.t_series_ser.ser_spe_code  IS 
'Species,  e.g. ''127186'' ref.tr_species_spe, the species can be null but
it should correspond to the main species target by the sampling';
COMMENT ON COLUMN dat.t_series_ser.ser_lfs_code  IS 
'Life stage see tr_lifestage_lfs,Code of the lifestage see tr_lifestage_lfs,  the constraint is set on 
both lfs_code, and lfs_spe_code (as two species can have the same lifestage code. The lifestage can be NULL but it should correspond to the main lifestage targeted by the series;';
COMMENT ON COLUMN dat.t_series_ser.ser_wkg_code IS 
'Code of the working group, one of WGBAST, WGEEL, WGNAS, WKTRUTTA';
COMMENT ON COLUMN dat.t_series_ser.ser_ver_code IS 
'Version code referencing tr_version_ver the data call e.g. NAS_2025dc_2020, wgeel_2016, wkemp_2025';
COMMENT ON COLUMN dat.t_series_ser.ser_cou_code IS
 'Code of the country';
COMMENT ON COLUMN dat.t_series_ser.ser_wltyp_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_series_ser.ser_hab_code IS 
'Code of the habitat, see tr_habitat_hab';
COMMENT ON COLUMN dat.t_series_ser.ser_are_code IS 
'Code of the area, areas are geographical sector most often corresponding to stock units, see tr_area_are.';
COMMENT ON COLUMN dat.t_series_ser.ser_uni_code IS 
'Unit for the value reported in annual table, if the series reports annual data in Kg or Number use kg or number.';
COMMENT ON COLUMN dat.t_series_ser.ser_effort_uni_code IS 
'Annual data collection effort unit code, used for the effort column in annual data';
COMMENT ON COLUMN dat.t_series_ser.ser_description IS 
'Concise description of the series. Should include species, stage targeted, location and gear. e.g. Glass eel monitoring in the Vilaine estuary (France) with a trapping ladder.';
COMMENT ON COLUMN dat.t_series_ser.ser_locationdescription IS
 'This should provide a description of the site, e.g. if ist far inland, in the middle of a river, near a dam etc. Also please specify the adjectant marine region (Baltic, North Sea) etc.
(e.g.  "Bresle river trap 3 km from the sea" or IYFS/IBTS sampling in the Skagerrak-Kattegat"';
COMMENT ON COLUMN dat.t_series_ser.ser_gea_code IS
 'Code of the gear used, see tr_gear_gea';
COMMENT ON COLUMN dat.t_series_ser.ser_fiw_code IS
 'Code the fishway, eg PO for pool type fishway';
COMMENT ON COLUMN dat.t_series_ser.ser_mon_code IS
 'Code the Monitoring device, eg SO for Sonar';
COMMENT ON COLUMN dat.t_series_ser.ser_stocking IS
 'Boolean, Is there restocking (for eel) or artifical reproduction in the river / basin, affecting the series ? ';
COMMENT ON COLUMN dat.t_series_ser.ser_stockingcomment IS
 'Comment on stocking';
COMMENT ON COLUMN dat.t_series_ser.ser_protocol IS
 'Describe sampling protocol';
COMMENT ON COLUMN dat.t_series_ser.ser_samplingstrategy IS
 'Describe sampling strategy';
COMMENT ON COLUMN dat.t_series_ser.ser_datarightsholder IS
 'Code of the data rights holder of the series, this field will be used in DATSU to acknowledge the source of data';
COMMENT ON COLUMN dat.t_series_ser.ser_datelastupdate IS
 'Last modification in the series, from a trigger';
COMMENT ON COLUMN dat.t_series_ser.geom IS
 'Series geometry column EPSG 4326, can be more detailed than the geometry for station';


GRANT ALL ON dat.t_series_ser TO diaspara_admin;
GRANT SELECT ON dat.t_series_ser TO diaspara_read; 

This table is inherited so the table created in dat will be empty, and will only receive data by inheritance. It can be considered as a view for ICES (no inheritance in SQL server). The table will be replicated in each working group, and there have specific foreign keys to tables that can be working group specific.

Since this table is inherited from dat.t_series_ser the wkg needs to be included. One table will be created per working group. These tables will be collated together. Most details information about metadata will be in the metadata tables, either to describe annual sampling or to describe individual trait collection.

Monitoring stations (including fixed stations) that are used for recurring sampling or data collection are managed via the Station Code Request Application in ICES (ICES 2024a). This table will reference monitoring station but it might be NULL, as some sampling designs or data collection, for instance for the DCF, are not related to a station.

5.3.2 Creating inherited series

SQL code to create table dateel.t_series_ser

-- when dumping this is inherited => I have a not null constraint on the server 
-- when the table is recreated

ALTER TABLE dat.t_series_ser ALTER COLUMN ser_are_code DROP NOT NULL;
ALTER TABLE dat.t_series_ser ALTER COLUMN ser_cou_code DROP NOT NULL;


DROP TABLE IF EXISTS dateel.t_series_ser;
CREATE TABLE dateel.t_series_ser ( 
  CONSTRAINT pk_ser_id PRIMARY KEY (ser_id),
  CONSTRAINT uk_ser_code UNIQUE (ser_code),
  CONSTRAINT uk_ser_name UNIQUE (ser_name),
  CONSTRAINT fk_ser_spe_code FOREIGN KEY (ser_spe_code) 
    REFERENCES ref.tr_species_spe(spe_code) 
    ON UPDATE CASCADE ON DELETE RESTRICT ,
  CONSTRAINT fk_ser_lfs_code_ser_spe_code 
    FOREIGN KEY (ser_lfs_code, ser_spe_code)
    REFERENCES ref.tr_lifestage_lfs (lfs_code, lfs_spe_code) 
    ON UPDATE CASCADE ON DELETE RESTRICT,  
  CONSTRAINT fk_ser_are_code FOREIGN KEY (ser_are_code)
    REFERENCES refeel.tr_area_are (are_code) 
    ON UPDATE CASCADE ON DELETE RESTRICT,
  CONSTRAINT fk_ser_wkg_code  FOREIGN KEY (ser_wkg_code)
   REFERENCES ref.tr_icworkinggroup_wkg(wkg_code)
   ON UPDATE CASCADE ON DELETE RESTRICT,   
  CONSTRAINT fk_ser_ver_code FOREIGN KEY (ser_ver_code)
   REFERENCES refeel.tr_version_ver(ver_code)
  ON UPDATE CASCADE ON DELETE RESTRICT,  
  CONSTRAINT fk_ser_cou_code FOREIGN KEY (ser_cou_code)
   REFERENCES ref.tr_country_cou(cou_code)
   ON UPDATE CASCADE ON DELETE RESTRICT,  
  CONSTRAINT fk_ser_uni_code FOREIGN KEY (ser_uni_code)
   REFERENCES ref.tr_units_uni(uni_code)
   ON DELETE CASCADE ON UPDATE CASCADE,
  CONSTRAINT fk_ser_effort_uni_code 
  FOREIGN KEY (ser_effort_uni_code)
   REFERENCES ref.tr_units_uni(uni_code)
   ON DELETE CASCADE  ON UPDATE CASCADE,
  CONSTRAINT fk_ser_wltyp_code FOREIGN KEY( ser_wltyp_code)
   REFERENCES ref."WLTYP"("Key") 
   ON UPDATE CASCADE ON DELETE RESTRICT,  
  CONSTRAINT fk_ser_gea_code FOREIGN KEY (ser_gea_code)
   REFERENCES ref.tr_gear_gea(gea_code)
   ON UPDATE CASCADE ON DELETE CASCADE,
  CONSTRAINT fk_ser_fiw_code FOREIGN KEY (ser_fiw_code)
   REFERENCES ref.tr_fishway_fiw(fiw_code)
   ON UPDATE CASCADE ON DELETE CASCADE,  
  CONSTRAINT fk_ser_mon_code FOREIGN KEY (ser_mon_code)
   REFERENCES ref.tr_monitoring_mon(mon_code)
   ON UPDATE CASCADE ON DELETE CASCADE
) inherits (dat.t_series_ser);

-- In the wgeel schema the default is WGEEL
ALTER TABLE dateel.t_series_ser ALTER COLUMN ser_wkg_code SET DEFAULT 'WGEEL';  

COMMENT ON TABLE dateel.t_series_ser IS
 'Table of time series, or sampling data identifier. This corresponds to a multi-annual data collection design.
It can correspond to time series data or individual metrics collection or both. This table is inherited from dat ';
COMMENT ON COLUMN dat.t_series_ser.ser_id IS
 'UUID, identifier of the series, primary key';
COMMENT ON COLUMN dat.t_series_ser.ser_code IS
 'Code of the series, short name of the recuitment series, this must be 4 letters + stage name, e.g. VilG, LiffGY, FremS for recruitment or silver eel series the first letter is capitalised and the stage name too. For sampling use country + name + (currently BIOM or HIST) for Biometry or Historic dataset, e.g. ES_Anda_Aguas_BIOM';
COMMENT ON COLUMN dat.t_series_ser.ser_name IS
 'Name of the series';
COMMENT ON COLUMN dat.t_series_ser.ser_spe_code  IS
 'Species, e.g. ''127186''... references ref.tr_species_spe, the species can be null but
it should correspond to the main species target by the sampling';
COMMENT ON COLUMN dat.t_series_ser.ser_lfs_code  IS
 'Life stage see tr_lifestage_lfs,Code of the lifestage see tr_lifestage_lfs,  the constraint is set on 
both lfs_code, and lfs_spe_code (as two species can have the same lifestage code. The lifestage can be NULL but it should correspond to the main lifestage targeted by the series;';
COMMENT ON COLUMN dat.t_series_ser.ser_wkg_code IS
 'Code of the working group, one of WGBAST, WGEEL, WGNAS, WKTRUTTA';
COMMENT ON COLUMN dat.t_series_ser.ser_ver_code IS
 'Version code from ref.tr_version_ver the data call e.g. WGNAS_2020_1, WGEEL_2016_1';
COMMENT ON COLUMN dat.t_series_ser.ser_cou_code IS
 'Code of the country';
COMMENT ON COLUMN dat.t_series_ser.ser_wltyp_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_series_ser.ser_hab_code IS
 'Code of the habitat, see tr_habitat_hab';
COMMENT ON COLUMN dat.t_series_ser.ser_are_code IS
 'Code of the area, areas are geographical sector most often corresponding to stock units, see tr_area_are.';
COMMENT ON COLUMN dat.t_series_ser.ser_uni_code IS
 'Annual value Unit, references table tr_unit_uni.';
COMMENT ON COLUMN dat.t_series_ser.ser_effort_uni_code IS
 'Annual data collection effort unit code, references table tr_unit_uni.';
COMMENT ON COLUMN dat.t_series_ser.ser_description IS
  'Concise description of the series. Should include species, stage targeted, location and gear. e.g. Glass eel monitoring in the Vilaine estuary (France) with a trapping ladder.';
COMMENT ON COLUMN dat.t_series_ser.ser_locationdescription IS
 'This should provide a description of the site, e.g. if ist far inland, in the middle of a river, near a dam etc. Also please specify the adjectant marine region (Baltic, North Sea) etc.
(e.g.  `Bresle river trap 3 km from the sea` or `IYFS/IBTS sampling in the Skagerrak-Kattegat`';
COMMENT ON COLUMN dat.t_series_ser.ser_gea_code IS
 'Code of the gear used, see tr_gear_gea, if a fishway or scientific monitoring device leave NULL and set mon_code';
COMMENT ON COLUMN dat.t_series_ser.ser_fiw_code IS
 'Code the fishway, eg PO for pool type fishway';
COMMENT ON COLUMN dat.t_series_ser.ser_mon_code IS
 'Code the Monitoring device, eg SO for Sonar';
COMMENT ON COLUMN dat.t_series_ser.ser_stocking IS
 'Boolean, Is there restocking (for eel) or artifical reproduction in the river / basin, affecting the series ? ';
COMMENT ON COLUMN dat.t_series_ser.ser_stockingcomment IS
 'Comment on stocking';
COMMENT ON COLUMN dat.t_series_ser.ser_protocol IS
 'Describe sampling protocol';
COMMENT ON COLUMN dat.t_series_ser.ser_samplingstrategy IS
 'Describe sampling strategy';
COMMENT ON COLUMN dat.t_series_ser.ser_datarightsholder IS
 'Code of the data rights holder of the series, this field will be used in DATSU to acknowledge the source of data';
COMMENT ON COLUMN dat.t_series_ser.ser_datelastupdate IS
 'Last modification in the series, from a trigger';
COMMENT ON COLUMN dat.t_series_ser.geom IS
 'Series geometry column EPSG 4326, can be more detailed than the geometry for station';

GRANT ALL ON dateel.t_series_ser TO diaspara_admin;
GRANT SELECT ON dateel.t_series_ser TO diaspara_read; 

-- pb with DUMP
 ALTER TABLE  dateel.t_series_ser ALTER COLUMN 

5.3.3 Import t_series_ser from wgeel

Code to import to to refeel.tr_series_ser
res <- dbGetQuery(con_diaspara, "SELECT * FROM dateel.t_series_ser")
clipr::write_clip(colnames(res))

# temporarily remove area constraint

dbExecute(con_diaspara_admin, "ALTER TABLE dateel.t_series_ser drop constraint 
fk_ser_are_code")
dbExecute(con_diaspara_admin, "ALTER TABLE dateel.t_series_ser ALTER COLUMN  
ser_are_code DROP NOT NULL")
dbExecute(con_diaspara_admin, "ALTER TABLE dateel.t_series_ser ALTER COLUMN  
ser_cou_code DROP NOT NULL")
dbExecute(con_diaspara_admin, 
          "ALTER TABLE dateel.t_series_ser DROP CONSTRAINT uk_ser_name")

t_series_ser <-
  data.frame(
    "ser_id" = uuid::UUIDgenerate(n=nrow(ser)),
    "ser_code" = ser$ser_nameshort,
    "ser_name"  = ser$ser_namelong,
    "ser_spe_code" = "ANG",
    "ser_lfs_code" = ser$ser_lfs_code,
    "ser_are_code" = ser$ser_emu_nameshort,
    "ser_wkg_code" = "WGEEL",
    "ser_ver_code" = case_when(ser$ser_dts_datasource =="dc_2019" ~ "ANG-2019-1",
                               ser$ser_dts_datasource =="dc_2021" ~ "ANG-2021-1",
                               ser$ser_dts_datasource =="dc_2022" ~ "ANG-2022-1",
                               ser$ser_dts_datasource =="dc_2023" ~ "ANG-2023-1",
                               ser$ser_dts_datasource =="dc_2024" ~ "ANG-2024-1",
                               .default = "ANG-2018-1"),
    "ser_cou_code" = ser$ser_cou_code,
    "ser_hab_code" = NA,
    "ser_gea_code" = ser$gea_issscfg_code,
    "ser_fiw_code" = NA,
    "ser_mon_code" = NA,
    "ser_uni_code" = ser$ser_uni_code,
    "ser_effort_uni_code" = ser$ser_effort_uni_code,
    "ser_description" = ser$ser_comment,
    "ser_locationdescription" = ser$ser_locationdescription,
    "ser_wltyp_code" = case_when(ser$ser_hty_code == "T" ~ "T",
                                 ser$ser_hty_code == "C" ~ "MC",
                                 ser$ser_hty_code == "F" ~ "FW",
                                 ser$ser_hty_code == "MO" ~ "MO"),
    "ser_stocking" = ser$ser_restocking,
    "ser_stockingcomment" = NA,
    "ser_protocol" = ser$ser_method,
    "ser_samplingstrategy" = NA,
    "ser_datarightsholder" = NA,
    "ser_datelastupdate" = '2025-06-09',
    "geom" = ser$geom    
  )

res <- dbWriteTable(con_diaspara_admin, "t_series_ser_temp", 
                    t_series_ser, overwrite = TRUE)
dbExecute(con_diaspara_admin, "DELETE FROM  dateel.t_series_ser;")
dbExecute(con_diaspara_admin, "INSERT INTO dateel.t_series_ser 
SELECT 
 ser_id::uuid,
 ser_code,
 ser_name,
 ser_spe_code,
 ser_lfs_code,
 ser_are_code,
 ser_wkg_code,
 ser_ver_code,
 ser_cou_code,
 ser_hab_code,
 ser_gea_code,
 ser_fiw_code,
 ser_mon_code,
 ser_uni_code,
 ser_effort_uni_code,
 ser_description,
 ser_locationdescription,
 ser_wltyp_code,
 ser_stocking,
 ser_stockingcomment,
 ser_protocol,
 ser_samplingstrategy,
 ser_datarightsholder,
 ser_datelastupdate::date,
 geom
FROM t_series_ser_temp") # 294 

sai <- dbGetQuery(con_wgeel_distant, 
                  "SELECT sai.* FROM datawg.t_samplinginfo_sai sai;
")

t_series_ser2 <-
  data.frame(
    "ser_id" = uuid::UUIDgenerate(n=nrow(sai)),
    "ser_code" = sai$sai_id,
    "ser_name"  = sai$sai_name,
    "ser_spe_code" = "ANG",
    "ser_lfs_code" = NA,
    "ser_are_code" = NA, # TODO sai_emu_nameshort sai_area_division
    "ser_wkg_code" = "WGEEL",
    "ser_ver_code" = case_when(sai$sai_dts_datasource =="dc_2019" ~ "WGEEL-2019-1",
                               sai$sai_dts_datasource =="dc_2021" ~ "WGEEL-2021-1",
                               sai$sai_dts_datasource =="dc_2022" ~ "WGEEL-2022-1",
                               sai$sai_dts_datasource =="dc_2023" ~ "WGEEL-2023-1",
                               sai$sai_dts_datasource =="dc_2024" ~ "WGEEL-2024-1",
                               .default = "WGEEL-2018-1"),
    "ser_cou_code" = sai$sai_cou_code,
    "ser_hab_code" = NA,
    "ser_gea_code" = NA,
    "ser_fiw_code" = NA,
    "ser_mon_code" = NA,
    "ser_uni_code" = NA,
    "ser_effort_uni_code" = NA,
    "ser_description" = sai$sai_comment,
    "ser_locationdescription" = NA,
    "ser_wltyp_code" = case_when(sai$sai_hty_code == "T" ~ "T",
                                 sai$sai_hty_code == "C" ~ "MC",
                                 sai$sai_hty_code == "F" ~ "FW",
                                 sai$sai_hty_code == "MO" ~ "MO"),
    "ser_stocking" = NA,
    "ser_stockingcomment" = NA,
    "ser_protocol" = sai$sai_protocol,
    "ser_samplingstrategy" = sai$sai_samplingstrategy,
    "ser_datarightsholder" = NA,
    "ser_datelastupdate" = sai$sai_lastupdate,
    "geom" = NA # no geom in this table  
  )

res <- dbWriteTable(con_diaspara_admin, "t_series_ser_temp2", 
                    t_series_ser2, overwrite = TRUE)
dbExecute(con_diaspara_admin, "INSERT INTO dateel.t_series_ser 
SELECT 
 ser_id::uuid,
 ser_code,
 ser_name,
 ser_spe_code,
 ser_lfs_code,
 ser_are_code,
 ser_wkg_code,
 ser_ver_code,
 ser_cou_code,
 ser_hab_code,
 ser_gea_code,
 ser_fiw_code,
 ser_mon_code,
 ser_uni_code,
 ser_effort_uni_code,
 ser_description,
 ser_locationdescription,
 ser_wltyp_code,
 ser_stocking,
 ser_stockingcomment,
 ser_protocol,
 ser_samplingstrategy,
 ser_datarightsholder,
 ser_datelastupdate::date,
 NULL
FROM t_series_ser_temp2") # 252 
Table 49: Table t_series_ser for series first 20 lines
ser_id ser_code ser_name ser_spe_code ser_lfs_code ser_are_code ser_wkg_code ser_ver_code ser_cou_code ser_hab_code ser_gea_code ser_fiw_code ser_mon_code ser_uni_code ser_effort_uni_code ser_description ser_locationdescription ser_wltyp_code ser_stocking ser_stockingcomment ser_protocol ser_samplingstrategy ser_datarightsholder ser_datelastupdate geom
2445a12b-f5b9-4c8e-aa83-dcecc9e92717 31 ES_Astu_Esva _HIST 126281 NA NA WGEEL WGEEL-2018-1 ES NA NA NA NA NA NA historical data Esva NA NA NA NA NA NA NA 2022-08-29 NA
95259d08-b9cf-4936-8484-0027c9c2d989 33 GB_Seve_Severn_HIST 126281 NA NA WGEEL WGEEL-2018-1 GB NA NA NA NA NA NA historical data Severn NA NA NA NA NA NA NA 2022-08-29 NA
379b8d44-0251-4d00-82bd-b2212b6913ad 34 GB_Scot_Girnock_Burn_Scotland_HIST 126281 NA NA WGEEL WGEEL-2018-1 GB NA NA NA NA NA NA historical data Girnock_Burn_Scotland NA NA NA NA NA NA NA 2022-08-29 NA
7e4fd77c-cf99-4eff-9c88-9d6d92b7242e 37 IE_West_Burrishoole_HIST 126281 NA NA WGEEL WGEEL-2018-1 IE NA NA NA NA NA NA historical data Burrishoole NA NA NA NA NA NA NA 2022-08-29 NA
b0354939-8b73-4b52-8b8c-2b1f95119950 40 NL_Neth_Ijsselmeer_HIST 126281 NA NA WGEEL WGEEL-2018-1 NL NA NA NA NA NA NA historical data Ijsselmeer NA NA NA NA NA NA NA 2022-08-29 NA
2e1d59f5-a843-4cc0-85e7-8a6f5b204014 43 NA_Balaton_HIST 126281 NA NA WGEEL WGEEL-2018-1 NA NA NA NA NA NA NA historical data Balaton NA NA NA NA NA NA NA 2022-08-29 NA
b314943a-d752-4a3c-995c-43e514c72a4d 662 ES_Anda_SanPedro_BIOM 126281 NA NA WGEEL WGEEL-2022-1 ES NA NA NA NA NA NA morphological data NA FW NA NA trapping partial scientific survey NA 2022-09-13 NA
ff7d196a-ef19-46c9-a500-2216dde17eee 664 ES_Anda_Tinto_BIOM 126281 NA NA WGEEL WGEEL-2022-1 ES NA NA NA NA NA NA morphological data NA FW NA NA trapping partial scientific survey NA 2022-09-13 NA
72feac60-485a-4740-970c-ed2ab042c40d 659 ES_Anda_Salado_BIOM 126281 NA NA WGEEL WGEEL-2022-1 ES NA NA NA NA NA NA morphological data NA FW NA NA trapping partial scientific survey NA 2022-09-13 NA
8892a7b8-5476-488a-8447-99f358445517 KilY Killough River 126281 Y GB_NorE WGEEL WGEEL-2021-1 GB NA 08.3 NA NA nr nr net.night Killough (effort 4 nights of 5 fyke nets per night). Fyke net survey. Killough River in Strangford FW FALSE NA Fyke net survey. NA NA 2025-06-09 0101000020E610000075931804568E16C04D840D4FAF344B40
0db2ddf8-d6b9-4894-85af-6f32589f2a26 LevS Leven Silver 126281 S GB_NorW WGEEL WGEEL-2021-1 GB NA 08.5 NA NA nr NA Silver eels counter Backbarrow silver eel counter on the River Leven 1.8km from tidal limit FW FALSE NA Full river width resistivity fish counter on permanent weir. Movements across the counter (up and downstream) are recorded continuously all year and post processed to identify which records (trace files) are eel. Trace files of d/s migrating eels are only identified for the months of August to December. NA NA 2025-06-09 0101000020E6100000C2AC0617E1EC07C0B5A679C729204B40
878afb2b-7346-4dca-8ff5-67e7392f5f03 826 SE_Inla_Roxen_HIST 126281 NA NA WGEEL WGEEL-2023-1 SE NA NA NA NA NA NA Data from lake Roxen NA FW NA NA SE_Inla Eels from commercial fishers NA 2023-09-05 NA
d98b022b-df0e-442b-98e8-a998265eb38c SuSY Suffolk Stour Catchment 126281 Y GB_Angl WGEEL WGEEL-2022-1 GB NA 10.4 NA NA nr/m2 nr electrofishing Index river estimates of eel density per year from pooled data taken from all quantitative surveys (all electrofishing) in that river. Any surveys that have 'Not recorded' as catch or sample method are excluded, as are all fyke net or other fixed instrument data and data with no area of fishing provided. There has been no major stocking in this EMU since 2013 so it is considered as not affected by stocking. Ser_distance was reported as a mean distance of 125 out of 141 surveyed sites. The sites with available data were relatively evenly distributed along the length of river, so seem representative enough. When new data become available this will be updated accordingly. river or catchment average FW FALSE NA Yellow eel sampled by hand-held electric fishing gear either single catch or catch depletion sampling across multiple sites. Sampling carried out throughout the year with main effort from June to September NA NA 2025-06-09 0101000020E6100000C3651536031CEC3FB24CBF44BCFB4940
fcadb13e-2fd3-4392-b622-8ed610cdb980 ImsaGY Imsa Near Sandnes trapping all 126281 GY NO_total WGEEL WGEEL-2022-1 NO NA 08.9 NA NA nr NA The stage is not really glass eel but elver Near Sandnes FW FALSE NA glass eel ladder NA NA 2025-06-09 0101000020E61000005C8FC2F5285C164085EB51B81E454D40
72854801-b3fa-4b81-8827-eb4eda137c43 LeeY Lee River 126281 Y GB_Tham WGEEL WGEEL-2022-1 GB NA 10.4 NA NA nr/m2 nr electrofishing Index river estimates of eel density per year from pooled data taken from all quantitative surveys (all electrofishing) in that river. Any surveys that have 'Not recorded' as catch or sample method are excluded, as are all fyke net or other fixed instrument data and data with no area of fishing provided. There has been no stocking in this EMU since 2013 so it is considered as not affected by stocking. Ser_distance was reported as a mean distance of 96 out of 143 surveyed sites. The sites with available data were relatively evenly distributed along the length of river, so seem representative enough. When new data become available this will be updated accordingly. river or catchment average FW FALSE NA Yellow eel sampled by hand-held electric fishing gear either single catch or catch depletion sampling across multiple sites. Sampling carried out throughout the year with main effort from June to September NA NA 2025-06-09 0101000020E610000092B9E81A1CDB91BF8675E3DD91D54940
31cb9a15-7b2a-46e4-887c-93673d9cd859 FneS Fane 126281 S IE_East WGEEL WGEEL-2024-1 IE NA 08.9 NA NA kg nr net.night Fane is the site of former commercial eel fishing; it is located on the outflow of Lough Muckno Fane FW FALSE NA Coghill nets on frame NA NA 2025-06-09 0101000020E61000002288F37002B31AC088821953B00C4B40
04a2dfd7-8444-4ba4-afe7-8a520c12df8e BarS Barrow 126281 S IE_East WGEEL WGEEL-2024-1 IE NA 08.9 NA NA kg nr net.night The barrow site was a former commercial eel fishing location, it is located above the tidal limit on the River Barrow Barrow FW FALSE NA Coghill nets on canal lock gates NA NA 2025-06-09 0101000020E6100000733ADECF04E21BC0BEF651828F4D4A40
1a6d2324-2d94-42d2-b3e4-4a65aa5ae98d DeBY Den Burg fyke net survey 126281 Y NL_Neth WGEEL WGEEL-2024-1 NL NA 08.3 NA NA index index fyke net survey updated 2011 / new data series og fyke net monitoruing Den Burg fyke net (CPUE) MO TRUE NA fyke net survey updated 2011 / new data series og fyke net monitoruing. All eel (yellow and silver, but that is no option in ser_lfs_code) NA NA 2025-06-09 0101000020E61000007CED9925010A13405721E527D57E4A40
2d8f9e41-f487-4064-b7f1-6a21b084e434 IJsFVY FYOE-IJM-Veg 126281 Y NL_Neth WGEEL WGEEL-2024-1 NL NA 10.4 NA NA index index Fishery indepent survey on shores in lake ijsselmeer with electro fishing net in august/september Lake ijsselmeer FW TRUE NA All eel, but almost all is Yellow eel. Fishery indepent survey on shores in lake ijsselmeer with electro fishing net in august/september NA NA 2025-06-09 0101000020E6100000AE4A22FB204B15409F7422C154694A40
d8b66f7a-c834-4b1b-b423-6a43d3b7c06a IJsFRY FYOE-IJM-Rock 126281 Y NL_Neth WGEEL WGEEL-2024-1 NL NA 10.4 NA NA index index Fishery indepent survey on shores in lake ijsselmeer with electro fishing net in august/september Lake ijsselmeer FW TRUE NA All eel, but most is Yellow eel. Fishery indepent survey on shores in lake ijsselmeer with electro fishing net in august/september NA NA 2025-06-09 0101000020E6100000AE4A22FB204B15409F7422C154694A40

5.4 Annual series table

This table holds annual data from the series.

SQL code to create table dat.t_serannual_san
DROP TABLE IF EXISTS dat.t_serannual_san CASCADE;
CREATE TABLE dat.t_serannual_san (
san_ser_id UUID,
CONSTRAINT fk_san_ser_id FOREIGN KEY (san_ser_id)
  REFERENCES dat.t_series_ser (ser_id) 
  ON UPDATE CASCADE ON DELETE CASCADE, 
san_id SERIAL NOT NULL,
CONSTRAINT c_uk_san_id UNIQUE (san_id, san_wkg_code),
san_value NUMERIC NULL,
san_year INTEGER NOT NULL,
CONSTRAINT uk_san_year_svc UNIQUE(san_year, san_ser_id),
san_comment TEXT NULL, 
san_effort NUMERIC NULL,
san_datelastupdate DATE NOT NULL,
san_qal_id INTEGER NOT NULL,
san_qal_comment TEXT, 
san_wkg_code TEXT NOT NULL,  
CONSTRAINT fk_san_wkg_code  FOREIGN KEY (san_wkg_code)
REFERENCES "ref".tr_icworkinggroup_wkg(wkg_code)
ON UPDATE CASCADE ON DELETE RESTRICT,
san_ver_code TEXT NOT NULL,
CONSTRAINT fk_san_ver_code FOREIGN KEY (san_ver_code)
REFERENCES ref.tr_version_ver(ver_code)
ON UPDATE CASCADE ON DELETE RESTRICT
);
  


COMMENT ON TABLE dat.t_serannual_san IS
 'Table of annual abundance data for series in dat.t_series_ser, these are recruitment or silver eel run data.  This table is inherited. It means that the data in dat is fed by
the content of the tables in datfeel, datnas, datbast ';

COMMENT ON COLUMN dat.t_serannual_san.san_ser_id IS
 'UUID, identifier of the series, primary key, references the table ref.tr_seriesvocab_svc (svc_id)';
COMMENT ON COLUMN dat.t_serannual_san.san_id IS
 'INTEGER, autoincremented, unique for one working group';
COMMENT ON COLUMN dat.t_serannual_san.san_year IS
 'Year of monitoring, note that for some of the series this corresponds to the main migration season, 
For glass eel, months from september y-1 to august y should be denoted year y / For silver eel, months from june y to may y+1 should be denoted year y / For yellow eels, use the calendar year), see the series metadata for more details.';
COMMENT ON COLUMN dat.t_serannual_san.san_comment IS
 'Comment on the annual value of the series';
COMMENT ON COLUMN dat.t_serannual_san.san_effort IS
 'Eventually a measure of effort to collect the series, e.g. number of nr haul, nr fyke.day,
check the t_metadataannual table for the unit used';
COMMENT ON COLUMN dat.t_serannual_san.san_datelastupdate IS
 'Date of last update on the annual data';
COMMENT ON COLUMN dat.t_serannual_san.san_qal_id IS
 'Quality ID code of the series';
COMMENT ON COLUMN dat.t_serannual_san.san_qal_comment IS
 'Comment related to data quality, e.g. why this year the series should not be used, or used with caution.';
COMMENT ON COLUMN dat.t_serannual_san.san_wkg_code IS
 'Code of the working group, one ofWGBAST, WGEEL, WGNAS, WKTRUTTA';
COMMENT ON COLUMN dat.t_serannual_san.san_ver_code IS
 'Version code sourced from ref.tr_version_ver the data call e.g. WGNAS_2020_1, WGEEL_2016_1';


ALTER TABLE dateel.t_serannual_san DROP  CONSTRAINT  fk_san_ver_code


ALTER TABLE dateel.t_serannual_san ADD CONSTRAINT  fk_san_ver_code FOREIGN KEY (san_ver_code)
REFERENCES refeel.tr_version_ver(ver_code)
ON UPDATE CASCADE ON DELETE RESTRICT

5.4.1 Creating inherited table for annual series

SQL code to create tables dateel.t_serannual_san
-- DROP TABLE IF EXISTS dateel.t_serannual_san;

CREATE TABLE dateel.t_serannual_san (
CONSTRAINT fk_san_ser_id FOREIGN KEY (san_ser_id)
  REFERENCES dateel.t_series_ser (ser_id) 
  ON UPDATE CASCADE ON DELETE CASCADE, 
CONSTRAINT c_uk_san_id UNIQUE (san_id, san_wkg_code), 
CONSTRAINT fk_san_wkg_code  FOREIGN KEY (san_wkg_code)
REFERENCES ref.tr_icworkinggroup_wkg(wkg_code),
CONSTRAINT fk_san_ver_code FOREIGN KEY (san_ver_code)
REFERENCES refeel.tr_version_ver(ver_code),
CONSTRAINT uk_san_year_svc UNIQUE(san_year, san_ser_id)
) INHERITS (dat.t_serannual_san);
  


COMMENT ON TABLE dateel.t_serannual_san IS
 'Table of annual abundance data for series in dat.t_series_ser, these are recruitment or silver eel run data.  This table is inherited. It means that the data in dat is fed by
the content of the tables in datfeel, datnas, datbast';

COMMENT ON COLUMN dateel.t_serannual_san.san_ser_id IS
 'UUID, identifier of the series, primary key, references the table ref.tr_seriesvocab_svc (svc_id)';
COMMENT ON COLUMN dateel.t_serannual_san.san_id IS
 'INTEGER, autoincremented, unique for one working group';
COMMENT ON COLUMN dateel.t_serannual_san.san_year IS
 'Year of monitoring, note that for some of the series this corresponds to the main migration season, 
For glass eel, months from september y-1 to august y should be denoted year y / For silver eel, months from june y to may y+1 should be denoted year y / For yellow eels, use the calendar year), see the series metadata for more details.';
COMMENT ON COLUMN dateel.t_serannual_san.san_comment IS
 'Comment on the annual value of the series';
COMMENT ON COLUMN dateel.t_serannual_san.san_effort IS
 'Eventually a measure of effort to collect the series, e.g. number of nr haul, nr fyke.day,
check the t_metadataannual table for the unit used';
COMMENT ON COLUMN dateel.t_serannual_san.san_datelastupdate IS
 'Date of last update on the annual data';
COMMENT ON COLUMN dateel.t_serannual_san.san_qal_id IS
 'Quality ID code of the series';
COMMENT ON COLUMN dateel.t_serannual_san.san_qal_comment IS
 'Comment related to data quality, e.g. why this year the series should not be used, or used with caution.';
COMMENT ON COLUMN dateel.t_serannual_san.san_wkg_code IS
 'Code of the working group, one of
WGBAST, WGEEL, WGNAS, WKTRUTTA';
COMMENT ON COLUMN dateel.t_serannual_san.san_ver_code IS
 'Version code sourced from ref.tr_version_ver the data call e.g. NAS_2025dc_2020, wgeel_2016, wkemp_2025';


GRANT ALL ON dateel.t_serannual_san TO diaspara_admin;
GRANT SELECT ON dateel.t_serannual_san TO diaspara_read; 

5.4.2 Annual series (dateel.t_serannual_ser)

Data are imported from WGEEL datawg.t_dataseries_dastable to dateel.t_serannual_ser.

Code to import to dateel.t_serannual_ser
das0 <- dbGetQuery(con_wgeel_distant, "SELECT * FROM datawg.t_dataseries_das;
")

res <- dbGetQuery(con_diaspara, "SELECT * FROM dateel.t_serannual_san")
clipr::write_clip(colnames(res))

das0$das_dts_datasource[is.na(das0$das_dts_datasource)] <- "WGEEL-2016"
das0$das_dts_datasource <- 
  paste0(gsub(pattern = "dc_", replacement = "WGEEL-", 
              x= das0$das_dts_datasource), "-1")
das0$das_qal_id[is.na(das0$das_qal_id)] <- 1

nrow(das0) # 6523
das0 <- das0 |> filter(das0$das_qal_id <5)
nrow(das0) # 6402

ser <-  dbGetQuery(con_diaspara, 
                   "SELECT ser_id, ser_code FROM dateel.t_series_ser")
ser0 <- dbGetQuery(con_wgeel_distant, 
                   "SELECT ser_id, ser_nameshort as ser_code FROM datawg.t_series_ser ser;")

# adding ser_code to the series.
das <- das0 |> rename(ser_id = das_ser_id) |>
  inner_join(ser0) |> select(-ser_id) |> 
  inner_join(ser)
nrow(das) #6523

t_serannual_san_temp <-
  data.frame(
    "san_ser_id" = das$ser_id,
    "san_id" = das$das_id,
    "san_value"=das$das_value,
    "san_year" = das$das_year,
    "san_comment" = das$das_comment,
    "san_effort" = das$das_effort,
    "san_datelastupdate" = das$das_last_update,
    "san_qal_id" = das$das_qal_id,
    "san_qal_comment" = das$das_qal_comment,
    "san_wkg_code" = "WGEEL",
    "san_ver_code" = das$das_dts_datasource)


res <- dbWriteTable(con_diaspara_admin, "t_serannual_san_temp", 
                    t_serannual_san_temp, overwrite = TRUE)
dbExecute(con_diaspara_admin, "DELETE FROM  dateel.t_serannual_san;")
dbExecute(con_diaspara_admin, "INSERT INTO dateel.t_serannual_san 
SELECT 
    san_ser_id::uuid,
    san_id,
    san_value,
    san_year,
    san_comment,
    san_effort,
    san_datelastupdate,
    san_qal_id,
    san_qal_comment,
    san_wkg_code,
    san_ver_code 
FROM t_serannual_san_temp") # 6402
Code to show series table.
dbGetQuery(con_diaspara, "SELECT * FROM dateel.t_serannual_san limit 20;")|>
  knitr::kable()|>
  kable_styling(bootstrap_options = c("striped", "hover", "condensed"))
Table 50: Table t_serannual_san for annual values first 20 lines
san_ser_id san_id san_value san_year san_comment san_effort san_datelastupdate san_qal_id san_qal_comment san_wkg_code san_ver_code
9e8e2e9d-8ed6-4a61-ac83-d9249370d9e5 2837 3.820000 2016 Change 2017 3,82 -> 4,279. Das_qal_id added in 2022. NA 2022-09-09 1 NA WGEEL WGEEL-2017-1
9910419d-ee03-45ab-b4ea-409d72aa505b 2925 120.800000 2017 Additional new traps captured a further 15 kg NA 2022-09-08 1 NA WGEEL WGEEL-2017-1
4e662794-26bc-4da5-90d5-6e47a1455a59 2926 0.454000 2012 NA NA 2022-09-08 1 NA WGEEL WGEEL-2017-1
4e662794-26bc-4da5-90d5-6e47a1455a59 2927 1.144000 2013 NA NA 2022-09-08 1 NA WGEEL WGEEL-2017-1
4e662794-26bc-4da5-90d5-6e47a1455a59 2928 0.311000 2014 NA NA 2022-09-08 1 NA WGEEL WGEEL-2017-1
4e662794-26bc-4da5-90d5-6e47a1455a59 2929 0.159000 2015 NA NA 2022-09-08 1 NA WGEEL WGEEL-2017-1
4e662794-26bc-4da5-90d5-6e47a1455a59 2930 0.360000 2016 NA NA 2022-09-08 1 NA WGEEL WGEEL-2017-1
4e662794-26bc-4da5-90d5-6e47a1455a59 2931 0.518000 2017 Trap refurbished, glass eel fell, young yellow eel increased NA 2022-09-08 1 NA WGEEL WGEEL-2017-1
6846b849-d11a-4eef-903d-39e7e30c503a 2932 0.720000 1987 NA NA 2022-09-08 1 NA WGEEL WGEEL-2017-1
6846b849-d11a-4eef-903d-39e7e30c503a 2933 14.480000 1988 NA NA 2022-09-08 1 NA WGEEL WGEEL-2017-1
6846b849-d11a-4eef-903d-39e7e30c503a 2934 0.259000 2007 NA NA 2022-09-08 1 NA WGEEL WGEEL-2017-1
3ca798cf-9474-48a0-b742-2756aca6df3c 1061 4283.000000 1997 NA NA 2022-09-12 1 NA WGEEL WGEEL-2016-1
56760cce-14d6-414b-98d0-871bd8a64384 1777 9453.000000 1960 NA NA 2022-09-12 1 NA WGEEL WGEEL-2016-1
0d83cf08-df7a-4853-95d8-cbdc18cde5f2 632 36.700000 1989 NA NA 2022-09-09 1 NA WGEEL WGEEL-2016-1
5534b8e4-ced3-4655-b5b7-8252cf01cfe0 680 121.000000 1952 NA NA 2022-09-09 1 NA WGEEL WGEEL-2016-1
5534b8e4-ced3-4655-b5b7-8252cf01cfe0 690 185.000000 1962 NA NA 2022-09-09 1 NA WGEEL WGEEL-2016-1
5534b8e4-ced3-4655-b5b7-8252cf01cfe0 695 258.000000 1967 NA NA 2022-09-09 1 NA WGEEL WGEEL-2016-1
caa6d368-37a5-4093-9585-bc303c769c14 2160 25.200000 1985 number of hauls =6 6 2022-09-09 1 NA WGEEL WGEEL-2016-1
4ae8d33f-3808-4258-a31f-7bf1f1233a8a 5440 115.000000 2013 Das_qal_id added in 2022. NA 2022-09-09 1 NA WGEEL WGEEL-2019-1
11e4ae1e-c7a8-4ab1-a080-18545786886d 4537 0.152542 1991 NA NA 2022-09-08 1 NA WGEEL WGEEL-2019-1

5.5 Creating table joining series and station

The table is created but empty. We need the stations in ICES first.

SQL code to create table dat.tj_seriesstation_ses
DROP TABLE IF EXISTS dat.tj_seriesstation_ses; 
CREATE TABLE dat.tj_seriesstation_ses (
 ses_ser_id uuid PRIMARY KEY,
 CONSTRAINT fk_ses_ser_id FOREIGN KEY (ses_ser_id)
    REFERENCES dat.t_series_ser (ser_id) 
    ON UPDATE CASCADE ON DELETE CASCADE,  
 CONSTRAINT uk_ses_ser_id UNIQUE (ses_ser_id) ,
 ses_station_code INTEGER NULL,
  CONSTRAINT fk_station_code FOREIGN KEY (ses_station_code) 
  REFERENCES "ref"."StationDictionary" ("Station_Code")   
  );
  

GRANT ALL ON dat.tj_seriesstation_ses TO diaspara_admin;
GRANT SELECT ON dat.tj_seriesstation_ses TO diaspara_read; 

5.5.1 Creating inherited joining series and station

SQL code to create table dateel.tj_seriesstation_ses
DROP TABLE IF EXISTS dateel.tj_seriesstation_ses; 
CREATE TABLE dateel.tj_seriesstation_ses (
 CONSTRAINT fk_ses_ser_id FOREIGN KEY (ses_ser_id)
    REFERENCES dat.t_series_ser (ser_id) 
    ON UPDATE CASCADE ON DELETE CASCADE,  
 CONSTRAINT uk_ses_ser_id UNIQUE (ses_ser_id) ,
  CONSTRAINT fk_station_code FOREIGN KEY (ses_station_code) 
  REFERENCES "ref"."StationDictionary" ("Station_Code")   
  ) inherits (dat.tj_seriesstation_ses);
  

GRANT ALL ON dateel.tj_seriesstation_ses TO diaspara_admin;
GRANT SELECT ON dateel.tj_seriesstation_ses TO diaspara_read; 

5.6 Creating group traits

Fish traits table aim to store information collected on individual fish. However, for various reasons, similar data are often collected and averaged on batches of individuals. We created a group trait to store those data

5.6.1 Create group table

SQL code to create table dat.t_group_gr

-- DROP TABLE dat.t_group_gr CASCADE;

CREATE TABLE dat.t_group_gr (
  gr_id serial4 NOT NULL,
  gr_ser_id UUID NOT NULL,
  CONSTRAINT fk_gr_ser_id FOREIGN KEY (gr_ser_id)
  REFERENCES dat.t_series_ser (ser_id) 
  ON UPDATE CASCADE ON DELETE CASCADE, 
  gr_gr_id INTEGER NULL,
  CONSTRAINT fk_gr_gr_id  FOREIGN KEY (gr_gr_id, gr_wkg_code)
  REFERENCES dat.t_group_gr(gr_id, gr_wkg_code)
  ON UPDATE CASCADE ON DELETE CASCADE,
  gr_wkg_code TEXT NOT NULL,  
  CONSTRAINT fk_gr_wkg_code  FOREIGN KEY (gr_wkg_code)
  REFERENCES ref.tr_icworkinggroup_wkg(wkg_code)
  ON UPDATE CASCADE ON DELETE RESTRICT,
  CONSTRAINT t_group_gr_pkey PRIMARY KEY (gr_id, gr_wkg_code),
  gr_spe_code TEXT,
  CONSTRAINT fk_gr_spe_code FOREIGN KEY (gr_spe_code) 
  REFERENCES "ref".tr_species_spe(spe_code) 
  ON UPDATE CASCADE ON DELETE RESTRICT ,
  gr_lfs_code TEXT,
  CONSTRAINT fk_gr_lfs_code_gr_spe_code FOREIGN KEY (gr_lfs_code, gr_spe_code)
  REFERENCES "ref".tr_lifestage_lfs (lfs_code, lfs_spe_code) 
  ON UPDATE CASCADE ON DELETE RESTRICT, 
  gr_sex_code TEXT,
  CONSTRAINT ck_nn_gr_sex_code_gr_gr_id CHECK ((gr_gr_id IS NULL AND gr_sex_code IS NULL) OR (gr_gr_id IS NOT NULL AND gr_sex_code IS NOT NULL)),
  CONSTRAINT ck_gr_sex_code CHECK (gr_sex_code = 'M' OR gr_sex_code = 'F' OR gr_sex_code IS NULL),
  gr_year int4 NULL,
  gr_number int4 NULL,
  gr_comment text NULL,
  gr_lastupdate date DEFAULT CURRENT_DATE NOT NULL,
  gr_ver_code TEXT NOT NULL,
  CONSTRAINT fk_gr_ver_code FOREIGN KEY (gr_ver_code)
  REFERENCES ref.tr_version_ver(ver_code)
  ON UPDATE CASCADE ON DELETE RESTRICT
);

COMMENT ON TABLE dat.t_group_gr IS
 'Table identifying the group metrics, a group metric corresponds to a
number of fish sampled for a given year, mostly to describe the annual series. Comments can be made
on the sampling with gr_comments. There can be several group metrics for the same year, for instance
with sampling designs for different stages';

COMMENT ON COLUMN dat.t_group_gr.gr_id IS
 'Group ID, serial primary key on gr_id and gr_wkg_code';
COMMENT ON COLUMN dat.t_group_gr.gr_gr_id IS
 'Parent group ID, used when giving separate metrics for male and females, in that case the gr_sex_code must be provided';
COMMENT ON COLUMN dat.t_group_gr.gr_wkg_code IS
 'Code of the working group, one of
WGBAST, WGEEL, WGNAS, WKTRUTTA';
COMMENT ON COLUMN dat.t_group_gr.gr_lfs_code IS
 'Life stage code';
COMMENT ON COLUMN dat.t_group_gr.gr_spe_code IS
 'Species code';
COMMENT ON COLUMN dat.t_group_gr.gr_sex_code IS
 'Sex code only for subgroups male or female';
COMMENT ON COLUMN dat.t_group_gr.gr_year IS
 'The year';
COMMENT ON COLUMN dat.t_group_gr.gr_number IS
 'Number of fish in the group';
COMMENT ON COLUMN dat.t_group_gr.gr_comment IS
 'Comment on the group metric, including on the sampling design applied to that particular year, if different from that applied for the whole series.';
COMMENT ON COLUMN dat.t_group_gr.gr_lastupdate IS
 'Last update, inserted automatically';
COMMENT ON COLUMN dat.t_group_gr.gr_ver_code IS
 'Version code as in tr_version_ver, corresponds to the working group code WGNAS-2024-1 WGEEL-2016-1, the -1 indicate the first data call in the year, -2 would be second etc....';


GRANT ALL ON dat.t_group_gr TO diaspara_admin;
GRANT SELECT ON dat.t_group_gr TO diaspara_read; 

5.6.2 Create group table for dateel

SQL code to create table dateel.t_group_gr

-- DROP TABLE IF EXISTS dateel.t_group_gr;

CREATE TABLE dateel.t_group_gr (
 CONSTRAINT fk_gr_ser_id FOREIGN KEY (gr_ser_id)
  REFERENCES dateel.t_series_ser (ser_id) 
  ON UPDATE CASCADE ON DELETE CASCADE, 
  CONSTRAINT fk_gr_gr_id  FOREIGN KEY (gr_gr_id, gr_wkg_code)
  REFERENCES dateel.t_group_gr(gr_id, gr_wkg_code)
  ON UPDATE CASCADE ON DELETE CASCADE,
  CONSTRAINT fk_gr_wkg_code  FOREIGN KEY (gr_wkg_code)
  REFERENCES ref.tr_icworkinggroup_wkg(wkg_code)
  ON UPDATE CASCADE ON DELETE RESTRICT,
  CONSTRAINT t_group_gr_pkey PRIMARY KEY (gr_id, gr_wkg_code), 
  CONSTRAINT fk_gr_ver_code FOREIGN KEY (gr_ver_code)
  REFERENCES refeel.tr_version_ver(ver_code)
  ON UPDATE CASCADE ON DELETE RESTRICT,
  CONSTRAINT fk_gr_lfs_code_gr_spe_code FOREIGN KEY (gr_lfs_code, gr_spe_code)
  REFERENCES "ref".tr_lifestage_lfs (lfs_code, lfs_spe_code) 
  ON UPDATE CASCADE ON DELETE RESTRICT, 
   CONSTRAINT fk_gr_spe_code FOREIGN KEY (gr_spe_code) 
  REFERENCES "ref".tr_species_spe(spe_code) 
  ON UPDATE CASCADE ON DELETE RESTRICT 
) INHERITS (dat.t_group_gr);


COMMENT ON TABLE dateel.t_group_gr IS
 'Table identifying the group metrics, a group metric corresponds to a
number of fish sampled for a given year, mostly to describe the annual series. Comments can be made
on the sampling with gr_comments. There can be several group metrics for the same year, for instance
with sampling designs for different stages';

COMMENT ON COLUMN dateel.t_group_gr.gr_id IS
 'Group ID, serial primary key on gr_id and gr_wkg_code';
COMMENT ON COLUMN dat.t_group_gr.gr_gr_id IS
 'Parent group ID, used when giving separate metrics for male and females, in that case the gr_sex_code must be provided';
COMMENT ON COLUMN dateel.t_group_gr.gr_wkg_code IS
 'Code of the working group, one of
WGBAST, WGEEL, WGNAS, WKTRUTTA';
COMMENT ON COLUMN dateel.t_group_gr.gr_year IS
 'The year';
COMMENT ON COLUMN dateel.t_group_gr.gr_number IS
 'Number of fish in the group';
COMMENT ON COLUMN dateel.t_group_gr.gr_comment IS
 'Comment on the group metric, including on the sampling design applied to that particular year, if different from that applied for the whole series.';
COMMENT ON COLUMN dateel.t_group_gr.gr_lastupdate IS
 'Last update, inserted automatically';
COMMENT ON COLUMN dateel.t_group_gr.gr_ver_code IS
 'Version code as in tr_version_ver, corresponds to the working group code WGNAS-2024-1 WGEEL-2016-1, the -1 indicate the first data call in the year, -2 would be second etc....';
COMMENT ON COLUMN dat.t_group_gr.gr_lfs_code IS
 'Life stage code';
COMMENT ON COLUMN dat.t_group_gr.gr_spe_code IS
 'Species code';
COMMENT ON COLUMN dat.t_group_gr.gr_sex_code IS
 'Sex code only for subgroups male or female';
GRANT ALL ON dateel.t_group_gr TO diaspara_admin;
GRANT SELECT ON dateel.t_group_gr TO diaspara_read; 

5.6.3 Import data for group

The following scripts are used to import group trait from the two existing data formats, sampling and series.

SQL code to Import data
/*
SELECT DISTINCT gr_dts_datasource 
FROM datwgeel.t_groupseries_grser
*/

/*
 * Scripts differ a bit for series and sampling. Check for some series with comment
so see if need removing.

>  all related metrics have qal_id=22 following data call 2022
 */

DELETE FROM dateel.t_group_gr;
INSERT INTO dateel.t_group_gr
(gr_id, gr_ser_id, gr_gr_id, gr_wkg_code, gr_spe_code, gr_lfs_code, gr_year, gr_number, gr_comment, gr_lastupdate, gr_ver_code)
SELECT 
gr_id,
tss2.ser_id ,
NULL AS gr_gr_id,
'WGEEL' AS gr_wkg_code,
'127186' AS gr_spe_code,
tss.ser_lfs_code AS gr_lfs_code,
gr_year,
gr_number,
gr_comment,
gr_lastupdate,
CASE WHEN gr_dts_datasource = 'dc_2019' THEN 'WGEEL-2019-1'
     WHEN gr_dts_datasource = 'dc_2020' THEN 'WGEEL-2020-1'
     WHEN gr_dts_datasource ='dc_2021' THEN 'WGEEL-2021-1'
     WHEN gr_dts_datasource ='dc_2022' THEN 'WGEEL-2022-1'
     WHEN gr_dts_datasource ='dc_2023' THEN 'WGEEL-2023-1'
     WHEN gr_dts_datasource ='dc_2024' THEN 'WGEEL-2024-1'
     ELSE 'WGEEL-2018-1' END AS gr_ver_code
FROM  datwgeel.t_groupseries_grser grser
JOIN datwgeel.t_series_ser AS tss ON grser_ser_id = ser_id
JOIN dateel.t_series_ser AS tss2 ON ser_code= ser_nameshort; --2681



INSERT INTO dateel.t_group_gr
(gr_id, gr_ser_id, gr_gr_id, gr_wkg_code,  gr_spe_code, gr_lfs_code, gr_year, gr_number, gr_comment, gr_lastupdate, gr_ver_code)
SELECT 
gr_id, 
tss2.ser_id  AS gr_ser_id,
NULL AS gr_gr_id,
'WGEEL' AS gr_wkg_code,
'127186' AS gr_spe_code,
grsa_lfs_code AS gr_lfs_code,
gr_year,
gr_number,
gr_comment,
gr_lastupdate,
CASE WHEN gr_dts_datasource = 'dc_2019' THEN 'WGEEL-2019-1'
     WHEN gr_dts_datasource = 'dc_2020' THEN 'WGEEL-2020-1'
     WHEN gr_dts_datasource ='dc_2021' THEN 'WGEEL-2021-1'
     WHEN gr_dts_datasource ='dc_2022' THEN 'WGEEL-2022-1'
     WHEN gr_dts_datasource ='dc_2023' THEN 'WGEEL-2023-1'
     WHEN gr_dts_datasource ='dc_2024' THEN 'WGEEL-2024-1'
     ELSE 'WGEEL-2018-1' END AS gr_ver_code
FROM  datwgeel.t_groupsamp_grsa 
JOIN datwgeel.t_samplinginfo_sai AS tss ON grsa_sai_id = sai_id
JOIN dateel.t_series_ser AS tss2 ON ser_code= sai_id::text; --798




-- INSERT Males AND Females WITH gr_gr_id

DROP SEQUENCE IF EXISTS seq_group;
CREATE TEMPORARY SEQUENCE seq_group;
SELECT setval('seq_group', (SELECT max(gr_id) FROM dateel.t_group_gr)); -- 13741

-- Males with gr_id from series (subgroupsample)

INSERT INTO dateel.t_group_gr
(gr_id, 
gr_ser_id, 
gr_gr_id, 
gr_wkg_code,  
gr_spe_code, 
gr_sex_code, 
gr_lfs_code, 
gr_year, 
gr_number, 
gr_comment, 
gr_lastupdate,
gr_ver_code)
SELECT 
nextval('seq_group') AS gr_id, 
tss2.ser_id  AS gr_ser_id,
grser.gr_id AS gr_gr_id,
'WGEEL' AS gr_wkg_code,
'127186' AS gr_spe_code,
'M' AS gr_sex_code,
tss.ser_lfs_code AS gr_lfs_code,
gr_year,
gr_number,
gr_comment,
gr_lastupdate,
CASE WHEN gr_dts_datasource = 'dc_2019' THEN 'WGEEL-2019-1'
     WHEN gr_dts_datasource = 'dc_2020' THEN 'WGEEL-2020-1'
     WHEN gr_dts_datasource ='dc_2021' THEN 'WGEEL-2021-1'
     WHEN gr_dts_datasource ='dc_2022' THEN 'WGEEL-2022-1'
     WHEN gr_dts_datasource ='dc_2023' THEN 'WGEEL-2023-1'
     WHEN gr_dts_datasource ='dc_2024' THEN 'WGEEL-2024-1'
     ELSE 'WGEEL-2018-1' END AS gr_ver_code
FROM  
datwgeel.t_metricgroupseries_megser 
JOIN datwgeel.t_groupseries_grser grser ON meg_gr_id = gr_id
JOIN datwgeel.t_series_ser AS tss ON grser_ser_id = ser_id
JOIN dateel.t_series_ser AS tss2 ON ser_code= ser_nameshort
WHERE meg_mty_id IN (18,19,20); --409

# Females WITH gr_gr_id series (subgroupsample)


INSERT INTO dateel.t_group_gr
(gr_id, 
gr_ser_id, 
gr_gr_id, 
gr_wkg_code,  
gr_spe_code, 
gr_sex_code, 
gr_lfs_code, 
gr_year, 
gr_number, 
gr_comment, 
gr_lastupdate,
gr_ver_code)
SELECT 
nextval('seq_group') AS gr_id, 
tss2.ser_id  AS gr_ser_id,
grser.gr_id AS gr_gr_id,
'WGEEL' AS gr_wkg_code,
'127186' AS gr_spe_code,
'F' AS gr_sex_code,
tss.ser_lfs_code AS gr_lfs_code,
gr_year,
gr_number,
gr_comment,
gr_lastupdate,
CASE WHEN gr_dts_datasource = 'dc_2019' THEN 'WGEEL-2019-1'
     WHEN gr_dts_datasource = 'dc_2020' THEN 'WGEEL-2020-1'
     WHEN gr_dts_datasource ='dc_2021' THEN 'WGEEL-2021-1'
     WHEN gr_dts_datasource ='dc_2022' THEN 'WGEEL-2022-1'
     WHEN gr_dts_datasource ='dc_2023' THEN 'WGEEL-2023-1'
     WHEN gr_dts_datasource ='dc_2024' THEN 'WGEEL-2024-1'
     ELSE 'WGEEL-2018-1' END AS gr_ver_code
FROM  
datwgeel.t_metricgroupseries_megser 
JOIN datwgeel.t_groupseries_grser grser ON meg_gr_id = gr_id
JOIN datwgeel.t_series_ser AS tss ON grser_ser_id = ser_id
JOIN dateel.t_series_ser AS tss2 ON ser_code= ser_nameshort
WHERE meg_mty_id IN (21,22,23); --553

# males from sampling


INSERT INTO dateel.t_group_gr
(gr_id, 
gr_ser_id, 
gr_gr_id, 
gr_wkg_code,  
gr_spe_code, 
gr_sex_code, 
gr_lfs_code, 
gr_year, 
gr_number, 
gr_comment, 
gr_lastupdate,
gr_ver_code)
SELECT 
nextval('seq_group') AS gr_id, 
tss2.ser_id  AS gr_ser_id,
grsa.gr_id AS gr_gr_id,
'WGEEL' AS gr_wkg_code,
'127186' AS gr_spe_code,
'M' AS gr_sex_code,
grsa_lfs_code,
gr_year,
gr_number,
gr_comment,
gr_lastupdate,
CASE WHEN gr_dts_datasource = 'dc_2019' THEN 'WGEEL-2019-1'
     WHEN gr_dts_datasource = 'dc_2020' THEN 'WGEEL-2020-1'
     WHEN gr_dts_datasource ='dc_2021' THEN 'WGEEL-2021-1'
     WHEN gr_dts_datasource ='dc_2022' THEN 'WGEEL-2022-1'
     WHEN gr_dts_datasource ='dc_2023' THEN 'WGEEL-2023-1'
     WHEN gr_dts_datasource ='dc_2024' THEN 'WGEEL-2024-1'
     ELSE 'WGEEL-2018-1' END AS gr_ver_code
FROM  
datwgeel.t_metricgroupsamp_megsa 
JOIN datwgeel.t_groupsamp_grsa  grsa ON meg_gr_id = gr_id
JOIN datwgeel.t_samplinginfo_sai AS tss ON grsa_sai_id = sai_id
JOIN dateel.t_series_ser AS tss2 ON ser_code=  sai_id::text
WHERE meg_mty_id IN (18,19,20); --544

# Females from sampling


INSERT INTO dateel.t_group_gr
(gr_id, 
gr_ser_id, 
gr_gr_id, 
gr_wkg_code,  
gr_spe_code, 
gr_sex_code, 
gr_lfs_code, 
gr_year, 
gr_number, 
gr_comment, 
gr_lastupdate,
gr_ver_code)
SELECT 
nextval('seq_group') AS gr_id, 
tss2.ser_id  AS gr_ser_id,
grsa.gr_id AS gr_gr_id,
'WGEEL' AS gr_wkg_code,
'127186' AS gr_spe_code,
'F' AS gr_sex_code,
grsa_lfs_code AS gr_lfs_code,
gr_year,
gr_number,
gr_comment,
gr_lastupdate,
CASE WHEN gr_dts_datasource = 'dc_2019' THEN 'WGEEL-2019-1'
     WHEN gr_dts_datasource = 'dc_2020' THEN 'WGEEL-2020-1'
     WHEN gr_dts_datasource ='dc_2021' THEN 'WGEEL-2021-1'
     WHEN gr_dts_datasource ='dc_2022' THEN 'WGEEL-2022-1'
     WHEN gr_dts_datasource ='dc_2023' THEN 'WGEEL-2023-1'
     WHEN gr_dts_datasource ='dc_2024' THEN 'WGEEL-2024-1'
     ELSE 'WGEEL-2018-1' END AS gr_ver_code
FROM  
datwgeel.t_metricgroupsamp_megsa 
JOIN datwgeel.t_groupsamp_grsa  grsa ON meg_gr_id = gr_id
JOIN datwgeel.t_samplinginfo_sai AS tss ON grsa_sai_id = sai_id
JOIN dateel.t_series_ser AS tss2 ON ser_code=  sai_id::text
WHERE meg_mty_id IN (21,22,23); --1183


Table 51: Table t_group_gr, group related to annual values first 20 lines
gr_id gr_ser_id gr_gr_id gr_wkg_code gr_spe_code gr_lfs_code gr_sex_code gr_year gr_number gr_comment gr_lastupdate gr_ver_code
12932 2d8f9e41-f487-4064-b7f1-6a21b084e434 NA WGEEL 126281 Y NA 2021 NA NA 2022-09-09 WGEEL-2022-1
1049 2d8f9e41-f487-4064-b7f1-6a21b084e434 NA WGEEL 126281 Y NA 2019 NA NA 2022-09-09 WGEEL-2020-1
1048 2d8f9e41-f487-4064-b7f1-6a21b084e434 NA WGEEL 126281 Y NA 2018 NA NA 2022-09-09 WGEEL-2020-1
1047 2d8f9e41-f487-4064-b7f1-6a21b084e434 NA WGEEL 126281 Y NA 2017 NA NA 2022-09-09 WGEEL-2020-1
1046 2d8f9e41-f487-4064-b7f1-6a21b084e434 NA WGEEL 126281 Y NA 2016 NA NA 2022-09-09 WGEEL-2020-1
690 d98b022b-df0e-442b-98e8-a998265eb38c NA WGEEL 126281 Y NA 2018 233 gr_number added in 2022; Note weight was not measured but estimated from L-W relationship 2022-09-13 WGEEL-2022-1
689 d98b022b-df0e-442b-98e8-a998265eb38c NA WGEEL 126281 Y NA 2017 49 gr_number added in 2022; Note weight was not measured but estimated from L-W relationship 2022-09-13 WGEEL-2022-1
688 d98b022b-df0e-442b-98e8-a998265eb38c NA WGEEL 126281 Y NA 2016 163 gr_number added in 2022; Note weight was not measured but estimated from L-W relationship 2022-09-13 WGEEL-2022-1
687 d98b022b-df0e-442b-98e8-a998265eb38c NA WGEEL 126281 Y NA 2015 228 gr_number added in 2022; Note weight was not measured but estimated from L-W relationship 2022-09-13 WGEEL-2022-1
686 d98b022b-df0e-442b-98e8-a998265eb38c NA WGEEL 126281 Y NA 2014 136 gr_number added in 2022; Note weight was not measured but estimated from L-W relationship 2022-09-13 WGEEL-2022-1
685 d98b022b-df0e-442b-98e8-a998265eb38c NA WGEEL 126281 Y NA 2013 33 gr_number added in 2022; Note weight was not measured but estimated from L-W relationship 2022-09-13 WGEEL-2022-1
684 d98b022b-df0e-442b-98e8-a998265eb38c NA WGEEL 126281 Y NA 2012 261 gr_number added in 2022; Note weight was not measured but estimated from L-W relationship 2022-09-13 WGEEL-2022-1
683 d98b022b-df0e-442b-98e8-a998265eb38c NA WGEEL 126281 Y NA 2011 23 gr_number added in 2022; Note weight was not measured but estimated from L-W relationship 2022-09-13 WGEEL-2022-1
682 d98b022b-df0e-442b-98e8-a998265eb38c NA WGEEL 126281 Y NA 2010 172 gr_number added in 2022; Note weight was not measured but estimated from L-W relationship 2022-09-13 WGEEL-2022-1
681 d98b022b-df0e-442b-98e8-a998265eb38c NA WGEEL 126281 Y NA 2009 169 gr_number added in 2022; Note weight was not measured but estimated from L-W relationship 2022-09-13 WGEEL-2022-1
680 d98b022b-df0e-442b-98e8-a998265eb38c NA WGEEL 126281 Y NA 2008 33 gr_number added in 2022; Note weight was not measured but estimated from L-W relationship 2022-09-13 WGEEL-2022-1
679 d98b022b-df0e-442b-98e8-a998265eb38c NA WGEEL 126281 Y NA 2007 51 gr_number added in 2022; Note weight was not measured but estimated from L-W relationship 2022-09-13 WGEEL-2022-1
678 d98b022b-df0e-442b-98e8-a998265eb38c NA WGEEL 126281 Y NA 2006 434 gr_number added in 2022; Note weight was not measured but estimated from L-W relationship 2022-09-13 WGEEL-2022-1
677 d98b022b-df0e-442b-98e8-a998265eb38c NA WGEEL 126281 Y NA 2005 17 gr_number added in 2022; Note weight was not measured but estimated from L-W relationship 2022-09-13 WGEEL-2022-1
676 d98b022b-df0e-442b-98e8-a998265eb38c NA WGEEL 126281 Y NA 2004 30 gr_number added in 2022; Note weight was not measured but estimated from L-W relationship 2022-09-13 WGEEL-2022-1

5.7 Grouptrait table

5.7.1 Create table

SQL code to create tables dat.t_grouptrait_grt and dateel.t_grouptrait_grt

-- DROP TABLE IF EXISTS dat.t_grouptrait_grt CASCADE;


CREATE TABLE dat.t_grouptrait_grt (
  grt_ser_id uuid,
 CONSTRAINT fk_grt_ser_id FOREIGN KEY (grt_ser_id)
    REFERENCES dat.t_series_ser (ser_id) 
    ON UPDATE CASCADE ON DELETE CASCADE,  
  grt_wkg_code TEXT NOT NULL,  
  CONSTRAINT fk_grt_wkg_code  FOREIGN KEY (grt_wkg_code)
  REFERENCES ref.tr_icworkinggroup_wkg(wkg_code)
  ON UPDATE CASCADE ON DELETE RESTRICT,
  grt_spe_code TEXT NOT NULL,  
  CONSTRAINT fk_grt_spe_code  FOREIGN KEY (grt_spe_code)
  REFERENCES ref.tr_species_spe(spe_code)
  ON UPDATE CASCADE ON DELETE RESTRICT,
  grt_id serial4 NOT NULL,
  grt_gr_id int4 NOT NULL,
  CONSTRAINT fk_grt_gr_id FOREIGN KEY (grt_gr_id, grt_wkg_code) 
  REFERENCES dat.t_group_gr(gr_id,gr_wkg_code) 
    ON UPDATE CASCADE ON DELETE CASCADE,
  grt_tra_code TEXT NOT NULL,
  CONSTRAINT fk_grt_tra_code FOREIGN KEY (grt_tra_code) 
  REFERENCES ref.tr_trait_tra(tra_code)
  ON UPDATE CASCADE ON DELETE RESTRICT,
  grt_value numeric NULL,
  grt_trv_code TEXT,
  CONSTRAINT fk_grt_trv_tra_code FOREIGN KEY (grt_trv_code, grt_tra_code,grt_wkg_code)
  REFERENCES ref.tr_traitvaluequal_trv(trv_code, trv_trq_code, trv_wkg_code)
  ON UPDATE CASCADE ON DELETE RESTRICT,
  grt_trm_code TEXT,
  CONSTRAINT fk_grt_trm_code FOREIGN KEY (grt_trm_code)
  REFERENCES ref.tr_traitmethod_trm(trm_code)
  ON UPDATE CASCADE ON DELETE RESTRICT,
  grt_last_update date DEFAULT CURRENT_DATE NOT NULL,
  grt_qal_code int4 NULL,
    CONSTRAINT fk_grt_qal_id FOREIGN KEY (grt_qal_code) 
  REFERENCES ref.tr_quality_qal(qal_code) ON UPDATE CASCADE,
  grt_ver_code TEXT NOT NULL,
  CONSTRAINT fk_grt_ver_code FOREIGN KEY (grt_ver_code)
  REFERENCES ref.tr_version_ver(ver_code)
  ON UPDATE CASCADE ON DELETE RESTRICT,
  CONSTRAINT uk_grt_gr UNIQUE (grt_gr_id, grt_trm_code, grt_wkg_code),
  CONSTRAINT t_grouptrait_grt_pkey PRIMARY KEY (grt_id, grt_wkg_code),
  CONSTRAINT ck_qualitative_or_numeric CHECK 
  (
  (grt_value IS NULL AND grt_trv_code IS NOT NULL) OR
  (grt_value IS NOT NULL AND grt_trv_code IS  NULL)
  )
);
CREATE INDEX dat_t_grouptrait_grt_idx ON dat.t_grouptrait_grt USING btree (grt_gr_id);

GRANT ALL ON dat.t_grouptrait_grt TO diaspara_admin;
GRANT SELECT ON dat.t_grouptrait_grt TO diaspara_read; 

DROP TABLE IF EXISTS  dateel.t_grouptrait_grt;
CREATE TABLE dateel.t_grouptrait_grt (
 CONSTRAINT fk_grt_ser_id FOREIGN KEY (grt_ser_id)
    REFERENCES dateel.t_series_ser (ser_id) 
    ON UPDATE CASCADE ON DELETE CASCADE,
  CONSTRAINT fk_grt_wkg_code  FOREIGN KEY (grt_wkg_code)
  REFERENCES ref.tr_icworkinggroup_wkg(wkg_code)
  ON UPDATE CASCADE ON DELETE RESTRICT,
  CONSTRAINT fk_grt_spe_code  FOREIGN KEY (grt_spe_code)
  REFERENCES ref.tr_species_spe(spe_code)
  ON UPDATE CASCADE ON DELETE RESTRICT,
  CONSTRAINT fk_grt_gr_id FOREIGN KEY (grt_gr_id, grt_wkg_code) 
  REFERENCES dateel.t_group_gr(gr_id,gr_wkg_code) 
    ON UPDATE CASCADE ON DELETE CASCADE,
  CONSTRAINT fk_grt_tra_code FOREIGN KEY (grt_tra_code) 
  REFERENCES refeel.tg_trait_tra(tra_code)
  ON UPDATE CASCADE ON DELETE RESTRICT,
  CONSTRAINT fk_grt_trv_tra_code FOREIGN KEY (grt_trv_code, grt_tra_code) 
  -- unlike in dat.t_grouptrait_grt this one does not take ref TO wkgcode, no need AS we are in dateel
  REFERENCES refeel.tr_traitvaluequal_trv(trv_code, trv_trq_code)
  ON UPDATE CASCADE ON DELETE RESTRICT,
  CONSTRAINT fk_grt_trm_code FOREIGN KEY (grt_trm_code)
  REFERENCES refeel.tr_traitmethod_trm(trm_code)
  ON UPDATE CASCADE ON DELETE RESTRICT,
  CONSTRAINT fk_grt_qal_id FOREIGN KEY (grt_qal_code) 
  REFERENCES ref.tr_quality_qal(qal_code) ON UPDATE CASCADE,
  CONSTRAINT fk_grt_ver_code FOREIGN KEY (grt_ver_code)
  REFERENCES refeel.tr_version_ver(ver_code)
  ON UPDATE CASCADE ON DELETE RESTRICT,
  CONSTRAINT uk_trv_gr_id_trv_tra_code UNIQUE(grt_gr_id,grt_tra_code)
) INHERITS (dat.t_grouptrait_grt);
CREATE INDEX dateel_t_grouptrait_grt_idx ON dateel.t_grouptrait_grt
 USING btree (grt_gr_id);
GRANT ALL ON dateel.t_grouptrait_grt TO diaspara_admin;
GRANT SELECT ON dateel.t_grouptrait_grt TO diaspara_read; 


COMMENT ON TABLE dateel.t_grouptrait_grt IS
 'Table joining groups and traits';
COMMENT ON COLUMN dateel.t_grouptrait_grt.grt_ser_id IS
 'Series UUID';
COMMENT ON COLUMN dateel.t_grouptrait_grt.grt_wkg_code IS
 'Working group on of WGEEL, WGNAS, WGBAST ...';
COMMENT ON COLUMN dateel.t_grouptrait_grt.grt_spe_code IS
 'Species code here ''127186''';
COMMENT ON COLUMN dateel.t_grouptrait_grt.grt_id IS
 'ID, integer, unique for wkg_code';
COMMENT ON COLUMN dateel.t_grouptrait_grt.grt_gr_id IS
 'ID of the group';
COMMENT ON COLUMN dateel.t_grouptrait_grt.grt_tra_code IS
 'Code of the trait, e.g. Lengthmm';
COMMENT ON COLUMN dateel.t_grouptrait_grt.grt_value IS
 'Value for numeric';
COMMENT ON COLUMN dateel.t_grouptrait_grt.grt_trv_code IS
 'Value for qualitative see refeel.tr_traitvaluequal_trv';
COMMENT ON COLUMN dateel.t_grouptrait_grt.grt_trm_code IS
 'Method see refeel.tr_traimethod_trm';
COMMENT ON COLUMN dateel.t_grouptrait_grt.grt_last_update IS
 'date last update';
COMMENT ON COLUMN dateel.t_grouptrait_grt.grt_qal_code IS
 'Quality code references ref.tr_quality_qal';
COMMENT ON COLUMN dateel.t_grouptrait_grt.grt_ver_code IS
 'version e.g. WGEEL_2024_1';

-- TODO trigger on date
-- TODO

5.7.2 Import data

Mapping previous database for groups :This is how the mapping was done for groups, on the left the new db with in red the fields for individual trait (not in group traits), on the right, the old db, with in oranges fields that need to be mapped to method. In yellow the groups that now refer to subgroup by sex recreated at previous step
SQL code to import data

/*
 * Insert numeric for group - series 
 */
DELETE FROM dateel.t_grouptrait_grt;

INSERT INTO dateel.t_grouptrait_grt
(grt_ser_id, 
grt_wkg_code, 
grt_spe_code, 
grt_id, 
grt_gr_id, 
grt_tra_code, 
grt_value, 
grt_trv_code, 
grt_trm_code, 
grt_last_update, 
grt_qal_code, 
grt_ver_code)
-- extract method from table
-- this will extract 3 columns, meg_gr_id, meg_method_anguillicola and meg_method_sex
WITH a1 AS (
SELECT meg_gr_id,
       meg_value AS meg_method_sex 
FROM datwgeel.t_metricgroupseries_megser 
WHERE meg_mty_id = 27
AND meg_value IS NOT NULL),
 a2 AS (
 SELECT meg_gr_id,
       meg_value AS meg_method_anguillicola 
FROM datwgeel.t_metricgroupseries_megser 
WHERE meg_mty_id = 28
AND meg_value IS NOT NULL),
mm AS (
SELECT coalesce(a1.meg_gr_id, a2.meg_gr_id)  AS meg_gr_id,
meg_method_sex,
meg_method_anguillicola
FROM  a1 FULL OUTER JOIN a2 ON a1.meg_gr_id = a2.meg_gr_id)
-- Insert select query
SELECT 
tss2.ser_id AS grt_ser_id,
'WGEEL' AS grt_wkg_code,
'127186' AS grt_spe_code,
meg_id AS grt_id, 
megser.meg_gr_id AS grt_gr_id, 
CASE WHEN meg_mty_id = 1 THEN 'Lengthmm'
WHEN meg_mty_id = 2 THEN 'Weightg'
WHEN meg_mty_id = 3 THEN 'Ageyear'
WHEN meg_mty_id = 6 THEN 'Female_proportion'
WHEN meg_mty_id = 7 THEN 'Differentiated_proportion'
WHEN meg_mty_id = 8 THEN 'Anguillicola_proportion'
WHEN meg_mty_id = 9 THEN 'Anguillicola_intensity'
WHEN meg_mty_id = 10 THEN 'Muscle_lipid'
WHEN meg_mty_id = 11 THEN 'Muscle_lipid' -- different method see method
WHEN meg_mty_id = 12 THEN 'Sum_6_pcb'
WHEN meg_mty_id = 13 THEN 'Evex_proportion'
WHEN meg_mty_id = 14 THEN 'Hva_proportion'
WHEN meg_mty_id = 15 THEN 'Pb'
WHEN meg_mty_id = 16 THEN 'Hg'
WHEN meg_mty_id = 17 THEN 'Cd'
WHEN meg_mty_id = 24 THEN 'G_in_gy_proportion'
WHEN meg_mty_id = 25 THEN 'S_in_ys_proportion'
WHEN meg_mty_id = 26 THEN 'Teq'
ELSE 'problem' END AS grt_tra_code,
meg_value AS grt_value, 
NULL AS grt_trv_code, -- there ARE NO qualitative VALUES FOR GROUP metrics
CASE WHEN meg_mty_id = 10 THEN 'Muscle_lipid_fatmeter'
WHEN meg_mty_id = 11 THEN 'Muscle_lipid_gravimeter' -- different method see method
WHEN meg_mty_id = 6 AND meg_method_sex = 1 THEN 'Gonadal_inspection'
WHEN meg_mty_id = 6 AND meg_method_sex = 0 THEN 'Length_based_sex'
WHEN meg_mty_id = 8 AND meg_method_anguillicola = 1 THEN 'Anguillicola_stereomicroscope_count'
WHEN meg_mty_id = 8 AND meg_method_anguillicola = 0 THEN 'Anguillicola_visual_count'
WHEN meg_mty_id = 9 AND meg_method_anguillicola = 1 THEN 'Anguillicola_stereomicroscope_count'
WHEN meg_mty_id = 9 AND meg_method_anguillicola = 0 THEN 'Anguillicola_visual_count'
ELSE NULL END AS grt_trm_code,
meg_last_update AS grt_last_update, 
meg_qal_id AS grt_qal_code, 
CASE WHEN meg_dts_datasource = 'dc_2019' THEN 'WGEEL-2019-1'
     WHEN meg_dts_datasource = 'dc_2020' THEN 'WGEEL-2020-1'
     WHEN meg_dts_datasource ='dc_2021' THEN 'WGEEL-2021-1'
     WHEN meg_dts_datasource ='dc_2022' THEN 'WGEEL-2022-1'
     WHEN meg_dts_datasource ='dc_2023' THEN 'WGEEL-2023-1'
     WHEN meg_dts_datasource ='dc_2024' THEN 'WGEEL-2024-1'
     ELSE 'WGEEL-2018-1' END AS grt_ver_code
FROM datwgeel.t_metricgroupseries_megser megser
JOIN datwgeel.t_groupseries_grser grser ON megser.meg_gr_id = gr_id
JOIN datwgeel.t_series_ser AS tss ON grser_ser_id = ser_id
JOIN dateel.t_series_ser AS tss2 ON ser_code= ser_nameshort
LEFT JOIN mm ON megser.meg_gr_id = mm.meg_gr_id -- joining subquery
WHERE meg_mty_id IN (1,2,3,6,7,8,9,10,11,12,13,14,15,16,17,24,25,26); --4194




/*
 * Insert numeric for group - sampling
 * Some values have both gravimeter and fatmeter, gravimeter chosen.
 */


INSERT INTO dateel.t_grouptrait_grt
(grt_ser_id, 
grt_wkg_code, 
grt_spe_code, 
grt_id, 
grt_gr_id, 
grt_tra_code, 
grt_value, 
grt_trv_code, 
grt_trm_code, 
grt_last_update, 
grt_qal_code, 
grt_ver_code)
-- extract method from table
-- this will extract 3 columns, meg_gr_id, meg_method_anguillicola and meg_method_sex
WITH a1 AS (
SELECT meg_gr_id,
       meg_value AS meg_method_sex 
FROM datwgeel.t_metricgroupsamp_megsa megsa
WHERE meg_mty_id = 27
AND meg_value IS NOT NULL),
 a2 AS (
 SELECT meg_gr_id,
       meg_value AS meg_method_anguillicola 
FROM datwgeel.t_metricgroupsamp_megsa megsa 
WHERE meg_mty_id = 28
AND meg_value IS NOT NULL),
mm AS (
SELECT coalesce(a1.meg_gr_id, a2.meg_gr_id)  AS meg_gr_id,
meg_method_sex,
meg_method_anguillicola
FROM  a1 FULL OUTER JOIN a2 ON a1.meg_gr_id = a2.meg_gr_id)
-- Insert select query
SELECT 
tss2.ser_id AS grt_ser_id,
'WGEEL' AS grt_wkg_code,
'127186' AS grt_spe_code,
meg_id AS grt_id, 
megsa.meg_gr_id AS grt_gr_id, 
CASE WHEN meg_mty_id = 1 THEN 'Lengthmm'
WHEN meg_mty_id = 2 THEN 'Weightg'
WHEN meg_mty_id = 3 THEN 'Ageyear'
WHEN meg_mty_id = 6 THEN 'Female_proportion'
WHEN meg_mty_id = 7 THEN 'Differentiated_proportion'
WHEN meg_mty_id = 8 THEN 'Anguillicola_proportion'
WHEN meg_mty_id = 9 THEN 'Anguillicola_intensity'
WHEN meg_mty_id = 10 THEN 'Muscle_lipid'
WHEN meg_mty_id = 11 THEN 'Muscle_lipid' -- different method see method
WHEN meg_mty_id = 12 THEN 'Sum_6_pcb'
WHEN meg_mty_id = 13 THEN 'Evex_proportion'
WHEN meg_mty_id = 14 THEN 'Hva_proportion'
WHEN meg_mty_id = 15 THEN 'Pb'
WHEN meg_mty_id = 16 THEN 'Hg'
WHEN meg_mty_id = 17 THEN 'Cd'
WHEN meg_mty_id = 24 THEN 'G_in_gy_proportion'
WHEN meg_mty_id = 25 THEN 'S_in_ys_proportion'
WHEN meg_mty_id = 26 THEN 'Teq'
ELSE 'problem' END AS grt_tra_code,
meg_value AS grt_value, 
NULL AS grt_trv_code, -- there ARE NO qualitative VALUES FOR GROUP metrics
CASE WHEN meg_mty_id = 10 THEN 'Muscle_lipid_fatmeter'
WHEN meg_mty_id = 11 THEN 'Muscle_lipid_gravimeter' -- different method see method
WHEN meg_mty_id = 6 AND meg_method_sex = 1 THEN 'Gonadal_inspection'
WHEN meg_mty_id = 6 AND meg_method_sex = 0 THEN 'Length_based_sex'
WHEN meg_mty_id = 8 AND meg_method_anguillicola = 1 THEN 'Anguillicola_stereomicroscope_count'
WHEN meg_mty_id = 8 AND meg_method_anguillicola = 0 THEN 'Anguillicola_visual_count'
WHEN meg_mty_id = 9 AND meg_method_anguillicola = 1 THEN 'Anguillicola_stereomicroscope_count'
WHEN meg_mty_id = 9 AND meg_method_anguillicola = 0 THEN 'Anguillicola_visual_count'
ELSE NULL END AS grt_trm_code,
meg_last_update AS grt_last_update, 
meg_qal_id AS grt_qal_code, 
CASE WHEN meg_dts_datasource = 'dc_2019' THEN 'WGEEL-2019-1'
     WHEN meg_dts_datasource = 'dc_2020' THEN 'WGEEL-2020-1'
     WHEN meg_dts_datasource ='dc_2021' THEN 'WGEEL-2021-1'
     WHEN meg_dts_datasource ='dc_2022' THEN 'WGEEL-2022-1'
     WHEN meg_dts_datasource ='dc_2023' THEN 'WGEEL-2023-1'
     WHEN meg_dts_datasource ='dc_2024' THEN 'WGEEL-2024-1'
     ELSE 'WGEEL-2018-1' END AS grt_ver_code
FROM datwgeel.t_metricgroupsamp_megsa megsa
JOIN datwgeel.t_groupsamp_grsa  ON megsa.meg_gr_id = gr_id
JOIN datwgeel.t_samplinginfo_sai AS tss ON grsa_sai_id = sai_id
JOIN dateel.t_series_ser AS tss2 ON ser_code= sai_id::text
LEFT JOIN mm ON megsa.meg_gr_id = mm.meg_gr_id -- joining subquery
WHERE meg_mty_id IN (1,2,3,6,7,8,9,11,12,13,14,15,16,17,24,25,26); --3028


-- Insert only fatmeter where gravimeter does not exist

INSERT INTO dateel.t_grouptrait_grt
(grt_ser_id, 
grt_wkg_code, 
grt_spe_code, 
grt_id, 
grt_gr_id, 
grt_tra_code, 
grt_value, 
grt_trv_code, 
grt_trm_code, 
grt_last_update, 
grt_qal_code, 
grt_ver_code)
WITH a1 AS (
SELECT meg_gr_id,
       meg_value AS meg_method_sex 
FROM datwgeel.t_metricgroupsamp_megsa megsa
WHERE meg_mty_id = 27
AND meg_value IS NOT NULL),
 a2 AS (
 SELECT meg_gr_id,
       meg_value AS meg_method_anguillicola 
FROM datwgeel.t_metricgroupsamp_megsa megsa 
WHERE meg_mty_id = 28
AND meg_value IS NOT NULL),
mm AS (
SELECT coalesce(a1.meg_gr_id, a2.meg_gr_id)  AS meg_gr_id,
meg_method_sex,
meg_method_anguillicola
FROM  a1 FULL OUTER JOIN a2 ON a1.meg_gr_id = a2.meg_gr_id),
-- Insert select query
fatmeter AS (
SELECT 
tss2.ser_id AS grt_ser_id,
'WGEEL' AS grt_wkg_code,
'127186' AS grt_spe_code,
meg_id AS grt_id, 
megsa.meg_gr_id AS grt_gr_id, 
CASE WHEN meg_mty_id = 1 THEN 'Lengthmm'
WHEN meg_mty_id = 2 THEN 'Weightg'
WHEN meg_mty_id = 3 THEN 'Ageyear'
WHEN meg_mty_id = 6 THEN 'Female_proportion'
WHEN meg_mty_id = 7 THEN 'Differentiated_proportion'
WHEN meg_mty_id = 8 THEN 'Anguillicola_proportion'
WHEN meg_mty_id = 9 THEN 'Anguillicola_intensity'
WHEN meg_mty_id = 10 THEN 'Muscle_lipid'
WHEN meg_mty_id = 11 THEN 'Muscle_lipid' -- different method see method
WHEN meg_mty_id = 12 THEN 'Sum_6_pcb'
WHEN meg_mty_id = 13 THEN 'Evex_proportion'
WHEN meg_mty_id = 14 THEN 'Hva_proportion'
WHEN meg_mty_id = 15 THEN 'Pb'
WHEN meg_mty_id = 16 THEN 'Hg'
WHEN meg_mty_id = 17 THEN 'Cd'
WHEN meg_mty_id = 24 THEN 'G_in_gy_proportion'
WHEN meg_mty_id = 25 THEN 'S_in_ys_proportion'
WHEN meg_mty_id = 26 THEN 'Teq'
ELSE 'problem' END AS grt_tra_code,
meg_value AS grt_value, 
NULL AS grt_trv_code, -- there ARE NO qualitative VALUES FOR GROUP metrics
CASE WHEN meg_mty_id = 10 THEN 'Muscle_lipid_fatmeter'
WHEN meg_mty_id = 11 THEN 'Muscle_lipid_gravimeter' -- different method see method
WHEN meg_mty_id = 6 AND meg_method_sex = 1 THEN 'Gonadal_inspection'
WHEN meg_mty_id = 6 AND meg_method_sex = 0 THEN 'Length_based_sex'
WHEN meg_mty_id = 8 AND meg_method_anguillicola = 1 THEN 'Anguillicola_stereomicroscope_count'
WHEN meg_mty_id = 8 AND meg_method_anguillicola = 0 THEN 'Anguillicola_visual_count'
WHEN meg_mty_id = 9 AND meg_method_anguillicola = 1 THEN 'Anguillicola_stereomicroscope_count'
WHEN meg_mty_id = 9 AND meg_method_anguillicola = 0 THEN 'Anguillicola_visual_count'
ELSE NULL END AS grt_trm_code,
meg_last_update AS grt_last_update, 
meg_qal_id AS grt_qal_code, 
CASE WHEN meg_dts_datasource = 'dc_2019' THEN 'WGEEL-2019-1'
     WHEN meg_dts_datasource = 'dc_2020' THEN 'WGEEL-2020-1'
     WHEN meg_dts_datasource ='dc_2021' THEN 'WGEEL-2021-1'
     WHEN meg_dts_datasource ='dc_2022' THEN 'WGEEL-2022-1'
     WHEN meg_dts_datasource ='dc_2023' THEN 'WGEEL-2023-1'
     WHEN meg_dts_datasource ='dc_2024' THEN 'WGEEL-2024-1'
     ELSE 'WGEEL-2018-1' END AS grt_ver_code
FROM datwgeel.t_metricgroupsamp_megsa megsa
JOIN datwgeel.t_groupsamp_grsa  ON megsa.meg_gr_id = gr_id
JOIN datwgeel.t_samplinginfo_sai AS tss ON grsa_sai_id = sai_id
JOIN dateel.t_series_ser AS tss2 ON ser_code= sai_id::text
LEFT JOIN mm ON megsa.meg_gr_id = mm.meg_gr_id -- joining subquery
WHERE meg_mty_id = 10)
SELECT * FROM fatmeter WHERE  grt_gr_id NOT IN 
(SELECT grt_gr_id FROM dateel.t_grouptrait_grt WHERE grt_tra_code = 'Muscle_lipid')
; --23





-- GROUP metrics FOR males sampling
SELECT count(*) FROM  datwgeel.t_metricgroupsamp_megsa megsa
WHERE meg_mty_id IN (18,19,20);--544



INSERT INTO dateel.t_grouptrait_grt
(grt_ser_id, 
grt_wkg_code, 
grt_spe_code, 
grt_id, 
grt_gr_id, 
grt_tra_code, 
grt_value, 
grt_trv_code, 
grt_trm_code, 
grt_last_update, 
grt_qal_code, 
grt_ver_code)
-- extract method from table
-- this will extract 3 columns, meg_gr_id, meg_method_anguillicola and meg_method_sex
WITH a1 AS (
SELECT meg_gr_id,
       meg_value AS meg_method_sex 
FROM datwgeel.t_metricgroupsamp_megsa megsa
WHERE meg_mty_id = 27
AND meg_value IS NOT NULL),
 a2 AS (
 SELECT meg_gr_id,
       meg_value AS meg_method_anguillicola 
FROM datwgeel.t_metricgroupsamp_megsa megsa 
WHERE meg_mty_id = 28
AND meg_value IS NOT NULL),
mm AS (
SELECT coalesce(a1.meg_gr_id, a2.meg_gr_id)  AS meg_gr_id,
meg_method_sex,
meg_method_anguillicola
FROM  a1 FULL OUTER JOIN a2 ON a1.meg_gr_id = a2.meg_gr_id)
-- Insert select query
SELECT DISTINCT ON (meg_id)
tss2.ser_id AS grt_ser_id,
'WGEEL' AS grt_wkg_code,
'127186' AS grt_spe_code,
meg_id AS grt_id, 
gr.gr_id AS grt_gr_id, 
CASE WHEN meg_mty_id IN (18, 21) THEN 'Lengthmm'
WHEN meg_mty_id IN (19,22) THEN 'Weightg'
WHEN meg_mty_id IN (20,23) THEN 'Ageyear'
ELSE 'problem' END AS grt_tra_code,
meg_value AS grt_value, 
NULL AS grt_trv_code, -- there ARE NO qualitative VALUES FOR GROUP metrics
CASE WHEN meg_mty_id = 10 THEN 'Muscle_lipid_fatmeter'
WHEN meg_mty_id = 11 THEN 'Muscle_lipid_gravimeter' -- different method see method
WHEN meg_method_sex = 1 THEN 'Gonadal_inspection'
WHEN meg_method_sex = 0 THEN 'Length_based_sex'
ELSE NULL END AS grt_trm_code,
meg_last_update AS grt_last_update, 
meg_qal_id AS grt_qal_code, 
CASE WHEN meg_dts_datasource = 'dc_2019' THEN 'WGEEL-2019-1'
     WHEN meg_dts_datasource = 'dc_2020' THEN 'WGEEL-2020-1'
     WHEN meg_dts_datasource ='dc_2021' THEN 'WGEEL-2021-1'
     WHEN meg_dts_datasource ='dc_2022' THEN 'WGEEL-2022-1'
     WHEN meg_dts_datasource ='dc_2023' THEN 'WGEEL-2023-1'
     WHEN meg_dts_datasource ='dc_2024' THEN 'WGEEL-2024-1'
     ELSE 'WGEEL-2018-1' END AS grt_ver_code
FROM datwgeel.t_metricgroupsamp_megsa megsa
JOIN datwgeel.t_groupsamp_grsa grsa  ON megsa.meg_gr_id = grsa.gr_id
JOIN datwgeel.t_samplinginfo_sai AS tss ON grsa_sai_id = sai_id
JOIN dateel.t_series_ser AS tss2 ON ser_code= sai_id::text
LEFT JOIN mm ON megsa.meg_gr_id = mm.meg_gr_id -- joining subquery
JOIN (SELECT gr_id, gr_ser_id, gr_year, gr_lfs_code FROM dateel.t_group_gr WHERE gr_sex_code = 'M') gr
ON (gr.gr_ser_id, COALESCE(gr.gr_year,1), gr_lfs_code) = ( tss2.ser_id, COALESCE(grsa.gr_year,1),grsa.grsa_lfs_code)
WHERE meg_mty_id IN (18,19,20); --544 C�dric pi fort

-- GROUP metrics FOR females   sampling
SELECT count(*) FROM  datwgeel.t_metricgroupseries_megser megsa
WHERE meg_mty_id IN (21,22,23);--553

INSERT INTO dateel.t_grouptrait_grt
(grt_ser_id, 
grt_wkg_code, 
grt_spe_code, 
grt_id, 
grt_gr_id, 
grt_tra_code, 
grt_value, 
grt_trv_code, 
grt_trm_code, 
grt_last_update, 
grt_qal_code, 
grt_ver_code)
-- extract method from table
-- this will extract 3 columns, meg_gr_id, meg_method_anguillicola and meg_method_sex
WITH a1 AS (
SELECT meg_gr_id,
       meg_value AS meg_method_sex 
FROM datwgeel.t_metricgroupsamp_megsa megsa
WHERE meg_mty_id = 27
AND meg_value IS NOT NULL),
 a2 AS (
 SELECT meg_gr_id,
       meg_value AS meg_method_anguillicola 
FROM datwgeel.t_metricgroupsamp_megsa megsa 
WHERE meg_mty_id = 28
AND meg_value IS NOT NULL),
mm AS (
SELECT coalesce(a1.meg_gr_id, a2.meg_gr_id)  AS meg_gr_id,
meg_method_sex,
meg_method_anguillicola
FROM  a1 FULL OUTER JOIN a2 ON a1.meg_gr_id = a2.meg_gr_id)
-- Insert select query
SELECT DISTINCT ON (meg_id)
tss2.ser_id AS grt_ser_id,
'WGEEL' AS grt_wkg_code,
'127186' AS grt_spe_code,
meg_id AS grt_id, 
gr.gr_id AS grt_gr_id, 
CASE WHEN meg_mty_id IN (18, 21) THEN 'Lengthmm'
WHEN meg_mty_id IN (19,22) THEN 'Weightg'
WHEN meg_mty_id IN (20,23) THEN 'Ageyear'
ELSE 'problem' END AS grt_tra_code,
meg_value AS grt_value, 
NULL AS grt_trv_code, -- there ARE NO qualitative VALUES FOR GROUP metrics
CASE WHEN meg_mty_id = 10 THEN 'Muscle_lipid_fatmeter'
WHEN meg_mty_id = 11 THEN 'Muscle_lipid_gravimeter' -- different method see method
WHEN meg_method_sex = 1 THEN 'Gonadal_inspection'
WHEN meg_method_sex = 0 THEN 'Length_based_sex'
ELSE NULL END AS grt_trm_code,
meg_last_update AS grt_last_update, 
meg_qal_id AS grt_qal_code, 
CASE WHEN meg_dts_datasource = 'dc_2019' THEN 'WGEEL-2019-1'
     WHEN meg_dts_datasource = 'dc_2020' THEN 'WGEEL-2020-1'
     WHEN meg_dts_datasource ='dc_2021' THEN 'WGEEL-2021-1'
     WHEN meg_dts_datasource ='dc_2022' THEN 'WGEEL-2022-1'
     WHEN meg_dts_datasource ='dc_2023' THEN 'WGEEL-2023-1'
     WHEN meg_dts_datasource ='dc_2024' THEN 'WGEEL-2024-1'
     ELSE 'WGEEL-2018-1' END AS grt_ver_code
FROM datwgeel.t_metricgroupsamp_megsa megsa
JOIN datwgeel.t_groupsamp_grsa grsa  ON megsa.meg_gr_id = grsa.gr_id
JOIN datwgeel.t_samplinginfo_sai AS tss ON grsa_sai_id = sai_id
JOIN dateel.t_series_ser AS tss2 ON ser_code= sai_id::text
LEFT JOIN mm ON megsa.meg_gr_id = mm.meg_gr_id -- joining subquery
JOIN (SELECT gr_id, gr_ser_id, gr_year, gr_lfs_code FROM dateel.t_group_gr WHERE gr_sex_code = 'F') gr
ON (gr.gr_ser_id, COALESCE(gr.gr_year,1), gr_lfs_code) = ( tss2.ser_id, COALESCE(grsa.gr_year,1),grsa.grsa_lfs_code)
WHERE meg_mty_id IN (21,22,23); --1183

-- GROUP metrics for males series

INSERT INTO dateel.t_grouptrait_grt
(grt_ser_id, 
grt_wkg_code, 
grt_spe_code, 
grt_id, 
grt_gr_id, 
grt_tra_code, 
grt_value, 
grt_trv_code, 
grt_trm_code, 
grt_last_update, 
grt_qal_code, 
grt_ver_code)
-- extract method from table
-- this will extract 3 columns, meg_gr_id, meg_method_anguillicola and meg_method_sex
WITH a1 AS (
SELECT meg_gr_id,
       meg_value AS meg_method_sex 
FROM datwgeel.t_metricgroupseries_megser megser
WHERE meg_mty_id = 27
AND meg_value IS NOT NULL),
 a2 AS (
 SELECT meg_gr_id,
       meg_value AS meg_method_anguillicola 
FROM datwgeel.t_metricgroupseries_megser megser 
WHERE meg_mty_id = 28
AND meg_value IS NOT NULL),
mm AS (
SELECT coalesce(a1.meg_gr_id, a2.meg_gr_id)  AS meg_gr_id,
meg_method_sex,
meg_method_anguillicola
FROM  a1 FULL OUTER JOIN a2 ON a1.meg_gr_id = a2.meg_gr_id)
-- Insert select query
SELECT DISTINCT ON (meg_id)
tss2.ser_id AS grt_ser_id,
'WGEEL' AS grt_wkg_code,
'127186' AS grt_spe_code,
meg_id AS grt_id, 
gr.gr_id AS grt_gr_id, 
CASE WHEN meg_mty_id IN (18, 21) THEN 'Lengthmm'
WHEN meg_mty_id IN (19,22) THEN 'Weightg'
WHEN meg_mty_id IN (20,23) THEN 'Ageyear'
ELSE 'problem' END AS grt_tra_code,
meg_value AS grt_value, 
NULL AS grt_trv_code, -- there ARE NO qualitative VALUES FOR GROUP metrics
CASE WHEN meg_mty_id = 10 THEN 'Muscle_lipid_fatmeter'
WHEN meg_mty_id = 11 THEN 'Muscle_lipid_gravimeter' -- different method see method
WHEN meg_method_sex = 1 THEN 'Gonadal_inspection'
WHEN meg_method_sex = 0 THEN 'Length_based_sex'
ELSE NULL END AS grt_trm_code,
meg_last_update AS grt_last_update, 
meg_qal_id AS grt_qal_code, 
CASE WHEN meg_dts_datasource = 'dc_2019' THEN 'WGEEL-2019-1'
     WHEN meg_dts_datasource = 'dc_2020' THEN 'WGEEL-2020-1'
     WHEN meg_dts_datasource ='dc_2021' THEN 'WGEEL-2021-1'
     WHEN meg_dts_datasource ='dc_2022' THEN 'WGEEL-2022-1'
     WHEN meg_dts_datasource ='dc_2023' THEN 'WGEEL-2023-1'
     WHEN meg_dts_datasource ='dc_2024' THEN 'WGEEL-2024-1'
     ELSE 'WGEEL-2018-1' END AS grt_ver_code
FROM datwgeel.t_metricgroupseries_megser megser
JOIN datwgeel.t_groupseries_grser grser ON megser.meg_gr_id = gr_id
JOIN datwgeel.t_series_ser AS tss ON grser_ser_id = ser_id
JOIN dateel.t_series_ser AS tss2 ON ser_code= ser_nameshort
LEFT JOIN mm ON megser.meg_gr_id = mm.meg_gr_id -- joining subquery
JOIN (SELECT gr_id, gr_ser_id, gr_year, gr_lfs_code FROM dateel.t_group_gr WHERE gr_sex_code = 'M') gr
ON (gr.gr_ser_id, COALESCE(gr.gr_year,1), gr_lfs_code) = ( tss2.ser_id, COALESCE(grser.gr_year,1),tss.ser_lfs_code)
WHERE meg_mty_id IN (18,19,20); --409

-- GROUP metrics for females series
SELECT count(*) FROM  datwgeel.t_metricgroupseries_megser megser
WHERE meg_mty_id IN (21,22,23);--553

INSERT INTO dateel.t_grouptrait_grt
(grt_ser_id, 
grt_wkg_code, 
grt_spe_code, 
grt_id, 
grt_gr_id, 
grt_tra_code, 
grt_value, 
grt_trv_code, 
grt_trm_code, 
grt_last_update, 
grt_qal_code, 
grt_ver_code)
-- extract method from table
-- this will extract 3 columns, meg_gr_id, meg_method_anguillicola and meg_method_sex
WITH a1 AS (
SELECT meg_gr_id,
       meg_value AS meg_method_sex 
FROM datwgeel.t_metricgroupseries_megser megser
WHERE meg_mty_id = 27
AND meg_value IS NOT NULL),
 a2 AS (
 SELECT meg_gr_id,
       meg_value AS meg_method_anguillicola 
FROM datwgeel.t_metricgroupseries_megser megser 
WHERE meg_mty_id = 28
AND meg_value IS NOT NULL),
mm AS (
SELECT coalesce(a1.meg_gr_id, a2.meg_gr_id)  AS meg_gr_id,
meg_method_sex,
meg_method_anguillicola
FROM  a1 FULL OUTER JOIN a2 ON a1.meg_gr_id = a2.meg_gr_id)
-- Insert select query
SELECT DISTINCT ON (meg_id)
tss2.ser_id AS grt_ser_id,
'WGEEL' AS grt_wkg_code,
'127186' AS grt_spe_code,
meg_id AS grt_id, 
gr.gr_id AS grt_gr_id, 
CASE WHEN meg_mty_id IN (18, 21) THEN 'Lengthmm'
WHEN meg_mty_id IN (19,22) THEN 'Weightg'
WHEN meg_mty_id IN (20,23) THEN 'Ageyear'
ELSE 'problem' END AS grt_tra_code,
meg_value AS grt_value, 
NULL AS grt_trv_code, -- there ARE NO qualitative VALUES FOR GROUP metrics
CASE WHEN meg_mty_id = 10 THEN 'Muscle_lipid_fatmeter'
WHEN meg_mty_id = 11 THEN 'Muscle_lipid_gravimeter' -- different method see method
WHEN meg_method_sex = 1 THEN 'Gonadal_inspection'
WHEN meg_method_sex = 0 THEN 'Length_based_sex'
ELSE NULL END AS grt_trm_code,
meg_last_update AS grt_last_update, 
meg_qal_id AS grt_qal_code, 
CASE WHEN meg_dts_datasource = 'dc_2019' THEN 'WGEEL-2019-1'
     WHEN meg_dts_datasource = 'dc_2020' THEN 'WGEEL-2020-1'
     WHEN meg_dts_datasource ='dc_2021' THEN 'WGEEL-2021-1'
     WHEN meg_dts_datasource ='dc_2022' THEN 'WGEEL-2022-1'
     WHEN meg_dts_datasource ='dc_2023' THEN 'WGEEL-2023-1'
     WHEN meg_dts_datasource ='dc_2024' THEN 'WGEEL-2024-1'
     ELSE 'WGEEL-2018-1' END AS grt_ver_code
FROM datwgeel.t_metricgroupseries_megser megser
JOIN datwgeel.t_groupseries_grser grser ON megser.meg_gr_id = gr_id
JOIN datwgeel.t_series_ser AS tss ON grser_ser_id = ser_id
JOIN dateel.t_series_ser AS tss2 ON ser_code= ser_nameshort
LEFT JOIN mm ON megser.meg_gr_id = mm.meg_gr_id -- joining subquery
JOIN (SELECT gr_id, gr_ser_id, gr_year, gr_lfs_code FROM dateel.t_group_gr WHERE gr_sex_code = 'F') gr
ON (gr.gr_ser_id, COALESCE(gr.gr_year,1), gr_lfs_code) = ( tss2.ser_id, COALESCE(grser.gr_year,1),tss.ser_lfs_code)
WHERE meg_mty_id IN (21,22,23); --553



;
Table 52: Table t_grouptrait_grt, group traits (t_grouptrait_grt)
grt_ser_id grt_wkg_code grt_spe_code grt_id grt_gr_id grt_tra_code grt_value grt_trv_code grt_trm_code grt_last_update grt_qal_code grt_ver_code
cbdf353c-2ce7-4d71-8d52-60548d94a3e8 WGEEL 126281 9581 3725 Weightg 108.500 NA NA 2022-09-09 1 WGEEL-2022-1
dec9711e-04d6-4641-8162-8aa71b6edade WGEEL 126281 14006 4248 Lengthmm 72.900 NA NA 2023-09-11 1 WGEEL-2023-1
a76757f8-4f3c-4513-a65e-82cae81c7063 WGEEL 126281 19591 5098 Weightg 645.760 NA NA 2024-09-12 1 WGEEL-2024-1
5b7cd6eb-bb35-44d4-8487-f799df771078 WGEEL 126281 21684 5618 Ageyear 14.665 NA NA 2024-09-13 1 WGEEL-2024-1
7eb93711-736d-442c-9f14-1d293e576394 WGEEL 126281 12488 3990 Muscle_lipid 22.600 NA Muscle_lipid_fatmeter 2023-09-04 1 WGEEL-2023-1
7eb93711-736d-442c-9f14-1d293e576394 WGEEL 126281 5405 2708 Muscle_lipid 22.500 NA Muscle_lipid_fatmeter 2022-09-06 1 WGEEL-2022-1
7eb93711-736d-442c-9f14-1d293e576394 WGEEL 126281 5394 2707 Muscle_lipid 23.000 NA Muscle_lipid_fatmeter 2022-09-06 1 WGEEL-2022-1
7eb93711-736d-442c-9f14-1d293e576394 WGEEL 126281 5383 2706 Muscle_lipid 23.400 NA Muscle_lipid_fatmeter 2022-09-06 1 WGEEL-2022-1
7eb93711-736d-442c-9f14-1d293e576394 WGEEL 126281 5372 2705 Muscle_lipid 25.800 NA Muscle_lipid_fatmeter 2022-09-06 1 WGEEL-2022-1
7eb93711-736d-442c-9f14-1d293e576394 WGEEL 126281 5361 2704 Muscle_lipid 23.600 NA Muscle_lipid_fatmeter 2022-09-06 1 WGEEL-2022-1
7eb93711-736d-442c-9f14-1d293e576394 WGEEL 126281 5350 2703 Muscle_lipid 25.400 NA Muscle_lipid_fatmeter 2022-09-06 1 WGEEL-2022-1
0cd50424-0ba6-4b6c-b9fe-d9572ff9c424 WGEEL 126281 12477 3989 Muscle_lipid 21.000 NA Muscle_lipid_fatmeter 2023-09-04 1 WGEEL-2023-1
0cd50424-0ba6-4b6c-b9fe-d9572ff9c424 WGEEL 126281 5324 2701 Muscle_lipid 23.300 NA Muscle_lipid_fatmeter 2022-09-06 1 WGEEL-2022-1
0cd50424-0ba6-4b6c-b9fe-d9572ff9c424 WGEEL 126281 5274 2697 Muscle_lipid 22.200 NA Muscle_lipid_fatmeter 2022-09-06 1 WGEEL-2022-1
0cd50424-0ba6-4b6c-b9fe-d9572ff9c424 WGEEL 126281 5252 2695 Muscle_lipid 22.900 NA Muscle_lipid_fatmeter 2022-09-06 1 WGEEL-2022-1
0cd50424-0ba6-4b6c-b9fe-d9572ff9c424 WGEEL 126281 5226 2693 Muscle_lipid 24.000 NA Muscle_lipid_fatmeter 2022-09-06 1 WGEEL-2022-1
0cd50424-0ba6-4b6c-b9fe-d9572ff9c424 WGEEL 126281 5203 2691 Muscle_lipid 24.300 NA Muscle_lipid_fatmeter 2022-09-06 1 WGEEL-2022-1
0cd50424-0ba6-4b6c-b9fe-d9572ff9c424 WGEEL 126281 5177 2689 Muscle_lipid 21.600 NA Muscle_lipid_fatmeter 2022-09-06 1 WGEEL-2022-1
0cd50424-0ba6-4b6c-b9fe-d9572ff9c424 WGEEL 126281 5151 2687 Muscle_lipid 21.500 NA Muscle_lipid_fatmeter 2022-09-06 1 WGEEL-2022-1
ae1030ac-b099-41b6-80bf-c3a7c455d17f WGEEL 126281 12466 3988 Muscle_lipid 18.800 NA Muscle_lipid_fatmeter 2023-09-04 1 WGEEL-2023-1

5.8 Creating ind traits

5.8.1 Fish table

SQL code to create tables dat.t_fish_fi and dateel.t_fish_fi
-- DROP TABLE IF EXISTS dat.t_fish_fi CASCADE;

CREATE TABLE dat.t_fish_fi (
  fi_id serial4 NOT NULL,
  fi_ser_id UUID NOT NULL,
  CONSTRAINT fk_fi_ser_id FOREIGN KEY (fi_ser_id)
  REFERENCES dat.t_series_ser (ser_id) 
  ON UPDATE CASCADE ON DELETE CASCADE, 
  fi_wkg_code TEXT NOT NULL,  
  CONSTRAINT fk_fi_wkg_code  FOREIGN KEY (fi_wkg_code)
  REFERENCES ref.tr_icworkinggroup_wkg(wkg_code)
  ON UPDATE CASCADE ON DELETE RESTRICT,
  CONSTRAINT t_fish_fi_pkey PRIMARY KEY (fi_id, fi_wkg_code),
  fi_spe_code TEXT,
  CONSTRAINT fk_fi_spe_code FOREIGN KEY (fi_spe_code) 
  REFERENCES ref.tr_species_spe(spe_code) 
  ON UPDATE CASCADE ON DELETE RESTRICT,
  fi_lfs_code TEXT,
  CONSTRAINT fk_fi_lfs_code_fi_spe_code FOREIGN KEY (fi_lfs_code, fi_spe_code)
  REFERENCES ref.tr_lifestage_lfs (lfs_code, lfs_spe_code) 
  ON UPDATE CASCADE ON DELETE RESTRICT, 
  fi_date date NULL,
  fi_year int4 NULL,
  CONSTRAINT ck_fi_date_fi_year CHECK (((fi_date IS NOT NULL) OR (fi_year IS NOT NULL))),
  fi_comment text NULL,
  fi_lastupdate date DEFAULT CURRENT_DATE NOT NULL,
  fi_idsource TEXT NULL UNIQUE,
  fi_ver_code TEXT NOT NULL,
  CONSTRAINT fk_gr_ver_code FOREIGN KEY (fi_ver_code)
  REFERENCES ref.tr_version_ver(ver_code)
  ON UPDATE CASCADE ON DELETE RESTRICT,
  fi_x_4326 NUMERIC,
  fi_y_4326 NUMERIC,
  fi_geom  GEOMETRY(Point, 4326) 
);




COMMENT ON TABLE dat.t_fish_fi IS 'Table identifying the fish metrics, a fish metric corresponds to a
 fish sampled at a given date or year.';

COMMENT ON COLUMN dat.t_fish_fi.fi_id IS 'Fi ID, serial primary key on fi_id and fi_wkg_code';
COMMENT ON COLUMN dat.t_fish_fi.fi_wkg_code IS 'Code of the working group, one of
WGBAST, WGEEL, WGNAS, WKTRUTTA';
COMMENT ON COLUMN dat.t_fish_fi.fi_lfs_code IS 'Life stage code';
COMMENT ON COLUMN dat.t_fish_fi.fi_spe_code IS 'Species code';
COMMENT ON COLUMN dat.t_fish_fi.fi_year IS 'The year';
COMMENT ON COLUMN dat.t_fish_fi.fi_comment IS 'Comment on the fish';
COMMENT ON COLUMN dat.t_fish_fi.fi_lastupdate IS 'Last update, inserted automatically';
COMMENT ON COLUMN dat.t_fish_fi.fi_ver_code IS 'Version code as in tr_version_ver, corresponds to the working group code WGNAS-2024-1 WGEEL-2016-1, the -1 indicate the first data call in the year, -2 would be second etc....';
COMMENT ON COLUMN dat.t_fish_fi.fi_idsource IS 'Identifier of the fish in the source (country) database';

GRANT ALL ON dat.t_fish_fi TO diaspara_admin;
GRANT SELECT ON dat.t_fish_fi TO diaspara_read; 

DROP TABLE IF EXISTS dateel.t_fish_fi;
CREATE TABLE dateel.t_fish_fi (
  CONSTRAINT fk_fi_ser_id FOREIGN KEY (fi_ser_id)
  REFERENCES dateel.t_series_ser (ser_id) 
  ON UPDATE CASCADE ON DELETE CASCADE, 
  CONSTRAINT fk_fi_wkg_code  FOREIGN KEY (fi_wkg_code)
  REFERENCES ref.tr_icworkinggroup_wkg(wkg_code)
  ON UPDATE CASCADE ON DELETE RESTRICT,
  CONSTRAINT t_fish_fi_pkey PRIMARY KEY (fi_id, fi_wkg_code),
  CONSTRAINT fk_fi_spe_code FOREIGN KEY (fi_spe_code) 
  REFERENCES ref.tr_species_spe(spe_code) 
  ON UPDATE CASCADE ON DELETE RESTRICT,
  CONSTRAINT fk_fi_lfs_code_fi_spe_code FOREIGN KEY (fi_lfs_code, fi_spe_code)
  REFERENCES ref.tr_lifestage_lfs (lfs_code, lfs_spe_code) 
  ON UPDATE CASCADE ON DELETE RESTRICT, 
  CONSTRAINT ck_fi_date_fi_year CHECK (((fi_date IS NOT NULL) OR (fi_year IS NOT NULL))),
  CONSTRAINT fk_gr_ver_code FOREIGN KEY (fi_ver_code)
  REFERENCES refeel.tr_version_ver(ver_code)
  ON UPDATE CASCADE ON DELETE RESTRICT  
) INHERITS (dat.t_fish_fi);
 

GRANT ALL ON dateel.t_fish_fi TO diaspara_admin;
GRANT SELECT ON dateel.t_fish_fi TO diaspara_read;  


-- Change to adapt to DIASPARA salmon dataset WP2 
 -- ALTER TABLE dat.t_fish_fish ADD COLUMN fi_tagnumber TEXT DEFAULT NULL;
    
SQL code to import data tables


-- insert from series
INSERT INTO dateel.t_fish_fi
(fi_id, 
fi_ser_id, 
fi_wkg_code, 
fi_spe_code, 
fi_lfs_code, 
fi_date, 
fi_year, 
fi_comment, 
fi_lastupdate, 
fi_idsource,
fi_ver_code,
fi_x_4326,
fi_y_4326,
fi_geom)
SELECT 
fi_id, 
tss2.ser_id AS fi_ser_id,
'WGEEL' AS fi_wkg_code,
'127186' AS fi_spe_code,
fi_lfs_code,
fi_date,
fi_year, 
fi_comment,
fi_lastupdate, 
fi_id_cou AS fi_idsource,
CASE WHEN fi_dts_datasource = 'dc_2019' THEN 'WGEEL-2019-1'
     WHEN fi_dts_datasource = 'dc_2020' THEN 'WGEEL-2020-1'
     WHEN fi_dts_datasource ='dc_2021' THEN 'WGEEL-2021-1'
     WHEN fi_dts_datasource ='dc_2022' THEN 'WGEEL-2022-1'
     WHEN fi_dts_datasource ='dc_2023' THEN 'WGEEL-2023-1'
     WHEN fi_dts_datasource ='dc_2024' THEN 'WGEEL-2024-1'
     ELSE 'WGEEL-2018-1' END AS fi_ver_code,
st_x(tss.geom),
st_y(tss.geom),
tss.geom
FROM datwgeel.t_fishseries_fiser 
JOIN datwgeel.t_series_ser tss ON ser_id = fiser_ser_id 
JOIN dat.t_series_ser tss2 ON ser_code = ser_nameshort ; --757787

-- Insert from sampling

INSERT INTO dateel.t_fish_fi
(fi_id, 
fi_ser_id, 
fi_wkg_code, 
fi_spe_code, 
fi_lfs_code, 
fi_date, 
fi_year, 
fi_comment, 
fi_lastupdate, 
fi_idsource,
fi_ver_code,
fi_x_4326,
fi_y_4326,
fi_geom)
SELECT 
fi_id, 
tss2.ser_id AS fi_ser_id,
'WGEEL' AS fi_wkg_code,
'127186' AS fi_spe_code,
CASE WHEN fi_lfs_code = 'NA' THEN 'YS' ELSE fi_lfs_code END AS fi_lfs_code,
fi_date,
fi_year, 
fi_comment,
fi_lastupdate, 
fi_id_cou AS fi_idsource,
CASE WHEN fi_dts_datasource = 'dc_2019' THEN 'WGEEL-2019-1'
     WHEN fi_dts_datasource = 'dc_2020' THEN 'WGEEL-2020-1'
     WHEN fi_dts_datasource ='dc_2021' THEN 'WGEEL-2021-1'
     WHEN fi_dts_datasource ='dc_2022' THEN 'WGEEL-2022-1'
     WHEN fi_dts_datasource ='dc_2023' THEN 'WGEEL-2023-1'
     WHEN fi_dts_datasource ='dc_2024' THEN 'WGEEL-2024-1'
     ELSE 'WGEEL-2018-1' END AS fi_ver_code,
fisa_x_4326,
fisa_y_4326,
fisa_geom
FROM  datwgeel.t_fishsamp_fisa 
JOIN datwgeel.t_samplinginfo_sai AS tss ON fisa_sai_id = sai_id
JOIN dateel.t_series_ser AS tss2 ON ser_code= sai_id::text;  --98545
Table 53: Table t_fish_fi, fish table
fi_id fi_ser_id fi_wkg_code fi_spe_code fi_lfs_code fi_date fi_year fi_comment fi_lastupdate fi_idsource fi_ver_code fi_x_4326 fi_y_4326 fi_geom
3419372 32870779-52d8-4326-b473-43095b95625a WGEEL 126281 Y 2023-04-25 2023 NA 2024-09-13 NA WGEEL-2024-1 NA NA NA
3419371 32870779-52d8-4326-b473-43095b95625a WGEEL 126281 Y 2023-04-25 2023 NA 2024-09-13 NA WGEEL-2024-1 NA NA NA
3419370 32870779-52d8-4326-b473-43095b95625a WGEEL 126281 Y 2023-04-25 2023 NA 2024-09-13 NA WGEEL-2024-1 NA NA NA
3419369 32870779-52d8-4326-b473-43095b95625a WGEEL 126281 Y 2023-04-25 2023 NA 2024-09-13 NA WGEEL-2024-1 NA NA NA
3419368 32870779-52d8-4326-b473-43095b95625a WGEEL 126281 Y 2023-04-25 2023 NA 2024-09-13 NA WGEEL-2024-1 NA NA NA
3419367 32870779-52d8-4326-b473-43095b95625a WGEEL 126281 Y 2023-04-25 2023 NA 2024-09-13 NA WGEEL-2024-1 NA NA NA
3419366 32870779-52d8-4326-b473-43095b95625a WGEEL 126281 Y 2023-04-25 2023 NA 2024-09-13 NA WGEEL-2024-1 NA NA NA
3419365 32870779-52d8-4326-b473-43095b95625a WGEEL 126281 Y 2023-04-25 2023 NA 2024-09-13 NA WGEEL-2024-1 NA NA NA
3419364 32870779-52d8-4326-b473-43095b95625a WGEEL 126281 Y 2023-04-25 2023 NA 2024-09-13 NA WGEEL-2024-1 NA NA NA
3419363 32870779-52d8-4326-b473-43095b95625a WGEEL 126281 Y 2023-04-25 2023 NA 2024-09-13 NA WGEEL-2024-1 NA NA NA
3419362 32870779-52d8-4326-b473-43095b95625a WGEEL 126281 Y 2023-04-25 2023 NA 2024-09-13 NA WGEEL-2024-1 NA NA NA
3419361 32870779-52d8-4326-b473-43095b95625a WGEEL 126281 Y 2023-04-25 2023 NA 2024-09-13 NA WGEEL-2024-1 NA NA NA
3419360 32870779-52d8-4326-b473-43095b95625a WGEEL 126281 Y 2023-04-25 2023 NA 2024-09-13 NA WGEEL-2024-1 NA NA NA
3419359 32870779-52d8-4326-b473-43095b95625a WGEEL 126281 Y 2023-04-25 2023 NA 2024-09-13 NA WGEEL-2024-1 NA NA NA
3419358 32870779-52d8-4326-b473-43095b95625a WGEEL 126281 Y 2023-04-25 2023 NA 2024-09-13 NA WGEEL-2024-1 NA NA NA
3419357 32870779-52d8-4326-b473-43095b95625a WGEEL 126281 Y 2023-04-25 2023 NA 2024-09-13 NA WGEEL-2024-1 NA NA NA
3419356 32870779-52d8-4326-b473-43095b95625a WGEEL 126281 Y 2023-04-25 2023 NA 2024-09-13 NA WGEEL-2024-1 NA NA NA
3419355 32870779-52d8-4326-b473-43095b95625a WGEEL 126281 Y 2023-04-25 2023 NA 2024-09-13 NA WGEEL-2024-1 NA NA NA
3419354 32870779-52d8-4326-b473-43095b95625a WGEEL 126281 Y 2023-04-25 2023 NA 2024-09-13 NA WGEEL-2024-1 NA NA NA
3419353 32870779-52d8-4326-b473-43095b95625a WGEEL 126281 Y 2023-04-25 2023 NA 2024-09-13 NA WGEEL-2024-1 NA NA NA

5.8.2 Table t_indtrait_int

SQL code to create tables dat.t_indivtrait_int and dateel.t_indivtrait_int

-- DROP TABLE IF EXISTS dat.t_indivtrait_int CASCADE;


CREATE TABLE dat.t_indivtrait_int (
  int_ser_id uuid,
 CONSTRAINT fk_int_ser_id FOREIGN KEY (int_ser_id)
    REFERENCES dat.t_series_ser (ser_id) 
    ON UPDATE CASCADE ON DELETE CASCADE,  
  int_wkg_code TEXT NOT NULL,  
  CONSTRAINT fk_int_wkg_code  FOREIGN KEY (int_wkg_code)
  REFERENCES ref.tr_icworkinggroup_wkg(wkg_code)
  ON UPDATE CASCADE ON DELETE RESTRICT,
  int_spe_code TEXT NOT NULL,  
  CONSTRAINT fk_int_spe_code  FOREIGN KEY (int_spe_code)
  REFERENCES ref.tr_species_spe(spe_code)
  ON UPDATE CASCADE ON DELETE RESTRICT,
  int_id serial4 NOT NULL,
  int_fi_id int4 NOT NULL,
  CONSTRAINT fk_int_fi_id FOREIGN KEY (int_fi_id, int_wkg_code) 
  REFERENCES dat.t_fish_fi(fi_id,fi_wkg_code) 
    ON UPDATE CASCADE ON DELETE CASCADE,
  int_tra_code TEXT NOT NULL,
  CONSTRAINT fk_int_tra_code FOREIGN KEY (int_tra_code) 
  REFERENCES ref.tr_trait_tra(tra_code)
  ON UPDATE CASCADE ON DELETE RESTRICT,
  int_value numeric NULL,
  int_trv_code TEXT,
  CONSTRAINT fk_int_trv_tra_code FOREIGN KEY (int_trv_code, int_tra_code,int_wkg_code)
  REFERENCES ref.tr_traitvaluequal_trv(trv_code, trv_trq_code, trv_wkg_code)
  ON UPDATE CASCADE ON DELETE RESTRICT,
  int_trm_code TEXT,
  CONSTRAINT fk_int_trm_code FOREIGN KEY (int_trm_code)
  REFERENCES ref.tr_traitmethod_trm(trm_code)
  ON UPDATE CASCADE ON DELETE RESTRICT,
  int_last_update date DEFAULT CURRENT_DATE NOT NULL,
  int_qal_code int4 NULL,
    CONSTRAINT fk_int_qal_id FOREIGN KEY (int_qal_code) 
  REFERENCES ref.tr_quality_qal(qal_code) ON UPDATE CASCADE,
  int_ver_code TEXT NOT NULL,
  CONSTRAINT fk_int_ver_code FOREIGN KEY (int_ver_code)
  REFERENCES ref.tr_version_ver(ver_code)
  ON UPDATE CASCADE ON DELETE RESTRICT,
  CONSTRAINT uk_int_fi UNIQUE (int_fi_id, int_trm_code, int_wkg_code),
  CONSTRAINT t_indivtrait_int_pkey PRIMARY KEY (int_id, int_wkg_code),
  CONSTRAINT ck_qualitative_or_numeric CHECK 
  (
  (int_value IS NULL AND int_trv_code IS NOT NULL) OR
  (int_value IS NOT NULL AND int_trv_code IS  NULL)
  )
);
CREATE INDEX dat_t_indivtrait_int_idx ON dat.t_indivtrait_int USING btree (int_fi_id);

GRANT ALL ON dat.t_indivtrait_int TO diaspara_admin;
GRANT SELECT ON dat.t_indivtrait_int TO diaspara_read; 

DROP TABLE IF EXISTS  dateel.t_indivtrait_int;
CREATE TABLE dateel.t_indivtrait_int (
 CONSTRAINT fk_int_ser_id FOREIGN KEY (int_ser_id)
    REFERENCES dateel.t_series_ser (ser_id) 
    ON UPDATE CASCADE ON DELETE CASCADE,
  CONSTRAINT fk_int_wkg_code  FOREIGN KEY (int_wkg_code)
  REFERENCES ref.tr_icworkinggroup_wkg(wkg_code)
  ON UPDATE CASCADE ON DELETE RESTRICT,
  CONSTRAINT fk_int_spe_code  FOREIGN KEY (int_spe_code)
  REFERENCES ref.tr_species_spe(spe_code)
  ON UPDATE CASCADE ON DELETE RESTRICT,
  CONSTRAINT fk_int_fi_id FOREIGN KEY (int_fi_id, int_wkg_code) 
  REFERENCES dateel.t_fish_fi(fi_id,fi_wkg_code) 
    ON UPDATE CASCADE ON DELETE CASCADE,
  CONSTRAINT fk_int_tra_code FOREIGN KEY (int_tra_code) 
  REFERENCES refeel.tg_trait_tra(tra_code)
  ON UPDATE CASCADE ON DELETE RESTRICT,
  CONSTRAINT fk_int_trv_tra_code FOREIGN KEY (int_trv_code, int_tra_code) 
  -- unlike in dat.t_indivtrait_int this one does not take ref TO wkgcode, no need AS we are in dateel
  REFERENCES refeel.tr_traitvaluequal_trv(trv_code, trv_trq_code)
  ON UPDATE CASCADE ON DELETE RESTRICT,
  CONSTRAINT fk_int_trm_code FOREIGN KEY (int_trm_code)
  REFERENCES refeel.tr_traitmethod_trm(trm_code)
  ON UPDATE CASCADE ON DELETE RESTRICT,
  CONSTRAINT fk_int_qal_id FOREIGN KEY (int_qal_code) 
  REFERENCES ref.tr_quality_qal(qal_code) ON UPDATE CASCADE,
  CONSTRAINT fk_int_ver_code FOREIGN KEY (int_ver_code)
  REFERENCES refeel.tr_version_ver(ver_code)
  ON UPDATE CASCADE ON DELETE RESTRICT,
  CONSTRAINT uk_trv_fi_id_trv_tra_code UNIQUE(int_fi_id,int_tra_code)
) INHERITS (dat.t_indivtrait_int);
CREATE INDEX dateel_t_indivtrait_int_idx ON dateel.t_indivtrait_int USING btree (int_fi_id);

GRANT ALL ON dateel.t_indivtrait_int TO diaspara_admin;
GRANT SELECT ON dateel.t_indivtrait_int TO diaspara_read; 


COMMENT ON TABLE dateel.t_indivtrait_int IS
 'Table joining fish and traits';
COMMENT ON COLUMN dateel.t_indivtrait_int.int_ser_id IS
 'Series UUID';
COMMENT ON COLUMN dateel.t_indivtrait_int.int_wkg_code IS
 'Working ind on of WGEEL, WGNAS, WGBAST ...';
COMMENT ON COLUMN dateel.t_indivtrait_int.int_spe_code IS
 'Species code here ''127186''';
COMMENT ON COLUMN dateel.t_indivtrait_int.int_id IS
 'ID, integer, unique for wkg_code';
COMMENT ON COLUMN dateel.t_indivtrait_int.int_fi_id IS
 'ID of the fish';
COMMENT ON COLUMN dateel.t_indivtrait_int.int_tra_code IS
 'Code of the trait, e.g. Lengthmm';
COMMENT ON COLUMN dateel.t_indivtrait_int.int_value IS
 'Value for numeric';
COMMENT ON COLUMN dateel.t_indivtrait_int.int_trv_code IS
 'Value for qualitative see refeel.tr_traitvaluequal_trv';
COMMENT ON COLUMN dateel.t_indivtrait_int.int_trm_code IS
 'Method see refeel.tr_traimethod_trm';
COMMENT ON COLUMN dateel.t_indivtrait_int.int_last_update IS 'date last update';
COMMENT ON COLUMN dateel.t_indivtrait_int.int_qal_code IS
 'Quality code references ref.tr_quality_qal';
COMMENT ON COLUMN dateel.t_indivtrait_int.int_ver_code IS
 'version e.g. WGEEL_2024_1';

-- TODO trigger on date
SQL code to import individual trait tables

/*
 * Insert numeric for indiv - series 
 */
DELETE FROM dateel.t_indivtrait_int;

INSERT INTO dateel.t_indivtrait_int
(int_ser_id, 
int_wkg_code, 
int_spe_code, 
int_id, 
int_fi_id, 
int_tra_code, 
int_value, 
int_trv_code, 
int_trm_code, 
int_last_update, 
int_qal_code, 
int_ver_code)
WITH a1 AS (
SELECT mei_fi_id,
       mei_value AS mei_method_sex 
FROM datwgeel.t_metricindsamp_meisa meisa
WHERE mei_mty_id = 27
AND mei_value IS NOT NULL),
 a2 AS (
 SELECT mei_fi_id,
       mei_value AS mei_method_anguillicola 
FROM datwgeel.t_metricindsamp_meisa meisa 
WHERE mei_mty_id = 28
AND mei_value IS NOT NULL),
mm AS (
SELECT coalesce(a1.mei_fi_id, a2.mei_fi_id)  AS mei_fi_id,
mei_method_sex,
mei_method_anguillicola
FROM  a1 FULL OUTER JOIN a2 ON a1.mei_fi_id = a2.mei_fi_id)
SELECT 
tss2.ser_id AS int_ser_id,
'WGEEL' AS int_wkg_code,
'127186' AS int_spe_code,
fi_id AS int_id, 
meiser.mei_fi_id AS int_fi_id, 
CASE WHEN mei_mty_id = 1 THEN 'Lengthmm'
WHEN mei_mty_id = 2 THEN 'Weightg'
WHEN mei_mty_id = 3 THEN 'Ageyear'
WHEN mei_mty_id = 4 THEN 'Eye_diam_meanmm'
WHEN mei_mty_id = 5 THEN 'Pectoral_lengthmm'
WHEN mei_mty_id = 9 THEN 'Anguillicola_intensity'
WHEN mei_mty_id = 11 THEN 'Muscle_lipid' -- IF fatmeter insert later only if gravimeter does not exists
WHEN mei_mty_id = 12 THEN 'Sum_6_pcb'
WHEN mei_mty_id = 15 THEN 'Pb'
WHEN mei_mty_id = 16 THEN 'Hg'
WHEN mei_mty_id = 17 THEN 'Cd'
WHEN mei_mty_id = 26 THEN 'Teq'
ELSE 'problem' END AS int_tra_code,
mei_value AS int_value, 
NULL AS int_trv_code, -- there ARE NO qualitative VALUES FOR GROUP metrics
CASE WHEN mei_mty_id = 11 THEN 'Muscle_lipid_gravimeter' -- different method see METHOD
WHEN mei_mty_id = 9 AND mei_method_anguillicola = 1 THEN 'Anguillicola_stereomicroscope_count'
WHEN mei_mty_id = 9 AND mei_method_anguillicola = 0 THEN 'Anguillicola_visual_count'
ELSE NULL END AS int_trm_code,
mei_last_update AS int_last_update, 
mei_qal_id AS int_qal_code, 
CASE WHEN mei_dts_datasource = 'dc_2019' THEN 'WGEEL-2019-1'
     WHEN mei_dts_datasource = 'dc_2020' THEN 'WGEEL-2020-1'
     WHEN mei_dts_datasource ='dc_2021' THEN 'WGEEL-2021-1'
     WHEN mei_dts_datasource ='dc_2022' THEN 'WGEEL-2022-1'
     WHEN mei_dts_datasource ='dc_2023' THEN 'WGEEL-2023-1'
     WHEN mei_dts_datasource ='dc_2024' THEN 'WGEEL-2024-1'
     ELSE 'WGEEL-2018-1' END AS int_ver_code
FROM datwgeel.t_metricindseries_meiser meiser
JOIN datwgeel.t_fishseries_fiser fiser ON meiser.mei_fi_id = fi_id
JOIN datwgeel.t_series_ser AS tss ON fiser_ser_id = ser_id
JOIN dateel.t_series_ser AS tss2 ON ser_code= ser_nameshort
LEFT JOIN mm ON meiser.mei_fi_id = mm.mei_fi_id -- joining subquery
WHERE mei_mty_id IN (1,2,3,4,5,9,11,12,15,16,17,26); --1145525


--10 Muscle lipid fatmeter




INSERT INTO dateel.t_indivtrait_int
(int_ser_id, 
int_wkg_code, 
int_spe_code, 
int_id, 
int_fi_id, 
int_tra_code, 
int_value, 
int_trv_code, 
int_trm_code, 
int_last_update, 
int_qal_code, 
int_ver_code)
WITH fatmeter AS (
SELECT 
tss2.ser_id AS int_ser_id,
'WGEEL' AS int_wkg_code,
'127186' AS int_spe_code,
fi_id AS int_id, 
meiser.mei_fi_id AS int_fi_id, 
CASE WHEN mei_mty_id = 10 THEN  'Muscle_lipid' 
ELSE 'problem' END AS int_tra_code,
mei_value AS int_value, 
NULL AS int_trv_code, 
CASE WHEN mei_mty_id = 10 THEN 'Muscle_lipid_fatmeter' -- different method see method
ELSE NULL END AS int_trm_code,
mei_last_update AS int_last_update, 
mei_qal_id AS int_qal_code, 
CASE WHEN mei_dts_datasource = 'dc_2019' THEN 'WGEEL-2019-1'
     WHEN mei_dts_datasource = 'dc_2020' THEN 'WGEEL-2020-1'
     WHEN mei_dts_datasource ='dc_2021' THEN 'WGEEL-2021-1'
     WHEN mei_dts_datasource ='dc_2022' THEN 'WGEEL-2022-1'
     WHEN mei_dts_datasource ='dc_2023' THEN 'WGEEL-2023-1'
     WHEN mei_dts_datasource ='dc_2024' THEN 'WGEEL-2024-1'
     ELSE 'WGEEL-2018-1' END AS int_ver_code
FROM datwgeel.t_metricindseries_meiser meiser
JOIN datwgeel.t_fishseries_fiser fiser ON meiser.mei_fi_id = fi_id
JOIN datwgeel.t_series_ser AS tss ON fiser_ser_id = ser_id
JOIN dateel.t_series_ser AS tss2 ON ser_code= ser_nameshort
WHERE mei_mty_id IN (10))
SELECT * FROM fatmeter WHERE  int_fi_id NOT IN 
(SELECT int_fi_id FROM dateel.t_indivtrait_int WHERE int_tra_code = 'Muscle_lipid')
; --0

/*
 * Insert numeric for  - sampling
 * Some values have both gravimeter and fatmeter, gravimeter chosen.
 */


INSERT INTO dateel.t_indivtrait_int
(int_ser_id, 
int_wkg_code, 
int_spe_code, 
int_id, 
int_fi_id, 
int_tra_code, 
int_value, 
int_trv_code, 
int_trm_code, 
int_last_update, 
int_qal_code, 
int_ver_code)
WITH a1 AS (
SELECT mei_fi_id,
       mei_value AS mei_method_sex 
FROM datwgeel.t_metricindsamp_meisa meisa
WHERE mei_mty_id = 27
AND mei_value IS NOT NULL),
 a2 AS (
 SELECT mei_fi_id,
       mei_value AS mei_method_anguillicola 
FROM datwgeel.t_metricindsamp_meisa meisa 
WHERE mei_mty_id = 28
AND mei_value IS NOT NULL),
mm AS (
SELECT coalesce(a1.mei_fi_id, a2.mei_fi_id)  AS mei_fi_id,
mei_method_sex,
mei_method_anguillicola
FROM  a1 FULL OUTER JOIN a2 ON a1.mei_fi_id = a2.mei_fi_id)
SELECT 
tss2.ser_id AS int_ser_id,
'WGEEL' AS int_wkg_code,
'127186' AS int_spe_code,
mei_id AS int_id, 
meisa.mei_fi_id AS int_fi_id, 
CASE WHEN mei_mty_id = 1 THEN 'Lengthmm'
WHEN mei_mty_id = 2 THEN 'Weightg'
WHEN mei_mty_id = 3 THEN 'Ageyear'
WHEN mei_mty_id = 4 THEN 'Eye_diam_meanmm'
WHEN mei_mty_id = 5 THEN 'Pectoral_lengthmm'
WHEN mei_mty_id = 9 THEN 'Anguillicola_intensity'
WHEN mei_mty_id = 11 THEN 'Muscle_lipid' -- IF fatmeter insert later only if gravimeter does not exists
WHEN mei_mty_id = 12 THEN 'Sum_6_pcb'
WHEN mei_mty_id = 15 THEN 'Pb'
WHEN mei_mty_id = 16 THEN 'Hg'
WHEN mei_mty_id = 17 THEN 'Cd'
WHEN mei_mty_id = 26 THEN 'Teq'
ELSE 'problem' END AS int_tra_code,
mei_value AS int_value, 
NULL AS int_trv_code,
CASE WHEN mei_mty_id = 11 THEN 'Muscle_lipid_gravimeter' -- different method see METHOD
WHEN mei_mty_id = 9 AND mei_method_anguillicola = 1 THEN 'Anguillicola_stereomicroscope_count'
WHEN mei_mty_id = 9 AND mei_method_anguillicola = 0 THEN 'Anguillicola_visual_count'
ELSE NULL END AS int_trm_code,
mei_last_update AS int_last_update, 
mei_qal_id AS int_qal_code, 
CASE WHEN mei_dts_datasource = 'dc_2019' THEN 'WGEEL-2019-1'
     WHEN mei_dts_datasource = 'dc_2020' THEN 'WGEEL-2020-1'
     WHEN mei_dts_datasource ='dc_2021' THEN 'WGEEL-2021-1'
     WHEN mei_dts_datasource ='dc_2022' THEN 'WGEEL-2022-1'
     WHEN mei_dts_datasource ='dc_2023' THEN 'WGEEL-2023-1'
     WHEN mei_dts_datasource ='dc_2024' THEN 'WGEEL-2024-1'
     ELSE 'WGEEL-2018-1' END AS int_ver_code
FROM datwgeel.t_metricindsamp_meisa meisa
JOIN datwgeel.t_fishsamp_fisa  ON meisa.mei_fi_id = fi_id
JOIN datwgeel.t_samplinginfo_sai AS tss ON fisa_sai_id = sai_id
JOIN dateel.t_series_ser AS tss2 ON ser_code= sai_id::TEXT
LEFT JOIN mm ON meisa.mei_fi_id = mm.mei_fi_id -- joining subquery
WHERE mei_mty_id IN (1,2,3,4,5,9,11,12,15,16,17,26); --298005


-- Insert only fatmeter where gravimeter does not exist

INSERT INTO dateel.t_indivtrait_int
(int_ser_id, 
int_wkg_code, 
int_spe_code, 
int_id, 
int_fi_id, 
int_tra_code, 
int_value, 
int_trv_code, 
int_trm_code, 
int_last_update, 
int_qal_code, 
int_ver_code)
WITH fatmeter AS (
SELECT 
tss2.ser_id AS int_ser_id,
'WGEEL' AS int_wkg_code,
'127186' AS int_spe_code,
mei_id AS int_id, 
meisa.mei_fi_id AS int_fi_id, 
CASE WHEN mei_mty_id = 10 THEN  'Muscle_lipid' 
ELSE 'problem' END AS int_tra_code,
mei_value AS int_value, 
NULL AS int_trv_code, -- there ARE NO qualitative VALUES FOR GROUP metrics
CASE WHEN mei_mty_id = 10 THEN 'Muscle_lipid_fatmeter' -- different method see method
ELSE NULL END AS int_trm_code,
mei_last_update AS int_last_update, 
mei_qal_id AS int_qal_code, 
CASE WHEN mei_dts_datasource = 'dc_2019' THEN 'WGEEL-2019-1'
     WHEN mei_dts_datasource = 'dc_2020' THEN 'WGEEL-2020-1'
     WHEN mei_dts_datasource ='dc_2021' THEN 'WGEEL-2021-1'
     WHEN mei_dts_datasource ='dc_2022' THEN 'WGEEL-2022-1'
     WHEN mei_dts_datasource ='dc_2023' THEN 'WGEEL-2023-1'
     WHEN mei_dts_datasource ='dc_2024' THEN 'WGEEL-2024-1'
     ELSE 'WGEEL-2018-1' END AS int_ver_code
FROM datwgeel.t_metricindsamp_meisa meisa
JOIN datwgeel.t_fishsamp_fisa  ON meisa.mei_fi_id = fi_id
JOIN datwgeel.t_samplinginfo_sai AS tss ON fisa_sai_id = sai_id
JOIN dateel.t_series_ser AS tss2 ON ser_code= sai_id::text
WHERE mei_mty_id = 10)
SELECT * FROM fatmeter WHERE  int_fi_id NOT IN 
(SELECT int_fi_id FROM dateel.t_indivtrait_int WHERE int_tra_code = 'Muscle_lipid')
; --100



-- Qualitative traits series


INSERT INTO dateel.t_indivtrait_int
(int_ser_id, 
int_wkg_code, 
int_spe_code, 
int_id, 
int_fi_id, 
int_tra_code, 
int_value, 
int_trv_code, 
int_trm_code, 
int_last_update, 
int_qal_code, 
int_ver_code)
WITH a1 AS (
SELECT mei_fi_id,
       mei_value AS mei_method_sex 
FROM datwgeel.t_metricindseries_meiser 
WHERE mei_mty_id = 27
AND mei_value IS NOT NULL),
 a2 AS (
 SELECT mei_fi_id,
       mei_value AS mei_method_anguillicola 
FROM datwgeel.t_metricindseries_meiser 
WHERE mei_mty_id = 28
AND mei_value IS NOT NULL),
mm AS (
SELECT coalesce(a1.mei_fi_id, a2.mei_fi_id)  AS mei_fi_id,
mei_method_sex,
mei_method_anguillicola
FROM  a1 FULL OUTER JOIN a2 ON a1.mei_fi_id = a2.mei_fi_id)
SELECT 
tss2.ser_id AS int_ser_id,
'WGEEL' AS int_wkg_code,
'127186' AS int_spe_code,
fi_id AS int_id, 
meiser.mei_fi_id AS int_fi_id, 
CASE 
WHEN mei_mty_id = 6 THEN 'Sex'
WHEN mei_mty_id = 7 THEN 'Is_differentiated'
WHEN mei_mty_id = 8 THEN 'Anguillicola_presence'
WHEN mei_mty_id = 13 THEN 'Evex_presence'
WHEN mei_mty_id = 14 THEN 'Hva_presence'
ELSE 'problem' END AS int_tra_code,
NULL AS int_value, 
CASE 
WHEN mei_mty_id = 6 AND mei_value = 1 THEN 'F'
WHEN mei_mty_id = 6 AND mei_value = 0 THEN 'M'
WHEN mei_mty_id = 7 AND mei_value = 1 THEN 'Y'
WHEN mei_mty_id = 7 AND mei_value = 0 THEN 'N'
WHEN mei_mty_id = 8 AND mei_value = 1 THEN 'Y'
WHEN mei_mty_id = 8 AND mei_value = 0 THEN 'N'
WHEN mei_mty_id = 13 AND mei_value= 1 THEN 'Y' 
WHEN mei_mty_id = 13 AND mei_value= 0 THEN 'N'
WHEN mei_mty_id = 14 AND mei_value= 1 THEN 'Y' 
WHEN mei_mty_id = 14 AND mei_value= 0 THEN 'N'
ELSE NULL END AS int_trv_code,
CASE 
WHEN mei_mty_id = 6 AND mei_method_sex = 1 THEN 'Gonadal_inspection'
WHEN mei_mty_id = 6 AND mei_method_sex = 0 THEN 'Length_based_sex'
WHEN mei_mty_id = 8 AND mei_method_anguillicola = 1 THEN 'Anguillicola_stereomicroscope_count'
WHEN mei_mty_id = 8 AND mei_method_anguillicola = 0 THEN 'Anguillicola_visual_count'
ELSE NULL END AS int_trm_code,
mei_last_update AS int_last_update, 
mei_qal_id AS int_qal_code, 
CASE WHEN mei_dts_datasource = 'dc_2019' THEN 'WGEEL-2019-1'
     WHEN mei_dts_datasource = 'dc_2020' THEN 'WGEEL-2020-1'
     WHEN mei_dts_datasource ='dc_2021' THEN 'WGEEL-2021-1'
     WHEN mei_dts_datasource ='dc_2022' THEN 'WGEEL-2022-1'
     WHEN mei_dts_datasource ='dc_2023' THEN 'WGEEL-2023-1'
     WHEN mei_dts_datasource ='dc_2024' THEN 'WGEEL-2024-1'
     ELSE 'WGEEL-2018-1' END AS int_ver_code
FROM datwgeel.t_metricindseries_meiser meiser
JOIN datwgeel.t_fishseries_fiser fiser ON meiser.mei_fi_id = fi_id
JOIN datwgeel.t_series_ser AS tss ON fiser_ser_id = ser_id
JOIN dateel.t_series_ser AS tss2 ON ser_code= ser_nameshort
LEFT JOIN mm ON meiser.mei_fi_id = mm.mei_fi_id -- joining subquery
WHERE mei_mty_id IN (6,7,8,13,14); --189327 (pigment stage is not yet in the db)

-- Qualitative trait sampling


INSERT INTO dateel.t_indivtrait_int
(int_ser_id, 
int_wkg_code, 
int_spe_code, 
int_id, 
int_fi_id, 
int_tra_code, 
int_value, 
int_trv_code, 
int_trm_code, 
int_last_update, 
int_qal_code, 
int_ver_code)
-- extract method from table
-- this will extract 3 columns, mei_fi_id, mei_method_anguillicola and mei_method_sex
WITH a1 AS (
SELECT mei_fi_id,
       mei_value AS mei_method_sex 
FROM datwgeel.t_metricindsamp_meisa meisa
WHERE mei_mty_id = 27
AND mei_value IS NOT NULL),
 a2 AS (
 SELECT mei_fi_id,
       mei_value AS mei_method_anguillicola 
FROM datwgeel.t_metricindsamp_meisa meisa 
WHERE mei_mty_id = 28
AND mei_value IS NOT NULL),
mm AS (
SELECT coalesce(a1.mei_fi_id, a2.mei_fi_id)  AS mei_fi_id,
mei_method_sex,
mei_method_anguillicola
FROM  a1 FULL OUTER JOIN a2 ON a1.mei_fi_id = a2.mei_fi_id)
-- Insert select query
SELECT 
tss2.ser_id AS int_ser_id,
'WGEEL' AS int_wkg_code,
'127186' AS int_spe_code,
mei_id AS int_id, 
meisa.mei_fi_id AS int_fi_id, 
CASE 
WHEN mei_mty_id = 6 THEN 'Sex'
WHEN mei_mty_id = 7 THEN 'Is_differentiated'
WHEN mei_mty_id = 8 THEN 'Anguillicola_presence'
WHEN mei_mty_id = 13 THEN 'Evex_presence'
WHEN mei_mty_id = 14 THEN 'Hva_presence'
ELSE 'problem' END AS int_tra_code,
NULL AS int_value, 
CASE 
WHEN mei_mty_id = 6 AND mei_value = 1 THEN 'F'
WHEN mei_mty_id = 6 AND mei_value = 0 THEN 'M'
WHEN mei_mty_id = 7 AND mei_value = 1 THEN 'Y'
WHEN mei_mty_id = 7 AND mei_value = 0 THEN 'N'
WHEN mei_mty_id = 8 AND mei_value = 1 THEN 'Y'
WHEN mei_mty_id = 8 AND mei_value = 0 THEN 'N'
WHEN mei_mty_id = 13 AND mei_value= 1 THEN 'Y' 
WHEN mei_mty_id = 13 AND mei_value= 0 THEN 'N'
WHEN mei_mty_id = 14 AND mei_value= 1 THEN 'Y' 
WHEN mei_mty_id = 14 AND mei_value= 0 THEN 'N'
ELSE NULL END AS int_trv_code,
CASE 
WHEN mei_mty_id = 6 AND mei_method_sex = 1 THEN 'Gonadal_inspection'
WHEN mei_mty_id = 6 AND mei_method_sex = 0 THEN 'Length_based_sex'
WHEN mei_mty_id = 8 AND mei_method_anguillicola = 1 THEN 'Anguillicola_stereomicroscope_count'
WHEN mei_mty_id = 8 AND mei_method_anguillicola = 0 THEN 'Anguillicola_visual_count'
ELSE NULL END AS int_trm_code,
mei_last_update AS int_last_update, 
mei_qal_id AS int_qal_code, 
CASE WHEN mei_dts_datasource = 'dc_2019' THEN 'WGEEL-2019-1'
     WHEN mei_dts_datasource = 'dc_2020' THEN 'WGEEL-2020-1'
     WHEN mei_dts_datasource ='dc_2021' THEN 'WGEEL-2021-1'
     WHEN mei_dts_datasource ='dc_2022' THEN 'WGEEL-2022-1'
     WHEN mei_dts_datasource ='dc_2023' THEN 'WGEEL-2023-1'
     WHEN mei_dts_datasource ='dc_2024' THEN 'WGEEL-2024-1'
     ELSE 'WGEEL-2018-1' END AS int_ver_code
FROM datwgeel.t_metricindsamp_meisa meisa
JOIN datwgeel.t_fishsamp_fisa  ON meisa.mei_fi_id = fi_id
JOIN datwgeel.t_samplinginfo_sai AS tss ON fisa_sai_id = sai_id
JOIN dateel.t_series_ser AS tss2 ON ser_code= sai_id::TEXT
LEFT JOIN mm ON meisa.mei_fi_id = mm.mei_fi_id -- joining subquery
WHERE mei_mty_id IN (6,7,8,13,14); --163914 (pigment stage is not yet in the db)






Table 54: Table t_indivtrait_int, fish trait table
int_ser_id int_wkg_code int_spe_code int_id int_fi_id int_tra_code int_value int_trv_code int_trm_code int_last_update int_qal_code int_ver_code
0424851e-9533-4e08-91c8-239e05dd5b73 WGEEL 126281 3413553 3413553 Pectoral_lengthmm 15.490 NA NA 2024-09-12 1 WGEEL-2024-1
0424851e-9533-4e08-91c8-239e05dd5b73 WGEEL 126281 3413553 3413553 Eye_diam_meanmm 6.035 NA NA 2024-09-12 1 WGEEL-2024-1
0424851e-9533-4e08-91c8-239e05dd5b73 WGEEL 126281 3413553 3413553 Weightg 32.100 NA NA 2024-09-12 1 WGEEL-2024-1
0424851e-9533-4e08-91c8-239e05dd5b73 WGEEL 126281 3413553 3413553 Lengthmm 290.000 NA NA 2024-09-12 1 WGEEL-2024-1
0424851e-9533-4e08-91c8-239e05dd5b73 WGEEL 126281 3413535 3413535 Pectoral_lengthmm 17.250 NA NA 2024-09-12 1 WGEEL-2024-1
0424851e-9533-4e08-91c8-239e05dd5b73 WGEEL 126281 3413535 3413535 Eye_diam_meanmm 5.660 NA NA 2024-09-12 1 WGEEL-2024-1
0424851e-9533-4e08-91c8-239e05dd5b73 WGEEL 126281 3413535 3413535 Weightg 58.200 NA NA 2024-09-12 1 WGEEL-2024-1
0424851e-9533-4e08-91c8-239e05dd5b73 WGEEL 126281 3413535 3413535 Lengthmm 328.000 NA NA 2024-09-12 1 WGEEL-2024-1
0424851e-9533-4e08-91c8-239e05dd5b73 WGEEL 126281 3413502 3413502 Pectoral_lengthmm 9.300 NA NA 2024-09-12 1 WGEEL-2024-1
0424851e-9533-4e08-91c8-239e05dd5b73 WGEEL 126281 3413502 3413502 Eye_diam_meanmm 4.715 NA NA 2024-09-12 1 WGEEL-2024-1
0424851e-9533-4e08-91c8-239e05dd5b73 WGEEL 126281 3413502 3413502 Weightg 42.000 NA NA 2024-09-12 1 WGEEL-2024-1
0424851e-9533-4e08-91c8-239e05dd5b73 WGEEL 126281 3413502 3413502 Lengthmm 308.000 NA NA 2024-09-12 1 WGEEL-2024-1
0424851e-9533-4e08-91c8-239e05dd5b73 WGEEL 126281 3413498 3413498 Pectoral_lengthmm 12.520 NA NA 2024-09-12 1 WGEEL-2024-1
0424851e-9533-4e08-91c8-239e05dd5b73 WGEEL 126281 3413498 3413498 Eye_diam_meanmm 4.510 NA NA 2024-09-12 1 WGEEL-2024-1
0424851e-9533-4e08-91c8-239e05dd5b73 WGEEL 126281 3413498 3413498 Weightg 59.250 NA NA 2024-09-12 1 WGEEL-2024-1
0424851e-9533-4e08-91c8-239e05dd5b73 WGEEL 126281 3413498 3413498 Lengthmm 316.000 NA NA 2024-09-12 1 WGEEL-2024-1
0424851e-9533-4e08-91c8-239e05dd5b73 WGEEL 126281 3413562 3413562 Pectoral_lengthmm 15.000 NA NA 2024-09-12 1 WGEEL-2024-1
0424851e-9533-4e08-91c8-239e05dd5b73 WGEEL 126281 3413562 3413562 Eye_diam_meanmm 6.930 NA NA 2024-09-12 1 WGEEL-2024-1
0424851e-9533-4e08-91c8-239e05dd5b73 WGEEL 126281 3413562 3413562 Weightg 57.200 NA NA 2024-09-12 1 WGEEL-2024-1
0424851e-9533-4e08-91c8-239e05dd5b73 WGEEL 126281 3413562 3413562 Lengthmm 315.000 NA NA 2024-09-12 1 WGEEL-2024-1

5.9 WGBAST

5.9.1 series table t_series_ser

5.9.1.1 Creating inherited series

SQL code to create table dateel.t_series_ser

-- when dumping this is inherited => I have a not null constraint on the server 
-- when the table is recreated




DROP TABLE IF EXISTS datbast.t_series_ser;
CREATE TABLE datbast.t_series_ser ( 
  CONSTRAINT pk_ser_id PRIMARY KEY (ser_id),
  CONSTRAINT uk_ser_code UNIQUE (ser_code),
  CONSTRAINT uk_ser_name UNIQUE (ser_name),
  CONSTRAINT fk_ser_spe_code FOREIGN KEY (ser_spe_code) 
    REFERENCES ref.tr_species_spe(spe_code) 
    ON UPDATE CASCADE ON DELETE RESTRICT ,
  CONSTRAINT fk_ser_lfs_code_ser_spe_code FOREIGN KEY (ser_lfs_code, ser_spe_code)
    REFERENCES ref.tr_lifestage_lfs (lfs_code, lfs_spe_code) 
    ON UPDATE CASCADE ON DELETE RESTRICT,  
  CONSTRAINT fk_ser_are_code FOREIGN KEY (ser_are_code)
    REFERENCES refbast.tr_area_are (are_code) 
    ON UPDATE CASCADE ON DELETE RESTRICT,
  CONSTRAINT fk_ser_wkg_code  FOREIGN KEY (ser_wkg_code)
   REFERENCES ref.tr_icworkinggroup_wkg(wkg_code)
   ON UPDATE CASCADE ON DELETE RESTRICT,   
  CONSTRAINT fk_ser_ver_code FOREIGN KEY (ser_ver_code)
   REFERENCES refbast.tr_version_ver(ver_code)
  ON UPDATE CASCADE ON DELETE RESTRICT,  
  CONSTRAINT fk_ser_cou_code FOREIGN KEY (ser_cou_code)
   REFERENCES ref.tr_country_cou(cou_code)
   ON UPDATE CASCADE ON DELETE RESTRICT,  
  CONSTRAINT fk_ser_uni_code FOREIGN KEY (ser_uni_code)
   REFERENCES ref.tr_units_uni(uni_code)
   ON DELETE CASCADE ON UPDATE CASCADE,
  CONSTRAINT fk_ser_effort_uni_code FOREIGN KEY (ser_effort_uni_code)
   REFERENCES ref.tr_units_uni(uni_code)
   ON DELETE CASCADE  ON UPDATE CASCADE,
  CONSTRAINT fk_ser_wltyp_code FOREIGN KEY( ser_wltyp_code)
   REFERENCES ref."WLTYP"("Key") 
   ON UPDATE CASCADE ON DELETE RESTRICT,  
  CONSTRAINT fk_ser_gea_code FOREIGN KEY (ser_gea_code)
   REFERENCES ref.tr_gear_gea(gea_code)
   ON UPDATE CASCADE ON DELETE CASCADE,
  CONSTRAINT fk_ser_fiw_code FOREIGN KEY (ser_fiw_code)
   REFERENCES ref.tr_fishway_fiw(fiw_code)
   ON UPDATE CASCADE ON DELETE CASCADE,  
  CONSTRAINT fk_ser_mon_code FOREIGN KEY (ser_mon_code)
   REFERENCES ref.tr_monitoring_mon(mon_code)
   ON UPDATE CASCADE ON DELETE CASCADE
) inherits (dat.t_series_ser);

-- In the wgeel schema the default is WGEEL
ALTER TABLE datbast.t_series_ser ALTER COLUMN ser_wkg_code SET DEFAULT 'WGBAST';  

COMMENT ON TABLE datbast.t_series_ser IS
 'Table of time series, or sampling data identifier. This corresponds to a multi-annual data collection design.
It can correspond to time series data or individual metrics collection or both. This table is inherited from dat ';
COMMENT ON COLUMN dat.t_series_ser.ser_id IS
 'UUID, identifier of the series, primary key';
COMMENT ON COLUMN dat.t_series_ser.ser_code IS
 'Code of the series, use country_code + name series (4 letters) + stage';
COMMENT ON COLUMN dat.t_series_ser.ser_name IS
 'Name of the series';
COMMENT ON COLUMN dat.t_series_ser.ser_spe_code  IS
 'Species, one of use aphiaID eg ''127186'' for Salmon and ''127187''for Trutta. references ref.tr_species_spe, the species can be null but
it should correspond to the main species target by the sampling';
COMMENT ON COLUMN dat.t_series_ser.ser_lfs_code  IS
 'Life stage see tr_lifestage_lfs,Code of the lifestage see tr_lifestage_lfs,  the constraint is set on 
both lfs_code, and lfs_spe_code (as two species can have the same lifestage code. The lifestage can be NULL but it should correspond to the main lifestage targeted by the series;';
COMMENT ON COLUMN dat.t_series_ser.ser_wkg_code IS
 'Code of the working group, one of WGBAST, WGEEL, WGNAS, WKTRUTTA';
COMMENT ON COLUMN dat.t_series_ser.ser_ver_code IS
 'Version code from ref.tr_version_ver the data call e.g. WGNAS_2020_1, WGEEL_2016_1';
COMMENT ON COLUMN dat.t_series_ser.ser_cou_code IS
 'Code of the country';
COMMENT ON COLUMN dat.t_series_ser.ser_wltyp_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_series_ser.ser_hab_code IS
'Code of the habitat, see tr_habitat_hab';
COMMENT ON COLUMN dat.t_series_ser.ser_are_code IS
 'Code of the area, areas are geographical sector most often corresponding to stock units, see tr_area_are.';
COMMENT ON COLUMN dat.t_series_ser.ser_uni_code IS
 'Annual value Unit, references table tr_unit_uni.';
COMMENT ON COLUMN dat.t_series_ser.ser_effort_uni_code IS
 'Annual data collection effort unit code, references table tr_unit_uni.';
COMMENT ON COLUMN dat.t_series_ser.ser_description IS
  'Concise description of the series. Should include species, stage targeted, location and gear. e.g. Glass eel monitoring in the Vilaine estuary (France) with a trapping ladder.';
COMMENT ON COLUMN dat.t_series_ser.ser_locationdescription IS
 'This should provide a description of the site, e.g. if ist far inland, in the middle of a river, near a dam etc. Also please specify the adjectant marine region (Baltic, North Sea) etc.
(e.g.  `Bresle river trap 3 km from the sea` or `IYFS/IBTS sampling in the Skagerrak-Kattegat`';
COMMENT ON COLUMN dat.t_series_ser.ser_gea_code IS
 'Code of the gear used, see tr_gear_gea, if a fishway or scientific monitoring device leave NULL and set mon_code';
COMMENT ON COLUMN dat.t_series_ser.ser_fiw_code IS
 'Code the fishway, eg PO for pool type fishway';
COMMENT ON COLUMN dat.t_series_ser.ser_mon_code IS
 'Code the Monitoring device, eg SO for Sonar';
COMMENT ON COLUMN dat.t_series_ser.ser_stocking IS
 'Boolean, Is there restocking (for eel) or artifical reproduction in the river / basin, affecting the series ? ';
COMMENT ON COLUMN dat.t_series_ser.ser_stockingcomment IS
 'Comment on stocking';
COMMENT ON COLUMN dat.t_series_ser.ser_protocol IS
 'Describe sampling protocol';
COMMENT ON COLUMN dat.t_series_ser.ser_samplingstrategy IS
 'Describe sampling strategy';
COMMENT ON COLUMN dat.t_series_ser.ser_datarightsholder IS
 'Code of the data rights holder of the series, this field will be used in DATSU to acknowledge the source of data';
COMMENT ON COLUMN dat.t_series_ser.ser_datelastupdate IS
 'Last modification in the series, from a trigger';
COMMENT ON COLUMN dat.t_series_ser.geom IS
'Series geometry column EPSG 4326, can be more detailed than the geometry for station';

GRANT ALL ON datbast.t_series_ser TO diaspara_admin;
GRANT SELECT ON datbast.t_series_ser TO diaspara_read; 



5.9.1.2 Import t_series_ser from trutta database

Code to import to to refeel.tr_series_ser
ser <- readxl::read_xlsx(file.path(datawd,
                                   "WGBAST_TRS_densities2024filled.xlsx"), sheet = "dane")
ser <- janitor::clean_names(ser)
ser <- ser[,1:9]
# res <- dbGetQuery(con_diaspara, "SELECT * FROM datbast.t_series_ser")
# clipr::write_clip(colnames(res))
riv <- dbGetQuery(con_diaspara_admin,
                  "SELECT are_code, riv_rivername  FROM refbast.tr_rivernames_riv 
                  JOIN refbast.tr_area_are on are_code = riv_are_code")
riv$riv = stringi::stri_trans_general(riv$riv_rivername, "latin-ascii")
ser$riv <-  stringi::stri_trans_general(ser$river, "latin-ascii")
ser <- ser |> inner_join(riv, by= join_by(riv))
# 584 on 10303 => 604 with stringi
# Need to add electrofishing types to gear
save(ser, file = "data/ser_wgbast.Rdata")
t_series_ser <-
  data.frame(
    "ser_id" = uuid::UUIDgenerate(n=nrow(ser)),
    "ser_code" = paste0(ser$country, "_", 
                        substr(stringi::stri_trans_general(ser$river, "latin-ascii"),1,4),"_P_TRS"),
    "ser_name"  = ser$river,
    "ser_spe_code" = "TRS",
    "ser_lfs_code" = "P",
    "ser_are_code" = ser$are_code,
    "ser_wkg_code" = "WGBAST",
    "ser_ver_code" = "WGBAST-2025-1",
    "ser_cou_code" = ser$country,
    "ser_hab_code" = NA, # TODO integrate habitats from eiunis https://eunis.eea.europa.eu/habitats-code-browser.jsp?expand=58,66,79,17#level_17
    "ser_gea_code" = '10.4', # electric fishing
    "ser_fiw_code" = NA,
    "ser_mon_code" = NA,
    "ser_uni_code" = "nr",
    "ser_effort_uni_code" = "nr/m2",
    "ser_description" = NA,
    "ser_locationdescription" = 
      paste0("main_river"=ser$main_river,", river = ",ser$river,",
     sub_div= ",ser$sub_div),
    "ser_wltyp_code" =  "FW",
    "ser_stocking" = NA,
    "ser_stockingcomment" = NA,
    "ser_protocol" = NA,
    "ser_samplingstrategy" = NA,
    "ser_datarightsholder" = NA,
    "ser_datelastupdate" = '2025-06-09' #,
    # geom
  )

res <- dbWriteTable(con_diaspara_admin, "t_series_ser_temp", 
                    t_series_ser, overwrite = TRUE)
dbExecute(con_diaspara_admin, "DELETE FROM  datbast.t_series_ser;")
dbExecute(con_diaspara_admin, "INSERT INTO datbast.t_series_ser 
SELECT distinct on (ser_code)
 ser_id::uuid,
 ser_code,
 ser_name,
 ser_spe_code,
 ser_lfs_code,
 ser_are_code::TEXT,
 ser_wkg_code,
 ser_ver_code,
 ser_cou_code,
 ser_hab_code,
 ser_gea_code,
 ser_fiw_code,
 ser_mon_code,
 ser_uni_code,
 ser_effort_uni_code,
 ser_description,
 ser_locationdescription,
 ser_wltyp_code,
 ser_stocking,
 ser_stockingcomment,
 ser_protocol,
 ser_samplingstrategy,
 ser_datarightsholder,
 ser_datelastupdate::date
FROM t_series_ser_temp") # 25 

The table t_series_ser contains an extract of the series. Only a few were joined when trying to match the names. A data integration using the habitat referential would allow to integrate at sub basin level though maybe a table of subbasins (with geometries) would need to be created.

Table 55: Table t_series_ser for series first 20 lines
ser_id ser_code ser_name ser_spe_code ser_lfs_code ser_are_code ser_wkg_code ser_ver_code ser_cou_code ser_hab_code ser_gea_code ser_fiw_code ser_mon_code ser_uni_code ser_effort_uni_code ser_description ser_locationdescription ser_wltyp_code ser_stocking ser_stockingcomment ser_protocol ser_samplingstrategy ser_datarightsholder ser_datelastupdate geom
031889a1-9e58-4ffc-ac37-bd75ccd5b69a EE_Valg_P_TRS Valgejõgi 127187 P 2120027920 WGBAST WGBAST-2025-1 EE NA 10.4 NA NA nr nr/m2 NA Valgejõgi, river = Valgejõgi, sub_div= 32 FW NA NA NA NA NA 2025-06-09 NA
b038c443-25aa-4ed5-9ffe-9e7e002800f1 FI_Akas_P_TRS Äkäsjoki 127187 P 2120030100 WGBAST WGBAST-2025-1 FI NA 10.4 NA NA nr nr/m2 NA Torniojoki, river = Äkäsjoki, sub_div= 31 FW NA NA NA NA NA 2025-06-09 NA
138859ce-3086-461d-8167-13eef6e0fe13 FI_Paka_P_TRS Pakajoki 127187 P 2120030100 WGBAST WGBAST-2025-1 FI NA 10.4 NA NA nr nr/m2 NA Torniojoki, river = Pakajoki, sub_div= 31 FW NA NA NA NA NA 2025-06-09 NA
7aa04bdc-fe00-4865-a959-6f9e8ef07fef LT_Bart_P_TRS Bartuva 127187 P 2120027040 WGBAST WGBAST-2025-1 LT NA 10.4 NA NA nr nr/m2 NA Nemunas, river = Bartuva, sub_div= 26 FW NA NA NA NA NA 2025-06-09 NA
1f27a1af-75b9-4d61-8086-ad929d06fee2 LT_Duby_P_TRS Dubysa 127187 P 2120026920 WGBAST WGBAST-2025-1 LT NA 10.4 NA NA nr nr/m2 NA Nemunas, river = Dubysa, sub_div= 26 FW NA NA NA NA NA 2025-06-09 NA
7bf51353-0f9c-4c8b-b370-25f0f2fec4a6 LT_Jura_P_TRS Jūra 127187 P 2120026920 WGBAST WGBAST-2025-1 LT NA 10.4 NA NA nr nr/m2 NA Nemunas, river = Jūra, sub_div= 26 FW NA NA NA NA NA 2025-06-09 NA
eaaad449-6808-4e2f-998f-e550f3a9ead9 LT_Neri_P_TRS Neris 127187 P 2120026920 WGBAST WGBAST-2025-1 LT NA 10.4 NA NA nr nr/m2 NA Nemunas, river = Neris, sub_div= 26 FW NA NA NA NA NA 2025-06-09 NA
a78e8a8c-85c5-4c68-8a04-1b19312d1cd9 LT_Zeim_P_TRS Žeimena 127187 P 2120026920 WGBAST WGBAST-2025-1 LT NA 10.4 NA NA nr nr/m2 NA Nemunas, river = Žeimena, sub_div= 26 FW NA NA NA NA NA 2025-06-09 NA
5814f7ac-1fb2-40c6-8867-31cecc3b2d23 LV_Amat_P_TRS Amata 127187 P 2120027350 WGBAST WGBAST-2025-1 LV NA 10.4 NA NA nr nr/m2 NA Gauja, river = Amata, sub_div= 28 FW NA NA NA NA NA 2025-06-09 NA
03487eee-e307-412d-9b0d-7b94a7e2be59 LV_Bras_P_TRS Brasla 127187 P 2120027350 WGBAST WGBAST-2025-1 LV NA 10.4 NA NA nr nr/m2 NA Gauja, river = Brasla, sub_div= 28 FW NA NA NA NA NA 2025-06-09 NA
6bd47a9d-b92b-45f2-aca1-9ae86a7a4e6f LV_Durb_P_TRS Durbe 127187 P 2120027060 WGBAST WGBAST-2025-1 LV NA 10.4 NA NA nr nr/m2 NA Venta, river = Durbe, sub_div= 28 FW NA NA NA NA NA 2025-06-09 NA
bfa6e3ff-c681-4a17-9b91-41d9f0452365 LV_Jaun_P_TRS Jaunupe 127187 P 2120027460 WGBAST WGBAST-2025-1 LV NA 10.4 NA NA nr nr/m2 NA Salaca, river = Jaunupe, sub_div= 28 FW NA NA NA NA NA 2025-06-09 NA
c261642a-848b-49ba-9eed-b3b06188c738 LV_Korg_P_TRS Korģe 127187 P 2120027460 WGBAST WGBAST-2025-1 LV NA 10.4 NA NA nr nr/m2 NA Salaca, river = Korģe, sub_div= 28 FW NA NA NA NA NA 2025-06-09 NA
9b1f00f6-7e57-40ec-aa84-7449c1bf8b5f LV_Liel_P_TRS Lielā Jugla 127187 P 2120027320 WGBAST WGBAST-2025-1 LV NA 10.4 NA NA nr nr/m2 NA Daugava, river = Lielā Jugla, sub_div= 28 FW NA NA NA NA NA 2025-06-09 NA
15f6eab9-8b72-4cdb-8dbd-a03513ea7967 LV_Liga_P_TRS Līgatne 127187 P 2120027350 WGBAST WGBAST-2025-1 LV NA 10.4 NA NA nr nr/m2 NA Gauja, river = Līgatne, sub_div= 28 FW NA NA NA NA NA 2025-06-09 NA
e2063839-865d-4001-87ef-10f8a9ad7951 LV_Maza_P_TRS Mazā Jugla 127187 P 2120027320 WGBAST WGBAST-2025-1 LV NA 10.4 NA NA nr nr/m2 NA Daugava, river = Mazā Jugla, sub_div= 28 FW NA NA NA NA NA 2025-06-09 NA
ed74d560-9ee0-4671-86f3-644935e0f907 LV_Svet_P_TRS Svētupe 127187 P 2120027440 WGBAST WGBAST-2025-1 LV NA 10.4 NA NA nr nr/m2 NA NA, river = Svētupe, sub_div= 28 FW NA NA NA NA NA 2025-06-09 NA
a62624ef-e7fb-460a-9c12-e8fbf7eba01c LV_Tebr_P_TRS Tebra 127187 P 2120027060 WGBAST WGBAST-2025-1 LV NA 10.4 NA NA nr nr/m2 NA Venta, river = Tebra, sub_div= 28 FW NA NA NA NA NA 2025-06-09 NA
71a8bc1f-5a71-4c20-9e78-8636cbf7710a PL_Draw_P_TRS Drawa 127187 P 2120026060 WGBAST WGBAST-2025-1 PL NA 10.4 NA NA nr nr/m2 NA Odra, river = Drawa, sub_div= 24 FW NA NA NA NA NA 2025-06-09 NA
10b28540-c037-4575-a2e8-d0c051e17e78 PL_Drwe_P_TRS Drwęca 127187 P 2120026550 WGBAST WGBAST-2025-1 PL NA 10.4 NA NA nr nr/m2 NA Vistula, river = Drwęca, sub_div= 26 FW NA NA NA NA NA 2025-06-09 NA

5.9.2 Creating table joining series and station

The table is created but empty. We need the stations in ICES first.

SQL code to create table datbast.tj_seriesstation_ses
DROP TABLE IF EXISTS datbast.tj_seriesstation_ses; 
CREATE TABLE datbast.tj_seriesstation_ses (
 CONSTRAINT fk_ses_ser_id FOREIGN KEY (ses_ser_id)
    REFERENCES datbast.t_series_ser (ser_id) 
    ON UPDATE CASCADE ON DELETE CASCADE,  
 CONSTRAINT uk_ses_ser_id UNIQUE (ses_ser_id) ,
  CONSTRAINT fk_station_code FOREIGN KEY (ses_station_code) 
  REFERENCES "ref"."StationDictionary" ("Station_Code")   
  ) inherits (dat.tj_seriesstation_ses);
  

GRANT ALL ON datbast.tj_seriesstation_ses TO diaspara_admin;
GRANT SELECT ON datbast.tj_seriesstation_ses TO diaspara_read; 

5.9.3 Creating inherited table for annual series

SQL code to create tables datbast.t_serannual_san
--DROP TABLE IF EXISTS datbast.t_serannual_san;

CREATE TABLE datbast.t_serannual_san (
 san_agegroup TEXT,
CONSTRAINT ck_san_agegroup CHECK (san_agegroup IS NULL OR san_agegroup='0+' OR san_agegroup = '>0+' OR san_agegroup ='all'),
CONSTRAINT ck_san_wkg_code CHECK (san_wkg_code = 'WGBAST'),
CONSTRAINT fk_san_ser_id FOREIGN KEY (san_ser_id)
  REFERENCES datbast.t_series_ser (ser_id) 
  ON UPDATE CASCADE ON DELETE CASCADE, 
CONSTRAINT c_uk_san_id UNIQUE (san_id, san_wkg_code), 
CONSTRAINT fk_san_wkg_code  FOREIGN KEY (san_wkg_code)
REFERENCES ref.tr_icworkinggroup_wkg(wkg_code),
CONSTRAINT fk_san_ver_code FOREIGN KEY (san_ver_code)
REFERENCES refbast.tr_version_ver(ver_code),
CONSTRAINT uk_san_year_svc UNIQUE(san_year, san_ser_id, san_agegroup)
) INHERITS (dat.t_serannual_san);
  
ALTER TABLE datbast.t_series_ser ALTER COLUMN ser_wkg_code SET DEFAULT 'WGBAST';  

COMMENT ON TABLE datbast.t_serannual_san IS
 'Table of annual abundance data for series in datbast.t_series_ser, electrofishing series or trap data';
COMMENT ON COLUMN datbast.t_serannual_san.san_ser_id IS
 'UUID, identifier of the series, primary key, references the table ref.tr_seriesvocab_svc (svc_id)';
COMMENT ON COLUMN datbast.t_serannual_san.san_id IS
 'INTEGER, autoincremented, unique for one working group';
COMMENT ON COLUMN datbast.t_serannual_san.san_year IS
 'Year of monitoring, note that for some of the series this corresponds to the main migration season';
COMMENT ON COLUMN datbast.t_serannual_san.san_agegroup IS
 'Age group of fish.';
COMMENT ON COLUMN datbast.t_serannual_san.san_comment IS
 'Comment on the annual value of the series';
COMMENT ON COLUMN datbast.t_serannual_san.san_effort IS
 'Eventually a measure of effort to collect the series, e.g. number of nr haul, nr fyke.day,
check the t_metadataannual table for the unit used';
COMMENT ON COLUMN datbast.t_serannual_san.san_datelastupdate IS
 'Date of last update on the annual data';
COMMENT ON COLUMN datbast.t_serannual_san.san_qal_id IS
 'Quality ID code of the series';
COMMENT ON COLUMN datbast.t_serannual_san.san_qal_comment IS
 'Comment related to data quality, e.g. why this year the series should not be used, or used with caution.';
COMMENT ON COLUMN datbast.t_serannual_san.san_wkg_code IS
 'Code of the working group, one of
WGBAST, WGEEL, WGNAS, WKTRUTTA';
COMMENT ON COLUMN datbast.t_serannual_san.san_ver_code IS
 'Version code sourced from ref.tr_version_ver the data call e.g. NAS_2025dc_2020, wgeel_2016, wkemp_2025';


GRANT ALL ON datbast.t_serannual_san TO diaspara_admin;
GRANT SELECT ON datbast.t_serannual_san TO diaspara_read; 

5.9.4 Import data for annual series

Data are imported from the electrofishing trutta db to datbast.t_serannual_ser. Data are structured not by stage but by age group.

Code to import to datbast.t_serannual_ser
# start over from ser, previous chunk
load(file = "data/ser_wgbast.Rdata") #ser

ser0 <- dbGetQuery(con_diaspara_admin, "SELECT * FROM datbast.t_series_ser")
ser <- ser |> mutate(ser_code =  
                       paste0(ser$country, "_", substr(
                         stringi::stri_trans_general(ser$river, "latin-ascii"),1,4),"_P_TRS")) |>
  inner_join(ser0)

t_serannual_san_temp <-
  data.frame(
    "san_ser_id" = ser$ser_id,
    "san_id" = seq(along.with= ser$ser_id),
    "san_value"=ser$density_n_100m2,
    "san_year" = ser$year,
    "san_comment" = NA,
    "san_effort" = ser$number_of_sites,
    "san_datelastupdate" = Sys.Date(),
    "san_qal_id" = 1,
    "san_qal_comment" = NA,
    "san_wkg_code" = "WGBAST",
    "san_ver_code" = "WGBAST-2025-1",
    "san_agegroup" = ifelse(is.na(ser$age),"all",ser$age))


dbWriteTable(con_diaspara_admin, "t_serannual_san_temp", 
             t_serannual_san_temp, overwrite = TRUE)
dbExecute(con_diaspara_admin, "DELETE FROM  datbast.t_serannual_san;")
dbExecute(con_diaspara_admin, "INSERT INTO datbast.t_serannual_san 
SELECT 
    san_ser_id::uuid,
    san_id,
    san_value,
    san_year,
    san_comment,
    san_effort,
    san_datelastupdate,
    san_qal_id,
    san_qal_comment,
    san_wkg_code,
    san_ver_code,
    san_agegroup
FROM t_serannual_san_temp") # 604
NoteNote for age

Here age needs to be part of a constraint, values are 0+, >0+ but all is necessary to replace NULL.

Code to show series table.
dbGetQuery(con_diaspara, "SELECT * FROM datbast.t_serannual_san limit 20;")|>
  knitr::kable()|>
  kable_styling(bootstrap_options = c("striped", "hover", "condensed"))
Table 56: Table databast.t_serannual_san for annual values first 20 lines
san_ser_id san_id san_value san_year san_comment san_effort san_datelastupdate san_qal_id san_qal_comment san_wkg_code san_ver_code san_agegroup
031889a1-9e58-4ffc-ac37-bd75ccd5b69a 1 0.0000000 1976 NA 1 2025-10-25 1 NA WGBAST WGBAST-2025-1 0+
031889a1-9e58-4ffc-ac37-bd75ccd5b69a 2 0.8493366 1983 NA 1 2025-10-25 1 NA WGBAST WGBAST-2025-1 0+
031889a1-9e58-4ffc-ac37-bd75ccd5b69a 3 7.9249550 1990 NA 1 2025-10-25 1 NA WGBAST WGBAST-2025-1 0+
031889a1-9e58-4ffc-ac37-bd75ccd5b69a 4 0.0000000 1995 NA 1 2025-10-25 1 NA WGBAST WGBAST-2025-1 0+
031889a1-9e58-4ffc-ac37-bd75ccd5b69a 5 2.0702579 1996 NA 2 2025-10-25 1 NA WGBAST WGBAST-2025-1 0+
031889a1-9e58-4ffc-ac37-bd75ccd5b69a 6 0.4246683 1997 NA 1 2025-10-25 1 NA WGBAST WGBAST-2025-1 0+
031889a1-9e58-4ffc-ac37-bd75ccd5b69a 7 0.2400354 1999 NA 7 2025-10-25 1 NA WGBAST WGBAST-2025-1 0+
031889a1-9e58-4ffc-ac37-bd75ccd5b69a 8 0.5229656 2000 NA 5 2025-10-25 1 NA WGBAST WGBAST-2025-1 0+
031889a1-9e58-4ffc-ac37-bd75ccd5b69a 9 0.1813328 2001 NA 4 2025-10-25 1 NA WGBAST WGBAST-2025-1 0+
031889a1-9e58-4ffc-ac37-bd75ccd5b69a 10 0.0000000 2002 NA 1 2025-10-25 1 NA WGBAST WGBAST-2025-1 0+
031889a1-9e58-4ffc-ac37-bd75ccd5b69a 11 0.0000000 2003 NA 3 2025-10-25 1 NA WGBAST WGBAST-2025-1 0+
031889a1-9e58-4ffc-ac37-bd75ccd5b69a 12 0.7017058 2004 NA 2 2025-10-25 1 NA WGBAST WGBAST-2025-1 0+
031889a1-9e58-4ffc-ac37-bd75ccd5b69a 13 2.4001195 2005 NA 3 2025-10-25 1 NA WGBAST WGBAST-2025-1 0+
031889a1-9e58-4ffc-ac37-bd75ccd5b69a 14 4.0790627 2006 NA 3 2025-10-25 1 NA WGBAST WGBAST-2025-1 0+
031889a1-9e58-4ffc-ac37-bd75ccd5b69a 15 4.2658571 2007 NA 3 2025-10-25 1 NA WGBAST WGBAST-2025-1 0+
031889a1-9e58-4ffc-ac37-bd75ccd5b69a 16 4.5519545 2008 NA 3 2025-10-25 1 NA WGBAST WGBAST-2025-1 0+
031889a1-9e58-4ffc-ac37-bd75ccd5b69a 17 5.7795221 2009 NA 3 2025-10-25 1 NA WGBAST WGBAST-2025-1 0+
031889a1-9e58-4ffc-ac37-bd75ccd5b69a 18 2.9153959 2010 NA 3 2025-10-25 1 NA WGBAST WGBAST-2025-1 0+
031889a1-9e58-4ffc-ac37-bd75ccd5b69a 19 1.0616671 2011 NA 3 2025-10-25 1 NA WGBAST WGBAST-2025-1 0+
eaaad449-6808-4e2f-998f-e550f3a9ead9 20 3.3000000 2004 NA NA 2025-10-25 1 NA WGBAST WGBAST-2025-1 all

6 Annex : Import data from WP2

Here we import files from WP2, this section is meant to test the inclusion of salmon data in the database, the development is needed to test the format for salmon data.

6.1 series table t_series_ser

6.1.1 Creating inherited series

SQL code to create table datnas.t_series_ser

-- when dumping this is inherited => I have a not null constraint on the server 
-- when the table is recreated




DROP TABLE IF EXISTS datnas.t_series_ser;
CREATE TABLE datnas.t_series_ser ( 
  CONSTRAINT pk_ser_id PRIMARY KEY (ser_id),
  CONSTRAINT uk_ser_code UNIQUE (ser_code),
  CONSTRAINT uk_ser_name UNIQUE (ser_name),
  CONSTRAINT fk_ser_spe_code FOREIGN KEY (ser_spe_code) 
    REFERENCES ref.tr_species_spe(spe_code) 
    ON UPDATE CASCADE ON DELETE RESTRICT ,
  CONSTRAINT fk_ser_lfs_code_ser_spe_code FOREIGN KEY (ser_lfs_code, ser_spe_code)
    REFERENCES ref.tr_lifestage_lfs (lfs_code, lfs_spe_code) 
    ON UPDATE CASCADE ON DELETE RESTRICT,  
  CONSTRAINT fk_ser_are_code FOREIGN KEY (ser_are_code)
    REFERENCES refnas.tr_area_are (are_code) 
    ON UPDATE CASCADE ON DELETE RESTRICT,
  CONSTRAINT fk_ser_wkg_code  FOREIGN KEY (ser_wkg_code)
   REFERENCES ref.tr_icworkinggroup_wkg(wkg_code)
   ON UPDATE CASCADE ON DELETE RESTRICT,   
  CONSTRAINT fk_ser_ver_code FOREIGN KEY (ser_ver_code)
   REFERENCES refnas.tr_version_ver(ver_code)
  ON UPDATE CASCADE ON DELETE RESTRICT,  
  CONSTRAINT fk_ser_cou_code FOREIGN KEY (ser_cou_code)
   REFERENCES ref.tr_country_cou(cou_code)
   ON UPDATE CASCADE ON DELETE RESTRICT,  
  CONSTRAINT fk_ser_uni_code FOREIGN KEY (ser_uni_code)
   REFERENCES ref.tr_units_uni(uni_code)
   ON DELETE CASCADE ON UPDATE CASCADE,
  CONSTRAINT fk_ser_effort_uni_code FOREIGN KEY (ser_effort_uni_code)
   REFERENCES ref.tr_units_uni(uni_code)
   ON DELETE CASCADE  ON UPDATE CASCADE,
  CONSTRAINT fk_ser_wltyp_code FOREIGN KEY( ser_wltyp_code)
   REFERENCES ref."WLTYP"("Key") 
   ON UPDATE CASCADE ON DELETE RESTRICT,  
  CONSTRAINT fk_ser_gea_code FOREIGN KEY (ser_gea_code)
   REFERENCES ref.tr_gear_gea(gea_code)
   ON UPDATE CASCADE ON DELETE CASCADE,
  CONSTRAINT fk_ser_fiw_code FOREIGN KEY (ser_fiw_code)
   REFERENCES ref.tr_fishway_fiw(fiw_code)
   ON UPDATE CASCADE ON DELETE CASCADE,  
  CONSTRAINT fk_ser_mon_code FOREIGN KEY (ser_mon_code)
   REFERENCES ref.tr_monitoring_mon(mon_code)
   ON UPDATE CASCADE ON DELETE CASCADE
) inherits (dat.t_series_ser);

-- In the wgeel schema the default is WGEEL
ALTER TABLE datnas.t_series_ser ALTER COLUMN ser_wkg_code SET DEFAULT 'WGNAS';  

COMMENT ON TABLE datnas.t_series_ser IS
 'Table of time series, or sampling data identifier. This corresponds to a multi-annual data collection design.
It can correspond to time series data or individual metrics collection or both. This table is inherited from dat ';
COMMENT ON COLUMN dat.t_series_ser.ser_id IS
 'UUID, identifier of the series, primary key';
COMMENT ON COLUMN dat.t_series_ser.ser_code IS
 'Code of the series, use country_code + name series (4 letters) + stage';
COMMENT ON COLUMN dat.t_series_ser.ser_name IS
 'Name of the series';
COMMENT ON COLUMN dat.t_series_ser.ser_spe_code  IS
 'Species, one of use aphiaID eg ''127186'' for Salmon and ''127187''for Trutta. references ref.tr_species_spe, the species can be null but
it should correspond to the main species target by the sampling';
COMMENT ON COLUMN dat.t_series_ser.ser_lfs_code  IS
 'Life stage see tr_lifestage_lfs,Code of the lifestage see tr_lifestage_lfs,  the constraint is set on 
both lfs_code, and lfs_spe_code (as two species can have the same lifestage code. The lifestage can be NULL but it should correspond to the main lifestage targeted by the series;';
COMMENT ON COLUMN dat.t_series_ser.ser_wkg_code IS
 'Code of the working group, one of WGBAST, WGEEL, WGNAS, WKTRUTTA';
COMMENT ON COLUMN dat.t_series_ser.ser_ver_code IS
 'Version code from ref.tr_version_ver the data call e.g. WGNAS_2020_1, WGEEL_2016_1';
COMMENT ON COLUMN dat.t_series_ser.ser_cou_code IS
 'Code of the country';
COMMENT ON COLUMN dat.t_series_ser.ser_wltyp_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_series_ser.ser_hab_code IS
'Code of the habitat, see tr_habitat_hab';
COMMENT ON COLUMN dat.t_series_ser.ser_are_code IS
 'Code of the area, areas are geographical sector most often corresponding to stock units, see tr_area_are.';
COMMENT ON COLUMN dat.t_series_ser.ser_uni_code IS
 'Annual value Unit, references table tr_unit_uni.';
COMMENT ON COLUMN dat.t_series_ser.ser_effort_uni_code IS
 'Annual data collection effort unit code, references table tr_unit_uni.';
COMMENT ON COLUMN dat.t_series_ser.ser_description IS
  'Concise description of the series. Should include species, stage targeted, location and gear. e.g. Glass eel monitoring in the Vilaine estuary (France) with a trapping ladder.';
COMMENT ON COLUMN dat.t_series_ser.ser_locationdescription IS
 'This should provide a description of the site, e.g. if ist far inland, in the middle of a river, near a dam etc. Also please specify the adjectant marine region (Baltic, North Sea) etc.
(e.g.  `Bresle river trap 3 km from the sea` or `IYFS/IBTS sampling in the Skagerrak-Kattegat`';
COMMENT ON COLUMN dat.t_series_ser.ser_gea_code IS
 'Code of the gear used, see tr_gear_gea, if a fishway or scientific monitoring device leave NULL and set mon_code';
COMMENT ON COLUMN dat.t_series_ser.ser_fiw_code IS
 'Code the fishway, eg PO for pool type fishway';
COMMENT ON COLUMN dat.t_series_ser.ser_mon_code IS
 'Code the Monitoring device, eg SO for Sonar';
COMMENT ON COLUMN dat.t_series_ser.ser_stocking IS
 'Boolean, Is there restocking (for eel) or artifical reproduction in the river / basin, affecting the series ? ';
COMMENT ON COLUMN dat.t_series_ser.ser_stockingcomment IS
 'Comment on stocking';
COMMENT ON COLUMN dat.t_series_ser.ser_protocol IS
 'Describe sampling protocol';
COMMENT ON COLUMN dat.t_series_ser.ser_samplingstrategy IS
 'Describe sampling strategy';
COMMENT ON COLUMN dat.t_series_ser.ser_datarightsholder IS
 'Code of the data rights holder of the series, this field will be used in DATSU to acknowledge the source of data';
COMMENT ON COLUMN dat.t_series_ser.ser_datelastupdate IS
 'Last modification in the series, from a trigger';
COMMENT ON COLUMN dat.t_series_ser.geom IS
'Series geometry column EPSG 4326, can be more detailed than the geometry for station';

GRANT ALL ON datnas.t_series_ser TO diaspara_admin;
GRANT SELECT ON datnas.t_series_ser TO diaspara_read; 



6.1.2 Import t_series_ser example data (WP2)

Code to import to to refnas.tr_series_ser
ser <- readxl::read_xlsx(file.path(datawd,
"../wgnas/burishoole.xlsx"),
sheet = "sampling_info",
col_types = c(rep("text",4),"numeric", rep("text", 8), rep("numeric", 2), "text")
)
# note I have manually added sai_x and sai_y to sampling_info
# below I'm getting the river code with a spatial query
ser <- ser[1:2,] 
ser <- st_as_sf(ser, coords = c("sai_x", "sai_y"), crs = 4326, remove = FALSE)

st_write(ser, con_diaspara, "series_temp")

temp = dbGetQuery(con_diaspara,
"SELECT * FROM series_temp join refnas.tr_area_are on 
          st_intersects(geometry, geom_polygon) WHERE
          are_lev_code = 'River'")$are_code

# Here check that we don't return two intersects or none (which might happen)

stopifnot(nrow(temp) == nrow(ser))
if (any(is.na(temp$are_code))) stop ("problem with projection, check location")


ser$are_code <- temp$are_code

# this was to get the name of the lfs code for name, I'm ignoring it currently
# stage = dbGetQuery(con_diaspara,
# "SELECT * FROM ref.tr_lifestage_lfs where lfs_spe_code = '127186'")

# ser$sai_lfs_code[ser$sai_lfs_code == 'S'] <- 'A'
# ser <- ser |> st_drop_geometry() |> left_join(stage|> select(lfs_code,lfs_name),
#  by = join_by(sai_lfs_code==lfs_code))

# create verion for diaspara
dbExecute(con_diaspara, "INSERT INTO refnas.tr_version_ver (ver_code,ver_year,ver_spe_code,ver_version,ver_description,ver_wkg_code)
    VALUES (
 'DIASPARA-2025-1',
 2025,
 'Salmo salar',
 1,
'WP2 data call for diaspara on LHT',
'WGNAS');"
)


# Need to add electrofishing types to gear
save(ser, file = "data/ser_burishoole.Rdata")
t_series_ser <-
data.frame(
"ser_id" = uuid::UUIDgenerate(n=nrow(ser)),
"ser_code" = ser$sai_name,
"ser_name"  = ser$sai_name,
"ser_spe_code" = "127186",
"ser_lfs_code" = ser$sai_lfs_code,
"ser_are_code" = ser$are_code, # got from spatial query
"ser_wkg_code" = "WGNAS",
"ser_ver_code" = "DIASPARA-2025-1",
"ser_cou_code" = ser$sai_cou_code,
"ser_hab_code" = NA, # TODO remove 
"ser_gea_code" = NA, # not used only monitoring
"ser_fiw_code" = NA,
"ser_mon_code" = "TR", -- both traps are TR, no fishway
"ser_uni_code" = "nr",
"ser_effort_uni_code" = NA,
"ser_description" = NA,
"ser_locationdescription" = NA, # TODO remove
"ser_wltyp_code" =  case_when(ser$sai_hty_code == "T" ~ "T",
ser$sai_hty_code == "C" ~ "MC",
ser$sai_hty_code == "F" ~ "FW",
ser$sai_hty_code == "MO" ~ "MO"),
"ser_stocking" = ser$"sai_riverorigin(0=reared,1=wild,2=mixed)" %in% c(0,2),
"ser_stockingcomment" = NA,
"ser_protocol" = ser$sai_protocol,
"ser_samplingstrategy" = ser$sai_samplingstrategy,
"ser_datarightsholder" = NA,
"ser_datelastupdate" = Sys.Date() #,
# geom
)

res <- dbWriteTable(con_diaspara, "t_series_ser_temp", 
t_series_ser, overwrite = TRUE)
dbExecute(con_diaspara_admin, "DELETE FROM  datnas.t_series_ser;")
dbExecute(con_diaspara_admin, "INSERT INTO datnas.t_series_ser 
SELECT distinct on (ser_code)
 ser_id::uuid,
 ser_code,
 ser_name,
 ser_spe_code,
 ser_lfs_code,
 ser_are_code::TEXT,
 ser_wkg_code,
 ser_ver_code,
 ser_cou_code,
 ser_hab_code,
 ser_gea_code,
 ser_fiw_code,
 ser_mon_code,
 ser_uni_code,
 ser_effort_uni_code,
 ser_description,
 ser_locationdescription,
 ser_wltyp_code,
 ser_stocking,
 ser_stockingcomment,
 ser_protocol,
 ser_samplingstrategy,
 ser_datarightsholder,
 ser_datelastupdate::date
FROM t_series_ser_temp") # 2
Code to show series table (burishoole example).
dbGetQuery(con_diaspara, "SELECT * FROM datnas.t_series_ser limit 20;")|>
  knitr::kable()|>
  kable_styling(bootstrap_options = c("striped", "hover", "condensed"))
Table 57: Table datnas.t_series_ser first 20 lines
ser_id ser_code ser_name ser_spe_code ser_lfs_code ser_are_code ser_wkg_code ser_ver_code ser_cou_code ser_hab_code ser_gea_code ser_fiw_code ser_mon_code ser_uni_code ser_effort_uni_code ser_description ser_locationdescription ser_wltyp_code ser_stocking ser_stockingcomment ser_protocol ser_samplingstrategy ser_datarightsholder ser_datelastupdate geom
a7650209-3817-4ced-85bb-4654aef393ec IE_Burrishoole_F_S IE_Burrishoole_F_S 127186 A 2120055090 WGNAS DIASPARA-2025-1 IE NA NA NA TR nr NA NA NA FW FALSE NA fixed gear/trap (river) Scientific survey NA 2025-12-22 NA
4a25ff88-9f1f-4b32-99cc-d0730ce4465b IE_Burrishoole_F_SM IE_Burrishoole_F_SM 127186 SM 2120055090 WGNAS DIASPARA-2025-1 IE NA NA NA TR nr NA NA NA FW FALSE NA fixed gear/trap (river) Scientific survey NA 2025-12-22 NA

6.1.3 Import t_seriesannual_san

SQL code to create table datnas.tj_seriesstation_ses
DROP TABLE IF EXISTS datnas.tj_seriesstation_ses; 
CREATE TABLE datnas.tj_seriesstation_ses (
 CONSTRAINT fk_ses_ser_id FOREIGN KEY (ses_ser_id)
    REFERENCES datnas.t_series_ser (ser_id) 
    ON UPDATE CASCADE ON DELETE CASCADE,  
 CONSTRAINT uk_ses_ser_id UNIQUE (ses_ser_id) ,
  CONSTRAINT fk_station_code FOREIGN KEY (ses_station_code) 
  REFERENCES "ref"."StationDictionary" ("Station_Code")   
  ) inherits (dat.tj_seriesstation_ses);
  

GRANT ALL ON datnas.tj_seriesstation_ses TO diaspara_admin;
GRANT SELECT ON datnas.tj_seriesstation_ses TO diaspara_read; 

6.2 Creating inherited table for annual series

SQL code to create tables datnas.t_serannual_san
--DROP TABLE IF EXISTS datnas.t_serannual_san;

CREATE TABLE datnas.t_serannual_san (
 san_agegroup TEXT,
CONSTRAINT ck_san_agegroup CHECK (san_agegroup IS NULL OR san_agegroup='0+' OR san_agegroup = '>0+' OR san_agegroup ='all'),
CONSTRAINT ck_san_wkg_code CHECK (san_wkg_code = 'WGBAST'),
CONSTRAINT fk_san_ser_id FOREIGN KEY (san_ser_id)
  REFERENCES datnas.t_series_ser (ser_id) 
  ON UPDATE CASCADE ON DELETE CASCADE, 
CONSTRAINT c_uk_san_id UNIQUE (san_id, san_wkg_code), 
CONSTRAINT fk_san_wkg_code  FOREIGN KEY (san_wkg_code)
REFERENCES ref.tr_icworkinggroup_wkg(wkg_code),
CONSTRAINT fk_san_ver_code FOREIGN KEY (san_ver_code)
REFERENCES refnas.tr_version_ver(ver_code),
CONSTRAINT uk_san_year_svc UNIQUE(san_year, san_ser_id, san_agegroup)
) INHERITS (dat.t_serannual_san);
  
ALTER TABLE datnas.t_serannual_san ALTER COLUMN san_wkg_code SET DEFAULT 'WGNAS';  

COMMENT ON TABLE datnas.t_serannual_san IS
 'Table of annual abundance data for series in datnas.t_series_ser, electrofishing series or trap data';
COMMENT ON COLUMN datnas.t_serannual_san.san_ser_id IS
 'UUID, identifier of the series, primary key, references the table ref.tr_seriesvocab_svc (svc_id)';
COMMENT ON COLUMN datnas.t_serannual_san.san_id IS
 'INTEGER, autoincremented, unique for one working group';
COMMENT ON COLUMN datnas.t_serannual_san.san_year IS
 'Year of monitoring, note that for some of the series this corresponds to the main migration season';
COMMENT ON COLUMN datnas.t_serannual_san.san_agegroup IS
 'Age group of fish.';
COMMENT ON COLUMN datnas.t_serannual_san.san_comment IS
 'Comment on the annual value of the series';
COMMENT ON COLUMN datnas.t_serannual_san.san_effort IS
 'Eventually a measure of effort to collect the series, e.g. number of nr haul, nr fyke.day,
check the t_metadataannual table for the unit used';
COMMENT ON COLUMN datnas.t_serannual_san.san_datelastupdate IS
 'Date of last update on the annual data';
COMMENT ON COLUMN datnas.t_serannual_san.san_qal_id IS
 'Quality ID code of the series';
COMMENT ON COLUMN datnas.t_serannual_san.san_qal_comment IS
 'Comment related to data quality, e.g. why this year the series should not be used, or used with caution.';
COMMENT ON COLUMN datnas.t_serannual_san.san_wkg_code IS
 'Code of the working group, one of
WGBAST, WGEEL, WGNAS, WKTRUTTA';
COMMENT ON COLUMN datnas.t_serannual_san.san_ver_code IS
 'Version code sourced from ref.tr_version_ver the data call e.g. NAS_2025dc_2020, wgeel_2016, wkemp_2025';


GRANT ALL ON datnas.t_serannual_san TO diaspara_admin;
GRANT SELECT ON datnas.t_serannual_san TO diaspara_read; 
NoteNotes

Currently there is no annual series in WP2 only group and individual traits, the the table is created but no import is done.

6.3 Creating group traits

6.3.1 Create group table

CautionNote for group traits

Need a foreign key on both species and lfs code.

6.4 Create group table for datnas

SQL code to create table datnas.t_group_gr

-- DROP TABLE IF EXISTS datnas.t_group_gr;

CREATE TABLE datnas.t_group_gr (
 CONSTRAINT fk_gr_ser_id FOREIGN KEY (gr_ser_id)
  REFERENCES datnas.t_series_ser (ser_id) 
  ON UPDATE CASCADE ON DELETE CASCADE, 
  CONSTRAINT fk_gr_gr_id  FOREIGN KEY (gr_gr_id, gr_wkg_code)
  REFERENCES datnas.t_group_gr(gr_id, gr_wkg_code)
  ON UPDATE CASCADE ON DELETE CASCADE,
  CONSTRAINT fk_gr_wkg_code  FOREIGN KEY (gr_wkg_code)
  REFERENCES ref.tr_icworkinggroup_wkg(wkg_code)
  ON UPDATE CASCADE ON DELETE RESTRICT,
  CONSTRAINT t_group_gr_pkey PRIMARY KEY (gr_id, gr_wkg_code), 
  CONSTRAINT fk_gr_ver_code FOREIGN KEY (gr_ver_code)
  REFERENCES refnas.tr_version_ver(ver_code)
  ON UPDATE CASCADE ON DELETE RESTRICT,
  CONSTRAINT fk_gr_lfs_code_gr_spe_code FOREIGN KEY (gr_lfs_code, gr_spe_code)
  REFERENCES "ref".tr_lifestage_lfs (lfs_code, lfs_spe_code) 
  ON UPDATE CASCADE ON DELETE RESTRICT, 
   CONSTRAINT fk_gr_spe_code FOREIGN KEY (gr_spe_code) 
  REFERENCES "ref".tr_species_spe(spe_code) 
  ON UPDATE CASCADE ON DELETE RESTRICT 
) INHERITS (dat.t_group_gr);


COMMENT ON TABLE datnas.t_group_gr IS
 'Table identifying the group metrics, a group metric corresponds to a
number of fish sampled for a given year, mostly to describe the annual series. Comments can be made
on the sampling with gr_comments. There can be several group metrics for the same year, for instance
with sampling designs for different stages';

COMMENT ON COLUMN datnas.t_group_gr.gr_id IS
 'Group ID, serial primary key on gr_id and gr_wkg_code';
COMMENT ON COLUMN dat.t_group_gr.gr_gr_id IS
 'Parent group ID, used when giving separate metrics for male and females, in that case the gr_sex_code must be provided';
COMMENT ON COLUMN datnas.t_group_gr.gr_wkg_code IS
 'Code of the working group, one of
WGBAST, WGEEL, WGNAS, WKTRUTTA';
COMMENT ON COLUMN datnas.t_group_gr.gr_year IS
 'The year';
COMMENT ON COLUMN datnas.t_group_gr.gr_number IS
 'Number of fish in the group';
COMMENT ON COLUMN datnas.t_group_gr.gr_comment IS
 'Comment on the group metric, including on the sampling design applied to that particular year, if different from that applied for the whole series.';
COMMENT ON COLUMN datnas.t_group_gr.gr_lastupdate IS
 'Last update, inserted automatically';
COMMENT ON COLUMN datnas.t_group_gr.gr_ver_code IS
 'Version code as in tr_version_ver, corresponds to the working group code WGNAS-2024-1 WGEEL-2016-1, the -1 indicate the first data call in the year, -2 would be second etc....';
COMMENT ON COLUMN dat.t_group_gr.gr_lfs_code IS
 'Life stage code';
COMMENT ON COLUMN dat.t_group_gr.gr_spe_code IS
 'Species code';
COMMENT ON COLUMN dat.t_group_gr.gr_sex_code IS
 'Sex code only for subgroups male or female';
GRANT ALL ON datnas.t_group_gr TO diaspara_admin;
GRANT SELECT ON datnas.t_group_gr TO diaspara_read; 

6.4.1 Import data for group

CautionGroup traits

There are no group traits currently

SQL code to create table datnas.t_group_gr
/*
SELECT DISTINCT gr_dts_datasource 
FROM datwgeel.t_groupseries_grser
*/

DELETE FROM dateel.t_group_gr;
INSERT INTO dateel.t_group_gr
(gr_id, gr_ser_id, gr_gr_id, gr_wkg_code, gr_spe_code, gr_lfs_code, gr_year, gr_number, gr_comment, gr_lastupdate, gr_ver_code)
SELECT 
gr_id,
tss2.ser_id ,
NULL AS gr_gr_id,
'WGEEL' AS gr_wkg_code,
'127186' AS gr_spe_code,
tss.ser_lfs_code AS gr_lfs_code,
gr_year,
gr_number,
gr_comment,
gr_lastupdate,
CASE WHEN gr_dts_datasource = 'dc_2019' THEN 'WGEEL-2019-1'
     WHEN gr_dts_datasource = 'dc_2020' THEN 'WGEEL-2020-1'
     WHEN gr_dts_datasource ='dc_2021' THEN 'WGEEL-2021-1'
     WHEN gr_dts_datasource ='dc_2022' THEN 'WGEEL-2022-1'
     WHEN gr_dts_datasource ='dc_2023' THEN 'WGEEL-2023-1'
     WHEN gr_dts_datasource ='dc_2024' THEN 'WGEEL-2024-1'
     ELSE 'WGEEL-2018-1' END AS gr_ver_code
FROM  datwgeel.t_groupseries_grser grser
JOIN datwgeel.t_series_ser AS tss ON grser_ser_id = ser_id
JOIN dateel.t_series_ser AS tss2 ON ser_code= ser_nameshort; --2681



INSERT INTO dateel.t_group_gr
(gr_id, gr_ser_id, gr_gr_id, gr_wkg_code,  gr_spe_code, gr_lfs_code, gr_year, gr_number, gr_comment, gr_lastupdate, gr_ver_code)
SELECT 
gr_id, 
tss2.ser_id  AS gr_ser_id,
NULL AS gr_gr_id,
'WGEEL' AS gr_wkg_code,
'127186' AS gr_spe_code,
grsa_lfs_code AS gr_lfs_code,
gr_year,
gr_number,
gr_comment,
gr_lastupdate,
CASE WHEN gr_dts_datasource = 'dc_2019' THEN 'WGEEL-2019-1'
     WHEN gr_dts_datasource = 'dc_2020' THEN 'WGEEL-2020-1'
     WHEN gr_dts_datasource ='dc_2021' THEN 'WGEEL-2021-1'
     WHEN gr_dts_datasource ='dc_2022' THEN 'WGEEL-2022-1'
     WHEN gr_dts_datasource ='dc_2023' THEN 'WGEEL-2023-1'
     WHEN gr_dts_datasource ='dc_2024' THEN 'WGEEL-2024-1'
     ELSE 'WGEEL-2018-1' END AS gr_ver_code
FROM  datwgeel.t_groupsamp_grsa 
JOIN datwgeel.t_samplinginfo_sai AS tss ON grsa_sai_id = sai_id
JOIN dateel.t_series_ser AS tss2 ON ser_code= sai_id::text; --798




-- INSERT Males AND Females WITH gr_gr_id

DROP SEQUENCE IF EXISTS seq_group;
CREATE TEMPORARY SEQUENCE seq_group;
SELECT setval('seq_group', (SELECT max(gr_id) FROM dateel.t_group_gr)); -- 13741

-- Males with gr_id from series (subgroupsample)

INSERT INTO dateel.t_group_gr
(gr_id, 
gr_ser_id, 
gr_gr_id, 
gr_wkg_code,  
gr_spe_code, 
gr_sex_code, 
gr_lfs_code, 
gr_year, 
gr_number, 
gr_comment, 
gr_lastupdate,
gr_ver_code)
SELECT 
nextval('seq_group') AS gr_id, 
tss2.ser_id  AS gr_ser_id,
grser.gr_id AS gr_gr_id,
'WGEEL' AS gr_wkg_code,
'127186' AS gr_spe_code,
'M' AS gr_sex_code,
tss.ser_lfs_code AS gr_lfs_code,
gr_year,
gr_number,
gr_comment,
gr_lastupdate,
CASE WHEN gr_dts_datasource = 'dc_2019' THEN 'WGEEL-2019-1'
     WHEN gr_dts_datasource = 'dc_2020' THEN 'WGEEL-2020-1'
     WHEN gr_dts_datasource ='dc_2021' THEN 'WGEEL-2021-1'
     WHEN gr_dts_datasource ='dc_2022' THEN 'WGEEL-2022-1'
     WHEN gr_dts_datasource ='dc_2023' THEN 'WGEEL-2023-1'
     WHEN gr_dts_datasource ='dc_2024' THEN 'WGEEL-2024-1'
     ELSE 'WGEEL-2018-1' END AS gr_ver_code
FROM  
datwgeel.t_metricgroupseries_megser 
JOIN datwgeel.t_groupseries_grser grser ON meg_gr_id = gr_id
JOIN datwgeel.t_series_ser AS tss ON grser_ser_id = ser_id
JOIN dateel.t_series_ser AS tss2 ON ser_code= ser_nameshort
WHERE meg_mty_id IN (18,19,20); --409

# Females WITH gr_gr_id series (subgroupsample)


INSERT INTO dateel.t_group_gr
(gr_id, 
gr_ser_id, 
gr_gr_id, 
gr_wkg_code,  
gr_spe_code, 
gr_sex_code, 
gr_lfs_code, 
gr_year, 
gr_number, 
gr_comment, 
gr_lastupdate,
gr_ver_code)
SELECT 
nextval('seq_group') AS gr_id, 
tss2.ser_id  AS gr_ser_id,
grser.gr_id AS gr_gr_id,
'WGEEL' AS gr_wkg_code,
'127186' AS gr_spe_code,
'F' AS gr_sex_code,
tss.ser_lfs_code AS gr_lfs_code,
gr_year,
gr_number,
gr_comment,
gr_lastupdate,
CASE WHEN gr_dts_datasource = 'dc_2019' THEN 'WGEEL-2019-1'
     WHEN gr_dts_datasource = 'dc_2020' THEN 'WGEEL-2020-1'
     WHEN gr_dts_datasource ='dc_2021' THEN 'WGEEL-2021-1'
     WHEN gr_dts_datasource ='dc_2022' THEN 'WGEEL-2022-1'
     WHEN gr_dts_datasource ='dc_2023' THEN 'WGEEL-2023-1'
     WHEN gr_dts_datasource ='dc_2024' THEN 'WGEEL-2024-1'
     ELSE 'WGEEL-2018-1' END AS gr_ver_code
FROM  
datwgeel.t_metricgroupseries_megser 
JOIN datwgeel.t_groupseries_grser grser ON meg_gr_id = gr_id
JOIN datwgeel.t_series_ser AS tss ON grser_ser_id = ser_id
JOIN dateel.t_series_ser AS tss2 ON ser_code= ser_nameshort
WHERE meg_mty_id IN (21,22,23); --553

# males from sampling


INSERT INTO dateel.t_group_gr
(gr_id, 
gr_ser_id, 
gr_gr_id, 
gr_wkg_code,  
gr_spe_code, 
gr_sex_code, 
gr_lfs_code, 
gr_year, 
gr_number, 
gr_comment, 
gr_lastupdate,
gr_ver_code)
SELECT 
nextval('seq_group') AS gr_id, 
tss2.ser_id  AS gr_ser_id,
grsa.gr_id AS gr_gr_id,
'WGEEL' AS gr_wkg_code,
'127186' AS gr_spe_code,
'M' AS gr_sex_code,
grsa_lfs_code,
gr_year,
gr_number,
gr_comment,
gr_lastupdate,
CASE WHEN gr_dts_datasource = 'dc_2019' THEN 'WGEEL-2019-1'
     WHEN gr_dts_datasource = 'dc_2020' THEN 'WGEEL-2020-1'
     WHEN gr_dts_datasource ='dc_2021' THEN 'WGEEL-2021-1'
     WHEN gr_dts_datasource ='dc_2022' THEN 'WGEEL-2022-1'
     WHEN gr_dts_datasource ='dc_2023' THEN 'WGEEL-2023-1'
     WHEN gr_dts_datasource ='dc_2024' THEN 'WGEEL-2024-1'
     ELSE 'WGEEL-2018-1' END AS gr_ver_code
FROM  
datwgeel.t_metricgroupsamp_megsa 
JOIN datwgeel.t_groupsamp_grsa  grsa ON meg_gr_id = gr_id
JOIN datwgeel.t_samplinginfo_sai AS tss ON grsa_sai_id = sai_id
JOIN dateel.t_series_ser AS tss2 ON ser_code=  sai_id::text
WHERE meg_mty_id IN (18,19,20); --544

# Females from sampling


INSERT INTO dateel.t_group_gr
(gr_id, 
gr_ser_id, 
gr_gr_id, 
gr_wkg_code,  
gr_spe_code, 
gr_sex_code, 
gr_lfs_code, 
gr_year, 
gr_number, 
gr_comment, 
gr_lastupdate,
gr_ver_code)
SELECT 
nextval('seq_group') AS gr_id, 
tss2.ser_id  AS gr_ser_id,
grsa.gr_id AS gr_gr_id,
'WGEEL' AS gr_wkg_code,
'127186' AS gr_spe_code,
'F' AS gr_sex_code,
grsa_lfs_code AS gr_lfs_code,
gr_year,
gr_number,
gr_comment,
gr_lastupdate,
CASE WHEN gr_dts_datasource = 'dc_2019' THEN 'WGEEL-2019-1'
     WHEN gr_dts_datasource = 'dc_2020' THEN 'WGEEL-2020-1'
     WHEN gr_dts_datasource ='dc_2021' THEN 'WGEEL-2021-1'
     WHEN gr_dts_datasource ='dc_2022' THEN 'WGEEL-2022-1'
     WHEN gr_dts_datasource ='dc_2023' THEN 'WGEEL-2023-1'
     WHEN gr_dts_datasource ='dc_2024' THEN 'WGEEL-2024-1'
     ELSE 'WGEEL-2018-1' END AS gr_ver_code
FROM  
datwgeel.t_metricgroupsamp_megsa 
JOIN datwgeel.t_groupsamp_grsa  grsa ON meg_gr_id = gr_id
JOIN datwgeel.t_samplinginfo_sai AS tss ON grsa_sai_id = sai_id
JOIN dateel.t_series_ser AS tss2 ON ser_code=  sai_id::text
WHERE meg_mty_id IN (21,22,23); --1183

6.5 Creating ind traits

SQL code to import data tables
DROP TABLE IF EXISTS datnas.t_fish_fi;
CREATE TABLE datnas.t_fish_fi (
  CONSTRAINT fk_fi_ser_id FOREIGN KEY (fi_ser_id)
  REFERENCES datnas.t_series_ser (ser_id) 
  ON UPDATE CASCADE ON DELETE CASCADE, 
  CONSTRAINT fk_fi_wkg_code  FOREIGN KEY (fi_wkg_code)
  REFERENCES ref.tr_icworkinggroup_wkg(wkg_code)
  ON UPDATE CASCADE ON DELETE RESTRICT,
  CONSTRAINT t_fish_fi_pkey PRIMARY KEY (fi_id, fi_wkg_code),
  CONSTRAINT fk_fi_spe_code FOREIGN KEY (fi_spe_code) 
  REFERENCES ref.tr_species_spe(spe_code) 
  ON UPDATE CASCADE ON DELETE RESTRICT,
  CONSTRAINT fk_fi_lfs_code_fi_spe_code FOREIGN KEY (fi_lfs_code, fi_spe_code)
  REFERENCES ref.tr_lifestage_lfs (lfs_code, lfs_spe_code) 
  ON UPDATE CASCADE ON DELETE RESTRICT, 
  CONSTRAINT ck_fi_date_fi_year CHECK (((fi_date IS NOT NULL) OR (fi_year IS NOT NULL))),
  CONSTRAINT fk_gr_ver_code FOREIGN KEY (fi_ver_code)
  REFERENCES refnas.tr_version_ver(ver_code)
  ON UPDATE CASCADE ON DELETE RESTRICT  
) INHERITS (dat.t_fish_fi);
 

GRANT ALL ON datnas.t_fish_fi TO diaspara_admin;
GRANT SELECT ON datnas.t_fish_fi TO diaspara_read;  

GRANT ALL ON SEQUENCE t_fish_fi_fi_id_seq TO diaspara_admin;    
Table 58: Table t_fish_fi, fish table
fi_id fi_ser_id fi_wkg_code fi_spe_code fi_lfs_code fi_date fi_year fi_comment fi_lastupdate fi_idsource fi_ver_code fi_x_4326 fi_y_4326 fi_geom
5932 a7650209-3817-4ced-85bb-4654aef393ec WGNAS 127186 A 1984-04-19 1984 Captured in a downstream trap. Likely to be a kelt on it's post-spawning downstream migration 2026-01-06 10302 DIASPARA-2025-1 -9.5833 53.9333 0101000020E61000007B832F4CA62A23C0ACADD85F76F74A40
5933 a7650209-3817-4ced-85bb-4654aef393ec WGNAS 127186 A 1984-04-19 1984 Captured in a downstream trap. Likely to be a kelt on it's post-spawning downstream migration 2026-01-06 10303 DIASPARA-2025-1 -9.5833 53.9333 0101000020E61000007B832F4CA62A23C0ACADD85F76F74A40
5934 a7650209-3817-4ced-85bb-4654aef393ec WGNAS 127186 A 1984-04-19 1984 Captured in a downstream trap. Likely to be a kelt on it's post-spawning downstream migration 2026-01-06 10304 DIASPARA-2025-1 -9.5833 53.9333 0101000020E61000007B832F4CA62A23C0ACADD85F76F74A40
5935 a7650209-3817-4ced-85bb-4654aef393ec WGNAS 127186 A 1984-04-19 1984 Captured in a downstream trap. Likely to be a kelt on it's post-spawning downstream migration 2026-01-06 10306 DIASPARA-2025-1 -9.5833 53.9333 0101000020E61000007B832F4CA62A23C0ACADD85F76F74A40
5936 a7650209-3817-4ced-85bb-4654aef393ec WGNAS 127186 A 1984-04-19 1984 Captured in a downstream trap. Likely to be a kelt on it's post-spawning downstream migration 2026-01-06 10308 DIASPARA-2025-1 -9.5833 53.9333 0101000020E61000007B832F4CA62A23C0ACADD85F76F74A40
5937 a7650209-3817-4ced-85bb-4654aef393ec WGNAS 127186 A 1984-04-19 1984 Captured in a downstream trap. Likely to be a kelt on it's post-spawning downstream migration 2026-01-06 10309 DIASPARA-2025-1 -9.5833 53.9333 0101000020E61000007B832F4CA62A23C0ACADD85F76F74A40
5938 a7650209-3817-4ced-85bb-4654aef393ec WGNAS 127186 A 1984-04-19 1984 Captured in a downstream trap. Likely to be a kelt on it's post-spawning downstream migration 2026-01-06 10310 DIASPARA-2025-1 -9.5833 53.9333 0101000020E61000007B832F4CA62A23C0ACADD85F76F74A40
5939 a7650209-3817-4ced-85bb-4654aef393ec WGNAS 127186 A 1984-04-19 1984 Captured in a downstream trap. Likely to be a kelt on it's post-spawning downstream migration 2026-01-06 10311 DIASPARA-2025-1 -9.5833 53.9333 0101000020E61000007B832F4CA62A23C0ACADD85F76F74A40
5940 a7650209-3817-4ced-85bb-4654aef393ec WGNAS 127186 A 1984-04-19 1984 Captured in a downstream trap. Likely to be a kelt on it's post-spawning downstream migration 2026-01-06 10312 DIASPARA-2025-1 -9.5833 53.9333 0101000020E61000007B832F4CA62A23C0ACADD85F76F74A40
5941 a7650209-3817-4ced-85bb-4654aef393ec WGNAS 127186 A 1984-04-19 1984 Captured in a downstream trap. Likely to be a kelt on it's post-spawning downstream migration 2026-01-06 10313 DIASPARA-2025-1 -9.5833 53.9333 0101000020E61000007B832F4CA62A23C0ACADD85F76F74A40
5942 a7650209-3817-4ced-85bb-4654aef393ec WGNAS 127186 A 1984-04-19 1984 Captured in a downstream trap. Likely to be a kelt on it's post-spawning downstream migration 2026-01-06 10314 DIASPARA-2025-1 -9.5833 53.9333 0101000020E61000007B832F4CA62A23C0ACADD85F76F74A40
5943 a7650209-3817-4ced-85bb-4654aef393ec WGNAS 127186 A 1984-04-19 1984 Captured in a downstream trap. Likely to be a kelt on it's post-spawning downstream migration 2026-01-06 10316 DIASPARA-2025-1 -9.5833 53.9333 0101000020E61000007B832F4CA62A23C0ACADD85F76F74A40
5944 a7650209-3817-4ced-85bb-4654aef393ec WGNAS 127186 A 1984-04-19 1984 Captured in a downstream trap. Likely to be a kelt on it's post-spawning downstream migration 2026-01-06 10317 DIASPARA-2025-1 -9.5833 53.9333 0101000020E61000007B832F4CA62A23C0ACADD85F76F74A40
5945 a7650209-3817-4ced-85bb-4654aef393ec WGNAS 127186 A 1984-04-19 1984 Captured in a downstream trap. Likely to be a kelt on it's post-spawning downstream migration 2026-01-06 10318 DIASPARA-2025-1 -9.5833 53.9333 0101000020E61000007B832F4CA62A23C0ACADD85F76F74A40
5946 a7650209-3817-4ced-85bb-4654aef393ec WGNAS 127186 A 1984-04-19 1984 Captured in a downstream trap. Likely to be a kelt on it's post-spawning downstream migration 2026-01-06 10319 DIASPARA-2025-1 -9.5833 53.9333 0101000020E61000007B832F4CA62A23C0ACADD85F76F74A40
5947 a7650209-3817-4ced-85bb-4654aef393ec WGNAS 127186 A 1984-04-19 1984 Captured in a downstream trap. Likely to be a kelt on it's post-spawning downstream migration 2026-01-06 10320 DIASPARA-2025-1 -9.5833 53.9333 0101000020E61000007B832F4CA62A23C0ACADD85F76F74A40
5948 a7650209-3817-4ced-85bb-4654aef393ec WGNAS 127186 A 1984-04-19 1984 Captured in a downstream trap. Likely to be a kelt on it's post-spawning downstream migration 2026-01-06 10322 DIASPARA-2025-1 -9.5833 53.9333 0101000020E61000007B832F4CA62A23C0ACADD85F76F74A40
5949 a7650209-3817-4ced-85bb-4654aef393ec WGNAS 127186 A 1984-04-19 1984 Captured in a downstream trap. Likely to be a kelt on it's post-spawning downstream migration 2026-01-06 10324 DIASPARA-2025-1 -9.5833 53.9333 0101000020E61000007B832F4CA62A23C0ACADD85F76F74A40
5950 a7650209-3817-4ced-85bb-4654aef393ec WGNAS 127186 A 1984-04-19 1984 Captured in a downstream trap. Likely to be a kelt on it's post-spawning downstream migration 2026-01-06 10325 DIASPARA-2025-1 -9.5833 53.9333 0101000020E61000007B832F4CA62A23C0ACADD85F76F74A40
5951 a7650209-3817-4ced-85bb-4654aef393ec WGNAS 127186 A 1984-04-19 1984 Captured in a downstream trap. Likely to be a kelt on it's post-spawning downstream migration 2026-01-06 10326 DIASPARA-2025-1 -9.5833 53.9333 0101000020E61000007B832F4CA62A23C0ACADD85F76F74A40

6.5.1 Referential for numeric traits (refnas.tr_traitnumeric_trn)

SQL code to create table refnas.tr_traitnumeric_trn
DROP TABLE IF EXISTS refnas.tr_traitnumeric_trn;
CREATE TABLE refnas.tr_traitnumeric_trn(  
  CONSTRAINT uk_refnas_num_tra_id UNIQUE (tra_id),
  CONSTRAINT uk_refnas_tra_code UNIQUE(tra_code),
  CONSTRAINT fk_tra_wkg_code  FOREIGN KEY (tra_wkg_code)
  REFERENCES ref.tr_icworkinggroup_wkg(wkg_code)
  ON UPDATE CASCADE ON DELETE RESTRICT,
  CONSTRAINT fk_tra_spe_code  FOREIGN KEY (tra_spe_code)
  REFERENCES ref.tr_species_spe(spe_code)
  ON UPDATE CASCADE ON DELETE RESTRICT, 
  CONSTRAINT fk_trn_uni_code FOREIGN KEY (trn_uni_code) 
  REFERENCES ref.tr_units_uni(uni_code)  
  ON UPDATE CASCADE ON DELETE CASCADE,
  CONSTRAINT uk_trn_code UNIQUE (tra_code)
) INHERITS  (ref.tr_traitnumeric_trn);

COMMENT ON COLUMN refnas.tr_traitnumeric_trn.tra_id IS
 'Integer, id of the trait';
COMMENT ON COLUMN refnas.tr_traitnumeric_trn.tra_code IS 
'Name of the trait';
COMMENT ON COLUMN refnas.tr_traitnumeric_trn.tra_description IS
 'Description of the fish trait';
COMMENT ON COLUMN refnas.tr_traitnumeric_trn.tra_indivorgroup IS
 'Is the metric a Group metric (group), or Individual metric (individual) 
or can be used in both tables (both) ?';
COMMENT ON COLUMN refnas.tr_traitnumeric_trn.trn_uni_code IS
 'Unit used, references tr_unit_uni';
COMMENT ON COLUMN refnas.tr_traitnumeric_trn.trn_minvalue IS
 'Minimum allowed value';
COMMENT ON COLUMN refnas.tr_traitnumeric_trn.trn_maxvalue IS 
'Maximum allowed value';


GRANT ALL ON refnas.tr_traitnumeric_trn TO diaspara_admin;
GRANT SELECT ON refnas.tr_traitnumeric_trn TO diaspara_read; 
Code to import numeric trait.
#tra <- dbGetQuery(con_diaspara, "SELECT * FROM ref.tr_traitnumeric_trn;")
# we will include group trait names later
# tra <- tra[tra$tra_id %in% c(1,2),]
# tra$tra_wkg_code <- "WGNAS"
# tra$tra_spe_code = "127186"


# df_to_tribble_code <- function(df) {
#   stopifnot(requireNamespace("tibble", quietly = TRUE))
  
  
#   cols <- names(df)
#   header <- paste0("tibble::tribble(\n  ~", paste(cols, collapse = ", ~"), ",\n")
  
#   row_lines <- apply(df, 1, function(row) {
#     vals <- Map(function(val) {
#       if (is.character(val)) {
#         dquote(val)
#       } else if (is.factor(val)) {
#         sprintf("%s", as.character(val))
#       } else if (is.logical(val)) {
#         ifelse(is.na(val), "NA", ifelse(val, "TRUE", "FALSE"))
#       } else if (is.numeric(val)) {
#         ifelse(is.na(val), "NA_real_", as.character(val))
#       } else if (inherits(val, "Date")) {
#         sprintf("as.Date("%s")", format(val, "%Y-%m-%d"))
#       } else if (inherits(val, "POSIXt")) {
#         sprintf("as.POSIXct("%s", tz = "%s")",
#                 format(val, "%Y-%m-%d %H:%M:%S"),
#                 attr(val, "tzone") %||% "UTC")
#       } else if (is.na(val)) {
#         "NA"
#       } else {
#         # Fallback to dput for unsupported types in a cell
#         paste(capture.output(dput(val)), collapse = "")
#       }
#     }, row)
#     paste0("  ", paste(vals, collapse = ", "), ",")
#   })
  
#   body <- paste(row_lines, collapse = "\n")
#   paste0(header, body, "\n)")
# }

# # Example
# library(tibble)
# df_to_tribble_code(tra)

tranum <- tibble::tribble(
  ~tra_id, ~tra_code, ~tra_description, ~tra_wkg_code, 
  ~tra_spe_code,  ~tra_indivorgroup, ~tra_qualitativeornumeric,
  ~trn_uni_code, ~trn_minvalue, ~trn_maxvalue,
  1, "Length_mm", 
  "Total body length in millimeters (mm) or mean total body length for group", 
  "WGNAS", "127186", "Both", "Numeric",
  "mm", NA, NA,
  2, "Weightg", "Weight (g) or mean weight for group", "WGNAS", 
  "127186", "Both", "Numeric",
  "g", NA, NA,
  3, "FreshwaterAge_year", 
  "Age at capture for juveniles or smolt age for adults in years. An individual aged in the same year as birth is 0.", 
  "WGNAS", "127186", "Both", "Numeric",
  "nr year", NA, NA,
  4, "SeaAge_year", 
  "Sea age at capture in years. Leave blank for juveniles.  An individual aged in the same year as its transition to salt water is 0", 
  "WGNAS", "127186", "Both", "Numeric", 
  "nr year", NA, NA,
  5, 
  "TotAge_year", 
  "Sea age at capture in years. Leave blank for juveniles. An individual aged in the same year as its transition to salt water is 0", 
  "WGNAS", "127186", "Both", "Numeric", 
  "nr year", NA, NA,  
  6, "ScalRad_mm", 
  "Scale reading radius in mm, if used provide a code for the ScalAnnCode method", 
  "WGNAS", "127186", "Individual", "Numeric", 
  "mm", NA, NA,  
  7, "Fec_negg", 
  "Fecundity in number of eggs", 
  "WGNAS", "127186", "Both", "Numeric",
   "nr", NA, NA,
  8, "Fec_uncertainty_sd",
  "Uncertainty in fecundity resulting from measures of egg samples. Standard deviation", 
  "WGNAS", "127186", "Both", "Numeric",
  "nr", NA, NA,
  9, "FemaleProportion", 
  "Proportion of female (in numbers) between 0 (all males) and 1 (all females).", 
  "WGNAS", "127186", "Group", "Numeric",
  )

tranum$trn_minvalue <- as.numeric(tranum$trn_minvalue)
tranum$trn_maxvalue <- as.numeric(tranum$trn_maxvalue)
dbWriteTable(con_diaspara_admin, "tr_traitnumeric_trn_temp", tranum, overwrite =TRUE)
dbExecute(con_diaspara_admin, "DELETE FROM refnas.tr_traitnumeric_trn")
dbExecute(con_diaspara_admin, "INSERT INTO refnas.tr_traitnumeric_trn(
tra_id,
tra_code,
tra_wkg_code,
tra_spe_code,
tra_description,
tra_indivorgroup,
trn_uni_code,
tra_qualitativeornumeric,
trn_minvalue,
trn_maxvalue)
SELECT 
tra_id,
tra_code,
tra_wkg_code,
tra_spe_code,
tra_description,
tra_indivorgroup,
trn_uni_code,
tra_qualitativeornumeric,
trn_minvalue::numeric,
trn_maxvalue::numeric
 FROM tr_traitnumeric_trn_temp") #8
Table 59: Quantitative parameters parameters

6.5.2 Referential for qualitative traits (refnas.tr_traitqualitative_trq)

SQL code to create table refnas.tr_traitqualitative_trq

DROP TABLE IF EXISTS refnas.tr_traitqualitative_trq;
CREATE TABLE refnas.tr_traitqualitative_trq (
  CONSTRAINT uk_refnas_qal_tra_id UNIQUE (tra_id),
  CONSTRAINT uk_refnas_qal_tra_code UNIQUE(tra_code),
  CONSTRAINT fk_tra_wkg_code  FOREIGN KEY (tra_wkg_code)
  REFERENCES ref.tr_icworkinggroup_wkg(wkg_code)
  ON UPDATE CASCADE ON DELETE RESTRICT,
  CONSTRAINT fk_tra_spe_code  FOREIGN KEY (tra_spe_code)
  REFERENCES ref.tr_species_spe(spe_code)
  ON UPDATE CASCADE ON DELETE RESTRICT
  ) INHERITS (ref.tr_traitqualitative_trq);


COMMENT ON TABLE refnas.tr_traitqualitative_trq IS 
'Table of qualitative trait parameters';

GRANT ALL ON refnas.tr_traitqualitative_trq TO diaspara_admin;
GRANT SELECT ON refnas.tr_traitqualitative_trq TO diaspara_read; 

Code to import qualitative trait.
traqal <- tibble::tribble(
  ~tra_id, ~tra_code, ~tra_description, ~tra_wkg_code, 
  ~tra_spe_code,  ~tra_indivorgroup, ~tra_qualitativeornumeric,
  1, "Sex", 
  "Sex (F Female,H Hermaphordite, I Immature attempt made, M Male, T Transitional, U Undetermined no attempt made, X Mixed)", 
  "WGNAS", "127186", "Individual", "Qualitative",

  2, "AdiposeFinPresence", "Presence of adipose fin (0 = absent (reared), 1=present (wild))", "WGNAS", 
  "127186", "Individual", "Numeric"    
  )


dbWriteTable(con_diaspara_admin, "tr_traitqualitative_trq_temp", traqal, overwrite =TRUE)
dbExecute(con_diaspara_admin, "DELETE FROM refnas.tr_traitqualitative_trq")
dbExecute(con_diaspara_admin, "INSERT INTO refnas.tr_traitqualitative_trq(
tra_id,
tra_code,
tra_wkg_code,
tra_spe_code,
tra_description,
tra_indivorgroup,
tra_qualitativeornumeric
)
SELECT 
tra_id,
tra_code,
tra_wkg_code,
tra_spe_code,
tra_description,
tra_indivorgroup,
tra_qualitativeornumeric
 FROM tr_traitqualitative_trq_temp") #2
Table 60: Quantitative parameters parameters
tra_id tra_code tra_description tra_wkg_code tra_spe_code tra_indivorgroup tra_qualitativeornumeric
1 Sex Sex (F Female,H Hermaphordite, I Immature attempt made, M Male, T Transitional, U Undetermined no attempt made, X Mixed) WGNAS 127186 Individual Qualitative
2 PresenceAdiposeFin Presence of adipose fin (0 = absent (reared), 1=present (wild)) WGNAS 127186 Individual Numeric

6.5.3 Values of Qualitative fish trait (tr_traitvaluequal_trv)

SQL code to create tables refnas.tr_traitvaluequal_trv and refeel.tr_traitvaluequal_trv


DROP TABLE IF EXISTS refnas.tr_traitvaluequal_trv CASCADE;
CREATE TABLE refnas.tr_traitvaluequal_trv(
  CONSTRAINT uk_trv_id UNIQUE (trv_id),
  CONSTRAINT fk_trv_trq_code 
  FOREIGN KEY (trv_trq_code)
    REFERENCES refnas.tr_traitqualitative_trq(tra_code)
      ON UPDATE CASCADE ON DELETE CASCADE,
  CONSTRAINT uk_refnas_trv_code UNIQUE (trv_code, trv_trq_code)
) INHERITS (ref.tr_traitvaluequal_trv);


COMMENT ON COLUMN refnas.tr_traitvaluequal_trv.trv_id IS
 'Integer, id of the qualitative used';
COMMENT ON COLUMN refnas.tr_traitvaluequal_trv.trv_code IS
 'Code of the qualitative trait';
COMMENT ON COLUMN refnas.tr_traitvaluequal_trv.trv_description IS
 'Description of the method';

GRANT ALL ON refnas.tr_traitvaluequal_trv TO diaspara_admin;
GRANT SELECT ON refnas.tr_traitvaluequal_trv TO diaspara_read; 
Table 61: Table of possible qualitative trait values
Code to import trait values for qualitative parm.
#trve <- dbGetQuery(con_diaspara, "SELECT * FROM ref.tr_traitvaluequal_trv;")
trqn <- dbGetQuery(con_diaspara, "SELECT * FROM refnas.tr_traitqualitative_trq;")
#clipr::write_clip(colnames(trv))
trv <-  data.frame(
  "trv_id"=1:12,
  "trv_trq_code"=c(
    rep(trqn$tra_code[1],7),
    rep(trqn$tra_code[2],5)
    ),
  "trv_code"=c(
    c("F","I","M","T","U","X","H"), 
    c("Y","N","P","NA","U")
    ),
  "trv_description" = c(
    c("Female",
    "Immature - attempt made but sex could not be destinguished",
  "Male",
  "Transitional", 
  "Undetermined - no attempt made",
  "Mixed",
  "Hermaphrodite"
  ),
  c("Yes","No", "Probable","Not Applicable", "Unknown")
  ),
  "trv_spe_code" = "127186",
  "trv_wkg_code" = "WGNAS"
)
dbWriteTable(con_diaspara_admin, "tr_traitvaluequal_trv_temp", trv,
             overwrite =TRUE)
dbExecute(con_diaspara_admin, "DELETE FROM refnas.tr_traitvaluequal_trv");
dbExecute(con_diaspara_admin, "INSERT INTO refnas.tr_traitvaluequal_trv (
trv_id,
trv_trq_code,
trv_code,
trv_description,
trv_spe_code,
trv_wkg_code)
SELECT 
trv_id,
trv_trq_code,
trv_code,
trv_description,
trv_spe_code,
trv_wkg_code
 FROM tr_traitvaluequal_trv_temp;") #12
Code to show trait value table.
dbGetQuery(con_diaspara, "SELECT * FROM refnas.tr_traitvaluequal_trv;") |>
  knitr::kable() |>
  kable_styling(bootstrap_options = c("striped", "hover", "condensed"))
Table 62: Values for qualitative parameters
trv_id trv_trq_code trv_code trv_description trv_spe_code trv_wkg_code
1 Sex F Female 127186 WGNAS
2 Sex I Immature - attempt made but sex could not be destinguished 127186 WGNAS
3 Sex M Male 127186 WGNAS
4 Sex T Transitional 127186 WGNAS
5 Sex U Undetermined - no attempt made 127186 WGNAS
6 Sex X Mixed 127186 WGNAS
7 Sex H Hermaphrodite 127186 WGNAS
8 PresenceAdiposeFin Y Yes 127186 WGNAS
9 PresenceAdiposeFin N No 127186 WGNAS
10 PresenceAdiposeFin P Probable 127186 WGNAS
11 PresenceAdiposeFin NA Not Applicable 127186 WGNAS
12 PresenceAdiposeFin U Unknown 127186 WGNAS

6.5.4 Referential for trait methods (refnas.tr_traitmethod_trm)

SQL code to create table refnas.tr_traitmethod_trm
DROP TABLE IF EXISTS refnas.tr_traitmethod_trm;
CREATE TABLE refnas.tr_traitmethod_trm (
  CONSTRAINT uk_refnas_tm_id UNIQUE (trm_id),
  CONSTRAINT uk_refnas_tm_code UNIQUE (trm_code),
  CONSTRAINT fk_trm_wkg_code  FOREIGN KEY (trm_wkg_code)
  REFERENCES ref.tr_icworkinggroup_wkg(wkg_code)
  ON UPDATE CASCADE ON DELETE RESTRICT,
  CONSTRAINT fk_trm_spe_code  FOREIGN KEY (trm_spe_code)
  REFERENCES ref.tr_species_spe(spe_code)
  ON UPDATE CASCADE ON DELETE RESTRICT,
  CONSTRAINT uk_trm_code UNIQUE (trm_code)
) INHERITS (ref.tr_traitmethod_trm);


COMMENT ON TABLE refnas.tr_traitmethod_trm IS 
'Table of method used to obtain a trait metric';
COMMENT ON COLUMN refnas.tr_traitmethod_trm.trm_id IS 
'Integer, id of the method used';
COMMENT ON COLUMN refnas.tr_traitmethod_trm.trm_code IS 
'Name of the method used';
COMMENT ON COLUMN refnas.tr_traitmethod_trm.trm_wkg_code IS 
'Working group code';
COMMENT ON COLUMN refnas.tr_traitmethod_trm.trm_spe_code IS 
'Species code';
COMMENT ON COLUMN refnas.tr_traitmethod_trm.trm_description IS 
'Description of the method';



GRANT ALL ON refnas.tr_traitmethod_trm TO diaspara_admin;
GRANT SELECT ON refnas.tr_traitmethod_trm TO diaspara_read; 
Code to import trait method.
trm <- tibble::tribble(
  ~trm_id, ~trm_code, ~trm_description, ~trm_wkg_code, 
  ~trm_spe_code,
  1, "GonadalInspection", 
  "Sex (F Female,H Hermaphordite, I Immature attempt made, M Male, T Transitional, U Undetermined no attempt made, X Mixed)", 
  "WGNAS", "127186", "Individual", "Qualitative",

  2, "PresenceAdiposeFin", "Presence of adipose fin (0 = absent (reared), 1=present (wild))", "WGNAS", 
  "127186", "Individual", "Numeric"    
  )

  6, 
  "ScalAnnCode", 
  "Scale reading annulus code for identifying the type of the corresponding scale radius measurement:
   0 means that the measurement corresponds to an annulus of the fish, 
   1 means salt water check (freshwater to saltwater transition) 
   and 2 means that the radius is a measurement from the center to the edge of the scale (radius at capture)", 
  "WGNAS", "127186", "Both", "Numeric", 

6.5.5 Table t_indtrait_int

SQL code to create table datnas.t_indivtrait_int


GRANT ALL ON dat.t_indivtrait_int TO diaspara_admin;
GRANT SELECT ON dat.t_indivtrait_int TO diaspara_read; 

DROP TABLE IF EXISTS  datnas.t_indivtrait_int;
CREATE TABLE datnas.t_indivtrait_int (
 CONSTRAINT fk_int_ser_id FOREIGN KEY (int_ser_id)
    REFERENCES datnas.t_series_ser (ser_id) 
    ON UPDATE CASCADE ON DELETE CASCADE,
  CONSTRAINT fk_int_wkg_code  FOREIGN KEY (int_wkg_code)
  REFERENCES ref.tr_icworkinggroup_wkg(wkg_code)
  ON UPDATE CASCADE ON DELETE RESTRICT,
  CONSTRAINT fk_int_spe_code  FOREIGN KEY (int_spe_code)
  REFERENCES ref.tr_species_spe(spe_code)
  ON UPDATE CASCADE ON DELETE RESTRICT,
  CONSTRAINT fk_int_fi_id FOREIGN KEY (int_fi_id, int_wkg_code) 
  REFERENCES datnas.t_fish_fi(fi_id,fi_wkg_code) 
    ON UPDATE CASCADE ON DELETE CASCADE,
  CONSTRAINT fk_int_tra_code FOREIGN KEY (int_tra_code) 
  REFERENCES refnas.tg_trait_tra(tra_code)
  ON UPDATE CASCADE ON DELETE RESTRICT,
  CONSTRAINT fk_int_trv_tra_code FOREIGN KEY (int_trv_code, int_tra_code) 
  -- unlike in dat.t_indivtrait_int this one does not take ref TO wkgcode, no need AS we are in datnas
  REFERENCES refnas.tr_traitvaluequal_trv(trv_code, trv_trq_code)
  ON UPDATE CASCADE ON DELETE RESTRICT,
  CONSTRAINT fk_int_trm_code FOREIGN KEY (int_trm_code)
  REFERENCES refnas.tr_traitmethod_trm(trm_code)
  ON UPDATE CASCADE ON DELETE RESTRICT,
  CONSTRAINT fk_int_qal_id FOREIGN KEY (int_qal_code) 
  REFERENCES ref.tr_quality_qal(qal_code) ON UPDATE CASCADE,
  CONSTRAINT fk_int_ver_code FOREIGN KEY (int_ver_code)
  REFERENCES refnas.tr_version_ver(ver_code)
  ON UPDATE CASCADE ON DELETE RESTRICT,
  CONSTRAINT uk_trv_fi_id_trv_tra_code UNIQUE(int_fi_id,int_tra_code)
) INHERITS (dat.t_indivtrait_int);

CREATE INDEX datnas_t_indivtrait_int_idx ON datnas.t_indivtrait_int USING btree (int_fi_id);

GRANT ALL ON datnas.t_indivtrait_int TO diaspara_admin;
GRANT SELECT ON datnas.t_indivtrait_int TO diaspara_read; 


COMMENT ON TABLE datnas.t_indivtrait_int IS
 'Table joining fish and traits';
COMMENT ON COLUMN datnas.t_indivtrait_int.int_ser_id IS
 'Series UUID';
COMMENT ON COLUMN datnas.t_indivtrait_int.int_wkg_code IS
 'Working ind on of WGEEL, WGNAS, WGBAST ...';
COMMENT ON COLUMN datnas.t_indivtrait_int.int_spe_code IS
 'Species code here ''127186''';
COMMENT ON COLUMN datnas.t_indivtrait_int.int_id IS
 'ID, integer, unique for wkg_code';
COMMENT ON COLUMN datnas.t_indivtrait_int.int_fi_id IS
 'ID of the fish';
COMMENT ON COLUMN datnas.t_indivtrait_int.int_tra_code IS
 'Code of the trait, e.g. Lengthmm';
COMMENT ON COLUMN datnas.t_indivtrait_int.int_value IS
 'Value for numeric';
COMMENT ON COLUMN datnas.t_indivtrait_int.int_trv_code IS
 'Value for qualitative see refnas.tr_traitvaluequal_trv';
COMMENT ON COLUMN datnas.t_indivtrait_int.int_trm_code IS
 'Method see refnas.tr_traimethod_trm';
COMMENT ON COLUMN datnas.t_indivtrait_int.int_last_update IS 'date last update';
COMMENT ON COLUMN datnas.t_indivtrait_int.int_qal_code IS
 'Quality code references ref.tr_quality_qal';
COMMENT ON COLUMN datnas.t_indivtrait_int.int_ver_code IS
 'version e.g. WGEEL_2024_1';

-- TODO trigger on date
Code to import to to refnas.t_indivtrait_int
ind <- readxl::read_xlsx(file.path(datawd,
"../wgnas/burishoole.xlsx"),
sheet = "new_individual_metrics",
col_types = c("text", "text", rep("date",2),"numeric", "text", rep("numeric",2),
 rep("text", 2), rep("numeric",8), "text", rep("numeric",3), 
 "text", rep("numeric",2), rep("text", 2))
) 
ind <- janitor::clean_names(ind)




st_write(ind, con_diaspara, "temp_ind")

temp = dbGetQuery(con_diaspara,
"SELECT * FROM temp_ind join datnas.t_series_ser on ser_code = sai_name")

stopifnot(nrow(ind)==nrow(temp))


# fi <- dbGetQuery(con_diaspara, 
# "SELECT * FROM datnas.t_fish_fi")
# paste(colnames(fi), collapse= ", ")
fi <- data.frame(
fi_ser_id =temp$ser_id, 
fi_wkg_code = temp$ser_wkg_code, 
fi_spe_code = temp$ser_spe_code, 
fi_lfs_code = case_when(temp$fi_lfs_code == "S" ~ "A",
is.na(temp$fi_lfs_code) ~ "SM"),
fi_date = temp$fi_datecapture, 
 fi_year = year(temp$fi_datecapture), 
 fi_comment = temp$fi_comment, 
 fi_lastupdate = today(), 
 fi_idsource = temp$fi_id_cou, 
 fi_ver_code = "DIASPARA-2025-1",
 fi_x_4326 = temp$fisa_x_4326, 
 fi_y_4326 = temp$fisa_y_4326)


dbWriteTable(con_diaspara,  "temp_fi", fi, overwrite =TRUE)

# create verion for diaspara
dbExecute(con_diaspara_admin, "INSERT INTO datnas.t_fish_fi (
fi_ser_id, fi_wkg_code, fi_spe_code, fi_lfs_code, fi_date, fi_year, 
fi_comment, fi_lastupdate, fi_idsource, fi_ver_code, fi_x_4326, fi_y_4326)
SELECT 
fi_ser_id::uuid, fi_wkg_code, fi_spe_code, fi_lfs_code, fi_date, fi_year, 
fi_comment, fi_lastupdate, fi_idsource, fi_ver_code, fi_x_4326, fi_y_4326 
from temp_fi")  # 2965

# process fi_geom

dbExecute(con_diaspara_admin, "UPDATE datnas.t_fish_fi set fi_geom = 
ST_SetSRID(ST_MakePoint(fi_x_4326, fi_y_4326),4326)") # 2965

t_series_ser <-
data.frame(
"ser_id" = uuid::UUIDgenerate(n=nrow(ser)),
"ser_code" = ser$sai_name,
"ser_name"  = ser$sai_name,
"ser_spe_code" = "127186",
"ser_lfs_code" = ser$sai_lfs_code,
"ser_are_code" = ser$are_code, # got from spatial query
"ser_wkg_code" = "WGNAS",
"ser_ver_code" = "DIASPARA-2025-1",
"ser_cou_code" = ser$sai_cou_code,
"ser_hab_code" = NA, # TODO remove 
"ser_gea_code" = NA, # electric fishing
"ser_fiw_code" = NA,
"ser_mon_code" = NA,
"ser_uni_code" = "nr",
"ser_effort_uni_code" = NA,
"ser_description" = NA,
"ser_locationdescription" = NA, # TODO remove
"ser_wltyp_code" =  case_when(ser$sai_hty_code == "T" ~ "T",
ser$sai_hty_code == "C" ~ "MC",
ser$sai_hty_code == "F" ~ "FW",
ser$sai_hty_code == "MO" ~ "MO"),
"ser_stocking" = ser$"sai_riverorigin(0=reared,1=wild,2=mixed)" %in% c(0,2),
"ser_stockingcomment" = NA,
"ser_protocol" = ser$sai_protocol,
"ser_samplingstrategy" = ser$sai_samplingstrategy,
"ser_datarightsholder" = NA,
"ser_datelastupdate" = Sys.Date() #,
# geom
)

res <- dbWriteTable(con_diaspara, "t_series_ser_temp", 
t_series_ser, overwrite = TRUE)
dbExecute(con_diaspara_admin, "DELETE FROM  datnas.t_series_ser;")
dbExecute(con_diaspara_admin, "INSERT INTO datnas.t_series_ser 
SELECT distinct on (ser_code)
 ser_id::uuid,
 ser_code,
 ser_name,
 ser_spe_code,
 ser_lfs_code,
 ser_are_code::TEXT,
 ser_wkg_code,
 ser_ver_code,
 ser_cou_code,
 ser_hab_code,
 ser_gea_code,
 ser_fiw_code,
 ser_mon_code,
 ser_uni_code,
 ser_effort_uni_code,
 ser_description,
 ser_locationdescription,
 ser_wltyp_code,
 ser_stocking,
 ser_stockingcomment,
 ser_protocol,
 ser_samplingstrategy,
 ser_datarightsholder,
 ser_datelastupdate::date
FROM t_series_ser_temp") # 2
Table 63: Table t_indivtrait_int, fish trait table

7 Final diagram

8 Conclusions

A database was created for ICES working groups WGNAS, WGBAST, and WGEEL. It could easily have a similar format for WGTRUTTA and other working groups working with diadromous fish species, such as lampreys and shads. It will allow for the integration of data call files using ICES DATSU and more generally, interoperable with other ICES processes (e.g. TAF), tools and databases (e.g. RDBES). The habitat database is currently ported to RDBES and it has been proposed in RDBFIS to allow for the inclusion of data in the continental part of the range for migratory fishes.

Starting with the creation of formats for metrics in the summer 2025, this database will progressively be handed over to ICES. Since it was programmed in Postgres, some work will be required to match it with ICES SQL. In the long run, however, the use of a common database and ICES tools will:

  1. simplify the learning needs of experts and knowledge, when shifting between different diadromous expert and assessment groups,

  2. allow to provide a more streamlined data flow between national and international level (e.g., data calls), and enhance accessibility and interoperability, and

  3. allow to benefit from further support from ICES Data Center and ensure the long term maintenance of the system

The shift to the new database will start in 2026 for WGEEL (metric DB) and probably 2028 for WGNAS and WGBAST depending on ressources to make the change. Changing from one database to another system will break links in the R codes used in the assessment groups, and the codes will will need to be reviewed.

Breaking change for all working groups

From now on everywhere in the db: Atlantic salmon will be 127186 and eel 126281.

spe_code spe_commonname spe_scientificname
127186 Atlantic salmon Salmo salar
126413 Twait shad Alosa alosa
126415 Allis shad Alosa fallax
101174 Sea lamprey Petromyzon marinus
101172 European river lamprey Lampetra fluviatilis
126281 European eel Anguilla anguilla
127187 Sea trout Salmo trutta

Breaking change for WGEEL

To WGEEL values for quality, 3 (bad quality) and 4 (Warnings) have been inverted ! This means that all scripts will have to be adapted. Also 2 (modified by wgeel becomes 5).

CREATE A STEERING GROUP IN WGDIAD

The most important vocabularies have been checked the working groups and a draft of the stage referential has been created in ICES : DIASPARA : Diadromous fish life stage #885. However, as for some other new referential created in ICES, they will need to be validated. It was proposed during the final DIASPARA meeting that this steering group is created within WGDIAD to discuss these issues.

9 Acknowledgements and references

  • Data source : EuroGeographics and UN-FAO for countries
  • We would like to deeply thank ICES people, in particular Maria and Joana for their help, assistance when building the data structure and vocabularies, and also offer a special thank to Rui and Carlos for their support.

References

ICES. 2024a. ICES Vocabularies and Codes.” ICES Data Flow Schematics. https://doi.org/10.17895/ICES.PUB.25288189.V1.
———. 2024b. “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.
———. 2024c. “Working Group on Biological Parameters (WGBIOP, Outputs from 2023 Meeting),” January. https://doi.org/10.17895/ices.pub.24961410.v2.
 

EU is not reponsible for the content of the project