diaspara database creation script

DIASPARA WP3.2 working document

Creation of the migdb Migratory fishes database, version = build
Author

Briand Cédric, Oliviero Jules, Helminen Jani

Published

28-03-2025

The main structure of the database has been proposed during the online diaspara meeting : database structure. This stucture would allow to store the data necessary to run the international stock models for the different working groups working on diadromous fishes. The structure of the proposed database and the structure of the wgeel database are very similar. This documents creates the diaspara database, first creating referential table for the different types proposed, and then populates the database with the contents of the wgeel and wgnas database. All chunks are run sequentially to run the database, but some are later marked with eval = FALSE to speed up the process of running the quarto document.

Hierarchical structure of the database

The database could start with the simplest structure, with a basic table corresponding to all data. Then three tables could be created, one per species. This is to allow querying the different tables independently. From these species tables, three different tables could be produced, one for data, one for parameters outputs, one for parameters priors. Since SQL server does not handle inheritance, once the table built, some of those will have to be replaced with views or partitioned views.

From these three table on could envisage the creation of specific table for working groups. Meaning one table for eel (wgeel), one table for salmon (wgnas), one table for salmon (wgbast), and one table for trutta (wgtrutta).

Referential tables

[TO BE EDITED LATER WHEN WE KNOW EXACTLY WHAT WE HAVE DONE]

Similarly, referential tables could be created with a mother table from which specific (or wg specific) tables would inherit. All mother table will be held in a schema called ref. Having working group specific tables make the setting up of consistent foreign key more easy. For instance wgbast could reference different age class than wgnas, and the stage would be completely different between wgeel and wgnas reference daughter tables. Some of these referential table would be common between species (e.g. source from ICES vocab, which corresponds to working group or accession events (datacalls)).

Unicity constraints

Another important point to add (at least to the salmoglob database) is unicity constraint. As some values would be null, creating unicity constraints with indexes would be necessary. These allow to have different levels of constraints for instance the unicity would be defined for : (year, age, area, parameter) (year, age, parameter) (year, area, parameter) (year, parameter)

One of the table will have to contain twice the area it will have to be treated separately. (year, area, area, parameter)

Creating the diaspara database

All along this document, the database will be named diaspara. The database is created with postgres.

Some rules

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

  • Code ELE, ANG, TRT are capitalized, as are the working group names WGEEL, WGNAS, or country codes.

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

  • All integer used for primary keys are called id all text used for primary keys are called code, the text is always called description.

  • All tables end with a 3 letter summary which allows to identify the source of one column so the table dataaccess will be called tr_dataaccess_dta. And the column for code will be named

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

  • Foreign key are used instead of check constrainst as check constraint might not ensure the integrity of data after their integration (only when new rows are created or modified).

  • Foreign key are name fk_columnname where the column name is the name in the table

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

  • Other constraints are check constraints ck_columnname and unique contraints uk_columnname

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

  • Column and table name are ALWAYS LOWERCASE, the underscore is only used to separate type of table and table shortcode t_table_abc. In column is separates table code abc_def_code (table abc will reference the column def_code in table def).

This is run in localhost, check the wp3_habitat repository for code to set up access to the database. In the future we will grant diaspara_admin and diaspara_read to specific users for example with a used named trout GRANT diaspara_admin TO trout ;

DIASPARA Note to self

need to edit the pb_hba.conf on the server if not in localhost to allow access to diaspara.

Code to create the diaspara DB
dbExecute(con_diaspara_admin, "DROP schema if exists ref CASCADE;");
dbExecute(con_diaspara_admin, "CREATE schema ref;")
dbExecute(con_diaspara_admin, "GRANT ALL PRIVILEGES ON SCHEMA ref TO diaspara_admin ;")
dbExecute(con_diaspara_admin, "GRANT ALL PRIVILEGES ON SCHEMA public TO diaspara_read ;")
dbExecute(con_diaspara_admin, paste0("GRANT CONNECT ON DATABASE ",cred$dbnamediaspara," TO diaspara_read;"))
dbExecute(con_diaspara_admin, paste0("ALTER DATABASE ",cred$dbnamediaspara," OWNER TO diaspara_admin;"))
dbExecute(con_diaspara_admin, "DROP schema if exists refeel CASCADE;");
dbExecute(con_diaspara_admin, "CREATE SCHEMA refeel;")
dbExecute(con_diaspara_admin, "ALTER SCHEMA refeel OWNER TO diaspara_admin;")
dbExecute(con_diaspara_admin, "DROP schema if exists refnas CASCADE;");
dbExecute(con_diaspara_admin, "CREATE SCHEMA refnas;")
dbExecute(con_diaspara_admin, "ALTER SCHEMA refnas OWNER TO diaspara_admin;")
dbExecute(con_diaspara_admin, "DROP schema if exists refbast CASCADE;");
dbExecute(con_diaspara_admin, "CREATE SCHEMA refbast;")
dbExecute(con_diaspara_admin, "ALTER SCHEMA refbast OWNER TO diaspara_admin;")
dbExecute(con_diaspara_admin, "DROP schema if exists reftrutta CASCADE;");
dbExecute(con_diaspara_admin, "CREATE SCHEMA reftrutta;")
dbExecute(con_diaspara_admin, "ALTER SCHEMA reftrutta OWNER TO diaspara_admin;")

# Create foreign data wrapper to wgeel database

dbExecute(con_diaspara_admin, "CREATE EXTENSION IF NOT EXISTS postgres_fdw;")

dbExecute(con_diaspara_admin,"
CREATE SERVER wgeel_data_wrapper
  FOREIGN DATA WRAPPER postgres_fdw
  OPTIONS (host 'localhost', port '5432', dbname 'wgeel');")
dbExecute(con_diaspara_admin,"
CREATE SERVER wgnas_data_wrapper
  FOREIGN DATA WRAPPER postgres_fdw
  OPTIONS (host 'localhost', port '5432', dbname 'salmoglob');")
dbExecute(con_diaspara_admin,"
CREATE USER MAPPING FOR USER
  SERVER wgeel_data_wrapper
  OPTIONS (user 'postgres', password 'postgres');")
dbExecute(con_diaspara_admin,"  
CREATE SCHEMA refwgeel;")
dbExecute(con_diaspara_admin,"IMPORT FOREIGN SCHEMA ref    
    FROM SERVER wgeel_data_wrapper
    INTO refwgeel;")

dbExecute(con_diaspara_admin, paste0("COMMENT ON DATABASE ",cred$dbnamediaspara," IS 'This database is named Frankenstein :-)'"))    
dbExecute(con_diaspara_admin,
"GRANT ALL PRIVILEGES ON SCHEMA refwgeel TO diaspara_admin;")
SQL code to additional data schema
Listing 1: Building additional schema
--| echo: TRUE
--| eval: FALSE


-- this one is straight into sql ... 

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';

Now the database has been created with different schema (Figure 1). The main schema for dictionaries is ref, and a schema is created per working group for specific referential tables. The Schema refwgeel is a schema created with a foreign data wrapper to get the data from wgeel, the same schema exists for wgnas. We’ll see later for wgbast and wgtrutta.

schema ref ref        tr_species_spe        tr_country_cou        tr_icworkinggroup_wkg        tr_version_ver        tr_metric_mtr        tr_category_cat        tr_destination_dest        tr_metadata_met        tr_area_are refeel refeel                               refeel->ref dateel dateel                               dateel->ref dateel->refeel refbast refbast                               refbast->ref datbast datbast                               datbast->ref datbast->refbast refnas refnas                               refnas->ref datnas datnas                               datnas->ref datnas->refnas reftrutta reftrutta                               reftrutta->ref dattrutta dattrutta                               dattrutta->ref dattrutta->reftrutta refwgeel refwgeel refwgeel->ref refwgeel->refeel salmoglob salmoglob salmoglob->ref salmoglob->refnas
Figure 1: Structure of the schema in diaspara. Dashed arrow indicate an import of data from existing

Now the database has been created with different schema (Figure 1). The main schema for dictionaries is ref, and a schema is created per working group for specific referential tables. The Schema refwgeel has been filled in with a foreign data wrapper to get the data from wgeel, the same schema exists for wgnas. We’ll see later for wgbast and wgtrutta. The schema dat is the common schema for all data. For each working group, schema datbast, dateel, datnas are created. The tables will be created in dat and later similar or a bit more complex tables (with some more columns) will be created using the INHERIT FROM syntax, which will allow to have a hierarchical structure in the db, and maintain the structure in a table common to all fishes. Note thatdat should not containt any data, but will hold all the views and inherited tables comming from the different schema.

Creating referentials

Species (tr_species_spe)

The first thing is to create a referential table for species. Anyways, we searched a bit for other species, even if we don’t plan to start storing data on Alosa and Lamprey it’s good to prepare the database. There are no code in ICES vocal for Alosa alosa, Alosa fallax, Petromyzon marinus, Lampetra fluviatilis.

Note Cédric : Thinking later about this, I chose to get rid of ELE and select ANG. This column with species will be everywhere. We want to avoid generations of researchers to avoid what ELE is (apart from elephants). For the others I’ve taken as close as possible to the latin name.

QUESTION ICES: species code

ANG, ALA, ALF, PET, LAM are these internal code OK ? Should we use SpecWoRMS or is Aphia OK ?

ANSWER ICES : Maria

For species, we would recommend that you use AphiaIDs (a copy of which is SpecWoRMs). You can also use the FAO ASFIS list, or both, but we would recommend having the AphiaIDs for sure.

Creating a referential table for species - code and queries to ICES
# No code for Lampetra, Alosa, petromyzon
sp <- getCodeList("IC_Species")
grep("Lampetra", sp$description)
integer(0)
grep("Petromyzon", sp$description)
integer(0)
grep("Alosa",  sp$description)
integer(0)
bind_rows(
  ele <- getCodeDetail("IC_Species","ELE")$detail,
  sal <- getCodeDetail("IC_Species","SAL")$detail,
  trs <- getCodeDetail("IC_Species","TRS")$detail) %>%
knitr::kable(caption = "Codes for migratory species in ICES, no code found for other species (Lamprey, Alosa ...)") %>% kable_styling(bootstrap_options = c("striped", "hover", "condensed"))
if (file.exists("data/tr_species_spe_temp.Rdata")) {
  load("data/tr_species_spe_temp.Rdata") } else {
  species_list <- tibble(
    spe_code = c("SAL", "ANG", "TRT", "ALA", "ALF", "PET", "LAM"),
    spe_icspecieskey = c("SAL", "ELE", "TRT", 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
Key Description LongDescription Modified Deprecated
ELE Anguilla anguilla NA 2019-04-15 FALSE
SAL Salmo salar NA 2019-04-15 FALSE
TRS Salmo trutta NA 2019-04-15 FALSE
(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
dbExecute(con_diaspara_admin, "DROP TABLE IF EXISTS ref.tr_species_spe;")
dbExecute(con_diaspara_admin,"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)");
dbExecute(con_diaspara_admin, "GRANT ALL ON TABLE ref.tr_species_spe to diaspara_admin")
dbExecute(con_diaspara_admin, "GRANT SELECT ON TABLE ref.tr_species_spe to diaspara_read")
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 SAL, ANG, TRT, ALA, ALF, PET, LAM, with 
reference to ICES vocabularies.'")
Table 2: Working groups table in the diaspara DB
spe_code spe_commonnname spe_scientificname spe_codeaphia spe_description
SAL Atlantic salmon Salmo salar 127186 NA
TRT Sea trout Salmo trutta 127187 NA
ALA Twait shad Alosa alosa 126413 NA
ALF Allis shad Alosa fallax 126415 NA
SLP Sea lamprey Petromyzon marinus 101174 NA
RLP European river lamprey Lampetra fluviatilis 101172 NA
ANG European eel Anguilla anguilla 126281 NA

Working group (tr_icworkinggroup_wkg)

Species is not enough. Data will be split by working groups. Several working groups working on the same species. There is a table for working group. Proposed table is Table 3 but need confirmation for WKTRUTTA2.

QUESTION ICES/ WGTRUTTA/ DIASPARA

what is the latest working group for WGTRUTTA, I found a WKTRUTTA2 but that is quite old. Do we want to refer to other groups on diadromous fishes there ? The name of the WGEEL is wrong in the referential, needs to reference GFCM… JOINT EIFAAC/ICES/GFCM WORKING GROUP ON EEL.

Code to create reference table for working groups
dbExecute(con_diaspara_admin,
"DROP TABLE IF EXISTS ref.tr_icworkinggroup_wkg CASCADE;")
dbExecute(con_diaspara_admin,
"CREATE TABLE ref.tr_icworkinggroup_wkg (
wkg_code TEXT PRIMARY KEY,
wkg_description TEXT,
wkg_icesguid uuid,
wkg_stockkeylabel TEXT
);")

dbExecute(con_diaspara_admin, "COMMENT ON TABLE ref.tr_icworkinggroup_wkg 
IS 'Table corresponding to the IC_WorkingGroup referential;';")
# 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;")

dbExecute(con_diaspara_admin, "COMMENT ON COLUMN 
ref.tr_icworkinggroup_wkg.wkg_code IS 
'Working group code uppercase, WGEEL, WGNAS, WGBAST, WGTRUTTA';")


dbExecute(con_diaspara_admin, "GRANT ALL ON ref.tr_icworkinggroup_wkg 
          TO diaspara_admin;")
dbExecute(con_diaspara_admin, "GRANT SELECT ON ref.tr_icworkinggroup_wkg 
          TO diaspara_read;")
Table 3: Working groups table in the diaspara DB
wkg_code wkg_description wkg_icesguid wkg_stockkeylabel
WGBAST Baltic Salmon and Trout Assessment Working Group 2cac261d-c837-459a-961b-e63e36cc19ec sal.27.2231
WGEEL Joint EIFAAC/ICES Working Group on Eels 7c13a79e-7855-4d0b-b567-21300bcaaf9a ele.2737.nea
WGNAS Working Group in North Atlantic Salmon b5fd158e-b153-4e2e-a6da-c4b0536d684e sal.neac.all
WKTRUTTA NA NA NA

Country (tr_country_cou)

Countries are mostly OK in the wgeel database but we need to add american countries. The shapefiles have been downloaded from https://gisco-services.ec.europa.eu/distribution/v2/countries/download/#countries source EuroGeographics and UN-FAO. Countries (Table 4) are ordered from North to South starting from the Baltic and ending in the Mediterranean, with American number being the highest in order.

Code to create table from wgeel and NUTS
dbExecute(con_diaspara_admin, "DROP TABLE IF EXISTS ref.tr_country_cou;")
dbExecute(con_diaspara_admin, "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)
);")


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

dbExecute(con_diaspara_admin,"COMMENT ON TABLE ref.tr_country_cou IS
          'Table of country codes source EuroGeographics and UN-FAO.';")
dbExecute(con_diaspara_admin,"ALTER TABLE ref.tr_country_cou 
          OWNER TO diaspara_admin;")
dbExecute(con_diaspara_admin,
          "GRANT SELECT ON TABLE ref.tr_country_cou TO diaspara_read;")
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
US United States 49 USA
SJ Svalbard and Jan Mayen 49 SJM
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 2: Map of countries in the diaspara DB © EuroGeographics

Unit (tr_units_uni)

Creating the unit from wgeel and checking ICES code

First we import from wgeel

Then we standarize using ICES codes, it takes a while to scroll through the vocab. Sometimes several vocab are available for the same thing. We used the p06 as the most common source. Hopefully that was the right choices ?

dbExecute(con_diaspara_admin, "DROP TABLE IF EXISTS ref.tr_units_uni CASCADE;")

dbExecute(con_diaspara_admin,
"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)
);")

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')
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;")
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

Some of the values are missing from ICES vocab (Table Table 5).

QUESTION ICES: missing values for units, what do we do ?

What do we do with units without correspondance? These come from FAO (if I remember well). Do we try to search for those in the wgeel database, and then remove if not existing or try to change existing values ?

  • Kg/day there is a kg/hour do we need to change to that type and convert existing series ?

  • Nr haul There is a definition of haul in the ICES vocab but it seems very related to sampling box, basket. And it’s not the number of haul.

  • Before working any further I would like your opinion there.

Parameters

Parameters are a simple way to reduce the complexity of data. It will correspond to all nimble variables, reduced to their lower level (e.g. 3 dimensional arrays with dimensions [area, year, stage] will be translated as many lines with the corresponding values in columns area, year, and stage), and the identifyer of the variable will be used for all the lines necessary to store this dataset. In practise, parameters also correspond to input data, and output data in the model. The parameters will be described by their metadata as illustrated in Figure 3

Figure 3: Mind map of the metadata structure

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

There is a problem in the “order or the dimensions which need to be aligned. For instance a column can hold year, or age. This is not good. The description could be used within a type array. SQL server does not work with array so it’s not a good idea to use those.

Checking stock codes using icesASD and icesSD packages
# install.packages('icesASD', 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('icesASD')
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()
Table 6: Access to the advice using icesASD
adviceDOI stockCode assessmentYear
16 https://doi.org/10.17895/ices.advice.4825 ele.2737.nea 2019
799 https://doi.org/10.17895/ices.advice.19772374.v1 ele.2737.nea 2022
866 https://doi.org/10.17895/ices.pub.3440 ele.2737.nea 2017
975 https://doi.org/10.17895/ices.advice.7752 ele.2737.nea 2021
1014 https://doi.org/10.17895/ices.advice.5898 ele.2737.nea 2020
1048 https://doi.org/10.17895/ices.pub.4601 ele.2737.nea 2018
1311 https://doi.org/10.17895/ices.advice.21907860.v2 ele.2737.nea 2023
1402 https://doi.org/10.17895/ices.advice.27100516 ele.2737.nea 2024
StockDatabaseID StockKey StockKeyLabel StockKeyDescription PreviousStockKey PreviousStockKeyLabel ActiveYear SpeciesScientificName SpeciesCommonName EcoRegion ExpertGroup ExpertGroupDescription AdviceDraftingGroup AdviceDraftingGroupDescription DataCategory YearOfLastAssessment AssessmentFrequency YearOfNextAssessment AssessmentType AdviceReleaseDate AdviceCategory AdviceType UseOfDiscardsInAdvice PABufferApplied TrophicGuild FisheriesGuild SizeGuild Published GeneratedOn SectionNumber AssessmentKey ModifiedDate ModelType ModelName
149 2600 169241 sal.27.22-31 Salmon (Salmo salar) in subdivisions 22-31 (Baltic Sea, excluding the Gulf of Finland) 136678 sal-2431 2020 Salmo salar Salmon Baltic Sea WGBAST Assessment Working Group on Baltic Salmon and Trout RG/ADGSalmon Salmon Review and Advice Drafting Group 1 2019 1 2020 Analytical model, Bayesian state-space model for a majority of rivers in AUs 1–4 NA MSY Catches Assessment NA pelagic piscivore Pelagic large benthopelagic TRUE 2025-03-28T16:29:41.203+01:00 8.3.15 13726 2019-05-29T11:25:06.9+01:00 O Unknown
186 2590 169095 ele.2737.nea European eel (Anguilla anguilla) throughout its natural range 136527 ele-nea 2020 Anguilla anguilla Eel Arctic Ocean, Azores, Bay of Biscay and the Iberian Coast, Barents Sea, Baltic Sea, Celtic Seas, Faroes, Greenland Sea, Icelandic Waters, Greater North Sea, Norwegian Sea, Oceanic Northeast Atlantic WGEEL Joint EIFAAC/ICES/GFCM Working Group on Eels ADGEEL Eel Advice Drafting GRoup 3.14 2020 1 2021 Trends-based assessment NA PA No directed fisheries Not used No demersal benthivore Demersal medium demersal TRUE 2025-03-28T16:29:41.203+01:00 9.3.13 14025 2020-11-12T15:09:35.93+01:00 NA NA
187 2601 169242 sal.27.32 Salmon (Salmo salar) in Subdivision 32 (Gulf of Finland) 136679 sal-32 2020 Salmo salar Salmon Baltic Sea WGBAST Assessment Working Group on Baltic Salmon and Trout RG/ADGSalmon Salmon Review and Advice Drafting Group 3 2020 1 2021 Qualitative assessment based on monitored parr densities and expert judgement. NA PA Catches Topped up No pelagic piscivore Pelagic large benthopelagic TRUE 2025-03-28T16:29:41.203+01:00 8.3.16 13453 2020-11-12T12:12:48.513+01:00 O Unknown
236 2512 169291 trs.27.22-32 Sea trout (Salmo trutta) in subdivisions 22-32 (Baltic Sea) 136729 trt-bal 2020 Salmo trutta Sea trout Baltic Sea WGBAST Assessment Working Group on Baltic Salmon and Trout NA NA 4 2019 2 2021 Evaluation of the relative status of stocks by comparing the observed parr densities to model-predicted maximal parr densities. NA PA Reduction Not used No demersal piscivore Pelagic large pelagic TRUE 2025-03-28T16:29:41.203+01:00 8.3.18 12866 2019-05-29T11:34:00.447+01:00 NA NA
259 2652 199793 sal.neac.all Salmon (Salmo salar) in Northeast Atlantic and Arctic Ocean NA NA 2020 Salmo salar Salmon Arctic Ocean, Azores, Bay of Biscay and the Iberian Coast, Barents Sea, Celtic Seas, Faroes, Greenland Sea, Icelandic Waters, Greater North Sea, Norwegian Sea, Oceanic Northeast Atlantic WGNAS Working Group on North Atlantic Salmon RG/ADGSalmon Salmon Review and Advice Drafting Group 1 2018 3 2021 Analytical model, run-reconstruction models and Bayesian forecasts, taking into account uncertainties in data and process error (results presented in a risk analysis framework) NA MSY/PA Catches Not used NA pelagic piscivore Pelagic large benthopelagic TRUE 2025-03-28T16:29:41.203+01:00 10.3.3 NA 2020-11-12T13:18:52.573+01:00 O Unknown
260 2650 199794 sal.nac.all Salmon (Salmo salar) from North America NA NA 2020 Salmo salar Salmon Greenland Sea, Oceanic Northeast Atlantic WGNAS Working Group on North Atlantic Salmon RG/ADGSalmon Salmon Review and Advice Drafting Group 1 2019 2 2021 Analytical model, run-reconstruction models and Bayesian forecasts, taking into account uncertainties in the data NA MSY/PA Catches Not used NA pelagic piscivore Pelagic large benthopelagic TRUE 2025-03-28T16:29:41.203+01:00 10.3.1 NA 2021-01-11T10:35:02.487+01:00 O Unknown
261 2651 199795 sal.wgc.all Salmon (Salmo salar) in Subarea 14 and NAFO division 1 (east and west of Greenland) NA NA 2020 Salmo salar Salmon Greenland Sea, Oceanic Northeast Atlantic WGNAS Working Group on North Atlantic Salmon RG/ADGSalmon Salmon Review and Advice Drafting Group 1 2019 2 2021 Analytical model, run reconstruction models and Bayesian forecasts, taking into account uncertainties in the data NA MSY/PA Catches Not used NA pelagic piscivore Pelagic large benthopelagic TRUE 2025-03-28T16:29:41.203+01:00 10.3.2 NA 2020-12-09T11:49:52.74+01:00 O Unknown
412 2819 169241 sal.27.22-31 Salmon (Salmo salar) in subdivisions 22-31 (Baltic Sea, excluding the Gulf of Finland) 136678 sal-2431 2021 Salmo salar Salmon Baltic Sea WGBAST Assessment Working Group on Baltic Salmon and Trout RG/ADGSalmon Salmon Review and Advice Drafting Group 1 2021 1 2022 Analytical model, Bayesian state-space model for a majority of rivers in AUs 1–4 NA MSY Catches Assessment NA pelagic piscivore Pelagic large benthopelagic TRUE 2025-03-28T16:29:42.173+01:00 8.3.15 13726 2021-10-29T11:41:04.66+01:00 O Unknown
448 2856 169095 ele.2737.nea European eel (Anguilla anguilla) throughout its natural range 136527 ele-nea 2021 Anguilla anguilla Eel Arctic Ocean, Azores, Bay of Biscay and the Iberian Coast, Barents Sea, Baltic Sea, Celtic Seas, Faroes, Greenland Sea, Icelandic Waters, Greater North Sea, Norwegian Sea, Oceanic Northeast Atlantic WGEEL Joint EIFAAC/ICES/GFCM Working Group on Eels ADGEEL Eel Advice Drafting GRoup 3.14 2021 1 2022 Trends-based assessment NA PA No directed fisheries Not used No demersal benthivore Demersal medium demersal TRUE 2025-03-28T16:29:42.173+01:00 9.3.13 16876 2021-11-11T11:41:40.003+01:00 NA NA
449 2857 169242 sal.27.32 Salmon (Salmo salar) in Subdivision 32 (Gulf of Finland) 136679 sal-32 2021 Salmo salar Salmon Baltic Sea WGBAST Assessment Working Group on Baltic Salmon and Trout RG/ADGSalmon Salmon Review and Advice Drafting Group 3 2021 1 2022 Qualitative assessment based on monitored parr densities and expert judgement. NA PA Catches Topped up No pelagic piscivore Pelagic large benthopelagic TRUE 2025-03-28T16:29:42.173+01:00 8.3.16 13453 2021-12-10T11:13:59.86+01:00 O Unknown
498 2906 169291 trs.27.22-32 Sea trout (Salmo trutta) in subdivisions 22-32 (Baltic Sea) 136729 trt-bal 2021 Salmo trutta Sea trout Baltic Sea WGBAST Assessment Working Group on Baltic Salmon and Trout NA NA 4 2021 2 2023 Evaluation of the relative status of stocks by comparing the observed parr densities to model-predicted maximal parr densities. NA PA Reduction Not used No demersal piscivore Pelagic large pelagic TRUE 2025-03-28T16:29:42.173+01:00 8.3.18 12866 2021-12-10T11:12:39.54+01:00 NA NA
520 2929 199793 sal.neac.all Salmon (Salmo salar) in Northeast Atlantic and Arctic Ocean NA NA 2021 Salmo salar Salmon Arctic Ocean, Azores, Bay of Biscay and the Iberian Coast, Barents Sea, Celtic Seas, Faroes, Greenland Sea, Icelandic Waters, Greater North Sea, Norwegian Sea, Oceanic Northeast Atlantic WGNAS Working Group on North Atlantic Salmon RG/ADGSalmon Salmon Review and Advice Drafting Group 1 2021 1 2022 Analytical model, run-reconstruction models and Bayesian forecasts, taking into account uncertainties in data and process error (results presented in a risk analysis framework) NA MSY Catches Not used NA pelagic piscivore Pelagic large benthopelagic TRUE 2025-03-28T16:29:42.173+01:00 10.3.3 NA 2021-10-29T11:46:05.567+01:00 O Unknown
521 2930 199794 sal.nac.all Salmon (Salmo salar) from North America NA NA 2021 Salmo salar Salmon Greenland Sea, Oceanic Northeast Atlantic WGNAS Working Group on North Atlantic Salmon RG/ADGSalmon Salmon Review and Advice Drafting Group 1 2021 1 2022 Analytical model, run-reconstruction models and Bayesian forecasts, taking into account uncertainties in the data NA MSY/PA Catches Not used NA pelagic piscivore Pelagic large benthopelagic TRUE 2025-03-28T16:29:42.173+01:00 10.3.1 NA 2021-10-29T11:44:11.297+01:00 O Unknown
522 2931 199795 sal.wgc.all Salmon (Salmo salar) in Subarea 14 and NAFO division 1 (east and west of Greenland) NA NA 2021 Salmo salar Salmon Greenland Sea, Oceanic Northeast Atlantic WGNAS Working Group on North Atlantic Salmon RG/ADGSalmon Salmon Review and Advice Drafting Group 1 2021 3 2024 Analytical model, run reconstruction models and Bayesian forecasts, taking into account uncertainties in the data NA MSY Catches Not used NA pelagic piscivore Pelagic large benthopelagic TRUE 2025-03-28T16:29:42.173+01:00 10.3.2 NA 2021-10-29T11:47:18.467+01:00 O Unknown
677 3058 169241 sal.27.22-31 Salmon (Salmo salar) in subdivisions 22-31 (Baltic Sea, excluding the Gulf of Finland) 136678 sal-2431 2022 Salmo salar Salmon Baltic Sea WGBAST Assessment Working Group on Baltic Salmon and Trout RG/ADGSalmon Salmon Review and Advice Drafting Group 1 2021 1 2022 Analytical model, Bayesian state-space model for a majority of rivers in AUs 1–4 NA MSY Catches Assessment NA pelagic piscivore Pelagic large benthopelagic TRUE 2025-03-28T16:29:43.117+01:00 8.3.15 13726 2021-10-29T11:41:04.66+01:00 O Unknown
713 3100 169095 ele.2737.nea European eel (Anguilla anguilla) throughout its natural range 136527 ele-nea 2022 Anguilla anguilla Eel Arctic Ocean, Azores, Bay of Biscay and the Iberian Coast, Barents Sea, Baltic Sea, Celtic Seas, Faroes, Greenland Sea, Icelandic Waters, Greater North Sea, Norwegian Sea, Oceanic Northeast Atlantic WGEEL Joint EIFAAC/ICES/GFCM Working Group on Eels ADGEEL Eel Advice Drafting GRoup 3.14 2022 1 2023 Trends-based assessment NA PA No directed fisheries Not used No demersal benthivore Demersal medium demersal TRUE 2025-03-28T16:29:43.117+01:00 9.3.13 17615 2023-01-03T10:52:52.937+01:00 NA NA
714 3101 169242 sal.27.32 Salmon (Salmo salar) in Subdivision 32 (Gulf of Finland) 136679 sal-32 2022 Salmo salar Salmon Baltic Sea WGBAST Assessment Working Group on Baltic Salmon and Trout RG/ADGSalmon Salmon Review and Advice Drafting Group 3 2021 1 2022 Qualitative assessment based on monitored parr densities and expert judgement. NA PA Catches Topped up No pelagic piscivore Pelagic large benthopelagic TRUE 2025-03-28T16:29:43.117+01:00 8.3.16 13453 2021-12-10T11:13:59.86+01:00 O Unknown
763 3144 169291 trs.27.22-32 Sea trout (Salmo trutta) in subdivisions 22-32 (Baltic Sea) 136729 trt-bal 2022 Salmo trutta Sea trout Baltic Sea WGBAST Assessment Working Group on Baltic Salmon and Trout NA NA 4 2021 2 2023 Evaluation of the relative status of stocks by comparing the observed parr densities to model-predicted maximal parr densities. NA PA Reduction Not used No demersal piscivore Pelagic large pelagic TRUE 2025-03-28T16:29:43.117+01:00 8.3.18 12866 2023-01-05T10:54:51.217+01:00 NA NA
785 3167 199793 sal.neac.all Salmon (Salmo salar) in Northeast Atlantic and Arctic Ocean NA NA 2022 Salmo salar Salmon Arctic Ocean, Azores, Bay of Biscay and the Iberian Coast, Barents Sea, Celtic Seas, Faroes, Greenland Sea, Icelandic Waters, Greater North Sea, Norwegian Sea, Oceanic Northeast Atlantic WGNAS Working Group on North Atlantic Salmon RG/ADGSalmon Salmon Review and Advice Drafting Group 1 2021 1 2022 Analytical model, run-reconstruction models and Bayesian forecasts, taking into account uncertainties in data and process error (results presented in a risk analysis framework) NA MSY Catches Not used NA pelagic piscivore Pelagic large benthopelagic TRUE 2025-03-28T16:29:43.117+01:00 10.3.3 NA 2021-10-29T11:46:05.567+01:00 O Unknown
786 3168 199794 sal.nac.all Salmon (Salmo salar) from North America NA NA 2022 Salmo salar Salmon Greenland Sea, Oceanic Northeast Atlantic WGNAS Working Group on North Atlantic Salmon RG/ADGSalmon Salmon Review and Advice Drafting Group 1 2021 1 2022 Analytical model, run-reconstruction models and Bayesian forecasts, taking into account uncertainties in the data NA MSY/PA Catches Not used NA pelagic piscivore Pelagic large benthopelagic TRUE 2025-03-28T16:29:43.117+01:00 10.3.1 NA 2021-10-29T11:44:11.297+01:00 O Unknown
787 3169 199795 sal.wgc.all Salmon (Salmo salar) in Subarea 14 and NAFO division 1 (east and west of Greenland) NA NA 2022 Salmo salar Salmon Greenland Sea, Oceanic Northeast Atlantic WGNAS Working Group on North Atlantic Salmon RG/ADGSalmon Salmon Review and Advice Drafting Group 1 2021 3 2024 Analytical model, run reconstruction models and Bayesian forecasts, taking into account uncertainties in the data NA MSY Catches Not used NA pelagic piscivore Pelagic large benthopelagic TRUE 2025-03-28T16:29:43.117+01:00 10.3.2 NA 2021-10-29T11:47:18.467+01:00 O Unknown
943 3279 169241 sal.27.22-31 Salmon (Salmo salar) in subdivisions 22-31 (Baltic Sea, excluding the Gulf of Finland) 136678 sal-2431 2023 Salmo salar Salmon Baltic Sea WGBAST Assessment Working Group on Baltic Salmon and Trout RG/ADGSalmon Salmon Review and Advice Drafting Group 1 2023 1 2024 Analytical model, Bayesian state-space model for a majority of rivers in AUs 1–4 NA MSY Catches Assessment NA pelagic piscivore Pelagic large benthopelagic TRUE 2025-03-28T16:29:44.07+01:00 8.3.15 13726 2023-05-31T13:58:57.367+01:00 B Unknown
979 3320 169095 ele.2737.nea European eel (Anguilla anguilla) throughout its natural range 136527 ele-nea 2023 Anguilla anguilla Eel Arctic Ocean, Bay of Biscay and the Iberian Coast, Celtic Seas, Greater North Sea, Oceanic Northeast Atlantic WGEEL Joint EIFAAC/ICES/GFCM Working Group on Eels ADGEEL Eel Advice Drafting GRoup 3.14 2022 1 2023 Trends-based assessment NA PA No directed fisheries Not used No demersal benthivore Demersal medium demersal TRUE 2025-03-28T16:29:44.07+01:00 9.3.13 18459 2023-11-14T09:05:55.627+01:00 NA NA
980 3321 169242 sal.27.32 Salmon (Salmo salar) in Subdivision 32 (Gulf of Finland) 136679 sal-32 2023 Salmo salar Salmon Baltic Sea WGBAST Assessment Working Group on Baltic Salmon and Trout RG/ADGSalmon Salmon Review and Advice Drafting Group 3 2023 1 2024 Qualitative assessment based on monitored parr densities and expert judgement. NA PA Catches Topped up No pelagic piscivore Pelagic large benthopelagic TRUE 2025-03-28T16:29:44.07+01:00 8.3.16 13453 2023-11-14T09:59:06.097+01:00 O Unknown
1028 3364 169291 trs.27.22-32 Sea trout (Salmo trutta) in subdivisions 22-32 (Baltic Sea) 136729 trt-bal 2023 Salmo trutta Sea trout Baltic Sea WGBAST Assessment Working Group on Baltic Salmon and Trout NA NA 4 2023 2 2025 Evaluation of the relative status of stocks by comparing the observed parr densities to model-predicted maximal parr densities. NA PA Reduction Not used No demersal piscivore Pelagic large pelagic TRUE 2025-03-28T16:29:44.07+01:00 8.3.18 12866 2023-05-31T14:05:23.573+01:00 NA NA
1050 3431 199793 sal.neac.all Salmon (Salmo salar) in Northeast Atlantic and Arctic Ocean NA NA 2023 Salmo salar Salmon Arctic Ocean, Azores, Bay of Biscay and the Iberian Coast, Barents Sea, Celtic Seas, Faroes, Greenland Sea, Icelandic Waters, Greater North Sea, Norwegian Sea, Oceanic Northeast Atlantic WGNAS Working Group on North Atlantic Salmon RG/ADGSalmon Salmon Review and Advice Drafting Group 1 2021 3 2024 Analytical model, run-reconstruction models and Bayesian forecasts, taking into account uncertainties in data and process error (results presented in a risk analysis framework) NA MSY Catches Not used NA pelagic piscivore Pelagic large benthopelagic TRUE 2025-03-28T16:29:44.07+01:00 10.3.3 NA 2023-10-10T09:13:51.963+01:00 O Unknown
1051 3432 199794 sal.nac.all Salmon (Salmo salar) from North America NA NA 2023 Salmo salar Salmon Greenland Sea, Oceanic Northeast Atlantic WGNAS Working Group on North Atlantic Salmon RG/ADGSalmon Salmon Review and Advice Drafting Group 1 2021 3 2024 Analytical model, run-reconstruction models and Bayesian forecasts, taking into account uncertainties in the data NA MSY Catches Not used NA pelagic piscivore Pelagic large benthopelagic TRUE 2025-03-28T16:29:44.07+01:00 10.3.1 NA 2023-10-10T09:09:42.107+01:00 O Unknown
1052 3433 199795 sal.wgc.all Salmon (Salmo salar) in Subarea 14 and NAFO division 1 (east and west of Greenland) NA NA 2023 Salmo salar Salmon Greenland Sea, Oceanic Northeast Atlantic WGNAS Working Group on North Atlantic Salmon RG/ADGSalmon Salmon Review and Advice Drafting Group 1 2021 3 2024 Analytical model, run reconstruction models and Bayesian forecasts, taking into account uncertainties in the data NA MSY Catches Not used NA pelagic piscivore Pelagic large benthopelagic TRUE 2025-03-28T16:29:44.07+01:00 10.3.2 NA 2021-10-29T11:47:18.467+01:00 O Unknown
1208 3561 169241 sal.27.22-31 Salmon (Salmo salar) in subdivisions 22–31 (Baltic Sea, excluding the Gulf of Finland) 136678 sal-2431 2024 Salmo salar Salmon Baltic Sea WGBAST Assessment Working Group on Baltic Salmon and Trout RG/ADGSalmon Salmon Review and Advice Drafting Group 1 2023 1 2024 Analytical model, Bayesian state-space model for a majority of rivers in AUs 1–4 NA MSY Catches Assessment NA pelagic piscivore Pelagic large benthopelagic TRUE 2025-03-28T16:29:44.98+01:00 8.3.15 13726 2024-01-11T09:30:20.893+01:00 B Unknown
1244 3601 169095 ele.2737.nea European eel (Anguilla anguilla) throughout its natural range 136527 ele-nea 2024 Anguilla anguilla Eel Arctic Ocean, Bay of Biscay and the Iberian Coast, Celtic Seas, Greater North Sea, Oceanic Northeast Atlantic WGEEL Joint EIFAAC/ICES/GFCM Working Group on Eels ADGEEL Eel Advice Drafting GRoup 3.14 2022 1 2023 Trends-based assessment NA PA No directed fisheries Not used No demersal benthivore Demersal medium demersal TRUE 2025-03-28T16:29:44.98+01:00 9.3.13 19270 2024-09-25T14:21:32.487+01:00 NA NA
1245 3602 169242 sal.27.32 Salmon (Salmo salar) in Subdivision 32 (Gulf of Finland) 136679 sal-32 2024 Salmo salar Salmon Baltic Sea WGBAST Assessment Working Group on Baltic Salmon and Trout RG/ADGSalmon Salmon Review and Advice Drafting Group 3 2023 1 2024 Qualitative assessment based on monitored parr densities and expert judgement. NA PA Catches Topped up No pelagic piscivore Pelagic large benthopelagic TRUE 2025-03-28T16:29:44.98+01:00 8.3.16 19019 2024-01-11T10:26:17.923+01:00 O Unknown
1293 3645 169291 trs.27.22-32 Sea trout (Salmo trutta) in subdivisions 22–32 (Baltic Sea) 136729 trt-bal 2024 Salmo trutta Sea trout Baltic Sea WGBAST Assessment Working Group on Baltic Salmon and Trout NA NA 4 2023 2 2025 Evaluation of the relative status of stocks by comparing the observed parr densities to model-predicted maximal parr densities. NA PA Reduction Not used No demersal piscivore Pelagic large pelagic TRUE 2025-03-28T16:29:44.98+01:00 8.3.18 12866 2024-01-11T09:08:41.113+01:00 NA NA
1316 3709 199793 sal.neac.all Salmon (Salmo salar) in Northeast Atlantic and Arctic Ocean NA NA 2024 Salmo salar Salmon Arctic Ocean, Azores, Bay of Biscay and the Iberian Coast, Barents Sea, Celtic Seas, Faroes, Greenland Sea, Icelandic Waters, Greater North Sea, Norwegian Sea, Oceanic Northeast Atlantic WGNAS Working Group on North Atlantic Salmon RG/ADGSalmon Salmon Review and Advice Drafting Group 1 2021 3 2024 Analytical model, run-reconstruction models and Bayesian forecasts, taking into account uncertainties in data and process error (results presented in a risk analysis framework) NA MSY Catches Not used NA pelagic piscivore Pelagic large benthopelagic TRUE 2025-03-28T16:29:44.98+01:00 10.3.3 NA 2023-10-10T09:13:51.963+01:00 O Unknown
1317 3710 199794 sal.nac.all Salmon (Salmo salar) from North America NA NA 2024 Salmo salar Salmon Greenland Sea, Oceanic Northeast Atlantic WGNAS Working Group on North Atlantic Salmon RG/ADGSalmon Salmon Review and Advice Drafting Group 1 2021 3 2024 Analytical model, run-reconstruction models and Bayesian forecasts, taking into account uncertainties in the data NA MSY Catches Not used NA pelagic piscivore Pelagic large benthopelagic TRUE 2025-03-28T16:29:44.98+01:00 10.3.1 NA 2023-10-10T09:09:42.107+01:00 O Unknown
1318 3711 199795 sal.wgc.all Salmon (Salmo salar) in Subarea 14 and NAFO division 1 (east and west of Greenland) NA NA 2024 Salmo salar Salmon Greenland Sea, Oceanic Northeast Atlantic WGNAS Working Group on North Atlantic Salmon RG/ADGSalmon Salmon Review and Advice Drafting Group 1 2021 3 2024 Analytical model, run reconstruction models and Bayesian forecasts, taking into account uncertainties in the data NA MSY Catches Not used NA pelagic piscivore Pelagic large benthopelagic TRUE 2025-03-28T16:29:44.98+01:00 10.3.2 NA 2021-10-29T11:47:18.467+01:00 O Unknown

The code for creating metadata is listed below

SQL code to create tables

-- the code is here : SQL/tr_metadata_met.sql
-- we first create all referential tables then the metadata itself

DROP TABLE IF EXISTS ref.tr_objecttype_oty CASCADE;
CREATE TABLE ref.tr_objecttype_oty (
oty_code TEXT PRIMARY KEY,
oty_description TEXT
);

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

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

COMMENT ON COLUMN ref.tr_objecttype_oty.oty_code IS 
'code of the object type, single_value, vector, ...';

COMMENT ON COLUMN ref.tr_objecttype_oty.oty_code IS 'description of the object type';
GRANT ALL ON ref.tr_objecttype_oty TO diaspara_admin;
GRANT SELECT ON ref.tr_objecttype_oty TO diaspara_read;
--nimble

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

COMMENT ON TABLE ref.tr_nimble_nim IS 
'Indicate the type of data, parameter constant, parameter estimate, output, other ...';
-- Note this is a mix of nimble and status, which mean the same....

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

-- 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),
--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,
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 ref.tr_version_ver
IS 'Table of data or variable version, essentially one datacall or advice.';
COMMENT ON COLUMN ref.tr_version_ver.ver_version 
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. ''ele'' references tr_species_spe.';
--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;
-- metric 

DROP TABLE IF EXISTS  ref.tr_metric_mtr CASCADE;
CREATE TABLE ref.tr_metric_mtr(
mtr_code TEXT PRIMARY KEY,
mtr_description TEXT
);


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

GRANT ALL ON ref.tr_metric_mtr TO diaspara_admin;
GRANT SELECT ON ref.tr_metric_mtr TO diaspara_read;
COMMENT ON TABLE ref.tr_metric_mtr IS 
'Table metric describe the type of parm used, Index, Bound ...';

-- 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;

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');


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


SELECT * FROM refsalmoglob."database" JOIN
refnas.tr_metadata_met AS tmm ON tmm.met_var = var_mod
WHERE "year" IS NULL


DROP TABLE IF EXISTS ref.tr_metadata_met CASCADE;
CREATE TABLE ref.tr_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_oty_code TEXT NOT NULL,
  met_nim_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_mtr_code TEXT NULL,
  met_des_code TEXT NULL,
  met_uni_code TEXT NULL,
  met_cat_code TEXT NULL,
  met_definition TEXT NULL, 
  met_deprecated 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_oty_code FOREIGN KEY (met_oty_code) 
  REFERENCES ref.tr_objecttype_oty (oty_code) ON DELETE CASCADE
  ON UPDATE CASCADE,
  CONSTRAINT fk_met_nim_code FOREIGN KEY (met_nim_code) 
  REFERENCES ref.tr_nimble_nim (nim_code) ON DELETE CASCADE
  ON UPDATE CASCADE,  
  CONSTRAINT fk_met_mtr_code FOREIGN KEY (met_mtr_code)
  REFERENCES ref.tr_metric_mtr(mtr_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 ref.tr_metadata_met IS 
'Table (metadata) of each variable (parameter) in the database.';
COMMENT ON COLUMN ref.tr_metadata_met.met_var 
IS 'Variable code, primary key on both met_spe_code and met_var.';
COMMENT ON COLUMN ref.tr_metadata_met.met_spe_code 
IS 'Species, ANG, SAL, TRT ... primary key on both met_spe_code and met_var.';
COMMENT ON COLUMN ref.tr_metadata_met.met_ver_code 
IS 'Code on the version of the model, see table tr_version_ver.';
COMMENT ON COLUMN ref.tr_metadata_met.met_oty_code 
IS 'Object type, single_value, vector, matrix see table tr_objecttype_oty.';
COMMENT ON COLUMN ref.tr_metadata_met.met_nim_code 
IS 'Nimble type, one of data, constant, output, other.';
COMMENT ON COLUMN ref.tr_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 ref.tr_metadata_met.met_dimname 
IS 'Dimension of the variable in Nimble, use {''year'', ''stage'', ''area''}.';
COMMENT ON COLUMN ref.tr_metadata_met.met_modelstage 
IS 'Currently one of fit, other, First year.';
COMMENT ON COLUMN ref.tr_metadata_met.met_type 
IS 'Type of data in the variable, homewatercatches, InitialISation first year,
abundance ....';
COMMENT ON COLUMN ref.tr_metadata_met.met_location 
IS 'Describe process at sea, e.g. Btw. FAR - GLD fisheries, or Aft. Gld fISheries.';
COMMENT ON COLUMN ref.tr_metadata_met.met_fishery 
IS 'Description of the fishery.';
COMMENT ON COLUMN ref.tr_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 ref.tr_metadata_met.met_uni_code 
IS 'Unit, references table tr_unit_uni.';
COMMENT ON COLUMN ref.tr_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 ref.tr_metadata_met.met_mtr_code 
IS 'Code of the metric, references tr_metric_mtr, Estimate, Bound, SD, CV ....';
COMMENT ON COLUMN ref.tr_metadata_met.met_definition 
IS 'Definition of the metric.';
COMMENT ON COLUMN ref.tr_metadata_met.met_deprecated
IS'Is the variable still used ?';

GRANT ALL ON ref.tr_metadata_met TO diaspara_admin;
GRANT SELECT ON ref.tr_metadata_met TO diaspara_read;
DIASPARA

Not yet completely sure about this …. Environment (sea, transition …), age, life stage and complex are in the metadata. But they are also in the main table. To start with, we remove them to reduce complexity and avoid errors. The complex will be derived from the spatial structure still in construction

DIASPARA

As in the diagram, added a category (data type in figure Figure 3). The idea is to be able to get quickly all parameters related to a type, e.g. catch, mortality, biomass. Please check and also check definitions.

DIASPARA

WGBAST, WGNAS, WGEEL, WGTRUTTA will have to check definitions in tr_destination_dest. Note this is just a column in tr_metadata_met not in the main table. Check if it could not simply be removed if the definition of the parameter is clear ?

Object type (tr_objectype_oty)

This table (Table 7) is used in metadata

Table 7: Object type
oty_code oty_description
Single_value Single value
Vector One dimension vector
Matrix Two dimensions matrix
Array Three dimensions array

Type of parm / data (tr_nimble_nim)

In the salmoglob db, this table (Table 8) corresponded to both tables status and nimble which most often contained the same information.

Table 8: Nimble
nim_code nim_description
Data Data entry to the model
Parameter constant Parameter input to the model
Parameter estimate Parameter input to the model
Output Output from the model, derived quantity
Other Applies currently to conservation limits

Version (tr_version_ver)

Currently in the salmoglob metadata there is no information about version. The version number is in the table itself. It seems to correspond to different versions of the same parameter. While currently this information is stored in the database and database_archive it seems to that metadata should also contain information about historical variables. For instance we create a new variable, so we know when it was introduced. So in addition with the data in the main table I’m adding a version number to metadata, Some variables might get deprecated over time. The year will be the year when the variable was introduced. All variables in this version of the DB in metadata will start with SAL-2024-1, the tr_version_ver should be able to store a version number but currently I need to understand to what it corresponds.

Note that the version (Table 9) contains both reference to the datacall (when data are loaded) and to the advice. The advice might still be null at the time the values will be entered into the database. The version will be handled in inherited tables for WGNAS, WGEEL and WGBAST. Here I’m currently entering the WGNAS data.

Question to WNGAS / Etienne

Check that this is correct, original values in the table metadata were “Const_nimble” “Data_nimble” “Output” “other”

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("SAL-",2020:2024,"-1"),
ver_year = 2020:2024,
ver_spe_code = "SAL",
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 SELECT * FROM temp_tr_version_ver;") # 5
 DBI::dbExecute(con_diaspara_admin, "DROP TABLE temp_tr_version_ver;")


# TODO eel and wgbast
#"ele.2737.nea","sal.27.22–31",

Question to WNGAS / ICES

  • Check there is just one version per year
  • Provide descriptions of the version of the model
  • Questions sent to ICES to provide access to historical DOI
  • Exchanges currently on this (17/03/2025) with Etienne / Pierre Yves Hernvann
Table 9: Version
ver_code ver_year ver_spe_code ver_stockkeylabel ver_datacalldoi ver_version ver_description
SAL-2020-1 2020 SAL NA sal.neac.all 1 NA
SAL-2021-1 2021 SAL NA sal.neac.all 1 NA
SAL-2022-1 2022 SAL NA sal.neac.all 1 NA
SAL-2023-1 2023 SAL NA sal.neac.all 1 NA
SAL-2024-1 2024 SAL https://doi.org/10.17895/ices.pub.25071005.v3 sal.neac.all 1 NA

QUESTION ICES: What is the vocabulary for datacalls

I would like to access to this table : datacall (see link in ICES webpage). Currently we see the current year, this is nice, how do we access to historical data, is there a way to get it using a query ? We’ve found a link for advice or stocks but not data calls.

Metric (tr_metric_mtr)

Table 10: Metric, type of parm used in the model
mtr_code mtr_description
Estimate Estimate
Index Index
Bound Either min or max
Hyperparameter Hyperparameter (prior)
SD Standard deviation
CV Coefficient of variation
Precision Inverse of variance
Mean Mean
Min Minimum
Max Maximum
NOTE

This list is probably incomplete. But the metric can be NULL in case of a number of fish released, not of the above (Table 10) will apply.

Category (tr_category_cat)

categories Table 11 were in the salmoglob metadata, we have simplified to reduce the number of categories and be able to get for instance all parameters dealing with catch.

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

Destination (tr_destination_dest)

A bit cumbersome this table, the idea is “what becomes of this fish”. Different types of landings. But it’s just in metatdata and we need need in WGBAST

Table 12: category of parameters
des_code des_description
Removed Removed from the environment, e.g. caught and kept
Seal damaged Seal damage
Discarded Discards
Released Released alive
NOTE DIASPARA

Here Hilaire say that naming the table “outcome” wasn’t ideal so I’ve followed his suggestion

Metadata (tr_metadata_met)

Table 13: metadata
met_var met_spe_code met_wkg_code met_ver_code met_oty_code met_nim_code met_dim met_dimname met_modelstage met_type met_location met_fishery met_mtr_code met_des_code met_uni_code met_cat_code met_definition met_deprecated
log_C5_NAC_1_lbnf_sd SAL WGNAS SAL-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
log_C5_NAC_2_lbnf_lab_sd SAL WGNAS SAL-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
log_C5_NAC_2_lbnf_oth_sd SAL WGNAS SAL-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
log_C5_NEC_1_far_sd SAL WGNAS SAL-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
log_C8_2_gld_tot_sd SAL WGNAS SAL-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
log_C8_NAC_1_lbnf_sd SAL WGNAS SAL-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
log_C8_NAC_3_lbnf_sd SAL WGNAS SAL-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
log_C8_NAC_4_lbnf_lab_sd SAL WGNAS SAL-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
log_C8_NAC_4_lbnf_oth_sd SAL WGNAS SAL-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
log_C8_NEC_1_far_sd SAL WGNAS SAL-2024-1 Vector Parameter constant {50,0,0} {'Year',NULL,NULL} Fit Sea catches Bef. Gld fisheries FAR fishery SD NA NA Catch Standard-deviation of observed total catches (log scale) of 2SW individuals from the NEC complex before maturation in Faroe islands NA
log_C8_NEC_3_far_sd SAL WGNAS SAL-2024-1 Vector Parameter constant {50,0,0} {'Year',NULL,NULL} Fit Sea catches Aft. Gld fisheries FAR fishery SD NA NA Catch Standard-deviation of observed total catches (log scale) of 2SW individuals from the NEC complex after maturation in Faroe islands NA
log_C5_NAC_1_lbnf_mu SAL WGNAS SAL-2024-1 Vector Data {52,0,0} {'Year',NULL,NULL} Fit Sea catches Bef. Gld fisheries neNF fishery Mean NA NA Catch Observed catches (log scale) of NAC 1 SW by early Newfoundland fishery NA
log_C5_NAC_2_lbnf_lab_mu SAL WGNAS SAL-2024-1 Vector Data {50,0,0} {'Year',NULL,NULL} Fit Sea catches Bef. Gld fisheries LB fishery Mean NA NA Catch Observed catches (log scale) of Labrador-origin 1 SW by late Newfoundland, Labrador and Saint Pierre et Miquelon fisheries NA
log_C5_NAC_2_lbnf_oth_mu SAL WGNAS SAL-2024-1 Vector Data {47,0,0} {'Year',NULL,NULL} Fit Sea catches Bef. Gld fisheries LB/SPM/swNF fishery Mean NA NA Catch Observed catches (log scale) of NAC Labrador-excluded 1 SW by late Newfoundland, Labrador and Saint Pierre et Miquelon fisheries NA
log_C5_NEC_1_far_mu SAL WGNAS SAL-2024-1 Vector Data {47,0,0} {'Year',NULL,NULL} Fit Sea catches Bef. Gld fisheries FAR fishery Mean NA NA Catch Observed total catches (log scale) of 1SW adults from the NEC complex in Faroe islands NA
log_C8_2_gld_tot_mu SAL WGNAS SAL-2024-1 Vector Data {47,0,0} {'Year',NULL,NULL} Fit Sea catches Gld fisheries GLD fishery Mean NA NA Catch Observed total catches (log scale) of 2SW adults (mixed complexes) in Greenland NA
log_C8_NAC_1_lbnf_mu SAL WGNAS SAL-2024-1 Vector Data {52,0,0} {'Year',NULL,NULL} Fit Sea catches Bef. Gld fisheries neNF fishery Mean NA NA Catch Observed catches (log scale) of NAC 1 SW by Labrador/Newfoundland fishery NA
log_C8_NAC_3_lbnf_mu SAL WGNAS SAL-2024-1 Vector Data {53,0,0} {'Year',NULL,NULL} Fit Sea catches Aft. Gld fisheries neNF fishery Mean NA NA Catch Observed catches (log scale) of NAC 2 SW by early Newfoundland fishery NA
log_C8_NAC_4_lbnf_lab_mu SAL WGNAS SAL-2024-1 Vector Data {47,0,0} {'Year',NULL,NULL} Fit Sea catches Aft. Gld fisheries LB fishery Mean NA NA Catch Observed catches (log scale) of Labrador-origin 2 SW by late Newfoundland, Labrador and Saint Pierre et Miquelon fisheries NA
log_C8_NAC_4_lbnf_oth_mu SAL WGNAS SAL-2024-1 Vector Data {47,0,0} {'Year',NULL,NULL} Fit Sea catches Aft. Gld fisheries LB/SPM/swNF fishery Mean NA NA Catch Observed catches (log scale) of NAC Labrador-excluded 2 SW by late Newfoundland, Labrador and Saint Pierre et Miquelon fisheries NA
log_C8_NEC_1_far_mu SAL WGNAS SAL-2024-1 Vector Data {47,0,0} {'Year',NULL,NULL} Fit Sea catches Bef. Gld fisheries FAR fishery Mean NA NA Catch Observed total catches (log scale) of 2SW individuals from the NEC complex before maturation in Faroe islands NA
log_C8_NEC_3_far_mu SAL WGNAS SAL-2024-1 Vector Data {47,0,0} {'Year',NULL,NULL} Fit Sea catches Aft. Gld fisheries FAR fishery Mean NA NA Catch Observed total catches (log scale) of 2SW individuals from the NEC complex after maturation in Faroe islands NA
C5_NAC_1 SAL WGNAS SAL-2024-1 Matrix Output {47,6,0} {'Year',"'Stock unit NAC'",NULL} Fit Sea catches Bef. Gld fisheries neNF fishery Estimate NA NA Catch Catches of 1SW adults from the NAC complex in early Newfoundland fisheries NA
C5_NAC_1_tot SAL WGNAS SAL-2024-1 Vector Output {47,0,0} {'Year',NULL,NULL} Fit Sea catches Bef. Gld fisheries neNF fishery Estimate NA NA Catch Total catch of 1 SW adults by Newfoundland and Labrador fisheries over all NAC SUs NA
C5_NAC_2 SAL WGNAS SAL-2024-1 Matrix Output {47,6,0} {'Year',"'Stock unit NAC'",NULL} Fit Sea catches Bef. Gld fisheries LB-LB/SPM/swNF fishery Estimate NA NA Catch Catches of 1SW adults from the NAC complex in late Newfoundland, Labrador and Saint Pierre et Miquelon fisheries NA
C5_NAC_2_lab SAL WGNAS SAL-2024-1 Vector Output {47,0,0} {'Year',NULL,NULL} Fit Sea catches Bef. Gld fisheries LB fishery Estimate NA NA Catch Catch of 1SW adults from the Labrador SU by late regional fisheries in Labrador NA
C5_NAC_2_other SAL WGNAS SAL-2024-1 Vector Output {47,0,0} {'Year',NULL,NULL} Fit Sea catches Bef. Gld fisheries LB/SPM/swNF fishery Estimate NA NA Catch Catch of 1SW adults from NAC SUs excluding Labrador by late regional fisheries in Labrador and Saint Pierre et Miquelon NA
C5_NEC_1 SAL WGNAS SAL-2024-1 Matrix Output {47,19,0} {'Year',"'Stock unit NEC'",NULL} Fit Sea catches Bef. Gld fisheries FAR fishery Estimate NA NA Catch Catches of 1SW adults from the NEC complex in Faroe islands NA
C5_NEC_1_tot SAL WGNAS SAL-2024-1 Vector Output {47,0,0} {'Year',NULL,NULL} Fit Sea catches Bef. Gld fisheries FAR fishery Estimate NA NA Catch Total catch of 1 SW adults by Faroes fisheries over all NEC SUs NA
C8_2 SAL WGNAS SAL-2024-1 Matrix Output {47,25,0} {'Year',"'Stock unit'",NULL} Fit Sea catches Gld fisheries GLD fishery Estimate NA NA Catch Catches of 2SW individuals by common fisheries in Greenland waters NA
C8_2_comp SAL WGNAS SAL-2024-1 Matrix Output {47,2,0} {'Year','Complex',NULL} Fit Sea catches Gld fisheries GLD fishery Estimate NA NA Catch Catches of 2SW individuals by common fisheries in Greenland waters for each complex NA
C8_2_tot SAL WGNAS SAL-2024-1 Vector Output {47,0,0} {'Year',NULL,NULL} Fit Sea catches Gld fisheries GLD fishery Estimate NA NA Catch Total catch of 2SW individuals by common Greenland fisheries over all Sus NA
C8_NAC_1 SAL WGNAS SAL-2024-1 Matrix Output {47,6,0} {'Year',"'Stock unit NAC'",NULL} Fit Sea catches Bef. Gld fisheries neNF fishery Estimate NA NA Catch Catches of 2SW from the NAC complex by Newfoundland and Labrador before Greenland fisheries NA
C8_NAC_1_tot SAL WGNAS SAL-2024-1 Vector Output {47,0,0} {'Year',NULL,NULL} Fit Sea catches Bef. Gld fisheries neNF fishery Estimate NA NA Catch Total catch of 1 SW non mature by Newfoundland and Labrador fisheries over all NAC SUs NA
C8_NAC_3 SAL WGNAS SAL-2024-1 Vector Output {47,0,0} {'Year',NULL,NULL} Fit Sea catches Aft. Gld fisheries neNF fishery Estimate NA NA Catch Catch of 2SW adults from the NAC complex by late regional fisheries in Newfoundland NA
C8_NAC_3_tot SAL WGNAS SAL-2024-1 Vector Output {47,0,0} {'Year',NULL,NULL} Fit Sea catches Aft. Gld fisheries neNF fishery Estimate NA NA Catch Total catch of NAC 2SW adults by late regional fisheries in Newfoundland NA
C8_NAC_4 SAL WGNAS SAL-2024-1 Matrix Output {47,6,0} {'Year',"'Stock unit NAC'",NULL} Fit Sea catches Aft. Gld fisheries LB-LB/SPM/swNF fishery Estimate NA NA Catch Catch of 2SW adults from the NAC complex by late regional fisheries in Labrador and Saint Pierre et Miquelon NA
C8_NAC_4_lab SAL WGNAS SAL-2024-1 Vector Output {47,0,0} {'Year',NULL,NULL} Fit Sea catches Aft. Gld fisheries LB fishery Estimate NA NA Catch Catch of 2SW adults from the Labrador SU by late regional fisheries in Labrador NA
C8_NAC_4_other SAL WGNAS SAL-2024-1 Vector Output {47,0,0} {'Year',NULL,NULL} Fit Sea catches Aft. Gld fisheries LB/SPM/swNF fishery Estimate NA NA Catch Catch of 2SW adults from NAC SUs excluding Labrador by late regional fisheries in Labrador and Saint Pierre et Miquelon NA
C8_NEC_1 SAL WGNAS SAL-2024-1 Matrix Output {47,19,0} {'Year',"'Stock unit NEC'",NULL} Fit Sea catches Bef. Gld fisheries FAR fishery Estimate NA NA Catch Catches of 2SW from the NEC complex before their maturation by Faroes fisheries NA
C8_NEC_1_tot SAL WGNAS SAL-2024-1 Vector Output {47,0,0} {'Year',NULL,NULL} Fit Sea catches Bef. Gld fisheries FAR fishery Estimate NA NA Catch Total catch of 2SW individuals over all NEC SUs by Faroes fisheries NA
C8_NEC_3 SAL WGNAS SAL-2024-1 Matrix Output {47,19,0} {'Year',"'Stock unit NEC'",NULL} Fit Sea catches Aft. Gld fisheries FAR fishery Estimate NA NA Catch Catch of 2SW adults from the NEC complex by late regional fisheries in Faroes NA
C8_NEC_3_tot SAL WGNAS SAL-2024-1 Vector Output {47,0,0} {'Year',NULL,NULL} Fit Sea catches Aft. Gld fisheries FAR fishery Estimate NA NA Catch Total catch of NEC 2SW adults by late regional fisheries in Faroes NA
p_C5_NEC_1_far_mu SAL WGNAS SAL-2024-1 Matrix Data {47,19,0} {'Year',"'Stock unit NEC'",NULL} Fit Origin distribution in sea catches FAR - by SU FAR fishery Mean NA NA Other Observed proportion of each NEC SU in the total sea catches of 1SW mature individuals of the NEC complex NA
p_C8_2_NAC_gld_mu SAL WGNAS SAL-2024-1 Matrix Data {53,6,0} {'Year',"'Stock unit NAC'",NULL} Fit Origin distribution in sea catches GLD - by NAC SU GLD fishery Mean NA NA Other Observed proportion of NAC salmon caught in Greenland fisheries NA
p_C8_2_NEC_gld_mu SAL WGNAS SAL-2024-1 Matrix Data {47,19,0} {'Year',"'Stock unit NEC'",NULL} Fit Origin distribution in sea catches GLD - by NEC SU GLD fishery Mean NA NA Other Observed proportion of NEC salmon caught in Greenland fisheries NA
p_C8_2_NECNAC_gld_mu SAL WGNAS SAL-2024-1 Matrix Data {53,2,0} {'Year','Complex',NULL} Fit Origin distribution in sea catches GLD - by cplx GLD fishery Mean NA NA Other Observed proportion of each complex in the total Greenland catches NA
p_C8_NEC_1_far_mu SAL WGNAS SAL-2024-1 Matrix Data {50,19,0} {'Year',"'Stock unit NEC'",NULL} Fit Origin distribution in sea catches FAR - by SU FAR fishery Mean NA NA Other Observed proportion of each NEC SU in the total sea catches of 1SW non mature (future 2SW) the NEC complex NA
p_C8_NEC_3_far_mu SAL WGNAS SAL-2024-1 Matrix Data {52,19,0} {'Year',"'Stock unit NEC'",NULL} Fit Origin distribution in sea catches FAR - by SU FAR fishery Mean NA NA Other Observed proportion of individuals of each SU in the total catch of 2SW at Faroes NA
p_C5_NEC_1 SAL WGNAS SAL-2024-1 Matrix Output {47,19,0} {'Year',"'Stock unit NEC'",NULL} Fit Origin distribution in sea catches FAR fisheries NA Estimate NA NA Other Proportion of individuals of each SU in the total catch of NEC 1SW at Faroes NA
p_C8_2_NAC SAL WGNAS SAL-2024-1 Matrix Output {47,6,0} {'Year',"'Stock unit NAC'",NULL} Fit Origin distribution in sea catches GLD fisheries NA Estimate NA NA Other Proportion of NAC 2SW individuals in the total Greenland catches for each NAC SU NA
p_C8_2_NEC SAL WGNAS SAL-2024-1 Matrix Output {47,19,0} {'Year',"'Stock unit NEC'",NULL} Fit Origin distribution in sea catches GLD fisheries NA Estimate NA NA Other Proportion of NEC 2SW individuals in the total Greenland catches for each NEC SU NA
p_C8_2_NECNAC SAL WGNAS SAL-2024-1 Matrix Output {47,2,0} {'Year','Complex',NULL} Fit Origin distribution in sea catches GLD fisheries NA Estimate NA NA Other Proportion of 2SW individuals in the total Greenland catches for each complex NA
p_C8_NEC_1 SAL WGNAS SAL-2024-1 Matrix Output {47,19,0} {'Year',"'Stock unit NEC'",NULL} Fit Origin distribution in sea catches FAR fisheries NA Estimate NA NA Other Proportion of individuals of each SU in the total catch of NEC 2SW at Faroes NA
p_C8_NEC_3 SAL WGNAS SAL-2024-1 Matrix Output {47,19,0} {'Year',"'Stock unit NEC'",NULL} Fit Origin distribution in sea catches FAR fisheries NA Estimate NA NA Other Proportion of 2SW individuals of each SU in the total Faroes catches of the NEC complex NA
CV_hw SAL WGNAS SAL-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
log_C6_delSp_sd SAL WGNAS SAL-2024-1 Matrix Parameter constant {50,25,0} {'Year',"'Stock unit'",NULL} Fit Homewater catches _ _ SD NA NA Catch Standard deviation of homewaters catches of 1SW delayed spawners NA
log_C6_sd SAL WGNAS SAL-2024-1 Matrix Parameter constant {47,25,0} {'Year',"'Stock unit'",NULL} Fit Homewater catches _ _ SD NA NA Catch Standard deviation of homewater catches of 1SW returns NA
log_C9_delSp_sd SAL WGNAS SAL-2024-1 Matrix Parameter constant {47,25,0} {'Year',"'Stock unit'",NULL} Fit Homewater catches _ _ SD NA NA Catch Standard deviation of homewaters catches of 2SW delayed spawners NA
log_C9_sd SAL WGNAS SAL-2024-1 Matrix Parameter constant {47,25,0} {'Year',"'Stock unit'",NULL} Fit Homewater catches _ _ SD NA NA Catch Standard deviation of homewater catches of 2SW returns NA
log_C6_delSp_mu SAL WGNAS SAL-2024-1 Matrix Data {52,25,0} {'Year',"'Stock unit'",NULL} Fit Homewater catches _ delayed spawners Mean NA NA Catch Observed catches (log scale) of 1SW delayed spawners in home waters NA
log_C6_mu SAL WGNAS SAL-2024-1 Matrix Data {52,25,0} {'Year',"'Stock unit'",NULL} Fit Homewater catches _ main Mean NA NA Catch Observed catches (log scale) of returning 1 SW adults in home waters NA
log_C9_delSp_mu SAL WGNAS SAL-2024-1 Matrix Data {50,25,0} {'Year',"'Stock unit'",NULL} Fit Homewater catches _ delayed spawners Mean NA NA Catch Observed catches (log scale) of 2SW delayed spawners in home waters NA
log_C9_mu SAL WGNAS SAL-2024-1 Matrix Data {47,25,0} {'Year',"'Stock unit'",NULL} Fit Homewater catches _ main Mean NA NA Catch Observed catches (log scale) of returning 2 SW adults in home waters NA
C6_hw SAL WGNAS SAL-2024-1 Matrix Output {47,25,0} {'Year',"'Stock unit'",NULL} Fit Homewater catches _ main Estimate NA NA Catch Homewater catches of returning 1SW spawners NA
C6_hw_delSp SAL WGNAS SAL-2024-1 Matrix Output {47,25,0} {'Year',"'Stock unit'",NULL} Fit Homewater catches _ delayed spawners Estimate NA NA Catch Homewater catches of 1SW delayed spawners NA
C9_hw SAL WGNAS SAL-2024-1 Matrix Output {47,25,0} {'Year',"'Stock unit'",NULL} Fit Homewater catches _ main Estimate NA NA Catch Homewater catches of returning 2SW spawners NA
C9_hw_delSp SAL WGNAS SAL-2024-1 Matrix Output {47,25,0} {'Year',"'Stock unit'",NULL} Fit Homewater catches _ delayed spawners Estimate NA NA Catch Homewater catches of 2SW delayed spawners NA
log_N6_sd SAL WGNAS SAL-2024-1 Matrix Parameter constant {47,25,0} {'Year',"'Stock unit'",NULL} Fit Returns _ NA SD NA NA Count Standard deviation of observed returns (log scale) of 1 SW adults in log scale NA
log_N9_sd SAL WGNAS SAL-2024-1 Matrix Parameter constant {52,25,0} {'Year',"'Stock unit'",NULL} Fit Returns _ NA SD NA NA Count Standard deviation of observed returns (log scale) of 2 SW adults in log scale NA
log_N6_mu SAL WGNAS SAL-2024-1 Matrix Data {52,25,0} {'Year',"'Stock unit'",NULL} Fit Returns _ NA Mean NA NA Count Observed returns (log scale) (log scale) of 1 SW adults in log scale NA
log_N9_mu SAL WGNAS SAL-2024-1 Matrix Data {50,25,0} {'Year',"'Stock unit'",NULL} Fit Returns _ NA Mean NA NA Count Observed returns (log scale) of 2 SW adults in log scale NA
eggs SAL WGNAS SAL-2024-1 Array Parameter constant {2,25,47} {"'Age sea winter'","'Stock unit'",'Year'} Fit Fecundity rate _ NA Mean NA NA Life trait Fecundity rates of 1SW and 2SW spawners NA
prop_female SAL WGNAS SAL-2024-1 Array Parameter constant {2,25,50} {"'Age sea winter'","'Stock unit'",'Year'} Fit Sex ratio _ _ Mean NA NA Life trait Proportion of females for all years in all SUs NA
theta6_delSp SAL WGNAS SAL-2024-1 Matrix Parameter constant {47,25,0} {'Year',"'Stock unit'",NULL} Fit Proportion of delayed individuals _ NA Mean NA NA Other Proportion of delayed individuals among 1SW spawners NA
N2_pr SAL WGNAS SAL-2024-1 Matrix Output {7,25,0} {'Year',"'Stock unit'",NULL} First year Abundance _ NA Mean NA NA Count First year: Pre-smolt abundance NA
theta9_delSp SAL WGNAS SAL-2024-1 Matrix Parameter constant {47,25,0} {'Year',"'Stock unit'",NULL} Fit Proportion of delayed individuals _ NA Mean NA NA Other Proportion of delayed individuals among 2SW spawners NA
p_smolt SAL WGNAS SAL-2024-1 Array Parameter constant {52,6,25} {'Year',"'Age fresh water'","'Stock unit'"} Fit Smolt age structure _ NA Mean NA NA Life trait Prior on the proportions of each smolt age in the total number of smolts NA
p_smolt_gamma SAL WGNAS SAL-2024-1 Array Output {47,6,25} {'Year',"'Age fresh water'","'Stock unit'"} Fit Smolt age structure _ NA Estimate NA NA Life trait Gamma distribution hyperparameters used to build the Dirichlet distribution for smolt ages proportions NA
p_smolt_stoch SAL WGNAS SAL-2024-1 Array Output {47,6,25} {'Year',"'Age fresh water'","'Stock unit'"} Fit Smolt age structure _ NA Estimate NA NA Life trait Proportions of each smolt age in the total number of smolts NA
Stocking_2SW SAL WGNAS SAL-2024-1 Matrix Parameter constant {52,25,0} {'Year',"'Stock unit'",NULL} Fit Stocking _ NA Mean NA NA Count Stocking of 2SW from aquaculture NA
B SAL WGNAS SAL-2024-1 Vector Parameter constant {25,0,0} {"'Stock unit'",NULL,NULL} First year Survival rate _ NA Mean NA NA Mortality First year: density dependence parameter B NA
CV_theta1 SAL WGNAS SAL-2024-1 Vector Parameter constant {25,0,0} {"'Stock unit'",NULL,NULL} Fit Survival rate _ NA CV NA NA Mortality Standard-deviation for eggs-smolt survival rate NA
E_theta1 SAL WGNAS SAL-2024-1 Matrix Parameter constant {50,25,0} {'Year',"'Stock unit'",NULL} Fit Survival rate _ NA Mean NA NA Mortality Mean eggs-smolts survival rate NA
theta6_surv SAL WGNAS SAL-2024-1 Matrix Parameter constant {47,25,0} {'Year',"'Stock unit'",NULL} Fit Survival rate _ NA Mean NA NA Mortality Survival rate to additional rate for 1SW spawners in home waters NA
theta9_surv SAL WGNAS SAL-2024-1 Matrix Parameter constant {52,25,0} {'Year',"'Stock unit'",NULL} Fit Survival rate _ NA Mean NA NA Mortality Survival rate to additional rate for 2SW spawners in home waters NA
deltat5_1 SAL WGNAS SAL-2024-1 Vector Parameter constant {25,0,0} {"'Stock unit'",NULL,NULL} Fit Time spent at sea Bef. Fisheries NA Mean NA NA Life trait Time spent (months) by 1SW adults in the environment before Newfoundland fisheries NA
deltat5_2 SAL WGNAS SAL-2024-1 Vector Parameter constant {25,0,0} {"'Stock unit'",NULL,NULL} Fit Time spent at sea Return aft. First fishery NA Mean NA NA Life trait Time spent (months) by 1SW adults in the environment after Newfoundland fisheries and before Labrador fisheries NA
deltat8_1 SAL WGNAS SAL-2024-1 Vector Parameter constant {25,0,0} {"'Stock unit'",NULL,NULL} Fit Time spent at sea Bef. Fisheries NA Mean NA NA Life trait Time spent (months) by 2SW individuals in the environment before early catches by Newfoundland and Labrador fisheries NA
deltat8_2 SAL WGNAS SAL-2024-1 Vector Parameter constant {25,0,0} {"'Stock unit'",NULL,NULL} Fit Time spent at sea Aft. First fisheries NA Mean NA NA Life trait Time spent (months) by 2SW individuals in the environment after early catches by Newfoundland and Labrador fisheries and before reaching Greenland NA
deltat8_2_1 SAL WGNAS SAL-2024-1 Vector Parameter constant {25,0,0} {"'Stock unit'",NULL,NULL} Fit Time spent at sea Aft. Second fisheries NA Mean NA NA Life trait Time spent (months) by 2SW individuals between Greenland and late Newfoundland, Labrador and St Pierre et Miquelon fisheries NA
deltat8_2_2 SAL WGNAS SAL-2024-1 Vector Parameter constant {25,0,0} {"'Stock unit'",NULL,NULL} Fit Time spent at sea Return aft. Second fishery NA Mean NA NA Life trait Time spent (months) by 2SW individuals after late Newfoundland, Labrador and St Pierre et Miquelon fisheries NA
cons_lim SAL WGNAS SAL-2024-1 Vector Other {17,0,0} {'Countries',NULL,NULL} other Conservation limits _ _ Mean NA NA Conservation limit Conservation limits by country NA
log_N1_pr SAL WGNAS SAL-2024-1 Matrix Output {7,25,0} {'Year',"'Stock unit'",NULL} First year Abundance _ NA Mean NA NA Count First year: Number (log scale) of eggs deposited in rivers by spawners NA
log_N9_pr SAL WGNAS SAL-2024-1 Vector Output {25,0,0} {"'Stock unit'",NULL,NULL} First year Abundance _ NA Estimate NA NA Count First year: Abundance (log scale) of 2SW adults returning to homewaters NA
logN2 SAL WGNAS SAL-2024-1 Matrix Output {47,25,0} {'Year',"'Stock unit'",NULL} Fit Abundance _ NA Estimate NA NA Count Observed number of smolts in log scale NA
logN2_pr SAL WGNAS SAL-2024-1 Matrix Output {7,25,0} {'Year',"'Stock unit'",NULL} First year Abundance _ NA Mean NA NA Count First year: Pre-smolt abundance (log scale) NA
logN4 SAL WGNAS SAL-2024-1 Matrix Output {47,25,0} {'Year',"'Stock unit'",NULL} Fit Abundance _ NA Estimate NA NA Count Pre-fishery salmons abundance (log scale) NA
logN5 SAL WGNAS SAL-2024-1 Matrix Output {47,25,0} {'Year',"'Stock unit'",NULL} Fit Abundance _ NA Estimate NA NA Count Abundance (log scale) of mature salmons after 1SW NA
logN8 SAL WGNAS SAL-2024-1 Matrix Output {47,25,0} {'Year',"'Stock unit'",NULL} Fit Abundance _ NA Estimate NA NA Count Abundance (log scale) of mature salmons after 2SW NA
mean_log_N9_pr SAL WGNAS SAL-2024-1 Vector Output {25,0,0} {"'Stock unit'",NULL,NULL} First year Abundance _ NA Mean NA NA Count First year: mean for distribution for abundance (log scale) of 2SW adults returning to homewaters NA
N1 SAL WGNAS SAL-2024-1 Matrix Output {47,25,0} {'Year',"'Stock unit'",NULL} Fit Abundance _ NA Estimate NA NA Count Number of eggs deposited in rivers by spawners NA
N1_pr SAL WGNAS SAL-2024-1 Matrix Output {7,25,0} {'Year',"'Stock unit'",NULL} First year Abundance _ NA Estimate NA NA Count First year: Number of eggs deposited in rivers by spawners NA
N10 SAL WGNAS SAL-2024-1 Matrix Output {47,25,0} {'Year',"'Stock unit'",NULL} Fit Abundance _ NA Estimate NA NA Count Abundance of 2SW spawners in homewaters NA
N3 SAL WGNAS SAL-2024-1 Array Output {47,6,25} {'Year',"'Age fresh water'","'Stock unit'"} Fit Abundance _ NA Estimate NA NA Count Abundance of smolts of each age starting migration NA
N3_pr SAL WGNAS SAL-2024-1 Array Output {13,6,25} {'Year',"'Age fresh water'","'Stock unit'"} First year Abundance _ NA Estimate NA NA Count First year: Abundance of smolts of each age starting migration NA
N3_tot SAL WGNAS SAL-2024-1 Matrix Output {47,25,0} {'Year',"'Stock unit'",NULL} Fit Abundance _ NA Estimate NA NA Count Total abundance of smolts of each age starting migration over all Sus NA
N4 SAL WGNAS SAL-2024-1 Matrix Output {47,25,0} {'Year',"'Stock unit'",NULL} Fit Abundance _ NA Estimate NA NA Count Pre-fishery salmons abundance NA
N5 SAL WGNAS SAL-2024-1 Matrix Output {47,25,0} {'Year',"'Stock unit'",NULL} Fit Abundance _ NA Estimate NA NA Count Abundance of mature salmons after 1SW NA
N7 SAL WGNAS SAL-2024-1 Matrix Output {47,25,0} {'Year',"'Stock unit'",NULL} Fit Abundance _ NA Estimate NA NA Count Abundance of 1SW spawners in homewaters NA
N8_1 SAL WGNAS SAL-2024-1 Matrix Output {47,25,0} {'Year',"'Stock unit'",NULL} Fit Abundance _ NA Estimate NA NA Count Abundance of 2SW individuals from the NAC complex after early catches by Newfoundland and Labrador catches NA
N8_2 SAL WGNAS SAL-2024-1 Matrix Output {47,25,0} {'Year',"'Stock unit'",NULL} Fit Abundance _ NA Estimate NA NA Count Abundance of 2SW individuals (mixed complexes) arriving at Greenland NA
CV_dummy SAL WGNAS SAL-2024-1 Single_value Parameter constant {1,0,0} {'CV_dummy',NULL,NULL} Fit Demographic transitions _ NA CV NA NA Other Coefficient of variation for demographic transitions NA
mu_psm_pr SAL WGNAS SAL-2024-1 Array Output {7,6,25} {'Year',"'Age fresh water'","'Stock unit'"} First year First year _ NA Hyperparameter NA NA Other First year: Prior on the proportions of each smolt age in the total number of smolts NA
h5_NAC_1 SAL WGNAS SAL-2024-1 Vector Output {47,0,0} {'Year',NULL,NULL} Fit High seas harvest rates NF/LB fisheries neNF Estimate NA NA Mortality Harvest rate of 1SW adults from the NAC complex due to early Newfoundland fisheries NA
h5_NAC_2 SAL WGNAS SAL-2024-1 Matrix Output {47,6,0} {'Year',"'Stock unit NAC'",NULL} Fit High seas harvest rates NF/LB/SPM fisheries LB-LB/SPM/swNF fishery Estimate NA NA Mortality Harvest rate of 1SW adults from the NAC complex due to late Newfoundland, Labrador and Saint Pierre et Miquelon fisheries NA
h5_NEC_1 SAL WGNAS SAL-2024-1 Matrix Output {47,19,0} {'Year',"'Stock unit NEC'",NULL} Fit High seas harvest rates FAR fisheries FAR fishery Estimate NA NA Mortality Harvest rate of 1SW adults from the NEC complex due to exploitation in Faroe islands NA
h8_2 SAL WGNAS SAL-2024-1 Matrix Output {47,25,0} {'Year',"'Stock unit'",NULL} Fit High seas harvest rates GLD fisheries GLD fishery Estimate NA NA Mortality Harvest rate of 2SW individuals from all complexes due to Greenland fisheries NA
h8_NAC_1 SAL WGNAS SAL-2024-1 Vector Output {47,0,0} {'Year',NULL,NULL} Fit High seas harvest rates NF/LB fisheries neNF Estimate NA NA Mortality Harvest rate of 2SW individuals from the NAC complex due to Newfoundland and Labrador fisheries before reaching Greenland NA
h8_NAC_3 SAL WGNAS SAL-2024-1 Vector Output {47,0,0} {'Year',NULL,NULL} Fit High seas harvest rates NF fisheries neNF Estimate NA NA Mortality Harvest rate of NAC 2SW adults due to late regional fisheries in Newfoundland NA
h8_NAC_4 SAL WGNAS SAL-2024-1 Matrix Output {47,6,0} {'Year',"'Stock unit NAC'",NULL} Fit High seas harvest rates LB/SPM fisheries tot LB-LB/SPM/swNF fishery Estimate NA NA Mortality Harvest rate of NAC 2SW adults due to late regional fisheries in Labrador and Saint Pierre et Miquelon NA
h8_NAC_4_lab SAL WGNAS SAL-2024-1 Vector Output {47,0,0} {'Year',NULL,NULL} Fit High seas harvest rates LB/SPM fisheries in Lb LB fishery Estimate NA NA Mortality Harvest rate of NAC 2SW adults from the Labrador SU due to late regional fisheries in Labrador NA
h8_NAC_4_other SAL WGNAS SAL-2024-1 Vector Output {47,0,0} {'Year',NULL,NULL} Fit High seas harvest rates LB/SPM fisheries out. Lb LB/SPM/swNF fishery Estimate NA NA Mortality Harvest rate of 2SW adults from NAC SUs excluding Labrador due to late regional fisheries in Labrador and Saint Pierre et Miquelon NA
tau_theta3 SAL WGNAS SAL-2024-1 Matrix Output {25,25,0} {"'Stock unit'","'Stock unit'",NULL} Fit Survival rate _ NA Precision NA NA Mortality Standard deviation between smolt and pre-fishery stages NA
h8_NEC_1 SAL WGNAS SAL-2024-1 Matrix Output {47,19,0} {'Year',"'Stock unit NEC'",NULL} Fit High seas harvest rates FAR fisheries FAR fishery Estimate NA NA Mortality Harvest rate of 2SW adults from the NEC complex due to exploitation in Faroe islands NA
h8_NEC_3 SAL WGNAS SAL-2024-1 Matrix Output {47,19,0} {'Year',"'Stock unit NEC'",NULL} Fit High seas harvest rates FAR fisheries FAR fishery Estimate NA NA Mortality Harvest rate of NEC 2SW adults due to late regional fisheries in Faroes NA
CV_N1_pr SAL WGNAS SAL-2024-1 Single_value Parameter constant {1,0,0} {'CV_N1_pr',NULL,NULL} First year Initialization first year _ NA CV NA NA Other First year: CV for Number of eggs deposited in rivers by spawners NA
E_theta1_pr SAL WGNAS SAL-2024-1 Matrix Parameter constant {7,25,0} {'Year',"'Stock unit'",NULL} First year Initialization first year _ NA Mean NA NA Other First year: Mean eggs-smolts survival rate NA
max_log_N9 SAL WGNAS SAL-2024-1 Vector Parameter constant {25,0,0} {"'Stock unit'",NULL,NULL} First year Initialization first year _ NA Bound NA NA Other First year: upper bound for Abundance of 2SW adults returning to homewaters NA
min_log_N9 SAL WGNAS SAL-2024-1 Vector Parameter constant {25,0,0} {"'Stock unit'",NULL,NULL} First year Initialization first year _ NA Bound NA NA Other First year: lower bound for Abundance of 2SW adults returning to homewaters NA
theta1 SAL WGNAS SAL-2024-1 Matrix Output {47,25,0} {'Year',"'Stock unit'",NULL} Fit Survival rate _ NA Estimate NA NA Mortality Eggs-smolts survival rate NA
mu_N1_pr SAL WGNAS SAL-2024-1 Vector Parameter constant {25,0,0} {"'Stock unit'",NULL,NULL} First year Initialization first year _ NA Mean NA NA Other First year: mean for distribution Number of eggs deposited in rivers by spawners NA
p_smolt_pr SAL WGNAS SAL-2024-1 Array Parameter constant {8,6,25} {'Year',"'Age fresh water'","'Stock unit'"} First year Initialization first year _ NA Mean NA NA Other First year: Hyperparameters of the Dirichlet distribution used for representing smolt age proportions NA
logit_theta4 SAL WGNAS SAL-2024-1 Matrix Output {47,25,0} {'Year',"'Stock unit'",NULL} Fit Maturation rate _ NA Estimate NA NA Life trait Maturation rate (logit) between delimiting the transition between the pre-fishery stage and 1SW mature salmons NA
tau_theta4 SAL WGNAS SAL-2024-1 Matrix Output {25,25,0} {"'Stock unit'","'Stock unit'",NULL} Fit Maturation rate _ NA Precision NA NA Life trait Precision matrix used to model variance-covariance structure of the maturation rate PFA-1SW between Sus NA
theta4 SAL WGNAS SAL-2024-1 Matrix Output {47,25,0} {'Year',"'Stock unit'",NULL} Fit Maturation rate _ NA Estimate NA NA Life trait Maturation rate between delimiting the transition between the pre-fishery stage and 1SW mature salmons NA
CV_M SAL WGNAS SAL-2024-1 Single_value Parameter constant {1,0,0} {"'Stock unit'",NULL,NULL} Fit Natural mortality rate _ NA CV NA NA NA Coefficient of variation of the monthly natural mortality for post-smolt stages at sea NA
E_log_M SAL WGNAS SAL-2024-1 Matrix Parameter constant {47,25,0} {'Year',"'Stock unit'",NULL} Fit Natural mortality rate _ NA Mean NA NA NA Mean (logscale) of the monthly natural mortality for post-smolt stages at sea when using lognormal distribution NA
E_M SAL WGNAS SAL-2024-1 Single_value Parameter constant {1,0,0} {'E_M',NULL,NULL} Fit Natural mortality rate _ NA Mean NA NA NA Mean single value used to set mortality rate values NA
nSm SAL WGNAS SAL-2024-1 Single_value Parameter constant {1,0,0} {'nSm',NULL,NULL} Fit Number of smolt ages _ NA Index NA NA NA Number of smolt ages considered NA
N SAL WGNAS SAL-2024-1 Single_value Parameter constant {1,0,0} {'N',NULL,NULL} Fit Number of SU _ NA Index NA NA Other Number of Stock units considered NA
N_NAC SAL WGNAS SAL-2024-1 Single_value Parameter constant {1,0,0} {'N_NAC',NULL,NULL} Fit Number of SU _ NA Index NA NA Other Number of SU in the NAC complex NA
N_NEC SAL WGNAS SAL-2024-1 Single_value Parameter constant {1,0,0} {'N_NEC',NULL,NULL} Fit Number of SU _ NA Index NA NA Other Number of SU in the NEC complex NA
date_begin SAL WGNAS SAL-2024-1 Single_value Parameter constant {1,0,0} {'date_begin',NULL,NULL} Fit Number of years _ NA Index NA NA Other First time-step of the model NA
date_end SAL WGNAS SAL-2024-1 Single_value Parameter constant {1,0,0} {'date_end',NULL,NULL} Fit Number of years _ NA Index NA NA Other Length of the up-to-date variables NA
date_end_hindcast SAL WGNAS SAL-2024-1 Single_value Parameter constant {1,0,0} {'date_end_hindcast',NULL,NULL} Fit Number of years _ NA Index NA NA Other Final time-step of the hindcast period NA
N_Sample SAL WGNAS SAL-2024-1 Vector Parameter constant {50,0,0} {'Year',NULL,NULL} Fit Prior hyperparameter _ NA Hyperparameter NA NA Other Equivalent sampling size in the Dirichlet distribution used for fish distribution between Sus NA
N_Sample_sm SAL WGNAS SAL-2024-1 Single_value Parameter constant {1,0,0} {'N_sample_sm',NULL,NULL} Fit Prior hyperparameter _ NA Hyperparameter NA NA Other Equivalent sampling size in the Dirichlet distribution used for representing smolt ages proportions NA
omega SAL WGNAS SAL-2024-1 Matrix Parameter constant {25,25,0} {"'Stock unit'","'Stock unit'",NULL} Fit Prior hyperparameter _ NA Hyperparameter NA NA Other Identify matrix for the formulationof Wishart priors NA
p_smolt_gamma_pr SAL WGNAS SAL-2024-1 Array Output {7,6,25} {'Year',"'Age fresh water'","'Stock unit'"} First year Prior hyperparameter _ NA Hyperparameter NA NA Other First year: Gamma distribution hyperparameters used to build the Dirichlet distribution for smolt ages proportions NA
p_smolt_stoch_pr SAL WGNAS SAL-2024-1 Array Output {7,6,25} {'Year',"'Age fresh water'","'Stock unit'"} First year Prior hyperparameter _ NA Hyperparameter NA NA Other First year: Proportions of each smolt age in the total number of smolts NA
N6 SAL WGNAS SAL-2024-1 Matrix Output {47,25,0} {'Year',"'Stock unit'",NULL} Fit Returns _ NA Estimate NA NA Count Abundance of 1SW adults returning to homewaters NA
N9 SAL WGNAS SAL-2024-1 Matrix Output {47,25,0} {'Year',"'Stock unit'",NULL} Fit Returns _ NA Estimate NA NA Count Abundance of 2SW adults returning to homewaters NA
h6_hw SAL WGNAS SAL-2024-1 Matrix Output {47,25,0} {'Year',"'Stock unit'",NULL} Fit River harvest rates _ main Estimate NA NA Mortality Harvest rate for 1SW spawners in home waters NA
h6_hw_delSp SAL WGNAS SAL-2024-1 Matrix Output {47,25,0} {'Year',"'Stock unit'",NULL} Fit River harvest rates _ delayed spawners Estimate NA NA Mortality Harvest rate for delayed 1SW spawners in home waters NA
h9_hw SAL WGNAS SAL-2024-1 Matrix Output {47,25,0} {'Year',"'Stock unit'",NULL} Fit River harvest rates _ main Estimate NA NA Mortality Harvest rate for 2SW spawners in home waters NA
h9_hw_delSp SAL WGNAS SAL-2024-1 Matrix Output {47,25,0} {'Year',"'Stock unit'",NULL} Fit River harvest rates _ delayed spawners Estimate NA NA Mortality Harvest rate for delayed 2SW spawners in home waters NA
logit_theta3 SAL WGNAS SAL-2024-1 Matrix Output {47,25,0} {'Year',"'Stock unit'",NULL} Fit Survival rate _ NA Estimate NA NA Mortality Survival (logit) between smolt and pre-fishery stages NA
logit_theta3_pr SAL WGNAS SAL-2024-1 Vector Output {25,0,0} {"'Stock unit'",NULL,NULL} First year Survival rate _ NA Estimate NA NA Mortality First year: Survival (logit) between smolt and pre-fishery stages NA
theta1_ddp SAL WGNAS SAL-2024-1 Matrix Output {47,25,0} {'Year',"'Stock unit'",NULL} Fit Survival rate _ NA Estimate NA NA Mortality Eggs-smolts survival rate when representing density-dependence NA
theta1_ddp_pr SAL WGNAS SAL-2024-1 Matrix Output {7,25,0} {'Year',"'Stock unit'",NULL} First year Survival rate _ NA Mean NA NA Mortality First year: Eggs-smolts survival rate when representing density-dependence NA
theta3 SAL WGNAS SAL-2024-1 Matrix Output {47,25,0} {'Year',"'Stock unit'",NULL} Fit Survival rate _ NA Estimate NA NA Mortality Survival between smolt and pre-fishery stages NA
theta3_pr SAL WGNAS SAL-2024-1 Vector Output {25,0,0} {"'Stock unit'",NULL,NULL} First year Survival rate _ NA Estimate NA NA Mortality First year: Survival between smolt and pre-fishery stages NA
theta5_1_NAC SAL WGNAS SAL-2024-1 Vector Output {6,0,0} {"'Stock unit NAC'",NULL,NULL} Fit Survival rate Bef. NF/LB fisheries NA Mean NA NA Mortality Survival rate of 1SW adults from the NAC complex before Newfoundland fisheries NA
theta5_1_NEC SAL WGNAS SAL-2024-1 Vector Output {19,0,0} {"'Stock unit NEC'",NULL,NULL} Fit Survival rate Bef. FAR fisheries NA Mean NA NA Mortality Survival rate of 1SW adults from the NEC complex before Faroes fisheries NA
theta5_2_NAC SAL WGNAS SAL-2024-1 Vector Output {6,0,0} {"'Stock unit NAC'",NULL,NULL} Fit Survival rate Aft. NF/LB fisheries NA Mean NA NA Mortality Survival rate of 1SW adults from the NAC complex after Newfoundland fisheries and before Labrador fisheries NA
theta5_2_NEC SAL WGNAS SAL-2024-1 Vector Output {19,0,0} {"'Stock unit NEC'",NULL,NULL} Fit Survival rate Aft. FAR fisheries NA Mean NA NA Mortality Survival rate of 1SW adults from the NEC complex after Faroes fisheries NA
theta8_1_NAC SAL WGNAS SAL-2024-1 Vector Output {6,0,0} {"'Stock unit NAC'",NULL,NULL} Fit Survival rate Bef. NF/LB fisheries NA Mean NA NA Mortality Survival rate of 2SW individuals from the NAC complex before Newfoundland and Labrador fisheries NA
theta8_1_NEC SAL WGNAS SAL-2024-1 Vector Output {19,0,0} {"'Stock unit NEC'",NULL,NULL} Fit Survival rate Bef. FAR fisheries NA Mean NA NA Mortality Survival rate of 2SW individuals from the NEC complex before Faroes fisheries NA
theta8_2 SAL WGNAS SAL-2024-1 Vector Output {25,0,0} {"'Stock unit'",NULL,NULL} Fit Survival rate _ NA Estimate NA NA Mortality Survival rate of NEC and NAC 2SW individuals after early fisheries and before reaching Greenland NA
theta8_2_1_NAC SAL WGNAS SAL-2024-1 Vector Output {6,0,0} {"'Stock unit NAC'",NULL,NULL} Fit Survival rate Btw. NF/LB - GLD fisheries NA Mean NA NA Mortality Survival rate of NAC 2SW individuals in the environment after Greenland catches and before late Newfoundland, Labrador and St Pierre et Miquelon fisheries NA
theta8_2_1_NEC SAL WGNAS SAL-2024-1 Vector Output {19,0,0} {"'Stock unit NEC'",NULL,NULL} Fit Survival rate Btw. FAR - GLD fisheries NA Mean NA NA Mortality Survival rate of NEC 2SW individuals in the environment after Greenland catches and before Faroes fisheries NA
theta8_2_2_NAC SAL WGNAS SAL-2024-1 Vector Output {6,0,0} {"'Stock unit NAC'",NULL,NULL} Fit Survival rate Btw. GLD - NF/LB fisheries NA Mean NA NA Mortality Survival rate of NAC 2SW individuals in the environment after late Newfoundland, Labrador and St Pierre et Miquelon fisheries NA
theta8_2_2_NEC SAL WGNAS SAL-2024-1 Vector Output {19,0,0} {"'Stock unit NEC'",NULL,NULL} Fit Survival rate Btw. GLD - FAR fisheries NA Mean NA NA Mortality Survival rate of NEC 2SW individuals in the environment after late Faroes fisheries NA

Area (tr_area_are)

Here I’m trying to build something consistent. I guess only the final result will tell but I have to start somewhere … A good idea to simploify the structure of the db is to get together marine and continental areas.

Continental areas

Code to create area
dbExecute(con_diaspara_admin,
"DROP TABLE IF EXISTS ref.tr_level_lev CASCADE;")

dbExecute(con_diaspara_admin,
"CREATE TABLE ref.tr_level_lev(
   lev_code TEXT PRIMARY KEY,
   lev_description TEXT  
);")

dbExecute(con_diaspara_admin,
  "INSERT INTO ref.tr_level_lev VALUES( 
  'Panpopulation',
  'This is the highest geographic level for assessement.'  
  );")

dbExecute(con_diaspara_admin,
  "INSERT INTO ref.tr_level_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_level_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_level_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_level_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_level_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_level_lev VALUES( 
  'River',
  'One river is a unit corresponding practically almost always to a watershed.'
  );")

dbExecute(con_diaspara_admin,
  "INSERT INTO ref.tr_level_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_level_lev VALUES( 
  'Major',
  'Major fishing areas from ICES.'
  );")

dbExecute(con_diaspara_admin,
  "INSERT INTO ref.tr_level_lev VALUES( 
  'Subarea',
  'Subarea from ICES, FAO and NAFO'
  );")

dbExecute(con_diaspara_admin,
  "INSERT INTO ref.tr_level_lev VALUES( 
  'Division',
  'Division from ICES, GFCM and NAFO'
  );")

dbExecute(con_diaspara_admin,
  "INSERT INTO ref.tr_level_lev VALUES( 
  'Subdivision',
  'Subdivision level from ICES, GFCM and NAFO'
  );")

dbExecute(con_diaspara_admin, "COMMENT ON TABLE ref.tr_level_lev 
IS 'Table of geographic levels stock, complex, country, region, basin, river,
the specific order depend according to working groups.';")

dbExecute(con_diaspara_admin, "GRANT ALL ON ref.tr_level_lev 
          TO diaspara_admin;")
dbExecute(con_diaspara_admin, "GRANT SELECT ON ref.tr_level_lev 
          TO diaspara_read;")


dbExecute(con_diaspara_admin,
"DROP TABLE IF EXISTS ref.tr_area_are CASCADE;")
dbExecute(con_diaspara_admin,
"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,
   geom geometry(MULTIPOLYGON, 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_level_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
);")

dbExecute(con_diaspara_admin, "GRANT ALL ON ref.tr_area_are 
          TO diaspara_admin;")
dbExecute(con_diaspara_admin, "GRANT SELECT ON ref.tr_area_are 
          TO diaspara_read;")

dbExecute(con_diaspara_admin, "COMMENT ON TABLE ref.tr_area_are 
IS 'Table corresponding to different geographic levels, from stock 
to river section.';")
Table 14: Geographical level tr_level_lev
lev_code lev_description
Stock This is the highest geographic level for assessement, stock level.
Complex Corresponds to large sublevels at which the stock is assessed, e.g. NAC NEC for WGNAST, Gulf of Bothnia for WGBAST, Mediterranean for WGEEL.
Country Corresponds to one or more units, but in almost all stocks this level is relevant to split data.
Assessment_unit Corresponds to an assessment unit in the Baltic sea, and area for WGNAS, and EMU for WGEEL.
Regional Corresponds to subunits of stock assessment units or basins grouping several river. Although it is not used yet for some models, regional genetic difference or difference in stock dynamic support collecting a regional leve
River One river is a unit corresponding practically almost always to a watershed.
river_section Section of river, only a part of a basin, for instance to separate between wild and mixed river category in the Baltic.
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
Note from Hilaire

The working groups might change over time, referencing a working group there is probably not the best. Cédric : Added stockkeylabel, this table is necessary to aggregate data (species is not enough).

Table 15: Geographic areas
are_id are_are_id are_code are_lev_code are_wkg_code are_ismarine geom
1 1 Baltic Stock WGBAST NA NA
2 1 Baltic marine Stock WGBAST TRUE 0106000020E61000000200000001030000002500000021080000304CA60A46C5254011363CBD522E4B40B515FBCBEEA92540984C158C4A2A4B40D7A3703D0A9725409CA223B9FC274B40EC51B81E858B254065AA605452274B40A8C64B37896125408F53742497274B40B459F5B9DA4A2540D0D556EC2F2B4B400EBE30992A382540A01A2FDD242E4B40CD3B4ED191BC24409D11A5BDC1374B408CB96B09F9402440F46C567DAE3E4B4011363CBD52362440CA54C1A8A43E4B4033C4B12E6E032440B1E1E995B23C4B409A081B9E5EC92340C3D32B65193A4B4008AC1C5A64BB2340FB3A70CE883A4B40C5FEB27BF2B0234069006F81043D4B405917B7D100BE234085EB51B81E3D4B407E1D386744C92340A1F831E6AE3D4B40C5FEB27BF2F02340295C8FC2F5404B40E0BE0E9C330224402575029A08434B40713D0AD7A310244002BC051214474B4014AE47E17A1424407E8CB96B09514B40A5BDC11726132440F697DD9387554B408B6CE7FBA9F12340FE65F7E461614B409031772D21DF23406ABC749318644B4076711B0DE0CD2340CCEEC9C342654B40A779C7293A9223405BB1BFEC9E644B40A779C7293A522340D5E76A2BF6674B40B98D06F0162823408B6CE7FBA9694B408CB96B09F9E022408195438B6C674B40DC4603780BE42240280F0BB5A6694B40F31FD26F5FE72240A69BC420B06A4B408CDB68006F012340F38E5374246F4B4052B81E85EB312340499D8026C2764B404FAF94658843234091ED7C3F35764B40613255302A492340EB73B515FB734B400A68226C783A2340A7E8482EFF714B408F537424973F2340CCEEC9C3426D4B407F6ABC749378234027C286A7576A4B4063EE5A423E8823403411363CBD724B40AED85F764F7E23400C93A98251794B4088F4DBD781732340BB270F0BB57E4B404B598638D6452340C3D32B6519824B40D42B6519E21823405C8FC2F528844B40A4703D0AD7032340917EFB3A70864B403F355EBA49EC2240BA6B09F9A08F4B40265305A392FA224096218E7571934B402E90A0F831262340C74B378941984B40273108AC1C3A2340713D0AD7A3984B402F6EA301BC4523408104C58F31974B40423EE8D9AC5A2340637FD93D79984B405DFE43FAED6B23406688635DDC9E4B40D3DEE00B936923407D3F355EBAA14B402B8716D9CE57234016FBCBEEC9A34B40E02D90A0F8312340643BDF4F8DAF4B40637FD93D793823406DC5FEB27BB24B40A4DFBE0E9C332340A5BDC11726B34B4004E78C28ED2D2340F697DD9387B54B40B8AF03E78C682340EB73B515FBC34B4033C4B12E6EA3234013F241CF66CD4B40E10B93A9827123404182E2C798D34B4026E4839ECD4A23408E06F01648D84B40EBE2361AC03B2340295C8FC2F5D84B40F241CF66D5272340B84082E2C7D84B4024B9FC87F41B2340448B6CE7FBD94B4027A089B0E1492340EC2FBB270FDB4B40CE1951DA1B5C2340B537F8C264DA4B40849ECDAACF752340728A8EE4F2D74B40E9482EFF219D234092CB7F48BFD54B40992A1895D4A923406744696FF0D54B4007F0164850FC23400AD7A3703DDA4B404850FC18731724402B1895D409E04B4082E2C798BB16244071AC8BDB68E84B400000000000002440613255302AE94B40EFC9C342ADE923409A99999999E94B40637FD93D79D8234099BB96900FEA4B40BC0512143FC62340C286A757CAEA4B40053411363CBD2340B22E6EA301EC4B40D7A3703D0AF723402BF697DD93EF4B404A7B832F4C062440728A8EE4F2EF4B4023DBF97E6A1C24409CC420B072F04B4089D2DEE00B3324404694F6065FF04B40E09C11A5BD4124409FCDAACFD5EE4B407E1D38674449244096B20C71ACEB4B40E6AE25E4835E24400B46257502EA4B4071AC8BDB68802440DAACFA5C6DF54B40E561A1D6348F24407CF2B0506B024C40DC68006F8184244097900F7A360B4C4099BB96900F7A24408104C58F310F4C403A234A7B836F244052499D8026124C40265305A3927A244012A5BDC117164C40228E75711BCD2440A1D634EF38254C40A1F831E6AEE52440E8D9ACFA5C254C403480B74082022540A69BC420B0224C40A167B3EA73F52440B1BFEC9E3C1C4C40728A8EE4F2DF2440F931E6AE251C4C40D95F764F1EB62440E17A14AE47194C4048E17A14AEC72440789CA223B9144C4060764F1E160A2540A2B437F8C20C4C40F0164850FC1825405B423EE8D90C4C40F5B9DA8AFD252540736891ED7C0F4C40ED9E3C2CD41A254095D4096822144C4004E78C28ED2D254098DD9387851A4C404182E2C7983B2540BE9F1A2FDD1C4C40D49AE61DA7482540E8D9ACFA5C1D4C4003780B24285E2540075F984C151C4C4003780B24285E2540D42B6519E2184C408313D1AFAD692540B461660272174C40EE0E63B1D168254046E4C30583154C40F668E4D27C6E254013FB1DED2C124C4011DF0D92D38D264037F56847FD004C4018EF0199218E26403356B49CF8004C40C126A57FCD90264013EFDF4071004C40E1F2F5087795264072DFACB90AFF4B404CB1DD1C329A2640FDC35402FBFD4B405DFE43FAED8B2640BBB88D06F0FE4B4020D26F5F078E26403EE8D9ACFAFC4B400EBE30992AB826407DAEB6627FF94B401895D40968C226408C4AEA0434F94B40F5B9DA8AFDE52640713D0AD7A3F84B40DE718A8EE4F22640B98D06F016F84B40EBE2361AC0FB264002BC051214F74B40F853E3A59B0427405A643BDF4FF54B4063EE5A423E082740265305A392F24B40F5B9DA8AFD0527401B0DE02D90F04B4088635DDC46032740AC8BDB6800EF4B4002BC051214FF26406891ED7C3FED4B4045D8F0F44AF9264088855AD3BCEB4B40006F8104C5AF264048E17A14AEDF4B40075F984C156C26405396218E75D94B4082734694F666264036AB3E575BD94B4070CE88D2DE6026407DAEB6627FD94B4011363CBD525626407DD0B359F5D94B4058A835CD3B4E2640ED0DBE3099DA4B4082734694F64626407A36AB3E57DB4B406E3480B740422640F8C264AA60DC4B409CA223B9FCE725405839B4C876DE4B405227A089B0E12540D881734694DE4B4041F163CC5DCB2540029A081B9EDE4B401895D40968C22540F5B9DA8AFDDD4B40CC5D4BC807FD2540713D0AD7A3D84B4011C7BAB88D262640D95F764F1ED64B40B1BFEC9E3C2C2640F7065F984CD54B40B515FBCBEE49264052B81E85EBC94B405C2041F1634C2640713D0AD7A3C84B4063EE5A423E6826405396218E75B94B401D386744696F26403411363CBDB24B40AA60545227602640A54E401361AB4B4076E09C11A57D2640C442AD69DE994B404ED1915CFE832640B7D100DE02994B4096B20C71AC8B26409B559FABAD984B40789CA223B99C2640711B0DE02D984B40DAACFA5C6DA52640AAF1D24D62984B40A4DFBE0E9CB326400BB5A679C7994B40772D211FF4CC2640091B9E5E299B4B40A167B3EA73D52640083D9B559F9B4B402575029A08DB2640083D9B559F9B4B400E4FAF9465E8264033333333339B4B40EFC9C342AD0927409A99999999994B404BEA0434111627409B559FABAD984B40D0D556EC2F1B2740D50968226C984B40EF38454772392740D5E76A2BF6974B40E2E995B20C512740D5E76A2BF6974B40AEB6627FD95D2740EEEBC039239A4B40DD24068195632740265305A3929A4B403A234A7B836F2740A60A4625759A4B4067D5E76A2B76274099BB96900F9A4B4096218E75717B27405396218E75994B40637FD93D79982740C05B2041F1934B40C5FEB27BF2902740295C8FC2F5904B404BEA0434117627409D11A5BDC1874B4058A835CD3BAE274097FF907EFB824B400EBE30992AB827400BB5A679C7814B40CCEEC9C342CD274093A98251497D4B40986E1283C0CA2740917EFB3A707E4B40FB5C6DC5FED227408D976E1283804B40FD87F4DBD7E127401C7C613255804B40D734EF3845E72740728A8EE4F27F4B40865AD3BCE3F42740211FF46C567D4B403D0AD7A370FD2740CEAACFD5567C4B40CCC6D675A0FF2740574C7C203F7C4B40D712F241CF062840C05B2041F17B4B4030BB270F0B1528405D6DC5FEB27B4B40302AA913D0242840EB73B515FB7B4B408C4AEA043451284002BC0512147F4B408126C286A7572840C7BAB88D06804B402497FF907E5B2840BA490C022B8F4B40780B24287E4C28409B559FABAD904B40894160E5D0422840705F07CE19914B407B14AE47E13A284054742497FF904B40022B8716D92E2840545227A089904B4066666666662628402A3A92CB7F904B401DC9E53FA41F284070CE88D2DE904B40D656EC2FBB072840A4DFBE0E9C934B40228E75711B0D2840A1F831E6AE954B406DC5FEB27B122840CA32C4B12E964B40B5A679C7295A2840B1BFEC9E3C9C4B40B98D06F01668284077BE9F1A2F9D4B4022FDF675E07C284011363CBD529E4B40EC51B81E858B28406744696FF09D4B40BC96900F7A9628404B598638D69D4B40A8C64B3789A128402041F163CC9D4B40F085C954C1A82840925CFE43FA9D4B403333333333D328408D28ED0DBEA04B400B46257502DA28407DAEB6627FA14B40DC68006F81E42840DE02098A1FA34B40226C787AA5EC2840F775E09C11A54B40060EAA05DDE9284030B58C7151A84B40F241CF66D5E72840A69BC420B0AA4B4033C4B12E6EE3284031992A1895AC4B40AEB6627FD9DD284020D26F5F07AE4B40780B24287ECC2840B84082E2C7B04B4070CE88D2DEC02840ED0DBE3099B24B405F07CE1951BA2840EC2FBB270FB34B40ABCFD556ECAF2840CF66D5E76AB34B40637FD93D799828404182E2C798B34B404D840D4FAF742840AD69DE718AB64B40992A1895D46928401CEBE2361AB84B40BEC1172653652840C520B07268B94B4052499D8026622840174850FC18BB4B403480B7408262284092CB7F48BFBD4B409A081B9E5E6928408E06F01648C04B40E9482EFF217D2840840D4FAF94C54B405227A089B08128401F85EB51B8C64B40B515FBCBEE89284048E17A14AEC74B40E7FBA9F1D2AD2840B30C71AC8BCB4B401C7C613255B0284096438B6CE7CB4B4034A2B437F8C22840AE47E17A14CE4B400E4FAF9465C82840AD69DE718ACE4B4074B515FBCBCE2840BBB88D06F0CE4B404772F90FE9D7284090A0F831E6CE4B403D0AD7A370DD284074B515FBCBCE4B40516B9A779CE22840598638D6C5CD4B40956588635DFC2840CCEEC9C342CD4B408CDB68006F012940E25817B7D1D04B405C2041F1630C2940FD87F4DBD7D14B40865AD3BCE31429404F1E166A4DD34B409A9999999919294032772D211FD44B40E5F21FD26F1F2940E8D9ACFA5CD54B401904560E2D322940B515FBCBEED94B407AA52C431C2B2940D95F764F1EDE4B40DE9387855A3329401B0DE02D90E04B403333333333332940E0BE0E9C33E24B4052B81E85EB3129403D2CD49AE6E54B40F5DBD781732629405C2041F163EC4B406E3480B740222940F6285C8FC2ED4B4003780B24281E2940AC8BDB6800EF4B40992A1895D409294086C954C1A8F44B407FD93D7958082940AE47E17A14F64B4058A835CD3B0E2940454772F90FF94B404ED1915CFE232940AC1C5A643BFF4B407AA52C431C2B2940ABCFD556ECFF4B4055302AA913302940462575029A004C4040A4DFBE0E3C2940E9482EFF21054C408C4AEA043411294027C286A7570A4C40D734EF38450729405E4BC8073D0B4C40EFC9C342ADA92840E4141DC9E50F4C400000000000A028408E06F01648104C400A68226C789A2840FF21FDF675104C407725340F8197284032A5BB0C7B104C407BA5C91861E42840EC7AB3179B264C401100FB6C0DEA2840F2F211846D264C40E22BB28452EB28407318C4EE58264C40C50C228C7EFC284025C4019942254C400AD87170A7FE2840F18D7448E2244C407AC7293A92EB2840925CFE43FA254C4044696FF085292940EEEBC03923124C4092CB7F48BF3D2940E7FBA9F1D20D4C404F401361C353294099BB96900F0A4C4022FDF675E05C2940ABCFD556EC074C40DE9387855AD3294088635DDC46EB4B40D0D556EC2FDB294036AB3E575BE94B403A92CB7F481F2A40F38E537424D74B40DDB5847CD0132A4063EE5A423ED04B4082E2C798BBF62940B1E1E995B2CC4B4096B20C71ACEB29403255302AA9CB4B408126C286A7D729407E1D386744C94B40857CD0B359D5294076711B0DE0C54B40DF51A55E9EF32940429348CB16B54B402D431CEBE2F6294088635DDC46B34B40107A36AB3E972A405D6DC5FEB2AB4B40C6DCB5847CB02A40CF66D5E76AAB4B4055C1A8A44EC02A40EC51B81E85AB4B400C022B8716D92A40AF94658863AD4B401FF46C567DEE2A408FE4F21FD2AF4B40C9E53FA4DFFE2A40FE43FAEDEBB04B4012A5BDC117462B40211FF46C56B54B4096B20C71AC6B2B404A7B832F4CB64B404BEA043411762B40BC96900F7AB64B400E4FAF9465C82B40D6C56D3480B74B40DE718A8EE4D22B4001DE02098AB74B409031772D21DF2B4048BF7D1D38B74B401C7C613255F02B403D2CD49AE6B54B401895D40968022C40C05B2041F1B34B403333333333132C40FD87F4DBD7B14B4003780B24281E2C40287E8CB96BB14B401F85EB51B83E2C401B0DE02D90B04B40FA7E6ABC74532C409B559FABADB04B40508D976E12632C40287E8CB96BB14B400000000000A02C404A7B832F4CBE4B405C2041F163AC2C404703780B24C04B407A36AB3E57BB2C4068226C787AC54B4074B515FBCBAE2C4099BB96900FCA4B40598638D6C58D2C4050FC1873D7D24B40401361C3D36B2C40B6847CD0B3D94B40516B9A779C622C40304CA60A46DD4B40A4703D0AD7632C4034A2B437F8E24B407FFB3A70CE682C4082734694F6E64B40E561A1D6346F2C4035EF384547EA4B40D1915CFE437A2C40F5B9DA8AFDED4B4082734694F6862C40287E8CB96BF14B40D3BCE3141DA92C40ABCFD556ECF74B40E9482EFF21BD2C403411363CBDFA4B40F5B9DA8AFD052D40CDCCCCCCCC044C40DA1B7C6132152D40AD69DE718A064C40EA043411361C2D408104C58F31074C4030BB270F0B352D40CA54C1A8A4064C40AEB6627FD93D2D404F401361C3034C40304CA60A46452D40295C8FC2F5004C40713D0AD7A3702D402B1895D409004C400B462575027A2D40FE65F7E461014C407FFB3A70CE882D40787AA52C43044C4071AC8BDB68802D401DC9E53FA4074C403F575BB1BF6C2D40B0726891ED0C4C403D0AD7A3705D2D40006F8104C50F4C40516B9A779C622D40151DC9E53F144C40E561A1D6346F2D40B1E1E995B2144C40A779C7293AB22D4086C954C1A8144C40933A014D842D2E4014AE47E17A144C40A4DFBE0E9C732E407A36AB3E57134C40AA60545227C02E40EFC9C342AD114C40A779C7293A322F40FE43FAEDEB184C4036AB3E575B512F4090A0F831E6164C403E7958A8358D2F40A52C431CEB124C404F401361C3932F4011363CBD520E4C40D0D556EC2FBB2F407958A835CD0B4C4037894160E500304088635DDC461B4C40B3EA73B5150B30407CF2B0506B224C405917B7D1000E30404703780B24284C408104C58F31173040C3F5285C8F324C40423EE8D9AC1A30405839B4C876364C40022B8716D91E3040C364AA60543A4C4065AA605452373040CB10C7BAB84D4C40FE43FAEDEB40304009F9A067B3524C40F2D24D6210483040EA04341136544C403D2CD49AE64D304040A4DFBE0E544C405305A3923A613040E9B7AF03E7544C400000000000603040787AA52C435C4C400E4FAF94656830404B598638D6654C40053411363C6D3040EB73B515FB6B4C4054E3A59BC47030407CF2B0506B724C406A4DF38E5374304035EF3845477A4C403A92CB7F487F30405B423EE8D9844C404BC8073D9B953040925CFE43FA854C4039D6C56D34903040158C4AEA048C4C4062A1D634EF88304057EC2FBB278F4C40166A4DF38E833040AC8BDB68008F4C40F5B9DA8AFD753040AEB6627FD9954C4031992A1895743040E02D90A0F8994C409EEFA7C64B773040B4C876BE9FA24C40D42B6519E2783040B003E78C28A54C40764F1E166A8D3040E25817B7D1B04C40D26F5F07CE993040B81E85EB51B04C401AC05B2041A13040637FD93D79B04C4089D2DEE00BA330404182E2C798B34C4043AD69DE71AA30403F355EBA49B44C40C5FEB27BF2B0304093A9825149BD4C4052B81E85EBA13040F46C567DAEC64C40AA60545227A0304065AA605452CF4C40D95F764F1EB63040B515FBCBEED94C40A60A462575B2304032E6AE25E4DB4C40D3BCE3141DA930406688635DDCDE4C407DAEB6627F993040C3F5285C8FE24C40B9FC87F4DB773040787AA52C43EC4C40B37BF2B0506B3040D26F5F07CEF14C403B70CE88D28E30409A081B9E5EE94C40F085C954C198304058A835CD3BE64C4092CB7F48BF9D304041F163CC5DE34C40E02D90A0F8B13040BBB88D06F0DE4C40E5F21FD26FAF3040B7627FD93DE14C40FF21FDF675903040211FF46C56ED4C4068B3EA73B5853040E3361AC05BF04C40363CBD5296813040E5D022DBF9FE4C40D122DBF97E9A3040499D8026C2F64C40CA32C4B12E9E304060764F1E16F24C40F085C954C1A83040454772F90FF14C40B1E1E995B2BC3040AB3E575BB1EF4C40C139234A7BC330401B9E5E29CBF04C40BB270F0BB5C630402041F163CCF54C4075029A081BBE3040C4B12E6EA3F94C4007F0164850BC30404FAF946588FB4C40B22E6EA301AC304068226C787AFD4C402B8716D9CEA73040B003E78C28FD4C40ADFA5C6DC59E30407593180456FE4C403255302AA9A330406666666666FE4C40E561A1D634BF3040C520B07268014D407A36AB3E57BB30404A7B832F4C064D4003780B2428BE3040C2172653050B4D40C1CAA145B6C33040C7BAB88D06104D40933A014D84CD304044FAEDEBC0114D406C09F9A067D33040029A081B9E164D40DE02098A1FD3304044696FF085194D407DD0B359F5C93040B7627FD93D294D4085EB51B81EC53040AC8BDB68002F4D4036AB3E575BB130406A4DF38E53344D406D567DAEB692304064CC5D4BC8374D40B1BFEC9E3C6C3040B003E78C283D4D4044FAEDEBC079304013F241CF663D4D405396218E75813040780B24287E3C4D407CF2B0506B8A3040EC2FBB270F3B4D40FBCBEEC9C392304060E5D022DB394D407D3F355EBA9930408C4AEA0434394D40AC8BDB6800BF3040F4FDD478E9364D40166A4DF38ED3304038F8C264AA384D40AC8BDB6800EF30408351499D803E4D40D7A3703D0AC730407CF2B0506B4A4D40F2D24D6210B83040CCEEC9C3424D4D40BC0512143FA630408195438B6C4F4D4073D712F2416F3040C442AD69DE514D4061C3D32B656930408351499D804E4D40022B8716D95E304068226C787A4D4D40B3EA73B5154B3040AD69DE718A4E4D406F8104C58F313040B81E85EB51504D40E9B7AF03E73C30403EE8D9ACFA544D40956588635D4C304022FDF675E0544D40EFC9C342AD693040CEAACFD556544D4072F90FE9B76F30405C8FC2F528544D40D95F764F1E76304096438B6CE7534D40933A014D84AD304044696FF085514D40EA95B20C71BC30408D976E1283504D40B5A679C729CA30408FE4F21FD24F4D402AA913D044E83040BBB88D06F04E4D407FFB3A70CE0831406F8104C58F514D40F9A067B3EA233140C58F31772D594D4030BB270F0B1531406ADE718A8E5C4D400EBE30992A0831400F9C33A2B45F4D402DB29DEFA71631408B6CE7FBA9614D408048BF7D1D2831402041F163CC5D4D40B7627FD93D393140933A014D845D4D4013F241CF6645314011363CBD525E4D409A999999995931408E06F01648604D40A2B437F8C294314014AE47E17A6C4D40E2E995B20CA13140DC68006F81744D40BADA8AFD65973140B84082E2C7784D40DC4603780B9431408B6CE7FBA9794D405BD3BCE3149D3140A2B437F8C27C4D4004560E2DB29D314024287E8CB9834D40C7293A92CB9F314044696FF085894D40265305A392AA3140764F1E166A954D404F401361C3C33140ACADD85F768F4D40F7E461A1D6C43140F8C264AA608C4D4019E25817B7C1314027C286A757824D4060764F1E16CA3140C66D3480B7784D4030BB270F0BE531406744696FF06D4D406A4DF38E53E43140E4141DC9E56F4D40BE9F1A2FDDE43140DDB5847CD0734D4068226C787A053240E8D9ACFA5C854D40F9A067B3EA233240083D9B559F8B4D40D26F5F07CE39324002BC0512148F4D4072F90FE9B74F3240295C8FC2F5904D408FC2F5285C4F324032772D211F9C4D40DB8AFD65F744324051DA1B7C61A24D4082734694F646324064CC5D4BC8A74D40F853E3A59B5432406FF085C954A94D4062105839B4583240C8073D9B55A74D40C3D32B6519623240F46C567DAEA64D40A1F831E6AE85324012143FC6DCA54D402B8716D9CE973240029A081B9EA64D4086C954C1A8A432408C4AEA0434A94D40B1BFEC9E3C9C32408FC2F5285CAF4D40499D8026C28632403D9B559FABB54D40C898BB96907F3240C976BE9F1AB74D40B5A679C7297A324072F90FE9B7B74D4091ED7C3F356E3240105839B4C8B64D4088635DDC46733240A60A462575B24D40D5E76A2BF677324074B515FBCBAE4D40EF38454772793240FAEDEBC039AB4D40BF7D1D386774324051DA1B7C61AA4D40FF21FDF6757032408638D6C56DAC4D4012143FC6DC6532403B014D840DAF4D40B7627FD93D59324064CC5D4BC8AF4D409EEFA7C64B4732406688635DDCAE4D40C976BE9F1A3F3240E9B7AF03E7AC4D40DB8AFD65F7343240B5A679C729AA4D40E0BE0E9C3322324062105839B4A84D40DE02098A1F133240545227A089A84D403D0AD7A3700D32402A3A92CB7FA84D402FDD2406810532400C022B8716A94D40C976BE9F1AFF314018265305A3AA4D40B29DEFA7C6FB31405F984C158CAA4D408B6CE7FBA9F131408D28ED0DBEA84D40637FD93D79E83140832F4CA60AA64D40D42B6519E2D83140FD87F4DBD7A14D40933A014D84BD31406DC5FEB27BA24D402EFF21FDF695314032772D211FA44D40F1F44A59867831406744696FF0A54D4036AB3E575B713140AC8BDB6800A74D4044FAEDEBC0693140D5E76A2BF6A74D4027C286A7575A31409A779CA223A94D4041F163CC5D5B3140AF94658863A54D401EA7E8482E5F3140A69BC420B0A24D403108AC1C5A6431408E06F01648A04D40022B8716D95E31409D11A5BDC19F4D40D0B359F5B94A3140FE43FAEDEBA04D40EF38454772493140613255302AA14D408D28ED0DBE403140992A1895D4A14D40166A4DF38E433140A1D634EF38A54D40931804560E4D31400C93A98251A94D40AC8BDB68004F31405C2041F163AC4D402B8716D9CE473140D93D7958A8AD4D40226C787AA52C31409D11A5BDC1AF4D4094F6065F981C3140ABCFD556ECAF4D40A1D634EF38F530406666666666B64D40E63FA4DFBEEE30406FF085C954B94D40F6285C8FC2E53040A4703D0AD7BB4D402E90A0F831D63040910F7A36ABBE4D406EA301BC05B230404E62105839BC4D40D200DE0209BA304099BB96900FBA4D40772D211FF4CC30405839B4C876B64D40D0B359F5B9DA3040CE1951DA1BB44D40C0EC9E3C2CE43040D044D8F0F4B24D40C66D3480B7E03040D42B6519E2B04D40569FABADD8CF3040EFC9C342ADB14D400000000000C030404A7B832F4CB64D40C6DCB5847CB03040DE9387855ABB4D40B5A679C729AA30405BB1BFEC9EBC4D40F6285C8FC25530406EA301BC05BA4D401EA7E8482E4F3040E09C11A5BDB94D40499D8026C246304046B6F3FDD4B84D4022FDF675E02C30408E06F01648B84D4096218E75711B3040B7D100DE02B94D40C364AA605412304035EF384547BA4D40B81E85EB51083040E63FA4DFBEBE4D4054742497FF103040F6285C8FC2BD4D40F085C954C1183040EA95B20C71BC4D40956588635D2C30404FAF946588BB4D4014AE47E17A543040CE88D2DEE0BB4D40B3EA73B5157B304039454772F9BF4D405EBA490C028B304082734694F6C64D40BD5296218E853040C58F31772DC94D40006F8104C57F304032E6AE25E4CB4D40B6847CD0B3893040AEB6627FD9CD4D40AC8BDB68008F30404BEA043411CE4D40CA54C1A8A49E3040A69BC420B0CA4D4062A1D634EFA83040917EFB3A70C64D40EF38454772C9304001DE02098AC74D40166A4DF38ED33040A52C431CEBCA4D403D0AD7A370DD304050FC1873D7CA4D40FD87F4DBD7F1304092CB7F48BFC54D40BC96900F7A063140143FC6DCB5C44D40713D0AD7A31031405A643BDF4FC54D405917B7D1001E3140D95F764F1EC64D40E5F21FD26F2F314014D044D8F0C44D40E0BE0E9C334231401B9E5E29CBC04D4017D9CEF7535331405839B4C876BE4D409D8026C28667314040A4DFBE0EBC4D4025068195436B31404A0C022B87BE4D402B8716D9CE6731403C4ED1915CC64D40575BB1BFEC5E314018265305A3CA4D407E1D386744593140CA54C1A8A4CE4D40A7E8482EFF61314088F4DBD781D34D40736891ED7C5F314011363CBD52CE4D4036AB3E575B7131409D8026C286C74D4074B515FBCB7E3140CCEEC9C342C54D407958A835CD8B3140DBF97E6ABCC44D40849ECDAACF853140295C8FC2F5C04D40787AA52C438C314082E2C798BBBE4D405E4BC8073DBB3140C5FEB27BF2B84D40613255302AC93140C0EC9E3C2CC44D406C787AA52CC33140992A1895D4C94D405917B7D100BE31404182E2C798CB4D4019E25817B7B13140F6285C8FC2CD4D4082734694F6963140FD87F4DBD7D14D40E4839ECDAA8F3140BD5296218ED54D40CB10C7BAB89D31407E8CB96B09D94D409487855AD39C314092CB7F48BFDD4D40499D8026C296314011363CBD52DE4D409A99999999893140CB10C7BAB8DD4D408AB0E1E995823140C58F31772DD94D40F90FE9B7AF833140986E1283C0D24D40BD5296218E8531402063EE5A42CE4D4048BF7D1D38873140A2B437F8C2CC4D402575029A088B3140D34D621058C94D404BEA043411863140355EBA490CCA4D40FD87F4DBD7713140AD69DE718AD64D406D567DAEB6723140A01A2FDD24DE4D40166A4DF38E8331408FC2F5285CDF4D4060E5D022DB893140006F8104C5DF4D40DBF97E6ABC9431404182E2C798E34D409EEFA7C64B97314074B515FBCBE64D408C4AEA0434A13140E9263108ACE44D400F0BB5A679A7314096438B6CE7DB4D40107A36AB3EA73140014D840D4FD74D40DA1B7C6132A531406891ED7C3FD54D4054E3A59BC4A03140A2B437F8C2D44D40F0164850FC983140A3923A014DD44D40B4C876BE9F9A314088635DDC46D34D4014AE47E17AA431409A99999999D14D4080B74082E2B7314072F90FE9B7CF4D402A3A92CB7FB83140A3923A014DD44D40A089B0E1E9B53140A1F831E6AED54D4014D044D8F0B4314058CA32C4B1D64D40462575029AB831400C022B8716D94D40E8D9ACFA5CBD3140A245B6F3FDD44D408B6CE7FBA9C13140F38E537424CF4D406FF085C954D13140508D976E12CB4D400E2DB29DEFD731405DFE43FAEDC34D4057EC2FBB27CF3140C364AA6054C24D400D71AC8BDBC8314057EC2FBB27BF4D40A60A462575C23140228E75711BB54D400E4FAF9465C8314036CD3B4ED1B14D403B014D840DCF3140ABCFD556ECAF4D40DA1B7C6132D531401F85EB51B8AE4D4024B9FC87F4DB3140840D4FAF94AD4D404B598638D6E53140158C4AEA04AC4D40CA54C1A8A4EE3140508D976E12AB4D408BFD65F7E40132405C8FC2F528AC4D40BADA8AFD6517324026E4839ECDAA4D40499D8026C2163240AC8BDB6800AF4D40CA54C1A8A40E3240C3D32B6519B24D4011363CBD52163240BA6B09F9A0B74D401F85EB51B81E3240C3D32B6519BA4D401973D712F2313240FDF675E09CB94D40A9A44E4013313240D8F0F44A59B64D40B537F8C2642A324031992A1895B44D40DC4603780B5432406DE7FBA9F1B24D409A081B9E5E4932400612143FC6B44D401895D409684232409A779CA223B94D402D211FF46C463240E9B7AF03E7BC4D408C4AEA04345132405BB1BFEC9EBC4D40C898BB96905F32404F401361C3BB4D406891ED7C3FA532405F07CE1951CA4D40ED0DBE3099AA32405D6DC5FEB2CB4D40226C787AA5BC32407C61325530D24D40A5BDC11726B3324043AD69DE71D24D40F2B0506B9AB732406744696FF0D54D40022B8716D9BE32409C33A2B437D84D40BADA8AFD65D732403333333333DB4D4032772D211FF432405C8FC2F528DC4D40CEAACFD556FC324088855AD3BCDB4D4063EE5A423E0833405C8FC2F528DC4D408AB0E1E9951233401FF46C567DDE4D40F8C264AA60143340A779C7293AE24D40D5E76A2BF6F73240A3923A014DE44D403A92CB7F48EF3240A3923A014DE44D40E8D9ACFA5CDD3240A01A2FDD24E64D401DC9E53FA4EF32408FC2F5285CEF4D408048BF7D1DF8324074B515FBCBEE4D402A3A92CB7F08334060764F1E16EA4D4054E3A59BC4103340C3F5285C8FEA4D40FC1873D71212334027A089B0E1F14D4096B20C71AC0B3340174850FC18F34D40FD87F4DBD7013340F7E461A1D6F44D40A245B6F3FDF432402041F163CCF54D405917B7D100EE32403C4ED1915CF64D40F163CC5D4BE832408E75711B0DF84D40A4703D0AD7E3324018265305A3FA4D408C4AEA0434D132408B6CE7FBA9094E4054742497FFD03240CEAACFD5560C4E409FCDAACFD5C63240CA32C4B12E0E4E40D95F764F1EB63240AAF1D24D62104E40A7E8482EFFA13240C3F5285C8F124E408048BF7D1D8832404182E2C798134E408BFD65F7E4813240B30C71AC8B134E4024B9FC87F46B3240D5E76A2BF6174E4013F241CF66653240B4C876BE9F1A4E40C58F31772D5132404850FC1873274E40423EE8D9AC5A3240A1D634EF38254E408B6CE7FBA9613240B4C876BE9F224E4070CE88D2DE703240C976BE9F1A1F4E40F1F44A5986783240AE47E17A141E4E40D5E76A2BF687324030BB270F0B1D4E40742497FF908E3240789CA223B91C4E407DAEB6627F99324003780B24281E4E40FB5C6DC5FE9232400000000000204E40107A36AB3E77324011363CBD52264E401CEBE2361A703240EC51B81E852B4E40E3361AC05B503240F7065F984C2D4E401361C3D32B45324087A757CA322C4E40211FF46C563D3240273108AC1C2A4E409FCDAACFD536324096438B6CE72B4E409A99999999193240A7E8482EFF394E40E71DA7E848FE314001DE02098A474E40BC74931804F6314016FBCBEEC94B4E40ABCFD556ECEF31406ADE718A8E4C4E40FBCBEEC9C3E23140B1506B9A774C4E4048E17A14AED73140EC51B81E854B4E40D9CEF753E3C53140705F07CE19494E400A68226C78BA3140B1E1E995B2444E40B29DEFA7C6BB314064CC5D4BC83F4E401CEBE2361AB03140E4839ECDAA3F4E40D50968226CA83140FFB27BF2B0404E4036CD3B4ED1A13140516B9A779C424E40401361C3D39B3140022B8716D9464E407AA52C431C9B3140EE7C3F355E4A4E4011C7BAB88DA63140B0726891ED4C4E40FBCBEEC9C3A231401EA7E8482E4F4E4024B9FC87F49B3140FE43FAEDEB504E40DC4603780B94314052B81E85EB514E4003780B24288E314027C286A757524E406891ED7C3F8531405F07CE1951524E406688635DDC663140FFB27BF2B0504E40545227A089603140AC1C5A643B4F4E40075F984C155C3140A7E8482EFF514E40BC96900F7A463140AD69DE718A564E407E8CB96B09493140A1F831E6AE5D4E40462575029A4831405F29CB10C7624E40F46C567DAE46314096438B6CE76B4E40CA32C4B12E3E3140EE7C3F355E724E406B9A779CA2333140E8D9ACFA5C754E40D7A3703D0A2731409B559FABAD784E40280F0BB5A6293140925CFE43FA854E403C4ED1915C2E3140E3361AC05B984E4032772D211F3431405D6DC5FEB2A34E40BD5296218E353140C442AD69DEA94E4085EB51B81E2531402041F163CCAD4E40D044D8F0F41A3140D0D556EC2FB34E408195438B6C2731403B70CE88D2B64E409C33A2B437383140BA6B09F9A0B74E4027C286A7572A31403480B74082C24E4003780B24281E3140C976BE9F1AC74E40B7627FD93D193140B003E78C28CD4E40174850FC18233140363CBD5296D14E40431CEBE2362A3140D42B6519E2D04E403A234A7B832F3140B7627FD93DD14E40C1CAA145B6433140D656EC2FBBD74E40105839B4C836314052499D8026DA4E40FF21FDF6753031405F07CE1951DA4E4012A5BDC117263140DDB5847CD0DB4E40431CEBE2363A31403FC6DCB584DC4E40F7065F984C55314017D9CEF753DB4E40EA95B20C715C3140355EBA490CDA4E4017D9CEF7536331402AA913D044D84E40075F984C156C3140E0BE0E9C33D24E40A7E8482EFF7131402A3A92CB7FD04E40ADFA5C6DC57E31405305A3923AD14E40832F4CA60A8631405396218E75D94E40C8073D9B557F3140B0726891EDDC4E4099BB96900F7A31401283C0CAA1DD4E40C66D3480B770314030BB270F0BDD4E403411363CBD62314046B6F3FDD4E04E40D95F764F1E563140C66D3480B7E84E40D26F5F07CE59314054E3A59BC4F84E400F9C33A2B4673140F46C567DAEFE4E40C66D3480B7703140BBB88D06F0FE4E40F46C567DAE763140E25817B7D1004F405D6DC5FEB27B3140645DDC4603104F40FCA9F1D24D823140B515FBCBEE194F404F401361C3833140DAACFA5C6D1D4F409A999999998931405AF5B9DA8A1D4F4039454772F98F3140F697DD93871D4F4096438B6CE78B3140EE5A423EE8194F409A9999999999314026E4839ECD1A4F40D95F764F1EA63140D93D7958A81D4F4072F90FE9B79F3140CA54C1A8A41E4F40C1CAA145B69331401DC9E53FA41F4F40E8D9ACFA5C8D3140C7BAB88D06204F40713D0AD7A38031400C022B8716214F402CD49AE61D773140A7E8482EFF214F4072F90FE9B75F3140992A1895D4294F40075F984C155C3140D95F764F1E2E4F404D840D4FAF543140917EFB3A703E4F409D11A5BDC1673140BF0E9C33A2444F40AE47E17A146E3140A3923A014D444F4044696FF085793140E25817B7D1404F408A1F63EE5A823140D93D7958A83D4F40462575029A883140B5A679C7293A4F40AE47E17A148E31408D28ED0DBE384F40CDCCCCCCCC9C3140BA6B09F9A0374F403FC6DCB584AC314070CE88D2DE384F40F1F44A5986A8314096438B6CE73B4F40C6DCB5847CB0314082734694F63E4F40B7627FD93DB93140B9FC87F4DB3F4F404703780B24C83140AA60545227404F406F8104C58FD13140F6285C8FC23D4F402D431CEBE2D63140A01A2FDD243E4F40EE7C3F355EFA314002BC051214474F40CE88D2DEE00B324087A757CA324C4F40D1915CFE430A32400000000000504F40BADA8AFD65F731408C4AEA0434514F40A9A44E4013E13140696FF085C9544F406B9A779CA2F33140CB10C7BAB8554F40B84082E2C7F8314079E9263108544F40917EFB3A70FE3140401361C3D3534F40C58F31772D013240B6F3FDD478594F40CA54C1A8A4FE3140933A014D845D4F40A857CA32C4E13140705F07CE19714F40A1F831E6AED53140ACADD85F76774F40091B9E5E29CB31408B6CE7FBA9794F40174850FC18C331406D567DAEB67A4F402575029A08BB31403FC6DCB5847C4F4017D9CEF753B331409E5E29CB107F4F40C217265305D33140014D840D4F7F4F4080B74082E2D73140091B9E5E297B4F40E78C28ED0DDE31408351499D80764F403D0AD7A370ED3140A4703D0AD76B4F40B3EA73B515FB314054E3A59BC4684F4044696FF085093240CF66D5E76A6B4F40FBCBEEC9C3123240174850FC186B4F40DFE00B93A9223240C898BB9690674F40D0B359F5B91A3240BBB88D06F0664F40DA1B7C6132153240EB73B515FB634F408E06F016482032406EA301BC05624F404E6210583934324088F4DBD781634F40D50968226C7832403CBD5296216E4F40C1A8A44E409332407AA52C431C7B4F40CA54C1A8A48E3240933A014D847D4F40F163CC5D4B88324012A5BDC1177E4F40DAACFA5C6D653240F38E5374247F4F405917B7D1005E324090A0F831E67E4F40F085C954C15832405839B4C8767E4F40D200DE02094A32401DC9E53FA47F4F40FD87F4DBD7613240029A081B9E864F40371AC05B20913240D7A3703D0A8F4F40A1F831E6AEA53240A7E8482EFF914F400612143FC6BC3240598638D6C5954F405F29CB10C7BA324051DA1B7C619A4F40B7D100DE02C93240FE65F7E461994F40363CBD5296C132401D5A643BDF974F409D11A5BDC1C73240696FF085C9944F40F6285C8FC2E53240545227A089984F4061C3D32B65E93240A69BC420B09A4F4035EF384547E23240F775E09C119D4F40D42B6519E2D832402EFF21FDF69D4F401FF46C567DCE324048E17A14AE9F4F40BD5296218EE5324034A2B437F8A24F4065AA605452F73240A3923A014D9C4F40D0B359F5B90A3340F5DBD78173964F400000000000103340CA54C1A8A4964F40B22E6EA3011C33405EBA490C029B4F404B598638D6153340CF66D5E76A9B4F405917B7D1000E3340401361C3D39B4F40075F984C150C3340C9E53FA4DF9E4F40F54A5986382633402B1895D409A84F402575029A083B334052B81E85EBA94F409FCDAACFD5463340CC5D4BC807B54F40448B6CE7FB4933405F984C158CBA4F4057EC2FBB274F33407A36AB3E57BB4F4054E3A59BC4503340A857CA32C4B94F40401361C3D35B3340AB3E575BB1B74F406DC5FEB27B723340E3361AC05BB84F40B7627FD93D793340A7E8482EFFB94F4005A3923A016D334004E78C28EDC54F409D8026C28677334048E17A14AEC74F40386744696F80334011363CBD52C64F402041F163CC9D334065AA605452BF4F404E62105839A4334016FBCBEEC9BB4F40FA7E6ABC74A333409BE61DA7E8B84F40772D211FF4AC3340C976BE9F1AB74F4014AE47E17AB433403A92CB7F48B74F4066F7E461A1C633407B14AE47E1BA4F40A913D044D8C0334029CB10C7BAC04F40BC96900F7AC63340787AA52C43C44F40DAACFA5C6DE533402041F163CCCD4F4089D2DEE00B033440FE65F7E461D14F409A99999999193440C05B2041F1D34F40166A4DF38E433440A1D634EF38D54F40EA95B20C714C34403411363CBDD24F40A9A44E401351344014AE47E17AD44F401A51DA1B7C613440E71DA7E848D64F407CF2B0506B6A3440D42B6519E2D84F4018265305A3723440454772F90FE14F40713D0AD7A38034407E8CB96B09E94F40295C8FC2F58834404A7B832F4CE64F406C09F9A067A334401CEBE2361AE84F4098DD938785BA34406ADE718A8EEC4F40A01A2FDD24C63440492EFF21FDEE4F405E4BC8073DCB34405396218E75F14F406891ED7C3FE534405C8FC2F52800504048E17A14AEE73440091B9E5E2903504082E2C798BBF63440E9482EFF21095040E5F21FD26F3F35403255302AA913504068B3EA73B5453540AC8BDB680013504036AB3E575B51354039B4C876BE1350404ED1915CFE6335405396218E751550406891ED7C3F7535407AA52C431C175040F6285C8FC29535404703780B241C504076711B0DE08D3540AE47E17A142250402CD49AE61D77354046B6F3FDD4245040211FF46C565D354027C286A75726504068226C787A453540A54E401361275040E6AE25E4831E35407958A835CD2B504026E4839ECD1A35404BEA0434112E50401B2FDD240621354066666666662E50402CD49AE61D273540AED85F764F2E5040B003E78C283D3540B9FC87F4DB2B5040BC74931804463540ADFA5C6DC52A504095D40968224C35402D211FF46C2A50403D9B559FAB4D35403F575BB1BF3050408A8EE4F21F423540F6285C8FC2315040D42B6519E2383540FC1873D7123250407FFB3A70CE283540C4B12E6EA33150401AC05B20412135401283C0CAA13150408048BF7D1D183540D95F764F1E32504060764F1E160A3540789CA223B934504026E4839ECD0A35404BEA04341136504017D9CEF753133540029A081B9E365040B8AF03E78C183540B0726891ED3450401B0DE02D90203540AAF1D24D62345040022B8716D92E354085EB51B81E35504068226C787A3535403333333333375040DBF97E6ABC34354037894160E5385040569FABADD83F3540143FC6DCB53C504005A3923A014D35405BD3BCE3143D5040C898BB96905F3540DF4F8D976E3E50400F0BB5A679773540FF21FDF67540504029CB10C7BA783540D88173469442504023DBF97E6A7C3540401361C3D34350400DE02D90A08835404F401361C343504032E6AE25E4933540F241CF66D5435040742497FF909E35405227A089B0495040CB10C7BAB88D3540A857CA32C44D504036AB3E575B8135404772F90FE94F504026E4839ECD6A35408F537424975350404E62105839543540226C787AA5545040DDB5847CD0433540280F0BB5A6555040F931E6AE255435405D6DC5FEB25750404850FC18737735408716D9CEF7535040917EFB3A707E3540D8F0F44A59525040EEEBC039238A354000917EFB3A505040022B8716D98E3540492EFF21FD4E504011C7BAB88D963540C2172653054F5040B84082E2C7A83540D656EC2FBB4F5040FB5C6DC5FEB2354003780B2428525040925CFE43FA9D3540B84082E2C7545040F697DD93879535403FC6DCB584545040EE5A423EE8893540B0726891ED545040FF21FDF675803540B537F8C264565040D49AE61DA77835401B0DE02D9058504096218E75718B3540D95F764F1E5A50405F07CE19519A35408351499D805A5040E09C11A5BDA13540DAACFA5C6D5950408126C286A7A735405BD3BCE31459504005A3923A01AD3540CC5D4BC80759504004E78C28EDED3540B6F3FDD478595040DD2406819503364088635DDC465B50400E2DB29DEF073640287E8CB96B5D5040423EE8D9ACFA35407A36AB3E575F5040CCEEC9C342ED3540F1F44A59866050401B0DE02D90F03540EC2FBB270F5F5040EC51B81E85EB35406C787AA52C5F5040F46C567DAEE6354016FBCBEEC95F504096218E7571DB354004E78C28ED61504088855AD3BCE33540E0BE0E9C33625040F085C954C1E8354068B3EA73B5615040917EFB3A70FE3540FE43FAEDEB6050402041F163CC0D3640D3BCE3141D615040D200DE02092A3640D95F764F1E625040A857CA32C4313640BB270F0BB5625040E5D022DBF91E36403E7958A83565504074B515FBCB0E3640B6847CD0B3655040F6285C8FC205364035EF3845476650409A779CA223D93540F5B9DA8AFD6950404ED1915CFED33540D8817346946A5040DC4603780BC43540D3DEE00B936D5040FB5C6DC5FED23540F085C954C16C5040B515FBCBEED9354010E9B7AF036B5040BF7D1D38671436406688635DDC665040302AA913D034364030BB270F0B6550403D2CD49AE63D3640C5FEB27BF2645040567DAEB6625F3640333333333363504066666666666636408A1F63EE5A62504095D40968226C3640FB5C6DC5FE6250406D567DAEB6623640151DC9E53F6850406D567DAEB65236407C613255306A5040D122DBF97E4A36405F984C158C6A5040C66D3480B75036403F355EBA4968504029ED0DBE30493640AA60545227685040006F8104C53F364014AE47E17A685040A7E8482EFF41364000917EFB3A6C5040DCD7817346543640705F07CE197550402063EE5A425E3640492EFF21FD765040091B9E5E296B3640AC8BDB6800775040166A4DF38E733640C286A757CA765040423EE8D9AC7A36400A68226C787650407958A835CD9B3640AC8BDB68007350404850FC1873A736407F6ABC74937050403D2CD49AE6AD3640E9263108AC705040BF7D1D3867B4364048E17A14AE735040228E75711BAD364079E9263108785040DC68006F81A43640933A014D8479504005A3923A01AD3640E09C11A5BD795040613255302AB93640143FC6DCB57850405F07CE1951CA3640D712F241CF7650403255302AA9D33640E3C798BB9674504055302AA913003740711B0DE02D705040DDB5847CD01337405B423EE8D96C5040A52C431CEB22374076E09C11A56D5040B22E6EA3013C374070CE88D2DE705040ABCFD556EC3F3740C1A8A44E40735040DB8AFD65F764374085EB51B81E7150403A92CB7F486F3740E9263108AC7050404D840D4FAF843740C1A8A44E40735040BADA8AFD65A73740A4DFBE0E9C7350402EFF21FDF6C5374090A0F831E6725040CAC342AD69EE3740E9263108AC705040158C4AEA04F4374052B81E85EB715040EA95B20C71FC37401F85EB51B8725040401361C3D30B3840E4839ECDAA7350404D840D4FAF1438408F537424977350405BD3BCE3141D38406C787AA52C73504012A5BDC11726384033C4B12E6E735040986E1283C02A38406ABC749318745040CDCCCCCCCC2C38402DB29DEFA77250400E4FAF94653838402FDD240681715040B5A679C7296A3840D3BCE3141D7150406DE7FBA9F17238409FCDAACFD572504027A089B0E189384090A0F831E6725040E4141DC9E58F3840B84082E2C7745040AAF1D24D62A038407FFB3A70CE785040386744696FB03840857CD0B359795040E17A14AE47A13840F46C567DAE76504057EC2FBB278F3840742497FF9072504004560E2DB28D384054E3A59BC4705040E561A1D6348F38403480B740826E5040B37BF2B050AB38403D2CD49AE66950401DC9E53FA4BF38401A51DA1B7C695040BD5296218EC5384020D26F5F076A50407958A835CDCB38403CBD5296216A5040C0EC9E3C2CE438407DAEB6627F6950404D840D4FAF1439405F29CB10C7665040D656EC2FBB17394027A089B0E165504099BB96900F1A3940386744696F64504036CD3B4ED12139400F0BB5A679635040D34D6210582939407AC7293A92635040545227A089303940DDB5847CD06350409E5E29CB103739400F0BB5A67963504092CB7F48BF4D3940DB8AFD65F7605040EE5A423EE859394018265305A35E504096218E75715B39404D840D4FAF5C5040D044D8F0F45A3940984C158C4A5A504033333333335339403CBD5296215650405BD3BCE3144D3940C286A757CA5250402575029A084B3940E2E995B20C51504014AE47E17A4439407B14AE47E14A5040ED0DBE30994A3940AC8BDB6800475040ED0DBE30995A3940A089B0E1E9455040022B8716D95E39405BD3BCE31445504044FAEDEBC06939407C6132553042504019E25817B771394069006F81043D5040D200DE02096A3940EA95B20C713C504091ED7C3F355E3940857CD0B3593D5040C364AA6054523940499D8026C23E50409F3C2CD49A363940107A36AB3E3F5040FF21FDF67530394004560E2DB23D504042CF66D5E73A3940D6C56D34803B5040567DAEB6624F39402041F163CC39504064CC5D4BC857394075029A081B3A504005C58F31775D3940B6F3FDD478395040E9263108AC5C39405BD3BCE314355040D7A3703D0A573940462575029A345040A857CA32C4513940CEAACFD5563450405C8FC2F5284C394032772D211F345040FE43FAEDEB4039408048BF7D1D34504097FF907EFB3A3940386744696F345040C4B12E6EA3313940273108AC1C36504003780B24282E3940C139234A7B37504092CB7F48BF1D3940AE47E17A143A50404BC8073D9B153940D8F0F44A593A50400000000000003940705F07CE1939504076E09C11A5CD3840BA6B09F9A0375040091B9E5E29BB3840F46C567DAE365040EEEBC039238A3840A5BDC11726335040454772F90F893840C7293A92CB2F5040CDCCCCCCCC6C384048BF7D1D382B5040744694F6065F38406B9A779CA2275040006F8104C55F38402FDD24068125504024B9FC87F45B3840499D8026C22250406688635DDC563840AF946588632150408104C58F314738407958A835CD1F5040A1F831E6AE3538402063EE5A421E50401F85EB51B81E38405DFE43FAED1B5040575BB1BFECFE3740068195438B18504093A9825149ED3740B4C876BE9F125040053411363CED37405305A3923A115040D044D8F0F4DA3740A4DFBE0E9C0F5040D42B6519E2B8374016FBCBEEC90B50402E90A0F831B637402D211FF46C0A504019E25817B7B1374052499D80260A504082734694F6A63740B7D100DE0209504024287E8CB99B3740984C158C4A065040B5A679C7299A374032772D211F045040A52C431CEB823740C364AA605402504005C58F31776D3740091B9E5E290350408AB0E1E995623740098A1F63EE02504002BC0512145F374011363CBD52FE4F403B70CE88D25E3740637FD93D79F84F40C4B12E6EA35137405F29CB10C7F24F40A54E401361333740C520B07268F14F4012143FC6DC253740AAF1D24D62F04F4054742497FF103740E9B7AF03E7EC4F40956588635DEC3640AD69DE718AE64F40E9482EFF21ED3640C4B12E6EA3E14F406666666666E63640287E8CB96BD94F4089D2DEE00BD33640C3D32B6519D24F402B8716D9CEC736401CEBE2361AD04F4005C58F3177BD36402C6519E258CF4F40DB8AFD65F7B43640BF7D1D3867D44F404FAF946588B33640736891ED7CD74F4043AD69DE71AA36408CDB68006FD94F409FCDAACFD59636407E8CB96B09D94F40E17A14AE478136407593180456CE4F4036AB3E575B81364009F9A067B3CA4F4093A98251497D3640D50968226CC84F4004E78C28ED6D3640B9FC87F4DBBF4F4068226C787A65364014AE47E17ABC4F408E06F01648603640F46C567DAEBE4F40BEC1172653553640C3F5285C8FC24F400BB5A679C7493640ECC039234AC34F401CEBE2361A3036408CB96B09F9B84F4017D9CEF7533336403D9B559FABB54F404BC8073D9B453640287E8CB96BB14F40EA95B20C714C36401CEBE2361AB04F4017B7D100DE523640C976BE9F1AAF4F402575029A085B3640C139234A7BAB4F40029A081B9E5E3640B98D06F016A84F40D7A3703D0A57364008AC1C5A64A34F409D8026C2863736402063EE5A429E4F405917B7D1002E36405AF5B9DA8A9D4F40832F4CA60A1636403FC6DCB5849C4F400F0BB5A679F735408195438B6C974F406ADE718A8EE4354051DA1B7C619A4F40C66D3480B7E0354054E3A59BC4A04F40C66D3480B7B035405F29CB10C79A4F40C05B2041F1A33540713D0AD7A3984F401AC05B20419135406A4DF38E539C4F4060E5D022DB89354068226C787A9D4F40E561A1D6347F3540355EBA490C9A4F40386744696F803540EA95B20C71944F40A2B437F8C28435402B1895D409904F406F1283C0CA91354099BB96900F8A4F403FC6DCB5849C3540C66D3480B7884F400F9C33A2B4A73540D95F764F1E864F40933A014D84AD3540CEAACFD556844F4074B515FBCBAE35407958A835CD834F403E7958A835AD3540265305A392824F401F85EB51B89E354051DA1B7C61824F40E9482EFF218D35402F6EA301BC854F4065AA6054528735402B1895D409884F4039D6C56D348035408D976E1283884F403A234A7B836F3540EA95B20C71844F40DE9387855A733540E25817B7D1804F408A8EE4F21F723540A4703D0AD77B4F40575BB1BFEC6E35408D28ED0DBE784F4068226C787A6535407DAEB6627F714F40C898BB96905F35403C4ED1915C6E4F40F1F44A5986583540AF946588636D4F4007F01648504C3540CA32C4B12E6E4F4035EF384547223540228E75711B654F402575029A081B3540A779C7293A624F4037894160E5103540068195438B4C4F4055302AA913203540AE47E17A14464F403D0AD7A3701D354090A0F831E63E4F4094F6065F981C354036CD3B4ED1394F402B8716D9CE273540F7E461A1D6344F408A1F63EE5A4235401CEBE2361A304F4030BB270F0B553540BE9F1A2FDD2C4F4057EC2FBB275F3540E17A14AE47214F403255302AA9633540B537F8C2641A4F4036AB3E575B6135402C6519E258174F4068226C787A5535405D6DC5FEB2134F40E71DA7E8484E35406744696FF00D4F40D3BCE3141D493540D42B6519E2084F40A913D044D840354062105839B4004F400D71AC8BDB4835409A779CA223F94E40B1E1E995B24C3540B8AF03E78CF84E4005A3923A015D354082734694F6F64E40D3BCE3141D693540A7E8482EFFF14E40E9482EFF217D3540F5DBD78173E64E4062A1D634EF783540C520B07268E14E407E8CB96B09893540083D9B559FD34E407DD0B359F599354069006F8104CD4E407DD0B359F5A93540B003E78C28C54E4043AD69DE719A3540CB10C7BAB8C54E40C898BB96907F3540C520B07268C94E402B1895D409783540AC1C5A643BC74E40C21726530583354061545227A0C14E402B8716D9CE873540B7627FD93DB94E4004E78C28ED8D3540F2B0506B9AA74E4041F163CC5D8B3540A54E401361A34E40917EFB3A707E3540A01A2FDD249E4E40A857CA32C471354013F241CF66954E402B8716D9CE67354096438B6CE7834E4088635DDC46633540D50968226C784E40DC4603780B543540499D8026C26E4E402575029A085B3540B81E85EB51684E4014AE47E17A64354062105839B4604E4050FC1873D7623540B9FC87F4DB574E4008AC1C5A645B35401E166A4DF3564E407958A835CD5B35403255302AA9534E4094F6065F986C354052499D80264A4E40F9A067B3EA7335400000000000484E40B37BF2B0507B35400DE02D90A0484E40A69BC420B082354044696FF085494E4077BE9F1A2F8D35409BE61DA7E8484E40F90FE9B7AF9335400000000000484E4011C7BAB88D9635408C4AEA0434414E40D200DE0209AA35401F85EB51B8464E40F7065F984CC535403EE8D9ACFA4C4E4089D2DEE00BD3354073D712F2414F4E40BF7D1D3867D4354017D9CEF7534B4E40CCEEC9C342CD35401C7C613255484E40E86A2BF697CD3540F6285C8FC23D4E40B0726891EDDC3540BF7D1D38673C4E40D656EC2FBBD73540B537F8C264424E40CA54C1A8A4DE3540174850FC18434E408A8EE4F21FF23540273108AC1C424E40462575029AF835405839B4C8763E4E40F90FE9B7AF033640166A4DF38E3B4E4013F241CF66153640E25817B7D1384E40E8D9ACFA5C1D36405396218E75394E4005A3923A012D364048BF7D1D38374E4094F6065F983C3640787AA52C43344E408A1F63EE5A4236406DE7FBA9F1324E402D431CEBE2463640FE65F7E461314E407958A835CD7B3640B5A679C729324E4071AC8BDB68A03640FFB27BF2B0304E40B7627FD93D8936400000000000284E4024B9FC87F47B3640151DC9E53F244E40BC96900F7A7636400BB5A679C7214E40C217265305733640744694F6061F4E4054E3A59BC4903640DE02098A1F1B4E40EFC9C342ADA93640EA95B20C711C4E40FB5C6DC5FEB23640211FF46C561D4E4040A4DFBE0EBC36409FABADD85F1E4E406D567DAEB6C2364073D712F2411F4E405BD3BCE314CD36400C022B8716214E40B37BF2B050EB3640BBB88D06F0264E4072F90FE9B70F37403E7958A8352D4E40A1F831E6AE153740234A7B832F2C4E40BF7D1D386704374032772D211F244E409D11A5BDC1F736402B1895D409204E40CCEEC9C342ED364021B07268911D4E40D6C56D3480E73640083D9B559F1B4E40CA54C1A8A4DE3640BBB88D06F0164E40569FABADD8DF3640B4C876BE9F124E40D5E76A2BF6E73640711B0DE02D104E4048E17A14AEF7364011363CBD520E4E402D211FF46C063740FF21FDF675104E40D044D8F0F40A37408104C58F310F4E408638D6C56D043740772D211FF40C4E403A234A7B83FF364089D2DEE00B0B4E4092CB7F48BFFD36402C6519E258074E40226C787AA50C37405BB1BFEC9E044E4087A757CA32143740A301BC0512044E402575029A081B37405B423EE8D9044E40E3361AC05B203740D93D7958A8054E40BD5296218E2537403D2CD49AE6054E40371AC05B20313740D95F764F1E064E401AC05B20414137403F575BB1BF044E4029CB10C7BA3837409C33A2B437004E40A4703D0AD7333740F38E537424FF4D40D0B359F5B92A3740D95F764F1EFE4D40EA95B20C711C374087A757CA32FC4D4024B9FC87F41B3740BC96900F7AF64D400AD7A3703D3A3740F4FDD478E9F64D40AA6054522740374054742497FFF84D409D11A5BDC1473740E8D9ACFA5CFD4D4079E92631084C37400000000000004E40386744696F503740D1915CFE43024E406744696FF0553740508D976E12034E40DE9387855A5337400000000000004E4024B9FC87F44B374009F9A067B3FA4D40FD87F4DBD7413740A1F831E6AEF54D40613255302A2937407E1D386744F14D403D0AD7A3701D37408C4AEA0434F14D40BC0512143F163740545227A089F04D403A92CB7F48EF36404182E2C798EB4D40BC96900F7AE63640D734EF3845E74D40C4B12E6EA33137407DD0B359F5E94D408FE4F21FD23F3740C1A8A44E40EB4D4076E09C11A55D3740462575029AF84D40917EFB3A707E3740ACADD85F76074E409A99999999893740D49AE61DA7084E400AD7A3703D8A3740A4DFBE0E9C034E404BC8073D9B853740A60A462575024E40D0B359F5B97A37402BF697DD93FF4D401FF46C567D6E374060764F1E16FA4D403480B740828237408716D9CEF7FB4D4072F90FE9B78F3740151DC9E53FFC4D4001DE02098A9F3740C442AD69DEF94D40F90FE9B7AFB33740B5A679C729FA4D40075F984C15CC3740DE02098A1FFB4D40FB5C6DC5FE1238407DD0B359F5014E409D8026C28637384030BB270F0B054E40B6847CD0B3493840E3361AC05B084E406891ED7C3F5538408C4AEA0434094E40956588635D5C384070CE88D2DE084E40CE88D2DEE06B3840C139234A7B034E407958A835CD6B38403C4ED1915CFE4D40295C8FC2F5783840ADFA5C6DC5FE4D406688635DDC963840744694F606074E40B29DEFA7C69B3840A4703D0AD70B4E4043AD69DE719A3840F2B0506B9A0F4E408E06F01648C0384044696FF085114E40D26F5F07CED938407DAEB6627F114E40DCD7817346F43840287E8CB96B114E40A913D044D8103940EB73B515FB134E40A9A44E40133139408F53742497174E4036CD3B4ED131394009F9A067B31A4E402D211FF46C263940787AA52C431C4E40FCA9F1D24D323940022B8716D91E4E4003780B24285E39408D28ED0DBE204E4024B9FC87F47B3940BA6B09F9A01F4E404182E2C7988B39408FE4F21FD2274E40C139234A7B933940C3D32B65192A4E40B81E85EB51A8394058A835CD3B2E4E408D976E1283B039405BB1BFEC9E2C4E400F9C33A2B4A73940508D976E122B4E40BB270F0BB5A63940BDE3141DC9254E4094F6065F98AC39405E4BC8073D234E40637FD93D79B839409D11A5BDC11F4E409FABADD85FC639403D2CD49AE61D4E4012A5BDC117D63940DF4F8D976E224E402506819543CB3940984C158C4A224E40E5D022DBF9BE3940F4FDD478E9264E40E561A1D634DF39405F29CB10C7224E40DE02098A1FE3394065AA6054521F4E4024B9FC87F4EB39408104C58F311F4E407D3F355EBAE93940A1F831E6AE2D4E40E5D022DBF9DE3940B7D100DE02314E40D881734694D639405EBA490C02334E40166A4DF38EE3394027A089B0E1314E40AC8BDB6800FF394032772D211F2C4E40423EE8D9AC0A3A409031772D21274E40C0EC9E3C2C143A401283C0CAA1254E4042CF66D5E71A3A4062A1D634EF284E4075029A081B0E3A40D95F764F1E364E4013F241CF66253A407CF2B0506B324E40B4C876BE9F6A3A40EEEBC03923324E409A779CA223793A4082E2C798BB364E400EBE30992A783A407B832F4CA63A4E40F7E461A1D6743A408F537424973F4E402D431CEBE2863A40E3361AC05B484E407958A835CD8B3A406DC5FEB27B4A4E403FC6DCB5849C3A40E09C11A5BD514E4010E9B7AF03A73A403411363CBD524E40371AC05B20B13A400AD7A3703D524E407FFB3A70CEB83A4002BC0512144F4E40ABCFD556ECBF3A40C4B12E6EA3494E40C3D32B6519B23A404F401361C34B4E40462575029AA83A40AEB6627FD94D4E403A234A7B839F3A40A1F831E6AE4D4E40B81E85EB51983A406ADE718A8E4C4E4052B81E85EB913A40A779C7293A4A4E407CF2B0506B7A3A401361C3D32B3D4E40C7BAB88D06803A40295C8FC2F5384E408E06F01648903A4074B515FBCB364E40D0B359F5B9AA3A40029A081B9E364E4093A9825149BD3A405396218E75394E401DC9E53FA4CF3A403FC6DCB5843C4E409D11A5BDC1E73A4014D044D8F03C4E40F7065F984CF53A409BE61DA7E8384E4083C0CAA145063B4079E9263108444E408048BF7D1D383B406D567DAEB64A4E4068226C787A453B40A3923A014D444E4096B20C71AC4B3B402A3A92CB7F404E40D3BCE3141D793B403EE8D9ACFA3C4E40EF38454772793B401B0DE02D90404E40B37BF2B0509B3B40B84082E2C7404E407958A835CDAB3B401B0DE02D90404E40B0726891EDBC3B405396218E75414E4024B9FC87F4BB3B406ADE718A8E444E4075029A081BBE3B408D976E1283484E4048BF7D1D38C73B40371AC05B20494E40E6AE25E483CE3B40F54A598638464E4074B515FBCBCE3B406744696FF0454E40A52C431CEBD23B407A36AB3E57434E40DA1B7C6132053C40DD24068195434E40BD5296218E253C404F401361C3434E4065AA605452573C4040A4DFBE0E4C4E401904560E2D623C404772F90FE94F4E40166A4DF38E633C40508D976E12534E40D3BCE3141D693C40E9482EFF21554E40C139234A7B833C4002BC051214574E40053411363CAD3C40CA32C4B12E5E4E404260E5D022BB3C4096B20C71AC5B4E40EC51B81E85BB3C40F46C567DAE564E405AF5B9DA8AAD3C404A7B832F4C4E4E40386744696FA03C4048BF7D1D384F4E405BB1BFEC9E9C3C40613255302A514E40DE02098A1F933C40C4B12E6EA3514E403D2CD49AE68D3C40D9CEF753E34D4E40A857CA32C4913C40A52C431CEB4A4E4042CF66D5E79A3C406F1283C0CA494E40705F07CE19A13C406B2BF697DD4B4E4098DD938785AA3C40355EBA490C4A4E4086C954C1A8B43C40FB5C6DC5FE3A4E401F85EB51B8AE3C40C3D32B65193A4E40D5E76A2BF6A73C40091B9E5E293B4E40DB8AFD65F7943C40499D8026C23E4E40E3361AC05B903C40D5E76A2BF63F4E40849ECDAACF853C40C217265305434E40C520B07268813C403BDF4F8D97464E408A1F63EE5A723C4083C0CAA145464E40613255302A993C406F8104C58F314E404F1E166A4DA33C40C8073D9B552F4E40B98D06F016B83C40A3923A014D2C4E4093A9825149BD3C405D6DC5FEB22B4E4044696FF085C93C40B459F5B9DA2A4E4048E17A14AED73C4001DE02098A274E408E06F01648E03C4069006F8104254E40789CA223B9FC3C404260E5D0221B4E40A913D044D8003D40E17A14AE47194E40499D8026C2063D4064CC5D4BC8174E40CE88D2DEE00B3D4073D712F241174E40D3DEE00B93293D40840D4FAF94154E4011C7BAB88D663D403108AC1C5A144E40FD87F4DBD7713D403D0AD7A370154E407F6ABC7493783D401D38674469174E40A2B437F8C2843D40B84082E2C7184E40CB10C7BAB88D3D40A835CD3B4E194E4014AE47E17A943D40287E8CB96B194E40075F984C15AC3D40705F07CE19194E40F085C954C1B83D40462575029A184E401DC9E53FA4BF3D40ABCFD556EC174E40FB5C6DC5FED23D405AF5B9DA8A154E40637FD93D79D83D403FC6DCB584144E401AC05B2041E13D40ED0DBE3099124E40F4FDD478E9E63D404850FC18730F4E40DBF97E6ABCE43D408716D9CEF70B4E408AB0E1E995F23D40C139234A7B034E409B559FABADF83D405F07CE1951024E40B6F3FDD478093E401B2FDD2406014E406B9A779CA2133E40545227A089004E40EC51B81E852B3E40F241CF66D5FF4D40CE88D2DEE03B3E40849ECDAACFFD4D4057EC2FBB273F3E404F401361C3FB4D402B8716D9CE373E4026E4839ECDF24D40C8073D9B552F3E402BF697DD93EF4D402B8716D9CE273E40D881734694EE4D404FAF946588133E403B014D840DEF4D4060764F1E160A3E4072F90FE9B7EF4D408A1F63EE5A023E40B84082E2C7F04D40E71DA7E848EE3D40EC51B81E85F34D40423EE8D9ACCA3D4064CC5D4BC8F74D4088635DDC46C33D40E3361AC05BF84D4003780B24287E3D4086C954C1A8FC4D4036CD3B4ED1313D4070CE88D2DE004E407A36AB3E571B3D404A0C022B87FE4D4055302AA913103D4040A4DFBE0EFC4D40107A36AB3E073D40C976BE9F1AF74D407E1D386744093D40265305A392F24D4010E9B7AF03073D40BBB88D06F0EE4D40091B9E5E29FB3C40E0BE0E9C33EA4D40BE9F1A2FDDF43C400D71AC8BDBE84D4030BB270F0BD53C403F355EBA49E44D40EEEBC03923BA3C4079E9263108E44D4019E25817B7B13C4005C58F3177E54D407CF2B0506BAA3C4055C1A8A44EE84D4014D044D8F0843C4067D5E76A2BEE4D40575BB1BFEC7E3C4068226C787AED4D40E4141DC9E56F3C400C93A98251E94D40ED9E3C2CD46A3C40865AD3BCE3E44D4099BB96900F6A3C40295C8FC2F5E04D40EB73B515FB6B3C405917B7D100DE4D4097900F7A366B3C4099BB96900FDA4D4063EE5A423E683C408104C58F31D74D40A4703D0AD7633C40E8D9ACFA5CD54D403D2CD49AE65D3C40BF0E9C33A2D44D40E6AE25E4833E3C4074B515FBCBD64D404A0C022B87363C40D42B6519E2D84D40BF7D1D3867343C40401361C3D3DB4D408A8EE4F21F323C40F241CF66D5DF4D4096218E75712B3C400AD7A3703DE24D4099BB96900F1A3C405AF5B9DA8AE54D40174850FC18133C4068B3EA73B5E54D40E0BE0E9C33023C409A779CA223E14D40CA32C4B12EFE3B408E06F01648D84D408D28ED0DBE003C4020D26F5F07D64D402C6519E258073C402575029A08D34D40C74B378941103C401361C3D32BCD4D4036CD3B4ED1113C408CB96B09F9C84D40C5FEB27BF2103C40A1F831E6AEC54D4060764F1E160A3C408E06F01648C04D404BC8073D9B053C404B598638D6BD4D40DC4603780B043C40CCEEC9C342BD4D40E5D022DBF9FE3B407C61325530BA4D40EE7C3F355EFA3B40AAF1D24D62B84D4087A757CA32F43B40917EFB3A70B64D40575BB1BFECEE3B4013F241CF66B54D404F1E166A4DE33B40A3923A014DB44D40D3BCE3141DD93B4040A4DFBE0EB44D40E86A2BF6978D3B406688635DDCB64D40C3F5285C8F823B40F2B0506B9AB74D4096B20C71AC7B3B4063EE5A423EB84D406C09F9A067733B40D3BCE3141DB94D40E8D9ACFA5C6D3B40FE65F7E461B94D4032772D211F643B40287E8CB96BB94D40E5F21FD26F2F3B408C4AEA0434B94D406666666666163B40462575029AB84D40F1F44A5986083B40713D0AD7A3B84D407E8CB96B09F93A40D42B6519E2B84D40CE88D2DEE0EB3A40B6847CD0B3B94D40E0BE0E9C33E23A405F29CB10C7BA4D407B14AE47E1DA3A4007CE1951DABB4D408C4AEA0434D13A405AF5B9DA8ABD4D404B598638D6C53A402A3A92CB7FC04D40226C787AA5BC3A407B14AE47E1C24D4005A3923A01AD3A40AE47E17A14C64D4011C7BAB88DA63A403B70CE88D2C64D4057EC2FBB279F3A4065AA605452C74D4088635DDC46933A4058CA32C4B1C64D408048BF7D1D883A40F7E461A1D6C44D40772D211FF47C3A40787AA52C43C44D40BEC1172653753A40CCEEC9C342C54D404F401361C3633A40E4141DC9E5C74D4017D9CEF753433A4097FF907EFBCA4D404ED1915CFE133A40BE9F1A2FDDCC4D4044696FF085093A4001DE02098ACF4D407B14AE47E1FA394054742497FFD04D403A234A7B83DF394086C954C1A8CC4D40F6285C8FC2C53940B6F3FDD478D14D40BBB88D06F0B639405BD3BCE314D54D4091ED7C3F35AE3940B1E1E995B2D44D4054E3A59BC4B03940744694F606CF4D408351499D80B639404F401361C3CB4D4031992A1895B439407E8CB96B09C94D40B5A679C729AA39402B1895D409C84D406C787AA52CA33940E3C798BB96C84D40D3BCE3141D993940A323B9FC87CC4D40431CEBE2367A39404E62105839D44D40B003E78C287D394055C1A8A44EC84D402E90A0F8316639401FF46C567DBE4D40CE88D2DEE05B394074B515FBCBBE4D40C4B12E6EA3513940B9FC87F4DBBF4D400E4FAF9465483940C58F31772DC14D408A8EE4F21F42394036CD3B4ED1C14D409D8026C28627394040A4DFBE0EC44D40B30C71AC8B1B39404F401361C3C34D40772D211FF40C394044696FF085C14D404260E5D022EB384070CE88D2DEC04D40DE02098A1FE338406DE7FBA9F1C24D40211FF46C56DD3840933A014D84C54D40B29DEFA7C6CB3840B81E85EB51C84D402E90A0F831C638402B8716D9CEC74D40295C8FC2F5C838407C61325530C24D407E8CB96B09B938407DD0B359F5B94D4061C3D32B6589384098DD938785BA4D402CD49AE61D673840B1E1E995B2BC4D40CF66D5E76A5B384014AE47E17ABC4D40A3923A014D543840B3EA73B515BB4D40A60A46257552384090A0F831E6B64D4086C954C1A8343840158C4AEA04AC4D40E6AE25E4832E384007F0164850AC4D40D9CEF753E32538404A7B832F4CAE4D401DC9E53FA41F38409C33A2B437B04D40D044D8F0F41A384036AB3E575BB14D406D567DAEB61238405F07CE1951B24D4097900F7A360B3840EEEBC03923B24D40BC74931804063840499D8026C2AE4D4082734694F6063840F7E461A1D6A44D401DC9E53FA4EF374050FC1873D7A24D406744696FF0E53740ED9E3C2CD4A24D4041F163CC5DDB3740F8C264AA60A44D404D840D4FAFD437405BD3BCE314A54D405F29CB10C7BA3740A52C431CEBA24D403FC6DCB584BC37408E06F01648A04D40AE47E17A14BE374001DE02098A9F4D403D2CD49AE6BD374091ED7C3F359E4D404703780B24B83740CC7F48BF7D9D4D405BD3BCE3149D3740F46C567DAE9E4D4036AB3E575B813740CC5D4BC8079D4D40107A36AB3E7737408BFD65F7E4994D40EC51B81E857B374096218E75718B4D40E63FA4DFBE6E37403A92CB7F48874D40454772F90F6937400B46257502824D40E09C11A5BD7137401E166A4DF37E4D40BADA8AFD65773740925CFE43FA7D4D406B9A779CA2833740840D4FAF947D4D40917EFB3A708E3740917EFB3A707E4D40CF66D5E76A9B374044FAEDEBC0814D40FED478E926913740E8D9ACFA5C854D408104C58F319737403FC6DCB584844D408FE4F21FD29F3740F0A7C64B37814D40FB5C6DC5FEA23740143FC6DCB57C4D404CA60A46259537405396218E75794D4052B81E85EB813740D5E76A2BF6774D40B5A679C7297A37400000000000784D4039D6C56D34703740B81E85EB51784D402575029A086B37405C2041F163744D4096B20C71AC7B374048E17A14AE674D400F0BB5A679973740BE9F1A2FDD644D40956588635DCC37403C4ED1915C664D404F401361C3D33740CCEEC9C342654D40053411363CDD37406DE7FBA9F1624D407D3F355EBAB9374065AA6054525F4D402BF697DD939737402041F163CC5D4D40A857CA32C4913740A01A2FDD245E4D407E8CB96B098937401E166A4DF35E4D40022B8716D97E3740A913D044D8584D408E06F01648803740FD87F4DBD7494D4011363CBD52863740ACADD85F76474D4072F90FE9B79F37406C787AA52C434D4076711B0DE0AD37405839B4C876364D4098DD938785BA3740ACADD85F762F4D4082E2C798BBC637405BB1BFEC9E2C4D40166A4DF38ED3374013F241CF662D4D40FDF675E09CF137407DAEB6627F294D40613255302AF93740D50968226C284D4091ED7C3F35FE3740BADA8AFD65274D40FBCBEEC9C3023840F54A598638264D40CB10C7BAB80D38407B832F4CA6224D4098DD9387851A3840A01A2FDD241E4D40925CFE43FA3D3840508D976E12234D40D26F5F07CE4938409CC420B072284D405C8FC2F5284C3840BE30992A182D4D404D840D4FAF5438407DAEB6627F314D4097FF907EFB5A3840C3D32B6519324D404ED1915CFE6338406EA301BC05324D4096218E75716B38407DAEB6627F314D4068226C787A753840D50968226C304D406ADE718A8E84384077BE9F1A2F2D4D40CBA145B6F38D38406F8104C58F294D40E63FA4DFBE8E3840F5DBD78173264D400D71AC8BDB883840EBE2361AC0234D4024B9FC87F47B384038F8C264AA204D400EBE30992A783840029A081B9E1E4D40A4703D0AD7733840BADA8AFD65174D40B81E85EB5178384088F4DBD781134D40F1F44A598678384055C1A8A44E104D404D158C4AEA743840E09C11A5BD094D40AE47E17A146E384021B0726891054D402B1895D409683840A52C431CEB024D40A4703D0AD7633840E3361AC05B004D40B29DEFA7C65B38407AA52C431CFB4C409D8026C28657384073D712F241F74C40713D0AD7A35038408F53742497EF4C40448B6CE7FB493840A69BC420B0EA4C40B5A679C7294A38403D0AD7A370E54C40AEB6627FD94D3840D93D7958A8DD4C404D840D4FAF54384044696FF085D94C40789CA223B95C384027C286A757CA4C40F085C954C1683840857CD0B359AD4C400BB5A679C7693840C139234A7BA34C400F0BB5A679673840AA60545227A04C4001DE02098A5F384079E92631089C4C40613255302A3938402A3A92CB7F904C409D11A5BDC127384014AE47E17A8C4C405C8FC2F528FC374050FC1873D7824C406ADE718A8EF437405396218E75814C401DC9E53FA4DF3740D8817346947E4C40EFC9C342ADD937406744696FF07D4C40613255302AC9374087A757CA327C4C40F9A067B3EAC33740C05B2041F17B4C409D11A5BDC1A737406B9A779CA27B4C40832F4CA60A96374069006F81047D4C40F085C954C1583740BBB88D06F0864C40A4703D0AD7533740D5E76A2BF6874C40E71DA7E8484E3740FE65F7E461894C406F8104C58F413740B0726891ED8C4C40C7293A92CB3F3740F46C567DAE8E4C40CB10C7BAB83D3740E86A2BF697954C407B14AE47E12A37402B1895D409A84C403411363CBD223740CA54C1A8A4AE4C4098DD9387851A374048E17A14AEAF4C4013F241CF661537401CEBE2361AB04C4094F6065F980C37400C93A98251B14C406B9A779CA2033740C217265305B34C40C5FEB27BF2F036409031772D21B74C409D11A5BDC1E73640E0BE0E9C33BA4C408E06F01648C036403FC6DCB584C44C40075F984C15AC3640705F07CE19C94C404D840D4FAFA43640A52C431CEBCA4C409C33A2B437983640FDF675E09CD14C402FDD240681953640D578E92631D84C4041F163CC5D9B364080B74082E2DF4C40DA1B7C61329536409B559FABADE04C4042CF66D5E77A3640910F7A36ABDE4C402B1895D4094836401DC9E53FA4D74C40613255302A1936409A779CA223D14C4094F6065F980C3640BBB88D06F0CE4C4030BB270F0B05364077BE9F1A2FCD4C40E7FBA9F1D2FD3540B1BFEC9E3CCC4C40B1BFEC9E3CEC3540CFF753E3A5CB4C40F46C567DAEE63540EB73B515FBCB4C4097900F7A36DB3540787AA52C43CC4C40E17A14AE47C13540DFE00B93A9CA4C40B4C876BE9FBA35406F8104C58FC94C404D840D4FAFB435401DC9E53FA4C74C4093A9825149AD3540CEAACFD556C44C40EE7C3F355EAA3540EEEBC03923C24C40A4703D0AD7A33540D881734694BE4C40462575029A9835408D28ED0DBEB84C40EC51B81E857B35403411363CBDAA4C4013F241CF667535401B0DE02D90A84C4057EC2FBB276F3540ADFA5C6DC5A64C40ED9E3C2CD46A3540075F984C15A44C409A999999996935403BDF4F8D979E4C400C93A98251693540ABCFD556EC8F4C4027C286A7576A3540EB73B515FB8B4C40EE7C3F355E6A3540D42B6519E2884C407FFB3A70CE68354011363CBD52864C40F7065F984C653540CF66D5E76A834C40083D9B559F5B354003098A1F637E4C40A52C431CEB423540D95F764F1E764C40EF3845477239354040A4DFBE0E744C4085EB51B81E25354072F90FE9B76F4C40728A8EE4F20F35404F401361C36B4C40E8D9ACFA5C0D3540713D0AD7A3684C40C74B378941103540075F984C15644C40713D0AD7A31035408126C286A75F4C403C4ED1915C0E35402A3A92CB7F584C40226C787AA50C35405917B7D100564C40B5A679C7290A3540A60A462575524C409FCDAACFD5063540029A081B9E4E4C4074B515FBCB0E354036AB3E575B414C406F8104C58F11354039B4C876BE374C4041F163CC5D0B3540DFE00B93A93A4C409FABADD85F063540E2E995B20C414C40567DAEB662FF34408C4AEA0434414C40D5E76A2BF6F73440AD69DE718A2E4C40B7627FD93DF93440F5DBD781731E4C40022B8716D9FE3440BA6B09F9A0174C40FAEDEBC0390335406744696FF0154C409F3C2CD49A063540EB73B515FB134C40D044D8F0F40A3540F38E5374240F4C40053411363C0D35408BFD65F7E4094C4057EC2FBB270F3540BA490C022B074C40371AC05B2011354020D26F5F07FE4B408FC2F5285C0F354044FAEDEBC0F94B4041F163CC5D0B3540865AD3BCE3F44B4096218E75710B354054742497FFF04B40575BB1BFEC0E354040A4DFBE0EE44B4088855AD3BC1335402041F163CCDD4B40234A7B832F1C35406C09F9A067DB4B404D158C4AEA24354082E2C798BBD64B40C3F5285C8F3235409A99999999C94B40575BB1BFEC3E35404F401361C3BB4B40448B6CE7FB493540E9263108ACA44B40166A4DF38E4335401D5A643BDF9F4B402E90A0F831463540228E75711B9D4B4033333333334335408BFD65F7E4994B40D1915CFE433A35406F8104C58F994B40A913D044D8303540174850FC18934B400F0BB5A67937354051DA1B7C61824B4027C286A7573A35405839B4C8767E4B40E63FA4DFBE3E35406E3480B7407A4B40295C8FC2F53835403A92CB7F48774B402B8716D9CE1735407B832F4CA6724B40B22E6EA301FC34400AD7A3703D724B4005C58F3177DD3440EC51B81E85734B40EC2FBB270FCB3440B81E85EB51784B4036AB3E575BC1344062105839B4784B4048E17A14AEA73440713D0AD7A3784B40D95F764F1E96344055C1A8A44E784B40C898BB96908F34409C33A2B437784B408048BF7D1D88344096218E75717B4B40DAACFA5C6D953440645DDC4603804B401A51DA1B7CA1344009F9A067B3824B405C8FC2F528AC34405AF5B9DA8A854B40BEC1172653B53440711B0DE02D884B402B8716D9CED734407AA52C431C934B401904560E2DE23440C58F31772D994B40F1F44A5986E83440A1D634EF389D4B40CE1951DA1BFC34406C09F9A067A34B4024B9FC87F40B3540E0BE0E9C33AA4B40EE7C3F355E1A354012143FC6DCB54B4054E3A59BC42035409A99999999C94B406DC5FEB27B223540545227A089D04B40C7BAB88D062035408195438B6CD74B40789CA223B91C35408B6CE7FBA9D94B40643BDF4F8D17354008AC1C5A64DB4B40F1F44A5986183540F5B9DA8AFDD54B40F1F44A598618354040A4DFBE0ECC4B400E2DB29DEF17354085EB51B81EC54B402EFF21FDF6153540FE43FAEDEBC04B40C6DCB5847C10354036CD3B4ED1B94B407AA52C431C0B3540CEAACFD556B44B40713D0AD7A300354085EB51B81EAD4B404182E2C798FB344027C286A757AA4B4036AB3E575BF13440A2B437F8C2A44B403A234A7B83EF34404F401361C3A34B40DB8AFD65F7E43440C976BE9F1A9F4B40F9A067B3EAD334401DC9E53FA4974B401895D40968B234400B462575028A4B405C8FC2F528AC34400000000000884B400000000000A03440EA95B20C71844B4026E4839ECD9A3440C217265305834B40EA95B20C718C344001DE02098A7F4B40234A7B832F6C344045D8F0F44A794B40226C787AA55C34401B0DE02D90784B4064CC5D4BC80734409A779CA223794B405AF5B9DA8AFD334098DD9387857A4B40C5FEB27BF2F03340499D8026C2764B40053411363CED3340174850FC18734B40780B24287EEC334091ED7C3F356E4B40C6DCB5847CF03340DE02098A1F6B4B40A1F831E6AEF53340F54A598638664B402FDD240681F53340FD87F4DBD7614B403F355EBA49EC334097900F7A365B4B402E90A0F831E63340711B0DE02D584B401D38674469DF3340A7E8482EFF514B409F3C2CD49AE63340D50968226C504B4004E78C28EDED3340713D0AD7A3504B40DCD7817346F43340E02D90A0F8514B4019E25817B7F13340F8C264AA60544B40BC74931804F63340D49AE61DA7584B405E4BC8073DFB3340FCA9F1D24D5A4B40A60A46257502344095D40968225C4B406F8104C58F3134408C4AEA0434594B4068B3EA73B5653440CAC342AD69564B40022B8716D93E3440AED85F764F4E4B409D8026C286373440A1D634EF384D4B400AD7A3703D1A34407DAEB6627F494B40B7627FD93D093440711B0DE02D484B40FB3A70CE88D233405D6DC5FEB23B4B4079E9263108CC3340645DDC4603384B40F46C567DAEB63340454772F90F314B40C5FEB27BF2A03340BE9F1A2FDD2C4B401904560E2D923340BF7D1D38672C4B40265305A3927A33409C33A2B437284B40AC8BDB68005F334051DA1B7C61224B40A913D044D8403340A4DFBE0E9C234B40B3EA73B5153B33406D567DAEB62A4B409E5E29CB10473340A3923A014D2C4B408E06F0164860334085EB51B81E2D4B40637FD93D796833406744696FF02D4B4076E09C11A56D3340499D8026C22E4B40BC0512143F8633405F29CB10C7324B4036AB3E575BA13340C66D3480B7384B40F46C567DAEA6334027C286A7573A4B4018265305A3B23340E8D9ACFA5C3D4B4036AB3E575BC1334052B81E85EB414B406ADE718A8ED433400C93A98251494B40D95F764F1ED63340CDCCCCCCCC4C4B4068226C787AC533403D2CD49AE6454B407A36AB3E57BB3340C3F5285C8F424B4017B7D100DEB23340E4141DC9E53F4B40E3C798BB96A033404F1E166A4D3B4B4005A3923A019D3340E0BE0E9C333A4B4055302AA91390334090A0F831E6364B40A3923A014D843340CE1951DA1B344B401B0DE02D90703340FE65F7E461314B407B14AE47E16A3340C66D3480B7304B40569FABADD85F33408FE4F21FD22F4B406666666666363340F7065F984C2D4B40166A4DF38E233340F8C264AA602C4B40CE88D2DEE00B33407958A835CD2B4B404B598638D60533407958A835CD2B4B40637FD93D79F83240C0EC9E3C2C2C4B4087A757CA32F4324069006F81042D4B40764F1E166AED3240CEAACFD5562C4B4086C954C1A8E43240B1BFEC9E3C2C4B40645DDC4603D83240CC5D4BC8072D4B40A7E8482EFFC13240ACADD85F762F4B40BEC1172653B5324054742497FF304B404694F6065F983240499D8026C2364B40C217265305933240FED478E926394B40C442AD69DE91324069006F81043D4B40A9A44E40139132401FF46C567D464B40B1BFEC9E3C8C3240FAEDEBC0394B4B40A52C431CEB823240B84082E2C7504B4080B74082E2773240A1D634EF38554B40D5E76A2BF66732401FF46C567D5E4B409D8026C286773240AED85F764F5E4B40EBE2361AC07B3240613255302A614B4054742497FF8032409CC420B072604B401895D4096892324013F241CF665D4B40696FF085C9B43240B84082E2C7584B40B3EA73B515BB32403B70CE88D2564B408CDB68006FC13240EB73B515FB534B40D93D7958A8C53240705F07CE19514B40B7627FD93DC932401EA7E8482E4F4B401904560E2DD232404ED1915CFE4B4B401361C3D32BD53240736891ED7C4F4B4011363CBD52C63240F7065F984C554B403D0AD7A370BD324072F90FE9B7574B4087A757CA32B43240C4B12E6EA3594B40B3EA73B5159B324003780B24285E4B40158C4AEA04943240107A36AB3E5F4B406688635DDC863240FE65F7E461614B40C217265305733240E9B7AF03E7644B40E5F21FD26F5F3240FF21FDF675684B40832F4CA60A5632405EBA490C026B4B40B3EA73B5150B3240986E1283C06A4B405E4BC8073DEB314036CD3B4ED1694B404BC8073D9BE531405396218E75694B40BC0512143FC6314048BF7D1D38674B40006F8104C5AF314005A3923A01654B4064CC5D4BC8973140C3F5285C8F624B402B8716D9CE8731406F8104C58F614B4057EC2FBB276F3140E3361AC05B604B40789CA223B95C314072F90FE9B75F4B408E06F0164840314068226C787A5D4B40A913D044D810314091ED7C3F35564B40D34D6210580931406ADE718A8E544B404D158C4AEA0431407B14AE47E1524B40C6DCB5847CF03040CC7F48BF7D4D4B405F07CE1951EA30403FC6DCB5844C4B408A1F63EE5AE23040C139234A7B4B4B40B3EA73B515CB3040B6847CD0B3494B40F90FE9B7AFB330407FFB3A70CE484B405F07CE1951AA30401B0DE02D90484B40C139234A7BA330404703780B24484B408A1F63EE5A923040AD69DE718A464B40091B9E5E298B3040CB10C7BAB8454B404ED1915CFE833040F8C264AA60444B405A643BDF4F7D3040B537F8C264424B40D9CEF753E3753040D5E76A2BF63F4B402A3A92CB7F683040508D976E123B4B401A51DA1B7C51304099BB96900F324B40E78C28ED0D4E30408126C286A72F4B406A4DF38E535430403D9B559FAB2D4B409D11A5BDC1373040C217265305234B40789CA223B92C3040C58F31772D214B40BE9F1A2FDD2430404694F6065F204B40F7E461A1D6143040B8AF03E78C204B40B1BFEC9E3C0C30407DAEB6627F214B40C66D3480B7C02F4001DE02098A1F4B40CB10C7BAB8AD2F4090A0F831E61E4B4066F7E461A1962F4014D044D8F01C4B405305A3923A812F40CF66D5E76A1B4B401E166A4DF34E2F40E25817B7D1184B40E9263108ACFC2E405A643BDF4F154B4007CE1951DADB2E40A2B437F8C2144B4009F9A067B3CA2E406ADE718A8E144B40DA1B7C6132B52E40158C4AEA04144B402575029A089B2E40A52C431CEB124B40DBF97E6ABC742E401B0DE02D90104B404BC8073D9BF52D409A779CA223094B408CB96B09F9A02D4069006F8104054B40E86A2BF6977D2D403255302AA9034B40CAC342AD691E2D4069006F8104FD4A40E0BE0E9C33022D405F29CB10C7FA4A404850FC1873F72C40B7627FD93DF94A40D26F5F07CED92C40AE47E17A14F64A40C66D3480B7C02C40A2B437F8C2F44A40DE9387855AB32C406ADE718A8EF44A40F241CF66D5A72C40CDCCCCCCCCF44A40728A8EE4F27F2C404BEA043411F64A40FA7E6ABC74732C406688635DDCF64A403D9B559FAB6D2C408FC2F5285CF74A4091ED7C3F355E2C409A779CA223F94A40F6285C8FC2352C408FE4F21FD2FF4A4038F8C264AA002C404694F6065F084B40E71DA7E848EE2B409A081B9E5E094B4040A4DFBE0EDC2B407C613255300A4B409BE61DA7E8C82B40166A4DF38E0B4B4096218E7571BB2B40D93D7958A80D4B400F0BB5A679A72B406E3480B740124B40AA60545227A02B40211FF46C56154B40B6F3FDD478892B40A1D634EF38154B40F931E6AE25842B4017B7D100DE124B409031772D219F2B404C378941600D4B40E78C28ED0D9E2B40613255302A094B40304CA60A46A52B40B1E1E995B2044B402B8716D9CEB72B40ABCFD556ECFF4A4005A3923A01CD2B4044696FF085014B40D881734694D62B40DC4603780B044B409A779CA223D92B40643BDF4F8D074B402A3A92CB7FE82B409D11A5BDC1074B4068B3EA73B5F52B40107A36AB3E074B405227A089B0012C40151DC9E53F044B40BA490C022B072C4036CD3B4ED1014B40D50968226C182C40FFB27BF2B0004B40E9263108AC1C2C404BEA043411FE4A40DCD7817346142C40D49AE61DA7F84A408351499D80062C4044696FF085F94A409FCDAACFD5F62B4097900F7A36FB4A40984C158C4AEA2B40FF21FDF675F84A40A9A44E4013E12B40228E75711BF54A40EBE2361AC0DB2B407B14AE47E1F24A405839B4C876BE2B40AAF1D24D62F04A40B8AF03E78CA82B40BC74931804EE4A40304CA60A46C52B404FAF946588EB4A40F5B9DA8AFDE52B40EB73B515FBEB4A40AA60545227002C40CC5D4BC807ED4A40C0EC9E3C2C142C40C8073D9B55EF4A400AD7A3703D2A2C4064CC5D4BC8EF4A40508D976E12632C400000000000F04A4055302AA913702C40AC1C5A643BEF4A4063EE5A423E882C40174850FC18EB4A4014AE47E17A942C400C93A98251E94A40598638D6C5AD2C40744694F606E74A40C1A8A44E40D32C404BEA043411EE4A40A301BC0512F42C40910F7A36ABEE4A4008AC1C5A641B2D402041F163CCED4A409A081B9E5E292D4014AE47E17AEC4A400A68226C783A2D402A3A92CB7FE84A40E86A2BF6973D2D40984C158C4AE24A40B22E6EA3011C2D406688635DDCD64A40CDCCCCCCCC0C2D406ADE718A8ED44A4035EF384547D22C40C976BE9F1AD74A4096218E7571BB2C4044696FF085D94A40228E75711B8D2C401A51DA1B7CD94A4088635DDC46832C407E1D386744D94A4018265305A3722C40B6847CD0B3D94A407AA52C431CEB2B403333333333E34A40CBA145B6F39D2B40764F1E166AED4A40BF7D1D3867A42B40711B0DE02DF04A402575029A08BB2B4088855AD3BCF34A407FFB3A70CEA82B402063EE5A42FE4A406DC5FEB27B922B406666666666064B400C022B8716992B405F29CB10C70A4B40F9A067B3EA932B40832F4CA60A0E4B405DFE43FAED6B2B4012143FC6DC154B402B8716D9CEF72A403A92CB7F480F4B40569FABADD8FF2A40C2172653050B4B4061C3D32B65F92A40D0D556EC2F0B4B40F085C954C1E82A408638D6C56D0C4B4052499D8026C22A4011363CBD52164B40E02D90A0F8912A404BEA0434111E4B40CDCCCCCCCC6C2A4063EE5A423E204B40789CA223B93C2A4008AC1C5A64234B40B1BFEC9E3C0C2A40091B9E5E29334B409D8026C28687294048E17A14AE2F4B40E86A2BF6975D29404703780B24304B40569FABADD83F294072F90FE9B72F4B40B515FBCBEE292940F38E5374242F4B40EF38454772192940A01A2FDD242E4B40849ECDAACFF528406DC5FEB27B2A4B4066F7E461A1D6284079E9263108244B400C022B8716D928409A779CA223214B4048BF7D1D38E72840D5E76A2BF61F4B4054742497FFD02840F241CF66D51F4B40AB3E575BB1BF2840363CBD5296214B405E4BC8073DBB28409E5E29CB10274B400B46257502DA284048E17A14AE2F4B40933A014D84ED2840265305A392324B400C93A982514929403EE8D9ACFA344B40BADA8AFD65572940F775E09C11354B407FD93D7958682940AC8BDB6800374B40857CD0B3597529402E90A0F831364B40151DC9E53F842940BE9F1A2FDD344B40894160E5D0C22940789CA223B9344B402B8716D9CED729401F85EB51B8364B40B003E78C28CD29400DE02D90A0384B40ECC039234A9B2940713D0AD7A3384B40CD3B4ED1915C2940C5FEB27BF2384B408A8EE4F21F522940705F07CE19394B4082734694F6462940B6F3FDD478394B40DBF97E6ABC1429403411363CBD3A4B40598638D6C50D2940B1E1E995B23C4B404BEA043411F628400D71AC8BDB384B40AB3E575BB1DF284099BB96900F324B40A5BDC11726B32840D712F241CF264B408195438B6CA72840B1E1E995B2244B401895D40968422840FF21FDF675184B4015719DF311002840B9D89BB567164B40D42B6519E2F82740CA32C4B12E164B401F85EB51B87E2740158C4AEA04144B400000000000602740083D9B559F134B401B0DE02D9040274058A835CD3B0E4B40C66D3480B74027405F984C158C0A4B4065AA6054522727405C2041F163044B40B22E6EA3011C274096218E7571034B402D431CEBE2162740A54E401361034B40B37BF2B0500B2740787AA52C43044B4007F0164850FC2640014D840D4FFF4A4067D5E76A2BF62640A52C431CEBFA4A40DE9387855AD32640CB10C7BAB8F54A40E25817B7D18026400EBE30992AF84A40CBA145B6F35D264044696FF085014B40C6DCB5847C302640E09C11A5BD014B40956588635D1C2640C5FEB27BF2004B402DB29DEFA7062640BADA8AFD65FF4A4004E78C28EDED254068226C787AFD4A403B014D840DCF2540FB3A70CE88FA4A40B1BFEC9E3CCC25401EA7E8482EF74A40508D976E12A32540B515FBCBEEF14A40B5A679C729BA2540E8D9ACFA5CF54A40D656EC2FBBC7254052499D8026FA4A40A60A462575C225402E90A0F831FE4A407E8CB96B09B9254048BF7D1D38FF4A40DB8AFD65F7A4254073D712F241FF4A402C6519E2589725408195438B6CFF4A4076711B0DE08D25400D71AC8BDB004B4016FBCBEEC983254031992A1895044B40BC0512143F862540AC1C5A643B074B405F07CE19519A254096218E75710B4B4060764F1E16AA2540083D9B559F0B4B40894160E5D0C22540083D9B559F0B4B401F85EB51B81E2640F46C567DAE164B40E3A59BC420302640FCA9F1D24D1A4B404B598638D6252640711B0DE02D304B402D431CEBE216264065AA6054522F4B40D49AE61DA70826408FC2F5285C2F4B4045D8F0F44AF92540F2B0506B9A2F4B407B832F4CA6EA25408D976E1283304B40A167B3EA73F52540C66D3480B7304B40F853E3A59BE42540F0A7C64B37314B40304CA60A46C5254011363CBD522E4B4005000000053411363CFD2540B81E85EB51304B409CC420B072082640545227A089304B403D0AD7A370FD2540D42B6519E2304B40A167B3EA73F52540C66D3480B7304B40053411363CFD2540B81E85EB51304B4030000000CAC342AD69FE27405D6DC5FEB2734B407B14AE47E1BA274045D8F0F44A794B4088F4DBD781B32740431CEBE2367A4B40E10B93A982B1274051DA1B7C617A4B40D49AE61DA7882740174850FC187B4B4091ED7C3F357E27407B14AE47E17A4B402D431CEBE2762740B5A679C7297A4B4079E92631086C27409C33A2B437784B408BFD65F7E4812740A1F831E6AE6D4B401C7C61325590274086C954C1A86C4B40A089B0E1E995274032772D211F6C4B40265305A3929A2740CF66D5E76A6B4B4011363CBD52B62740174850FC18634B405C2041F163CC2740EB73B515FB5B4B40D49AE61DA7C82740E09C11A5BD594B408CDB68006FC127402B1895D409584B405917B7D100BE274013F241CF66554B405839B4C876BE2740A54E401361534B40D1915CFE43DA2740A8C64B3789494B40F90FE9B7AFE32740713D0AD7A3484B40AC8BDB6800EF2740ABCFD556EC474B4091392221C2F227406FAF16E98F484B406891ED7C3FF52740F0164850FC484B40DE718A8EE4F22740DE02098A1F4B4B403A234A7B83EF27405917B7D1004E4B40228E75711BED2740462575029A504B40EC51B81E85EB2740A52C431CEB524B4026E4839ECDEA2740E9B7AF03E7544B40780B24287EEC2740C976BE9F1A574B40C6DCB5847CF0274044696FF085594B40BC96900F7AF62740A52C431CEB5A4B4007F01648501C2840091B9E5E29634B40F5DBD78173262840CDCCCCCCCC644B40E8D9ACFA5C2D2840840D4FAF94654B402D431CEBE23628403C4ED1915C664B4093A98251493D284048BF7D1D38674B40E2E995B20C51284099BB96900F6A4B40D95F764F1E562840FAEDEBC0396B4B40F5B9DA8AFD4528401EA7E8482E6F4B40E9482EFF213D2840FE43FAEDEB704B407F6ABC74933828409A99999999714B40FB5C6DC5FE322840C3D32B6519724B407C613255302A284051DA1B7C61724B409031772D211F284099BB96900F724B4088F4DBD7811328400AD7A3703D724B400AD7A3703D0A28403411363CBD724B40DC31AF0200002840922F780392734B40CAC342AD69FE27405D6DC5FEB2734B40360000009A081B9E5EC92640C976BE9F1A6F4B40D42B6519E2B826409A779CA223714B40C286A757CAB22640DF4F8D976E724B40EA95B20C71AC264030BB270F0B754B40A4DFBE0E9C93264062105839B4784B40228E75711B8D26406F8104C58F794B40D0B359F5B97A264098DD9387857A4B4017B7D100DE6226405F984C158C7A4B40C0EC9E3C2C542640A60A4625757A4B404B598638D6452640C3D32B65197A4B4022FDF675E03C2640B6847CD0B3794B406ADE718A8E242640D50968226C784B40E86A2BF6971D264048E17A14AE774B404BC8073D9B152640A01A2FDD24764B40E561A1D6340F2640CDCCCCCCCC744B40BA490C022B0726405F07CE1951724B40772D211FF40C264063EE5A423E684B40ED9E3C2CD4FA2540A1D634EF38654B4023DBF97E6AFC254014AE47E17A644B4060764F1E160A2640C4B12E6EA3614B4074B515FBCB0E2640C5FEB27BF2604B40C286A757CA322640D7A3703D0A5F4B4055C1A8A44E402640499D8026C25E4B40B515FBCBEE49264011363CBD525E4B40A8C64B378961264022FDF675E05C4B40AEB6627FD97D2640174850FC185B4B40BC0512143F86264098DD9387855A4B4003098A1F638E26406F8104C58F594B408CDB68006FA126405839B4C876564B40DE9387855AB32640CEAACFD556544B40371AC05B20C126405F29CB10C7524B409BE61DA7E8E826402C6519E2584F4B401C7C613255F0264001DE02098A4F4B40EC51B81E850B2740B5A679C729524B4026E4839ECD2A2740B0726891ED544B409CA223B9FC472740CDCCCCCCCC544B4088635DDC4663274096438B6CE7534B4052B81E85EB7127407A36AB3E57534B407E8CB96B09792740ED0DBE3099524B403A234A7B838F2740E02D90A0F8514B40D044D8F0F4AA27405BB1BFEC9E544B4000917EFB3AB02740A1F831E6AE554B402D431CEBE2B62740B9FC87F4DB574B4045D8F0F44AB92740014D840D4F5F4B40A857CA32C4B12740984C158C4A624B40637FD93D797827403D0AD7A3706D4B4026E4839ECD6A27402B1895D409704B401C7C6132555027405D6DC5FEB2734B407D3F355EBA4927404F401361C3734B40295C8FC2F5482740E3361AC05B704B408CB96B09F92027408C4AEA0434694B402CD49AE61D072740E0BE0E9C336A4B4036AB3E575BD1264066666666666E4B409A081B9E5EC92640C976BE9F1A6F4B4011000000B1BFEC9E3C8C26406D567DAEB63A4B400612143FC67C26403A92CB7F483F4B402D431CEBE2762640AAF1D24D62404B40AED85F764F5E2640C3F5285C8F424B40E0BE0E9C332226408638D6C56D444B40BC96900F7A16264027C286A757424B4058CA32C4B10E2640E3C798BB96404B4044696FF0850926403B70CE88D23E4B404B598638D6052640931804560E3D4B40DE02098A1F032640265305A3923A4B40F853E3A59B042640B7627FD93D394B40986E1283C00A26400EBE30992A384B40E5F21FD26F3F26406ABC749318344B40D734EF384547264040A4DFBE0E344B400000000000A02640787AA52C43344B40D0B359F5B99A264083C0CAA145364B40B1BFEC9E3C8C26406D567DAEB63A4B401D000000933A014D84AD25408D28ED0DBE784B408104C58F31B72540CE88D2DEE07B4B408CB96B09F9C0254012143FC6DC7D4B40A1F831E6AEC52540D8817346947E4B40091B9E5E29CB2540ABCFD556EC7F4B40A779C7293AD22540083D9B559F834B40789CA223B9DC2540B6847CD0B3894B40AB3E575BB1DF2540EC51B81E858B4B40EC2FBB270FEB2540098A1F63EE924B400F0BB5A679E725405C2041F163944B406FF085C954E12540F853E3A59B944B40CFF753E3A5DB2540CE1951DA1B944B40FDF675E09CD1254099BB96900F924B409E5E29CB10C725406744696FF08D4B4088F4DBD781B32540F6285C8FC2854B40B81E85EB519825408351499D807E4B407C613255308A2540A1D634EF387D4B4029ED0DBE3079254050FC1873D77A4B40DE02098A1F632540832F4CA60A764B40E9482EFF215D2540A3923A014D744B40598638D6C54D2540091B9E5E296B4B40560E2DB29D4F25401F85EB51B8664B409A999999995925402A3A92CB7F604B4071AC8BDB6860254066666666665E4B409F3C2CD49A662540228E75711B5D4B4004E78C28ED6D2540CDCCCCCCCC5C4B404FAF946588832540C139234A7B634B40DE718A8EE4922540158C4AEA046C4B40933A014D84AD25408D28ED0DBE784B403200000020D26F5F07CE2440091B9E5E29CB4B40508D976E12A32440CA54C1A8A4CE4B40F46C567DAE9624403B70CE88D2CE4B40CDCCCCCCCC6C244086C954C1A8CC4B408126C286A7572440DF4F8D976ECA4B40075F984C154C24407DAEB6627FC94B40569FABADD83F2440C66D3480B7C84B404B598638D625244073D712F241C74B40AA6054522700244093A9825149C54B402497FF907EDB2340363CBD5296C14B405B423EE8D9CC234029CB10C7BAC04B40736891ED7CBF2340B7D100DE02C14B40E4839ECDAAAF2340ED0DBE3099C24B4082734694F6A6234092CB7F48BFC54B403A92CB7F487F2340B003E78C28C54B40B22E6EA3015C2340BA6B09F9A0BF4B40DA1B7C6132752340B1E1E995B2BC4B407E1D3867448923404F401361C3BB4B409031772D219F2340E4141DC9E5B74B4011C7BAB88DC6234096218E7571AB4B40091B9E5E29CB234087A757CA32A44B4034A2B437F80224408D28ED0DBE984B4046B6F3FDD43824408195438B6C974B40598638D6C54D2440AA8251499D904B40304CA60A46452440AC8BDB68008F4B4058A835CD3B4E244026E4839ECD8A4B40C9E53FA4DFFE24405D6DC5FEB2834B40B515FBCBEE0925403255302AA9834B403B014D840D0F25404F401361C3834B40022B8716D92E25406519E25817874B403C4ED1915C3E2540006F8104C5874B40DBF97E6ABC5425409D11A5BDC1874B402AA913D044782540E3361AC05B884B40E2E995B20C91254080B74082E28F4B40AA8251499DA02540454772F90F994B407D3F355EBAA9254011363CBD52A64B40DBF97E6ABC942540917EFB3A70AE4B40E86A2BF6977D2540BBB88D06F0BE4B40FC1873D71252254097900F7A36CB4B4008AC1C5A643B2540A01A2FDD24CE4B405C8FC2F5283C2540711B0DE02DC84B400A68226C783A25406DC5FEB27BC24B40DA1B7C6132352540F54A598638BE4B40FB3A70CE88F22440645DDC4603B84B40B6847CD0B3D924408D976E1283B84B4046B6F3FDD4D824404F1E166A4DBB4B402F6EA301BCE52440A167B3EA73BD4B406DC5FEB27BF2244052B81E85EBC14B400EBE30992AF824405C8FC2F528C44B4020D26F5F07CE2440091B9E5E29CB4B40090000000B462575025A254082734694F67E4B40371AC05B20412540840D4FAF94854B40FE43FAEDEB0025400D71AC8BDB804B4048E17A14AE072540840D4FAF947D4B407B14AE47E11A2540C520B07268794B408CDB68006F212540705F07CE19794B407B14AE47E13A2540C4B12E6EA3794B40BBB88D06F05625405BD3BCE3147D4B400B462575025A254082734694F67E4B4014000000CC5D4BC8071D254032772D211FFC4B40AED85F764F1E2540AED85F764FFE4B4003780B24281E2540BA6B09F9A0FF4B4066F7E461A1162540D734EF3845FF4B40075F984C150C2540AF25E4839EFD4B400E4FAF9465082540787AA52C43FC4B40F5B9DA8AFD052540D7A3703D0AE74B4058A835CD3B0E25400AD7A3703DE24B402D431CEBE2162540287E8CB96BE14B403D9B559FAB2D2540295C8FC2F5E04B40DE9387855A332540295C8FC2F5E04B4046B6F3FDD4382540B6F3FDD478E14B404CA60A4625552540BA6B09F9A0EF4B40A167B3EA735525406E3480B740F24B40DCD781734654254064CC5D4BC8EF4B40014D840D4F4F2540F46C567DAEEE4B40304CA60A46452540910F7A36ABEE4B40CAC342AD693E2540736891ED7CEF4B40744694F6061F25407DD0B359F5F94B40CC5D4BC8071D254032772D211FFC4B400A000000CC5D4BC8079D2440CA54C1A8A4764B40A779C7293A9224408FE4F21FD2774B408F537424975F2440789CA223B97C4B405227A089B0612440B4C876BE9F7A4B402041F163CC7D24408716D9CEF7734B40780B24287ECC24407DAEB6627F694B40C6DCB5847CD024409A779CA223694B40E86A2BF697DD244088855AD3BC6B4B405227A089B0E12440D8817346946E4B40CC5D4BC8079D2440CA54C1A8A4764B402400000052499D802682234026E4839ECD8A4B403F575BB1BF6C2340A60A4625758A4B406A4DF38E535423409B559FABAD884B40F31FD26F5F472340D6C56D3480874B4017D9CEF75343234083C0CAA145864B40B3EA73B5155B234052499D8026824B402F6EA301BC65234045D8F0F44A814B40560E2DB29D6F23408C4AEA0434814B4007CE1951DA7B23406F8104C58F814B401B9E5E29CB902340A7E8482EFF814B408126C286A79723408B6CE7FBA9814B40CDCCCCCCCCAC2340F853E3A59B7C4B401E166A4DF3AE2340B8AF03E78C784B40B8AF03E78CA823401B0DE02D90784B4033C4B12E6EA32340C58F31772D794B4055302AA91390234040A4DFBE0E7C4B40F697DD9387852340DAACFA5C6D7D4B40151DC9E53F842340EC2FBB270F7B4B40EC51B81E858B234090A0F831E6764B40A913D044D890234023DBF97E6A744B40EBE2361AC09B2340DE02098A1F734B407B832F4CA6CA23402BF697DD936F4B40CC5D4BC807DD23402063EE5A426E4B40EFC9C342ADE923404B598638D66D4B4030BB270F0BF523403D2CD49AE66D4B405F07CE1951FA2340AE47E17A146E4B40C139234A7B232440B9FC87F4DB6F4B4085EB51B81E2524406FF085C954714B4033C4B12E6E232440ED0DBE3099724B404BEA043411162440D578E92631784B401895D4096802244013F241CF667D4B400000000000002440A089B0E1E97D4B40E3A59BC420F023409A081B9E5E814B40F6285C8FC29523409A99999999894B4097900F7A368B234027C286A7578A4B4052499D802682234026E4839ECD8A4B4017000000F085C954C1D8384000917EFB3A405040832F4CA60AF638406F8104C58F4150400000000000003940D93D7958A8415040BC96900F7A0639404B598638D6415040B81E85EB51083940F5DBD78173425040F7E461A1D6043940C286A757CA425040D3BCE3141DD9384014D044D8F044504013F241CF66D53840CC5D4BC807455040AC8BDB6800CF384054742497FF4450406C09F9A067B33840CD3B4ED191445040E86A2BF697AD384071AC8BDB68445040BEC1172653A53840A301BC051244504074B515FBCB9E38405D6DC5FEB2435040AC8BDB68008F3840A01A2FDD24425040053411363C8D38409A99999999415040C520B07268913840BADA8AFD653F50402EFF21FDF69538400AD7A3703D3E50407DAEB6627F9938405227A089B03D504085EB51B81EB53840CD3B4ED1913C50407E8CB96B09B93840D50968226C3C50405C8FC2F528BC38409CC420B0723C5040A7E8482EFFD138405227A089B03D5040F085C954C1D8384000917EFB3A4050400F000000226C787AA58C374050FC1873D7FA4D40D26F5F07CE893740A52C431CEBFA4D40D9CEF753E38537405F29CB10C7FA4D4035EF3845476237408351499D80F64D403B70CE88D25E374069006F8104F54D40386744696F6037407958A835CDF34D4032772D211F643740A54E401361F34D4082734694F66637404F1E166A4DF34D40FD87F4DBD781374077BE9F1A2FF54D40F085C954C19837402063EE5A42F64D402041F163CC9D3740BC96900F7AF64D40BC0512143FA6374012143FC6DCF54D404D840D4FAFB43740F46C567DAEF64D407DD0B359F5B93740E561A1D634F74D40226C787AA58C374050FC1873D7FA4D401500000068226C787A6537408351499D80464D40D93D7958A8653740D5E76A2BF6474D40B9FC87F4DB573740355EBA490C524D408C4AEA04345137404F1E166A4D534D4068226C787A45374030BB270F0B554D408FC2F5285C3F37403D2CD49AE6554D40BADA8AFD65373740499D8026C2564D406C09F9A067333740BBB88D06F0564D4072F90FE9B72F374074B515FBCB564D40EA95B20C712C37408351499D80564D4011363CBD522637402041F163CC554D40F9A067B3EA233740A1D634EF38554D401B0DE02D90103740AC1C5A643B4F4D40C976BE9F1A0F3740AF946588634D4D40FE65F7E46111374096B20C71AC4B4D4065AA60545217374035EF3845474A4D402CD49AE61D373740B1BFEC9E3C444D40B5A679C7293A37407958A835CD434D403D0AD7A3705D3740A4703D0AD7434D408E06F01648603740B1BFEC9E3C444D4068226C787A6537408351499D80464D40160000001F85EB51B85E3740068195438B7C4D406F8104C58F6137403EE8D9ACFA7C4D40DDB5847CD063374058A835CD3B7E4D40F90FE9B7AF633740711B0DE02D804D40CB10C7BAB85D3740C1A8A44E40834D4060764F1E165A3740075F984C15844D4082734694F65637403FC6DCB584844D406C09F9A067533740CDCCCCCCCC844D408C4AEA04343137404C37894160854D40917EFB3A702E374013F241CF66854D409F3C2CD49A26374077BE9F1A2F854D4088635DDC46233740E9B7AF03E7844D40386744696F20374014AE47E17A844D405917B7D1001E3740C05B2041F1834D40B1E1E995B21C3740A69BC420B0824D4017D9CEF75323374069006F81047D4D40BC74931804263740C05B2041F17B4D40B5A679C7292A37405E4BC8073D7B4D4091ED7C3F352E3740C2172653057B4D4082734694F646374088635DDC467B4D40D0B359F5B94A3740CF66D5E76A7B4D401F85EB51B85E3740068195438B7C4D403900000057EC2FBB27DF364002BC0512144F4D40E25817B7D1D03640BBB88D06F04E4D401283C0CAA1C536403E7958A8354D4D40C7293A92CB9F3640C05B2041F14B4D40386744696F8036405BD3BCE3144D4D404F401361C353364052B81E85EB494D40FDF675E09C313640832F4CA60A464D40CDCCCCCCCC1C3640AC8BDB68003F4D4075029A081BFE35400B46257502424D40CDCCCCCCCCEC3540E0BE0E9C33424D409FABADD85FD635400D71AC8BDB404D4040A4DFBE0EDC35404B598638D63D4D4054E3A59BC4E03540B1E1E995B23C4D400C93A98251E93540508D976E123B4D4002BC051214FF3540E25817B7D1304D40A857CA32C4013640D93D7958A82D4D40BF0E9C33A2F4354096438B6CE72B4D408A8EE4F21FE23540C1CAA145B62B4D40D578E92631D8354069006F8104254D40545227A089E03540C5FEB27BF2204D4050FC1873D7123640D95F764F1E164D40FA7E6ABC74233640EA95B20C71144D405227A089B03136408AB0E1E995124D40F46C567DAE263640EC2FBB270F0B4D4025068195431B3640ED9E3C2CD40A4D40BC7493180416364052499D80260A4D405D6DC5FEB2FB35407958A835CDFB4C40C8073D9B55FF354092CB7F48BFF54C40C0EC9E3C2C04364086C954C1A8F44C40EFC9C342AD093640787AA52C43F44C40053411363C0D3640EA95B20C71F44C40FBCBEEC9C3123640211FF46C56F54C4061C3D32B65193640C976BE9F1AF74C40A4703D0AD7333640F54A598638FE4C406C09F9A0674336406ADE718A8E0C4D40A167B3EA734536404182E2C798134D409FCDAACFD5463640C976BE9F1A174D40ACADD85F765F3640CEAACFD5561C4D4097900F7A367B3640492EFF21FD1E4D406891ED7C3F853640AC8BDB68001F4D40DB8AFD65F79436406688635DDC1E4D40D95F764F1EA6364068226C787A1D4D40A857CA32C4C13640499D8026C21E4D4065AA6054520737402041F163CC2D4D40386744696F103740FE65F7E461314D40F90FE9B7AF1337403EE8D9ACFA344D4014AE47E17A243740B84082E2C7384D4088855AD3BC3337407E1D386744394D4027A089B0E139374080B74082E2374D406E3480B740423740744694F606374D40158C4AEA045437408C4AEA0434394D40D5E76A2BF6473740D8F0F44A593E4D4017D9CEF753433740D6C56D34803F4D40107A36AB3E17374063EE5A423E484D4095D4096822FC3640789CA223B94C4D407E1D386744E936401E166A4DF34E4D4057EC2FBB27DF364002BC0512144F4D4013000000569FABADD8CF36405C8FC2F528FC4D402041F163CCCD364044FAEDEBC0F94D40295C8FC2F5D83640A1F831E6AEF54D40FDF675E09CE136403255302AA9F34D407B14AE47E1EA364097FF907EFBF24D40933A014D84ED3640C217265305F34D408A8EE4F21FF23640C139234A7BF34D40BF0E9C33A20437403333333333F34D40EE7C3F355E0A374050FC1873D7F24D40E86A2BF6970D374017D9CEF753F34D40E0BE0E9C3312374044696FF085F94D4076711B0DE00D374009F9A067B3FA4D40C6DCB5847C0037406DE7FBA9F1FA4D4041F163CC5DFB364009F9A067B3FA4D40C66D3480B7F03640A60A462575FA4D409F3C2CD49AD63640A779C7293AFA4D406ADE718A8ED43640A54E401361FB4D4088855AD3BCD33640F853E3A59BFC4D40569FABADD8CF36405C8FC2F528FC4D404700000063EE5A423EB83640FF21FDF675804D406C09F9A067B3364052499D8026824D401895D40968B23640D95F764F1E864D406C09F9A067933640B84082E2C7884D40832F4CA60A8636407B14AE47E1824D4022FDF675E07C3640AC8BDB68007F4D402B8716D9CE77364077BE9F1A2F7D4D40E561A1D6346F36405D6DC5FEB27B4D40AA6054522760364036CD3B4ED1794D40FE43FAEDEB303640E17A14AE47794D40713D0AD7A310364027A089B0E1794D40E8D9ACFA5C0D36406F8104C58F794D407A36AB3E570B3640D49AE61DA7784D4094F6065F980C36403B014D840D774D408E06F01648103640F54A598638764D400AD7A3703D2A3640B5A679C729724D40E8D9ACFA5C2D36400BB5A679C7714D40D0B359F5B93A3640AAF1D24D62704D40022B8716D93E3640FF21FDF675704D402D431CEBE2463640FD87F4DBD7714D40832F4CA60A563640E0BE0E9C33724D40CA54C1A8A45E36407DD0B359F5714D4050FC1873D76236405305A3923A714D4048E17A14AE6736402BF697DD936F4D405BD3BCE3146D364068226C787A6D4D4018265305A372364050FC1873D76A4D407FFB3A70CE783640E09C11A5BD614D400E2DB29DEF7736402575029A085B4D407B14AE47E17A36406F8104C58F594D406ADE718A8E843640FF21FDF675584D408048BF7D1D8836404703780B24584D405C8FC2F5288C3640D5E76A2BF6574D40C66D3480B790364080B74082E2574D40637FD93D799836401CEBE2361A584D40C7293A92CB9F3640FF21FDF675584D4068226C787AA536400C93A98251594D40D0B359F5B9AA364035EF3845475A4D40933A014D84AD36407A36AB3E575B4D40FE43FAEDEBB03640D95F764F1E5E4D40166A4DF38EB336402A3A92CB7F604D40462575029AB8364040A4DFBE0E644D40E71DA7E848BE3640ADFA5C6DC5664D409F3C2CD49AC63640B84082E2C7684D403F355EBA49CC36409A99999999694D400000000000D036400BB5A679C7694D404FAF946588D33640FE43FAEDEB684D402041F163CCCD36406688635DDC664D40D044D8F0F4CA3640917EFB3A70664D409D11A5BDC1C73640933A014D84654D40645DDC4603C8364096B20C71AC634D40956588635DCC3640C217265305634D40A913D044D8D03640A52C431CEB624D40D3BCE3141DD93640C217265305634D40FBCBEEC9C3E2364007F0164850644D40DFE00B93A9E23640AA60545227684D4004E78C28EDDD3640C58F31772D694D401895D40968E23640B4C876BE9F6A4D40FBCBEEC9C3F23640075F984C156C4D402EFF21FDF6F536405C8FC2F5286C4D4036AB3E575B0137405F07CE19516A4D40BD5296218E0537407E8CB96B09694D404182E2C7980B3740EC2FBB270F6B4D4024287E8CB90B37403FC6DCB5846C4D40A4703D0AD7F336404F401361C37B4D405917B7D100EE3640F6285C8FC27D4D40956588635DDC36409C33A2B437804D402B8716D9CED736408E06F01648804D405BD3BCE314CD36401DC9E53FA47F4D40ABCFD556ECBF36400000000000804D40CE88D2DEE0BB3640711B0DE02D804D4063EE5A423EB83640FF21FDF675804D401200000060764F1E16EA36400D71AC8BDBE84F4042CF66D5E7EA3640984C158C4AEA4F40BE30992A18E53640AC1C5A643BEF4F40C520B07268E1364072F90FE9B7EF4F4076711B0DE0DD3640E4141DC9E5EF4F403C4ED1915CCE364063EE5A423EF04F404ED1915CFEB336407E8CB96B09E94F4003780B2428AE36403A92CB7F48E74F403FC6DCB584AC3640211FF46C56E54F404D158C4AEAB436405E4BC8073DE34F4039D6C56D34C036407958A835CDE34F40DA1B7C6132C53640F8C264AA60E44F40371AC05B20D1364096438B6CE7E34F4043AD69DE71DA364096218E7571E34F40E71DA7E848DE3640B4C876BE9FE24F400000000000E0364074B515FBCBE64F4035EF384547E236401CEBE2361AE84F4060764F1E16EA36400D71AC8BDBE84F4018000000DA1B7C6132A5364097FF907EFB1A4E40BC96900F7A96364052B81E85EB194E40D3BCE3141D7936405D6DC5FEB21B4E4085EB51B81E753640CEAACFD5561C4E408A1F63EE5A723640083D9B559F1B4E4003780B24286E3640D42B6519E2184E405F07CE19516A3640C139234A7B134E4094F6065F986C364012143FC6DC0D4E40462575029A7836405305A3923A094E40462575029A7836402B8716D9CEFF4D40FB5C6DC5FE8236409C33A2B437004E406666666666863640E3C798BB96004E40C3F5285C8F923640EC51B81E85034E40D26F5F07CE993640B81E85EB51004E4027A089B0E199364012143FC6DCFD4D408A8EE4F21FA23640462575029A004E4076711B0DE0AD3640D5E76A2BF6FF4D405E4BC8073DBB364055C1A8A44E004E406666666666D63640B22E6EA3010C4E40F0164850FCD83640BA6B09F9A00F4E40F6285C8FC2D53640E25817B7D1184E4089D2DEE00BD336405BD3BCE3141D4E40EC51B81E85BB36405C8FC2F5281C4E40DA1B7C6132A5364097FF907EFB1A4E401700000004E78C28ED3D364048BF7D1D38274E40F2B0506B9A37364001DE02098A274E404D840D4FAF3436402BF697DD93274E40462575029A183640BADA8AFD65274E40C3F5285C8F1236404C37894160254E406DC5FEB27B123640A7E8482EFF214E40A9A44E40132136408D28ED0DBE204E40F46C567DAE263640B84082E2C7204E40956588635D2C3640B6F3FDD478214E40AE47E17A142E3640A69BC420B0224E40BF0E9C33A22436404F401361C3234E40BD5296218E3536407B14AE47E1224E402B1895D40938364098DD938785224E409F3C2CD49A363640BBB88D06F01E4E40B3EA73B5153B3640AA60545227204E40F2D24D621048364099BB96900F224E40075F984C154C3640B5A679C729224E403A234A7B834F364052B81E85EB214E40A7E8482EFF51364044696FF085214E40BEC1172653553640E02D90A0F8214E400F0BB5A679573640CD3B4ED191244E40C520B072685136405AF5B9DA8A254E4004E78C28ED3D364048BF7D1D38274E401100000057EC2FBB27FF35406744696FF02D4E40575BB1BFECEE3540211FF46C56354E4068226C787AE53540D42B6519E2384E406B9A779CA2D335405D6DC5FEB23B4E40FE43FAEDEBD03540CE88D2DEE03B4E4003098A1F63CE354033333333333B4E40D42B6519E2C83540C4B12E6EA3314E407E8CB96B09C9354063EE5A423E304E40EC2FBB270FCB35408195438B6C2F4E40C4B12E6EA3D135404B598638D62D4E40BC0512143FE63540A52C431CEB2A4E4035EF384547F23540FD87F4DBD7294E40A1F831E6AEF535406F8104C58F294E40D42B6519E2F83540287E8CB96B294E404182E2C798FB35407DAEB6627F294E40C898BB9690FF354026E4839ECD2A4E4057EC2FBB27FF35406744696FF02D4E400E000000E8D9ACFA5CDD3540A4703D0AD7134E40C3F5285C8FE23540AED85F764F164E40E5F21FD26FDF35401DC9E53FA4174E405E4BC8073DDB3540545227A089184E404F401361C3D33540D50968226C184E40613255302AB93540B9FC87F4DB174E4011363CBD52B635401EA7E8482E174E406A4DF38E53B43540E8D9ACFA5C154E40C217265305B33540029A081B9E0E4E405F07CE1951BA3540D95F764F1E0E4E40053411363CBD3540AE47E17A140E4E4072F90FE9B7BF35402063EE5A420E4E40295C8FC2F5C8354048BF7D1D380F4E40E8D9ACFA5CDD3540A4703D0AD7134E4012000000A7E8482EFF213540462575029A984F406744696FF0253540D881734694964F405F07CE19512A3540F54A598638964F4005A3923A012D35406666666666964F401F85EB51B82E3540BADA8AFD65974F4054E3A59BC43035409C33A2B437984F40C7BAB88D064035404F401361C3934F40E561A1D6343F354098DD938785924F409D8026C28647354097FF907EFB924F4003780B24284E3540EC51B81E85934F40068195438B6C35409BE61DA7E8984F40D122DBF97E6A3540E4141DC9E59F4F40022B8716D95E3540E25817B7D1A04F40613255302A593540545227A089A04F40B29DEFA7C64B354090A0F831E69E4F40F853E3A59B1435402497FF907EA34F400C93A98251193540F54A5986389E4F40A7E8482EFF213540462575029A984F403B0000003C4ED1915CDE33403255302AA9334E4096218E7571DB33403255302AA9334E403333333333D33340E0BE0E9C33324E40575BB1BFECCE3340B81E85EB51304E402B1895D409C83340CC5D4BC8072D4E4067D5E76A2BD633400C022B8716294E403D0AD7A370DD3340B81E85EB51284E40560E2DB29DDF33400BB5A679C7294E4036AB3E575BE1334008AC1C5A642B4E40A1D634EF38E53340C1CAA145B62B4E403C4ED1915CEE334090A0F831E6264E4039454772F9EF3340857CD0B359254E40022B8716D9EE3340401361C3D3234E401CEBE2361AD03340E4141DC9E5174E40B37BF2B050CB3340D578E92631184E404F1E166A4DC333403B014D840D1F4E402D431CEBE2C63340287E8CB96B214E400E4FAF9465C8334005C58F3177254E4072F90FE9B7BF3340AC8BDB6800274E40BC74931804A633405305A3923A214E408AB0E1E995B23340BF0E9C33A2144E40F085C954C1B833404703780B24104E4039D6C56D34C033405C8FC2F5280C4E40BD5296218EC5334027C286A7570A4E40295C8FC2F5D83340B6847CD0B3094E405BD3BCE314DD33406F1283C0CA094E4057EC2FBB27DF334025068195430B4E4030BB270F0BE53340EA95B20C710C4E40637FD93D79E8334087A757CA320C4E402575029A08EB3340CE88D2DEE00B4E40E9482EFF21ED3340508D976E120B4E408E06F01648F033402BF697DD93074E40C4B12E6EA3F1334068226C787A054E4018265305A3F2334099BB96900F0A4E40F8C264AA60F43340D0D556EC2F0B4E4080B74082E2F73340166A4DF38E0B4E40569FABADD8FF334096218E75710B4E40BD5296218E05344097FF907EFB0A4E40234A7B832F0C344097900F7A360B4E40211FF46C560D3440F853E3A59B0C4E409F3C2CD49A063440EBE2361AC0134E40CDCCCCCCCCFC33402041F163CC154E40A9A44E4013F133408FC2F5285C174E402041F163CCED3340E3361AC05B184E40448B6CE7FBE9334096218E75711B4E40BC96900F7A0634409D11A5BDC1274E40EF384547720934409D11A5BDC1274E40B22E6EA3010C3440BADA8AFD65274E40386744696F103440F54A598638264E4074B515FBCB1E34401F85EB51B81E4E40E5F21FD26F1F344014D044D8F01C4E40D122DBF97E1A34408716D9CEF71B4E406744696FF01534405839B4C876164E40D0B359F5B92A3440BE9F1A2FDD144E409D11A5BDC1373440DFE00B93A91A4E40D7A3703D0A473440174850FC18234E40A1F831E6AE153440F7E461A1D62C4E4080B74082E2E733403333333333334E403C4ED1915CDE33403255302AA9334E400D000000C520B072683134408E06F01648084E4027A089B0E1293440B84082E2C7084E403A234A7B831F34405F07CE19510A4E405C8FC2F5281C344088635DDC460B4E404260E5D0221B3440EB73B515FB0B4E408048BF7D1D18344096438B6CE70B4E40C520B0726801344063EE5A423E084E40386744696F003440D712F241CF064E40C3D32B6519223440F38E537424FF4D4069006F81043534406891ED7C3FFD4D4099BB96900F3A3440711B0DE02D004E4013F241CF663534404772F90FE9074E40C520B072683134408E06F01648084E40100000003FC6DCB584AC3340A01A2FDD24164E4042CF66D5E7AA33409CC420B072184E401B0DE02D90A0334048BF7D1D381F4E40226C787AA59C3340AAF1D24D62204E4060764F1E169A33408D28ED0DBE204E40A1F831E6AE9533408D28ED0DBE204E401A51DA1B7C91334055302AA913204E40D26F5F07CE893340B003E78C281D4E40A52C431CEB8233403B70CE88D2164E402EFF21FDF68533404F1E166A4D134E40B22E6EA3018C33409C33A2B437104E4055302AA91390334072F90FE9B70F4E4088635DDC46933340F2B0506B9A0F4E40D0B359F5B99A33404182E2C798134E400612143FC6AC33403255302AA9134E403FC6DCB584AC3340A01A2FDD24164E4013000000CE88D2DEE04B334069006F8104FD4C40613255302A49334069006F8104FD4C4026E4839ECD1A3340F7E461A1D6FC4C408126C286A7173340BF7D1D3867FC4C407E8CB96B09093340DA1B7C6132F54C40F0A7C64B3709334089D2DEE00BF34C404F1E166A4D1333403CBD529621EE4C4080B74082E2173340931804560EED4C408E06F01648203340C139234A7BEB4C40DC4603780B2433407958A835CDF34C402EFF21FDF6253340CCEEC9C342F54C40423EE8D9AC2A3340D712F241CFF64C40B0726891ED3C33408C4AEA0434F94C4019E25817B741334044696FF085F94C40DAACFA5C6D45334029ED0DBE30F94C409C33A2B437483340711B0DE02DF84C40BD5296218E55334026E4839ECDFA4C401F85EB51B84E3340789CA223B9FC4C40CE88D2DEE04B334069006F8104FD4C40330000002CD49AE61D5732407D3F355EBA814C4064CC5D4BC85732408B6CE7FBA9894C40BF0E9C33A26432408D28ED0DBE904C4026E4839ECD6A3240A60A462575924C40C3F5285C8F723240401361C3D3934C408B6CE7FBA9813240DAACFA5C6D954C4093A98251498D3240BADA8AFD65974C40637FD93D79A83240787AA52C439C4C40D881734694B63240D734EF38459F4C40D26F5F07CEC93240FE65F7E461B94C40696FF085C9C4324032772D211FBC4C406DC5FEB27BC232407E8CB96B09C14C40B3EA73B515CB3240F8C264AA60D44C4057EC2FBB27CF324099BB96900FDA4C400C93A98251D93240A3923A014DDC4C4004E78C28EDED3240F46C567DAEDE4C40F1F44A5986083340FD87F4DBD7E94C4054742497FF003340EC2FBB270FF34C40FE65F7E461013340EB73B515FBF34C40F1F44A5986E83240CC7F48BF7DF54C40A857CA32C4E13240CB10C7BAB8F54C40637FD93D79B832405917B7D100F64C40560E2DB29DAF3240228E75711BF54C408195438B6C77324072F90FE9B7E74C4096218E75716B32400C93A98251E14C409FCDAACFD5663240AD69DE718ADE4C40A857CA32C4613240EB73B515FBDB4C40B3EA73B5155B3240454772F90FD94C40499D8026C256324073D712F241D74C4096218E75714B3240DFE00B93A9D24C40F46C567DAE463240C58F31772DD14C4090A0F831E63E324073D712F241CF4C40F163CC5D4B3832403D2CD49AE6CD4C40E5F21FD26F2F32407958A835CDCB4C40C139234A7B233240AD69DE718AC64C40933A014D841D32405E4BC8073DC34C40234A7B832F1C3240E3C798BB96C04C40933A014D841D32405AF5B9DA8ABD4C4014AE47E17A243240BF7D1D3867B44C40637FD93D79283240D50968226CA84C402EFF21FDF6253240D95F764F1E9E4C40956588635D2C3240B5A679C729924C40FED478E926413240EEEBC039238A4C4019E25817B741324032772D211F844C40BD5296218E353240029A081B9E7E4C40F1F44A5986283240545227A089784C4069006F8104253240BE30992A18754C405E4BC8073D2B324014AE47E17A744C402EFF21FDF6353240CDCCCCCCCC744C40780B24287E4C32408FE4F21FD2774C402CD49AE61D5732407D3F355EBA814C400F000000FD87F4DBD78132406ADE718A8E2C4E40A2B437F8C27432401F85EB51B8364E405C8FC2F5286C32404A7B832F4C3E4E409B559FABAD683240D5E76A2BF63F4E4018265305A3623240462575029A404E40ACADD85F765F3240F2B0506B9A3F4E40A857CA32C4613240F7065F984C354E404D840D4FAF6432408E06F01648304E40F46C567DAE663240499D8026C22E4E406A4DF38E53843240713D0AD7A3284E4094F6065F988C32401EA7E8482E274E40C7293A92CB8F324002BC051214274E4035EF3845479232409D11A5BDC1274E4044696FF085893240A4703D0AD72B4E40FD87F4DBD78132406ADE718A8E2C4E400F00000076E09C11A5BD3140273108AC1CB24D4011C7BAB88DA631404A7B832F4CB64D40166A4DF38EA33140AD69DE718AB64D4001DE02098A9F3140917EFB3A70B64D4096B20C71AC9B3140D93D7958A8B54D40AE47E17A149E3140A52C431CEBB24D40EF38454772A9314096438B6CE7AB4D40B22E6EA301AC314050FC1873D7AA4D40569FABADD8AF3140A7E8482EFFA94D40F085C954C1B83140FF21FDF675A84D40371AC05B20C13140F2B0506B9AA74D402CD49AE61DC73140D6C56D3480A74D407D3F355EBAC931402AA913D044A84D4011C7BAB88DC631401D38674469AF4D4076E09C11A5BD3140273108AC1CB24D400A000000F90FE9B7AF83314030BB270F0B354F400F9C33A2B47731407B14AE47E13A4F40575BB1BFEC5E31405C2041F1633C4F4098DD9387856A3140AAF1D24D62304F4019E25817B7713140D7A3703D0A2F4F404D158C4AEA743140499D8026C22E4F40075F984C157C3140BC96900F7A2E4F408A1F63EE5A8231408351499D802E4F407B14AE47E18A31406688635DDC2E4F40F90FE9B7AF83314030BB270F0B354F400E000000C58F31772D51314096438B6CE7B34D409D11A5BDC1473140ABCFD556ECB74D406A4DF38E534431400D71AC8BDBB84D40A857CA32C4413140C58F31772DB94D40EA95B20C713C31406F8104C58FB94D4011C7BAB88D263140A60A462575BA4D4082734694F61631407B14AE47E1BA4D401973D712F2113140A60A462575BA4D40499D8026C226314045D8F0F44AB14D40091B9E5E293B314055302AA913B04D40C4B12E6EA341314064CC5D4BC8AF4D4087A757CA32443140ABCFD556ECAF4D40C74B37894150314009F9A067B3B24D40C58F31772D51314096438B6CE7B34D40340000003FC6DCB5847C3040AF25E4839E1D4C40AC8BDB68007F30403B70CE88D21E4C40E86A2BF6978D30400BB5A679C7294C408A1F63EE5A9230403D0AD7A3702D4C404F1E166A4D93304066F7E461A12E4C40E0BE0E9C339230404772F90FE92F4C4052B81E85EB91304060764F1E16324C406B9A779CA29330406ABC749318344C406D567DAEB6A230407CF2B0506B424C40D200DE0209BA304027A089B0E1594C40DA1B7C6132C5304012143FC6DC654C4063EE5A423EC830401D38674469674C40C7BAB88D06D030409A99999999694C404ED1915CFED33040C4B12E6EA3694C40499D8026C2D630407C613255306A4C40613255302AD93040158C4AEA046C4C4036AB3E575BE13040AC8BDB6800774C40053411363CED304022FDF675E0844C40832F4CA60AF63040C4B12E6EA3894C4035EF384547023140D42B6519E2904C40B0726891ED0C3140E4141DC9E5974C40C7293A92CB1F3140454772F90FA94C40EEEBC039231A3140789CA223B9AC4C40E6AE25E4830E3140925CFE43FAAD4C40D3BCE3141D09314030BB270F0BAD4C40A1F831E6AE0531405C8FC2F528AC4C40C3F5285C8F0231403333333333AB4C4091ED7C3F35FE30406F8104C58FA94C404182E2C798FB3040AAF1D24D62A84C40613255302AF9304002BC051214A74C4065AA605452F73040840D4FAF94A54C402F6EA301BCF53040C139234A7BA34C404B598638D6F53040D42B6519E2A04C408104C58F31F73040BBB88D06F09E4C4012A5BDC117F63040A245B6F3FD9C4C406666666666E63040E17A14AE47914C40D3BCE3141DD930409C33A2B437884C40569FABADD8BF30408E06F01648784C4085EB51B81EA53040705F07CE19714C40A9A44E4013A13040545227A089704C40CCEEC9C3429D3040736891ED7C6F4C407B14AE47E18A3040A54E401361634C404182E2C7986B3040EC2FBB270F4B4C4069006F81046530405C8FC2F528444C40DCD7817346643040EC51B81E853B4C40107A36AB3E673040174850FC18234C40613255302A693040CDCCCCCCCC1C4C404260E5D0226B3040ECC039234A1B4C405917B7D1006E30403411363CBD1A4C40ABCFD556EC6F3040EC2FBB270F1B4C40B7627FD93D793040789CA223B91C4C403FC6DCB5847C3040AF25E4839E1D4C4019000000A089B0E1E9352E4034A2B437F8824B405C2041F1634C2E4097FF907EFB8A4B40075F984C154C2E40545227A089904B40F5DBD78173462E40C3D32B6519924B40744694F6063F2E40EC2FBB270F934B401FF46C567D2E2E40CE88D2DEE0934B40C139234A7B232E405BB1BFEC9E944B401F85EB51B8FE2D40D5E76A2BF6974B40BC0512143FC62D40E8D9ACFA5C9D4B40E8D9ACFA5CAD2D4055302AA913A04B401361C3D32BA52D409A779CA223A14B40AA60545227A02D40A60A462575A24B40423EE8D9AC9A2D40C1CAA145B6A34B40D578E92631882D4002BC051214A74B40E86A2BF6977D2D401283C0CAA1A54B404B598638D6652D40EC51B81E859B4B402497FF907E5B2D40E9B7AF03E78C4B40A167B3EA73752D400C93A98251894B40CAC342AD697E2D40E3361AC05B884B404FAF946588C32D405D6DC5FEB2834B40C3F5285C8FE22D40B6847CD0B3814B40F6285C8FC2152E4065AA6054527F4B40B0726891ED1C2E404850FC18737F4B40D734EF3845272E404703780B24804B40A089B0E1E9352E4034A2B437F8824B405E000000EE5A423EE8D92A40A3923A014D544B40C3D32B6519E22A409FABADD85F564B40423EE8D9ACDA2A408FC2F5285C574B406ADE718A8EC42A40F38E537424574B40265305A392BA2A4082734694F6564B404BC8073D9B952A40CA32C4B12E564B40CA54C1A8A48E2A406744696FF0554B40D712F241CF862A40211FF46C56554B4093A98251497D2A4040A4DFBE0E544B408716D9CEF7732A40FC1873D712524B40567DAEB6627F2A40BADA8AFD65474B405396218E75912A4000917EFB3A484B40744694F6069F2A40FE65F7E461494B407FFB3A70CEA82A40ED0DBE30994A4B402EFF21FDF6B52A40E8D9ACFA5C4D4B40569FABADD8BF2A4012A5BDC1174E4B403108AC1C5AC42A40D200DE02094A4B40B5A679C729DA2A40295C8FC2F5484B4097900F7A36EB2A408351499D80464B406FF085C954012B409FABADD85F464B402A3A92CB7F082B4019E25817B7414B40363CBD5296012B402CD49AE61D3F4B409D11A5BDC1F72A40A089B0E1E93D4B4085EB51B81EE52A40D8817346943E4B40107A36AB3ED72A405F29CB10C7424B407C61325530CA2A404C37894160454B408CDB68006FC12A40E5F21FD26F474B40CE1951DA1BBC2A40984C158C4A4A4B40772D211FF4AC2A402A3A92CB7F484B40CFF753E3A59B2A40917EFB3A70464B4017B7D100DE822A40742497FF90464B40BC96900F7A762A401F85EB51B8464B4025068195434B2A404B598638D6454B404BC8073D9B552A4019E25817B7414B402D431CEBE2762A40CA32C4B12E3E4B4030BB270F0B752A40EC51B81E853B4B40DCD7817346542A408F53742497374B40B537F8C2646A2A4074B515FBCB364B40EE7C3F355E7A2A40E9263108AC344B402CD49AE61D872A40713D0AD7A3304B4029CB10C7BA782A402BF697DD932F4B40FFB27BF2B0702A4065AA6054522F4B402DB29DEFA7662A4072F90FE9B72F4B40022B8716D94E2A402B1895D409304B40F853E3A59B442A4001DE02098A2F4B409487855AD33C2A40174850FC182B4B40ABCFD556EC4F2A40C976BE9F1A274B405227A089B0812A40FE43FAEDEB204B407E1D386744892A40713D0AD7A3204B40DE02098A1FA32A408FE4F21FD21F4B4043AD69DE71CA2A40F8C264AA601C4B40265305A392DA2A40CA32C4B12E1E4B40098A1F63EEDA2A40D656EC2FBB1F4B40643BDF4F8DD72A400C93A98251214B401C7C613255D02A40B515FBCBEE214B40D7A3703D0AB72A40B7627FD93D214B406519E25817B72A4034A2B437F8224B401C7C613255F02A406EA301BC052A4B4088635DDC46032B407958A835CD2B4B40AB3E575BB15F2B40BF0E9C33A22C4B40CDCCCCCCCC6C2B4045D8F0F44A294B405DFE43FAED6B2B40BC74931804264B40DC4603780B642B406ABC749318244B40228E75711B6D2B4026E4839ECD224B40857CD0B359752B4097900F7A36234B4022FDF675E07C2B4051DA1B7C612A4B4011363CBD52762B4013F241CF662D4B40CE88D2DEE06B2B4054E3A59BC4304B4048E17A14AE672B40EFC9C342AD314B409D11A5BDC1572B4008AC1C5A64334B40D044D8F0F44A2B40A54E401361334B40DE02098A1F432B407A36AB3E57334B40B0726891ED3C2B40083D9B559F334B4026E4839ECD2A2B40545227A089384B402BF697DD93272B406DC5FEB27B3A4B40BA6B09F9A0272B40401361C3D33B4B403F575BB1BF2C2B40AEB6627FD93D4B40992A1895D4492B4036CD3B4ED1414B4011363CBD52562B40986E1283C0424B40EE7C3F355E5A2B404F401361C3434B40EBE2361AC05B2B403D0AD7A370454B40D34D621058592B40F1F44A5986484B40F4FDD478E9462B4017B7D100DE4A4B4007F01648503C2B40C2172653054B4B40560E2DB29D2F2B4050FC1873D74A4B4063EE5A423E082B40992A1895D4494B40F46C567DAEF62A406F8104C58F494B4061545227A0E92A409A081B9E5E494B403D2CD49AE6DD2A407DD0B359F5494B40E3C798BB96D02A4041F163CC5D4B4B407FD93D7958C82A40A1F831E6AE4D4B40A2B437F8C2C42A40B5A679C729524B40EFC9C342ADC92A40ECC039234A534B40EE5A423EE8D92A40A3923A014D544B401800000033C4B12E6E0329406EA301BC05824B409D8026C286E7284096218E7571834B40B537F8C264CA28405C8FC2F528844B40AB3E575BB19F28403FC6DCB584844B402575029A085B2840F6285C8FC27D4B40F853E3A59B442840273108AC1C7A4B40ECC039234A3B284088855AD3BC734B403E7958A8354D2840287E8CB96B714B404F401361C35328407E8CB96B09714B405917B7D1005E28409B559FABAD704B40D734EF3845872840D93D7958A8754B40575BB1BFEC9E28406F8104C58F794B40228E75711BAD28403411363CBD7A4B4029ED0DBE30B92840091B9E5E297B4B40371AC05B20C1284088635DDC467B4B401E166A4DF3CE284088635DDC467B4B40006F8104C5EF2840A60A4625757A4B4070CE88D2DE002940B7627FD93D794B40D122DBF97E0A29400D71AC8BDB784B40C286A757CA122940295C8FC2F5784B409D11A5BDC11729409A081B9E5E794B40B0726891ED1C2940DE9387855A7B4B40E2E995B20C11294038F8C264AA804B4033C4B12E6E0329406EA301BC05824B4001030000000100000008000000772D211FF42C2840D881734694DE4B40022B8716D92E2840F7E461A1D6DC4B4055302AA913302840C217265305DB4B40E561A1D6342F2840FE65F7E461D94B40E6AE25E4831E28405DFE43FAEDD34B400F123F5286182840A8C08F8BE6D34B408D955EBC9B2A284078F75B968ADF4B40772D211FF42C2840D881734694DE4B40
clusterA Panpopulation clusterB Complex clusterC Stock clusterD Country clusterE Assessment_unit clusterF Regional clusterG River clusterH River_section clusterZ Major clusterY Subareas clusterX Division clusterW Sudivision clusterV Unit
Figure 4: The nested structure layed out in table tr_area_area, dotted box indicate that the level is optional. This table will be created specifically for each group.

Data access (tr_dataaccess_dta)

Type of data Public, or Restricted

Code to create dataaccess tr_dataaccess_dta
dbExecute(con_diaspara_admin,
"DROP TABLE IF EXISTS ref.tr_dataaccess_dta CASCADE;")

dbExecute(con_diaspara_admin,
"CREATE TABLE ref.tr_dataaccess_dta(
   dta_code TEXT PRIMARY KEY,
   dta_description TEXT  
);")


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

dbExecute(con_diaspara_admin, "GRANT ALL ON ref.tr_dataaccess_dta 
          TO diaspara_admin;")
dbExecute(con_diaspara_admin, "GRANT SELECT ON ref.tr_dataaccess_dta 
          TO diaspara_read;")

dbExecute(con_diaspara_admin, "COMMENT ON TABLE ref.tr_dataaccess_dta 
IS 'Table with two values, Public or Restricted access.';")

Missing data (tr_missvalueqal_mis)

This comes from wgeel.

Code to create tr_missvalueqal_mis
dbExecute(con_diaspara_admin,
"DROP TABLE IF EXISTS ref.tr_missvalueqal_mis CASCADE;")

dbExecute(con_diaspara_admin,
"CREATE TABLE ref.tr_missvalueqal_mis(
   mis_code TEXT PRIMARY KEY,
   mis_description TEXT NOT NULL,  
   mis_definition TEXT);")

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).';")

dbExecute(con_diaspara_admin, "GRANT ALL ON ref.tr_missvalueqal_mis 
          TO diaspara_admin;")
dbExecute(con_diaspara_admin, "GRANT SELECT ON ref.tr_missvalueqal_mis 
          TO diaspara_read;")

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

Life stages (tr_lifestage_lfs)

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

Creating a life stage referential is a challenging issue that will require inputs from the working groups for validation.

Considerations about the database structure

For life stage, unlike in other referentials, using working group specific life stage would lead to confusion. WGBAST and WGNAS would share the same stages for salmon. So unlike in many other table, the referentials will not use inheritance (see paragraph Section 1 for more details on inheritance). This means that we will create a table grouping all life stages and then we will only select the relevant ones at working group levels. For instance currently WGEEL does not use the Egg or Parr stages. It will be listed in the ref.tr_lifestage_lfs table but not in the refeel.tr_lifestage_lfs table. So the working group referentials, refnas, refbast, refeel … will have tr_lifestage_lfs tables with a foreign key to ref.tr_lifestage_lfs, and a subset of values used by the working group.

The lifestages in working group databases

The creation of life stage is discussed in the issue 16 in git github link to issue

Stages use are described in WGNAS metadata paragraph life stage of the WGNAS description report and WGBAST reports (though for the young fish 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.

Adding a stage dimension

Currently the stage is used by WGEEL and not by WGNAS or WGBAST landings data. For WGBAST it is used to describe the numbers release from hatchery at various stages. Spatial information, and information about the age are used to split the dataset, not the stage. We have two solutions : 1 / ignore the stage for WGBAST and WGNAS and only have the stage as a new column in the wgeel database when the inherited table is created. 2/ Add it everywhere and populate the column using the metadata (which should not be too hard) but with no practical use in the table since the information is not used currently. Our preference would go for the second because having a single data structure should make the common shiny development more easy, what do you think ?

Use of lifestages to include other information.

The different steps in the models are identified using spatio temporal units and stages (e.g; post smolt and location at sea) ICES (2024), a location and stage to descibe the different steps in the return migration (for instance returning adult in seawater, in freshwater…). Some of the elements added in the stage column are not stage per-se, but elements used to describe the spatio-temporal elements within the life-cycle, for instance the use PFA (pre-fishery-abundance) which correspond to the number at sea of different stages before fishery. To deal with those, we will simplify the stages table, remove elements which are not stages, and still refer to spatio temporal parameters from their definition. Here we are focusing on the stock DB which will group information, but the individual metric database might require more details that the simple adult stage. For this reason, we will add the maturity scale from ICES in the DB.

Adding a bit more complexity with the eel.

In some cases mixture of stages are used. Many fyke net fisheries for eel will not distinguish between yellow and silver eel stage and WGEEL uses the YS stage. Some historical trap series did not distinguish between small yellow eels and glass eel, or the glass eel ascending are in a late stage. In that case the GYstage is used to count the recruits.

QUESTION TO WGEEL

The new database will have to include a source WILD/HATCHERY/AQUACULTURE shouldn’t we use that opportunity to get rid of OG (ongrown) and QG (quarantine glass eel) which are cumbersome when we try to make simple graphs ?

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,
  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 : one of SAL, ELE, TRT, ALA, ALF, SLP, RLP ';
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;

Existing stages in ICES dictionaries.

Code
types <- icesVocab::getCodeTypeList()
types[grep('stage', tolower(types$Description)),]%>% kable()
TS_MATURITY <- icesVocab::getCodeList('TS_MATURITY')
TS_DevStage <- icesVocab::getCodeList('TS_DevStage')
# Devstage is 1 to 15 => no 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")) 
Table 17: ICES vocabularies for life stages
(a) Possible match for stage in ICES vocab.
GUID Key Description LongDescription Modified
30 76fab5ff-5f3e-4488-8167-17d360f47c35 STAGE Developmental Stage of Specimens NA 2024-10-22
216 dcc61865-822a-47a4-a740-a85a5702d0c5 TS_DevStage Development stage or maturity NA 2024-04-11
324 eac72d6a-219e-42a7-99b3-f50ac258b607 DevScale Scale applied for reporting developmental stages At present, the codetype targets the Eggs and Larvae surveys 2023-09-21
325 d943050b-a4e3-4508-b0ca-10b298f308f5 DevStage Developmental stage codes NA 2023-09-21
426 2e045807-14b1-48b0-bb2e-43967cec51e7 POFStaging Stages of POF (description to be updated) NA 2023-09-21
448 8b86cce6-b742-4865-986c-13932874d9df LifeStage Life stage based on plumage (birds) NA 2023-09-21
464 14cbcbfe-f084-40a8-80e3-052e69b06334 DigestionStage Digestion stage of stomach content. Visual-based assessment of digestion stage, in relation to diet studies. 2023-09-21
(b) TS_MATURITY table
GUID Key Description LongDescription Modified Deprecated
7c946d9d-fe30-48fa-a19d-54e72a4160da -9 Missing Value NA 2024-04-04 FALSE
0da7235e-9a5f-471f-8685-cdcceb3259c0 1 Juvenile/Immature (4-stage scale) NA 2024-04-04 FALSE
781f7cd8-2e68-4590-9124-f9d936e31f52 2 Maturing (4-stage scale) NA 2024-04-04 FALSE
ebb2258d-81fd-47d0-8383-7bfe88af82cd 3 Spawning (4-stage scale) NA 2024-04-04 FALSE
5e364aed-fe87-494e-81ff-195c6363f191 4 Spent (4-stage scale) NA 2024-04-04 FALSE
02c6638c-9a7d-49d1-b06f-942ee5d95a39 5 Resting/Skip of spawning (4-stage scale, additional option) NA 2024-04-04 FALSE
37d204b2-f8a6-48cd-a244-728ab4010111 51 Immature (5 stage scale) NA 2024-04-04 FALSE
46d154b0-61f7-414a-b1d1-4275839afdfe 52 Developing/Resting (5-stage scale) NA 2024-04-04 FALSE
54992917-0bbd-4dd6-8044-32bb70754279 53 Pre-spawning ((5-stage scale) NA 2024-04-04 FALSE
4146842c-eb45-49cd-8674-8d69ee6b81c1 54 Spawning (5-stage scale) NA 2024-04-04 FALSE
52a5be9c-c656-496f-adba-b6af23ba88a3 55 Post-spawning (5-stage scale) NA 2024-04-04 FALSE
17e59dde-46b3-4764-80f1-01e1134c8ba0 6 Abnormal (4-stage scale, additional option) NA 2024-04-04 FALSE
9dab155a-95e6-4dcc-adaf-c8b67febbb60 61 Juvenile/Immature (6-stage scale) NA 2024-04-04 FALSE
32e854ae-0e44-4523-855d-92b8bccdabbe 62 Maturing (6-stage scale) NA 2024-04-04 FALSE
85c79865-4505-4b6e-96bb-37e5a18b9c95 63 Spawning (6-stage scale) NA 2024-04-04 FALSE
2637e1c0-8dba-4da8-beba-7c865acfd7b4 64 Spent (6-stage scale) NA 2024-04-04 FALSE
f682c57c-f70e-4c1b-859c-ab77f865c3f6 65 Resting/Skip of spawning (6-stage scale) NA 2024-04-04 FALSE
8165075c-ae3b-49e4-b8ed-0dad8f215e78 66 Abnormal (6-stage scale) NA 2024-04-04 FALSE
a25f81c6-91af-47fe-b2a1-6f76a8643ac3 A Immature NA 2024-04-04 FALSE
62b08142-2f9d-4b8c-b53f-d9bce26b1c35 B Developing NA 2024-04-04 FALSE
4b4643bd-0255-42bc-a473-0b936492ae9f Ba Developing, but functionally immature (first-time developer) NA 2024-04-04 FALSE
5fb2d514-c4f0-4911-8eb4-f4e9c692041d Bb Developing and functionally mature NA 2024-04-04 FALSE
1ad95503-f3e6-46a6-997f-eefcba1c9bd7 Be Berried (crustaceans) Used to be "B", changed to leave code for maturity scale SMSF 2024-04-04 FALSE
c5e12291-673e-4ad2-b7b8-6f2adf52ec21 C Spawning NA 2024-04-04 FALSE
a9bc29b4-4ee3-4b1b-bf31-76d58170d75e Ca Actively spawning NA 2024-04-04 FALSE
8d8784d6-9795-43c0-927b-f404a18f3491 Cb Spawning capable NA 2024-04-04 FALSE
5af75fd2-06df-4d60-a843-2a3977cd6e5c D Regressing / Regenerating NA 2024-04-04 FALSE
c11149a2-e084-4af0-b737-4d41d59d3943 Da Regressing NA 2024-04-04 FALSE
ecb4cdea-3ac1-42cd-a279-c9b20e360999 Db Regenerating NA 2024-04-04 FALSE
a1cf8684-f842-4f2f-9912-aefefea6d9d3 E Omitted spawning NA 2024-04-04 FALSE
1dce569f-2d2d-43a9-8041-d90950ade023 Eg Elasmobranch egg Used to be "E", changed it to use the code for maturity scale SMSF 2024-04-04 FALSE
1736cf72-fbca-4389-868d-e996159664e3 F Abnormal NA 2024-04-04 FALSE
429ad685-ee68-4781-84eb-90f0cd8f0634 I Immature / National BITS scale step NA 2024-04-04 FALSE
ad5c19e1-3c59-4bd6-b001-f1cfbcab0b6d II National BITS scale step NA 2020-06-03 FALSE
595124ad-a831-4ce0-ba88-26fb4183022c III National BITS scale step NA 2020-06-03 FALSE
52e89979-b100-4cee-93c9-206d132a4c2a IV National BITS scale step NA 2024-04-04 FALSE
60f82148-71f3-4f0f-98c1-a6cd59918f25 IX National BITS scale step NA 2024-04-04 FALSE
9ddbe93e-b920-46fc-8f0d-b1bc94cacace M Mature NA 2024-04-04 FALSE
4b9a6671-aae4-4731-8a20-6bfa6764cc9c R1_1 Immature IMARES RIVO 4 scale code for Immature used before 2000 for cod, haddock, whiting, Norway pout and saithe 2024-04-04 FALSE
542d1576-cb99-42b4-a046-c5af124c7812 R1_2 Maturing IMARES RIVO 4 scale code for Maturing, used before 2000 for cod, haddock, whiting, Norway pout and saithe 2024-04-04 FALSE
e5dba8d3-daf0-49b7-9a5e-0deaeae94591 R1_3 Spawning IMARES RIVO 4 scale used before 2000 for Spawning, for cod, haddock, whiting, Norway pout and saithe 2024-04-04 FALSE
35caf0f4-b23e-4114-b004-53ceed7dc5ae R1_4 Spent IMARES PIVO 4 scale code for Spent, used before 2000 for cod, haddock, whiting, Norway pout and saithe 2024-04-04 FALSE
cc410273-2714-4253-bfa6-fadd39e83099 R2_2 Immature IMARES RIVO new 4 scale code for Immature, used from 2000 til 1-1-2011, for all species 2024-04-04 FALSE
24e63a36-bbcc-422e-9b42-1938d816574c R2_4 Maturing IMARES RIVO new 4 scale code for Maturing, used between 2000 and 1-1-2011, for all species 2024-04-04 FALSE
6024da49-355d-41e0-9c35-91c92133adef R2_6 Spawning IMARES RIVO new 4 scale for Spawning, used between 2001 and 1-1-2011, for all species 2024-04-04 FALSE
8f5b8ad1-f335-487a-bb17-58936b4bae8b R2_8 Spent/Recovering IMARES RIVO new 4 scale code for Spent/Recovering, used between 2001 and 1-1-2011, for all species 2024-04-04 FALSE
193d1307-7594-4e61-bddb-5ed722448fc1 RF1 Immature redfish NA 2024-04-04 FALSE
2bd20b2d-41f7-4ce4-944c-c124c2ee25bc RF2 Maturing_mature redfish NA 2024-04-04 FALSE
34288e8c-0586-48e9-bce9-2ea62580d278 RF3 Mature_fertilized redfish NA 2024-04-04 FALSE
8891c3b8-f440-4eca-8cb9-32c3f544cb82 RF4 Parturition redfish NA 2024-04-04 FALSE
94165bd1-2c96-485e-92f7-f8fdbec294d0 RF5 Postspawning redfish NA 2024-04-04 FALSE
b725388b-288c-4895-819e-029e9625d0a4 RF6 Recovery redfish NA 2024-04-04 FALSE
add7abf9-c812-4073-afd5-6168efc473da S1 Immature (6-stage scale) NA 2024-04-04 FALSE
d94cc258-cf59-41df-8e12-e917b8c8753d S2 Maturing (6-stage scale) NA 2024-04-04 FALSE
ab5a79b8-c948-41d0-ba0e-2d048c9c2d65 S3 Pre-spawning (6-stage scale) NA 2024-04-04 FALSE
185d00c7-b55b-4b6f-ad48-bc02494e7c3e S4 Spawning (6-stage scale) NA 2024-04-04 FALSE
d7b6f253-9fa6-41bb-96ff-4e4ee3440858 S5 Post-partial spawning (6-stage scale) NA 2024-04-04 FALSE
2fad9d30-d07a-4ffb-b665-1bd687131d5b S6 Spent/Recovery (6-stage scale) NA 2024-04-04 FALSE
7d6b8aeb-1019-410c-9377-e03dd45bb06c V National BITS scale step NA 2020-06-03 FALSE
61f27c0b-f86f-4d44-b1fc-e695a071ff76 VI National BITS scale step NA 2024-04-04 FALSE
94bbebde-ffe9-41e9-b0d8-d712018b81e6 VII National BITS scale step NA 2024-04-04 FALSE
304ebd7a-7749-4b94-b155-301e786d8f6a VIII National BITS scale step NA 2024-04-04 FALSE
39a755c5-f830-49f0-8ca1-d1ea31989843 X National BITS scale step NA 2024-04-04 FALSE
(c) DevScale table
GUID Key Description LongDescription Modified Deprecated
16f8c30a-b724-4636-bd78-0a9a1776039e -9 No information NA 2024-04-04 FALSE
c1566f6d-c099-44c3-bd39-222fe4c033de B Berried NA 2024-04-04 FALSE
0424ae90-03aa-4e73-8cda-e8745d0b8158 E Egg NA 2024-04-04 FALSE
3ea553fe-66cf-47ff-b4ff-eb83d1c28643 J Juvenile NA 2024-04-04 FALSE

QUESTION TO ICES

Does it make sense to use a code outside from its scope (I seems to me that yes). If so can we use the TS_DevStage and add values in it and propose definitions ?

Importing the lifestages for Salmon.

Some of the definitions come from Ontology portal.

Code to import stages from WGBAST and WGNAS databases.
lfs <- tribble(
  ~lfs_code, ~lfs_name, ~lfs_spe_code, ~lfs_description, 
  ~lfs_icesvalue, ~lfs_icesguid, ~lfs_icestablesource,
  "E",   "Egg", "SAL" , "In fish, the term egg usually refers to female haploid gametes.", 
  "E",   "0424ae90-03aa-4e73-8cda-e8745d0b8158", "TS_DevStage",
  "EE",   "Eyed egg", "SAL" , "Eyed eggs are fertilized eggs that have developed to the stage where the eyes of the fish can easily be seen with naked eyes through the translucent egg shell. They might be used for stocking purpose.", 
  NA,  NA , NA,
  "ALV",   "Alevin with the yolk sac", "SAL" , "Larval salmon that have hatched but have not yet completely absorbed their yolk sacs and usually have not yet emerged from the gravel.  http://purl.dataone.org/odo/SALMON_00000403", 
  NA,  NA , NA,
  "FR",   "Fry", "SAL" , "A young salmonid at the post-larval stage who has resorbed the yolk sac but remains buried in the gravel.  The stage starts at the end of dependence on the yolk sac as the primary source of nutrition to dispersal from the redd.", 
  NA,  NA , NA,
  "P", "Parr", "SAL", 
  "A young salmonid with parr-marks before migration to the sea and after dispersal from the redd.  http://purl.dataone.org/odo/SALMON_00000649",
  NA, NA, NA,
  "SM", "Smolt", "SAL", "1) A young salmonid which has developed silvery coloring on its sides, obscuring the parr marks, and which is about to migrate or has just migrated into the sea, 2) to undergo the transformation from parr to smolt.http://purl.dataone.org/odo/SALMON_00000404",
  NA, NA, NA,
  "PS", "Post Smolt", "SAL", "A young salmonid after
  the smolt freshwater or estuarine migration. [TODO check this]",
  NA, NA, NA,
 "A", "Adult", "SAL", "Salmonids that have fully developed morphological and meristic characters and that have attained sexual maturity, for salmon this might refer to fishes during their spawning migration in coastal waters, or spawning adults in freshwater. More details can be given on the maturity of the fish using the maturity scale.", NA, NA, NA
)
dbWriteTable(con_diaspara_admin, "temp_lfs", lfs, overwrite = TRUE)
    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")

Import lifestages for eel.

Code to import stages from WGEEL databases.
dbExecute(con_diaspara_admin,"DELETE FROM ref.tr_lifestage_lfs WHERE lfs_spe_code ='ANG';")
dbExecute(con_diaspara_admin, "INSERT INTO ref.tr_lifestage_lfs (lfs_code,lfs_name,lfs_description, lfs_spe_code)
SELECT lfs_code,initcap(lfs_name),lfs_definition, 'ANG' 
FROM refwgeel.tr_lifestage_lfs ;") # 8

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

Content of the tr_lifestage_lfs table

Code
dbGetQuery(con_diaspara, "SELECT * FROM ref.tr_lifestage_lfs;") %>% 
knitr::kable() %>% 
kable_styling(bootstrap_options = c("striped", "hover", "condensed"))
Code for missing values
lfs_id lfs_code lfs_name lfs_spe_code lfs_description lfs_icesvalue lfs_icesguid lfs_icestablesource
1 E Egg SAL In fish, the term egg usually refers to female haploid gametes. E 0424ae90-03aa-4e73-8cda-e8745d0b8158 TS_DevStage
2 EE Eyed egg SAL Eyed eggs are fertilized eggs that have developed to the stage where the eyes of the fish can easily be seen with naked eyes through the translucent egg shell. They might be used for stocking purpose. NA NA NA
3 ALV Alevin with the yolk sac SAL Larval salmon that have hatched but have not yet completely absorbed their yolk sacs and usually have not yet emerged from the gravel. http://purl.dataone.org/odo/SALMON_00000403 NA NA NA
4 FR Fry SAL A young salmonid at the post-larval stage who has resorbed the yolk sac but remains buried in the gravel. The stage starts at the end of dependence on the yolk sac as the primary source of nutrition to dispersal from the redd. NA NA NA
5 P Parr SAL A young salmonid with parr-marks before migration to the sea and after dispersal from the redd. http://purl.dataone.org/odo/SALMON_00000649 NA NA NA
6 SM Smolt SAL 1) A young salmonid which has developed silvery coloring on its sides, obscuring the parr marks, and which is about to migrate or has just migrated into the sea, 2) to undergo the transformation from parr to smolt.http://purl.dataone.org/odo/SALMON_00000404 NA NA NA
7 PS Post Smolt SAL A young salmonid after the smolt freshwater or estuarine migration. [TODO check this] |NA |NA |NA
8 A Adult SAL Salmonids that have fully developed morphological and meristic characters and that have attained sexual maturity, for salmon this might refer to fishes during their spawning migration in coastal waters, or spawning adults in freshwater. More details can be given on the maturity of the fish using the maturity scale. NA NA NA
9 G Glass Eel ANG Young, unpigmented eel, recruiting from the sea into continental waters. WGEEL consider the glass eel term to include all recruits of the 0+ cohort age. In some cases, however, also includes the early pigmented stages. NA NA NA
10 S Silver Eel ANG Migratory phase following the yellow eel phase. Eel in this phase are characterized by darkened back, silvery belly with a clearly contrasting black lateral line, enlarged eyes. Silver eel undertake downstream migration towards the sea, and subsequently westwards. This phase mainly occurs in the second half of calendar years, although some are observed throughout winter and following spring. NA NA NA
11 GY Glass Eel + Yellow Eel ANG A mixture of glass and yellow eel, some traps have historical set of data where glass eel and yellow eel were not separated, they were dominated by glass eel |NA |NA |NA
12 OG Ongrown Eel ANG Eel that have been held in water tanks for some days or months between first capture and then release to a new water basin, and they have been fed and grown during that time. NA NA NA
13 QG Quarantined Eel ANG Ongrown eel (see definition above) that have been held in isolation between capture and restocking. NA NA NA
14 AL All Stages ANG All stages combined NA NA NA
15 YS Yellow Eel+ Silver Eel ANG Yellow and Silver eel defined below NA NA NA
16 Y Yellow Eel ANG Life-stage resident in continental waters. Often defined as a sedentary phase, but migration within and between rivers, and to and from coastal waters occurs and therefore includes young pigmented eels (‘elvers’ and bootlace). Sometimes is also called Brown eel. |NA |NA |NA
17 E Egg TRT In fish, the term egg usually refers to female haploid gametes. E 0424ae90-03aa-4e73-8cda-e8745d0b8158 TS_DevStage
18 EE Eyed egg TRT 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
19 ALV Alevin with the yolk sac TRT 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
20 FR Fry TRT 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
21 P Parr TRT 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
22 SM Smolt TRT 1) A young salmonid which has developed silvery coloring on its sides, obscuring the parr marks, and which is about to migrate or has just migrated into the sea, 2) to undergo the transformation from parr to smolt.http://purl.dataone.org/odo/SALMON_00000404 NA NA NA
23 PS Post Smolt TRT A young salmonid after the smolt freshwater or estuarine migration. [TODO check this] |NA |NA |NA
24 A Adult TRT Salmonids that have fully developed morphological and meristic characters and that have attained sexual maturity, for salmon this might refer to fishes during their spawning migration in coastal waters, or spawning adults in freshwater. More details can be given on the maturity of the fish using the maturity scale. NA NA NA

Maturity (ts_maturity_mat)

Working on stages, and looking at the ICES vocab, we have decided to include information on maturity.

SQL code to create table tr_maturity_mat
-- maturity table 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 ';

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

The information about the stage mixes information on stage and maturity. So here we add a table of maturity following the 6 stage scale of ICES vocab (Table (tbl_tr_maturity_mat?)).

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(61,62,63,64,65,66)) |>
mutate(mat_icestablesource = "TS_MATURITY",
       mat_id = 1:6,
      mat_code = c("Juvenile", "Maturing", "Spawning", "Spent", "Skip", "Abnormal")) |>
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")


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"))
Code for missing values
mat_id mat_code mat_description mat_icesvalue mat_icesguid mat_icestablesource
1 Juvenile Juvenile/Immature (6-stage scale) 61 9dab155a-95e6-4dcc-adaf-c8b67febbb60 TS_MATURITY
2 Maturing Maturing (6-stage scale) 62 32e854ae-0e44-4523-855d-92b8bccdabbe TS_MATURITY
3 Spawning Spawning (6-stage scale) 63 85c79865-4505-4b6e-96bb-37e5a18b9c95 TS_MATURITY
4 Spent Spent (6-stage scale) 64 2637e1c0-8dba-4da8-beba-7c865acfd7b4 TS_MATURITY
5 Skip Resting/Skip of spawning (6-stage scale) 65 f682c57c-f70e-4c1b-859c-ab77f865c3f6 TS_MATURITY
6 Abnormal Abnormal (6-stage scale) 66 8165075c-ae3b-49e4-b8ed-0dad8f215e78 TS_MATURITY

ICES areas

Download shapefiles from NAFO => create table following ICES_Areas for GUID 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 subarea division subdivision

code 27.9.b.2 area_full area_27 9.b.2

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 word was somewhere on my computer. Cannot trace the source, it’s exaclty the same for NAFO but changed in the med and ICES. For some reasons was not complete in table from wgeel so have to download it again to postgres.

Values for geom have been updated from ICES areas, the new boundaries are different, however, 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 5: Map of ICES fishing areas at Major level, source NAFO, FAO, ICES, GFCM.
Code to create a map of fishing areas at Subarea level
if (file.exists("data/fishingareas_subarea.Rdata")) load("data/fishingareas_subarea.Rdata") else {
fishing_areas_subarea <- sf::st_read(con_diaspara,
                          query = "SELECT fia_code, ST_MakeValid(geom) 
                          from ref.tr_fishingarea_fia
                          WHERE fia_level = 'Subarea'") %>%
  sf::st_transform(4326) 
save(fishing_areas_subarea, file="data/fishing_areas_subarea.Rdata")
}
crs_string <- "+proj=ortho +lon_0=-30 +lat_0=30"

area_sf2 <-  fishing_areas_subarea %>% 
  sf::st_intersection(ocean %>% sf::st_transform(4326)) %>% 
  sf::st_transform(crs = crs_string) # reproject to 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 6: Map of ICES fishing areas at Subarea level, source NAFO, FAO, ICES, GFCM.
Code to create a map of fishing areas at Division level
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 7: 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 8: Map of ICES fishing areas at subdivision level, source NAFO, FAO, ICES, GFCM.

SCHEMA datnas and refnas

Create referential for WGNAS

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_version 
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. 'SAL' 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;


-- values inserted in chunk tr_version_ver insert


DROP TABLE IF EXISTS refnas.tr_metadata_met;

CREATE TABLE refnas.tr_metadata_met(met_oldversion numeric)
INHERITS (ref.tr_metadata_met);


-- ADDING CONSTRAINTS

ALTER TABLE refnas.tr_metadata_met ADD
 CONSTRAINT t_metadata_met_pkey PRIMARY KEY(met_var, met_spe_code);
 
ALTER TABLE refnas.tr_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 refnas.tr_metadata_met ADD
    CONSTRAINT ck_met_spe_code CHECK (met_spe_code='SAL'); 

 ALTER TABLE refnas.tr_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 refnas.tr_metadata_met ADD
    CONSTRAINT ck_met_wkg_code CHECK (met_wkg_code='WGNAS');

ALTER TABLE refnas.tr_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 refnas.tr_metadata_met ADD
  CONSTRAINT fk_met_oty_code FOREIGN KEY (met_oty_code) 
  REFERENCES ref.tr_objecttype_oty (oty_code) ON DELETE CASCADE
  ON UPDATE CASCADE;

ALTER TABLE refnas.tr_metadata_met ADD
  CONSTRAINT fk_met_nim_code FOREIGN KEY (met_nim_code) 
  REFERENCES ref.tr_nimble_nim (nim_code) ON DELETE CASCADE
  ON UPDATE CASCADE;

ALTER TABLE refnas.tr_metadata_met ADD  
  CONSTRAINT fk_met_mtr_code FOREIGN KEY (met_mtr_code)
  REFERENCES ref.tr_metric_mtr(mtr_code)
  ON DELETE CASCADE
  ON UPDATE CASCADE;

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


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



Import the metadata table

Code to import to refnas work in progress …
# TODO create tr_area_are
# tr_metadata_met

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

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

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

tr_metadata_met <-
    data.frame(
        met_var = metadata$var_mod,
        met_spe_code = "SAL",
        met_wkg_code = "WGNAS",
        met_ver_code = "SAL-2024-1", # no data on version in metadata
        met_oty_code = metadata$type_object,
         met_nim_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_mtr_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, "tr_metadata_met_temp", 
tr_metadata_met, overwrite = TRUE)
dbExecute(con_diaspara_admin, "INSERT INTO refnas.tr_metadata_met 
SELECT 
 met_var,
 met_spe_code,
 met_wkg_code,
 met_ver_code,
 upper(substring(met_oty_code from 1 for 1)) ||
          substring(met_oty_code from 2 for length(met_oty_code)), 
 met_nim_code,
 met_dim::INTEGER[], 
 met_dimname::TEXT[], 
 met_modelstage, 
 met_type,
 met_location, 
 met_fishery, 
 met_mtr_code, 
 met_des_code, 
 met_uni_code,
 met_cat_code, 
 met_definition, 
 met_deprecated
FROM tr_metadata_met_temp")

dbExecute(con_diaspara_admin, "DROP TABLE tr_metadata_temp CASCADE;")
TODO diaspara: Integrate new data from REFNAS

Collect the latest version of the db from Jerome, there are new variables there.

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

Table 18: Content of the refnas metadata table
met_var met_spe_code met_wkg_code met_ver_code met_oty_code met_nim_code met_dim met_dimname met_modelstage met_type met_location met_fishery met_mtr_code met_des_code met_uni_code met_cat_code met_definition met_deprecated met_oldversion
log_C5_NAC_1_lbnf_sd SAL WGNAS SAL-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 SAL WGNAS SAL-2024-1 Vector Parameter constant {47,0,0} {'Year',NULL,NULL} Fit Sea catches Bef. Gld fisheries LB fishery SD NA NA Catch Standard-deviation of observed catches (log scale) of NAC Labrador-origin 1 SW by late Newfoundland, Labrador and Saint Pierre et Miquelon fisheries NA NA
log_C5_NAC_2_lbnf_oth_sd SAL WGNAS SAL-2024-1 Vector Parameter constant {47,0,0} {'Year',NULL,NULL} Fit Sea catches Bef. Gld fisheries LB/SPM/swNF fishery SD NA NA Catch Standard-deviation of observed catches (log scale) of NAC Labrador-excluded 1 SW by late Newfoundland, Labrador and Saint Pierre et Miquelon fisheries NA NA
log_C5_NEC_1_far_sd SAL WGNAS SAL-2024-1 Vector Parameter constant {47,0,0} {'Year',NULL,NULL} Fit Sea catches Bef. Gld fisheries FAR fishery SD NA NA Catch Standard-deviation of observed total catches (log scale) of 1SW adults from the NEC complex in Faroe islands NA NA
log_C8_2_gld_tot_sd SAL WGNAS SAL-2024-1 Vector Parameter constant {47,0,0} {'Year',NULL,NULL} Fit Sea catches Gld fisheries GLD fishery SD NA NA Catch Standard-deviation of observed total catches (log scale) of 2SW adults (mixed complexes) in Greenland NA NA
log_C8_NAC_1_lbnf_sd SAL WGNAS SAL-2024-1 Vector Parameter constant {47,0,0} {'Year',NULL,NULL} Fit Sea catches Bef. Gld fisheries neNF fishery SD NA NA Catch Standard-deviation of observed catches (log scale) of NAC 1 SW by Labrador/Newfoundland fishery NA NA
log_C8_NAC_3_lbnf_sd SAL WGNAS SAL-2024-1 Vector Parameter constant {47,0,0} {'Year',NULL,NULL} Fit Sea catches Aft. Gld fisheries neNF fishery SD NA NA Catch Standard-deviation of observed catches (log scale) of NAC 2 SW by early Newfoundland fishery NA NA
log_C8_NAC_4_lbnf_lab_sd SAL WGNAS SAL-2024-1 Vector Parameter constant {47,0,0} {'Year',NULL,NULL} Fit Sea catches Aft. Gld fisheries LB fishery SD NA NA Catch Standard-deviation of observed catches (log scale) of NAC Labrador-origin 2 SW by late Newfoundland, Labrador and Saint Pierre et Miquelon fisheries NA NA
log_C8_NAC_4_lbnf_oth_sd SAL WGNAS SAL-2024-1 Vector Parameter constant {52,0,0} {'Year',NULL,NULL} Fit Sea catches Aft. Gld fisheries LB/SPM/swNF fishery SD NA NA Catch Standard-deviation of observed catches (log scale) of NAC Labrador-excluded 2 SW by late Newfoundland, Labrador and Saint Pierre et Miquelon fisheries NA NA
log_C8_NEC_1_far_sd SAL WGNAS SAL-2024-1 Vector Parameter constant {50,0,0} {'Year',NULL,NULL} Fit Sea catches Bef. Gld fisheries FAR fishery SD NA NA Catch Standard-deviation of observed total catches (log scale) of 2SW individuals from the NEC complex before maturation in Faroe islands NA NA

Import the database table from the salmoglob (WGNAS) database

For data we first need to create the table.

The code for creating t_stock_sto is listed below

SQL code to create tables (TODO HERE work in progress ….)
-- before working there should have been these constraints in the salmoglob DB

DBI::dbGetQuery(con_salmoglob, 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_nim_code FROM refnas.tr_metadata_met
JOIN refsalmoglob."database" ON var_mod = met_var

WHERE  met_cat_code ='Other'


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




CREATE TABLE dat.t_stock_sto (
  sto_id serial4 NOT NULL,
  sto_met_var NOT NULL CONSTRAINT fk_met_var FOREIGN KEY REFERENCES "ref".tr_metadata_met(met_var) ,
  sto_year int4 NULL,
  sto_value numeric NULL,
  sto_are_code TEXT NOT NULL 
  CONSTRAINT fk_sto_are_code FOREIGN KEY REFERENCES "ref".tr_area_are(are_code) 
  ON UPDATE CASCADE ON DELETE CASCADE,
  -- 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).
  eel_emu_nameshort varchar(20) NOT NULL,
  eel_cou_code varchar(2) NULL,
  eel_lfs_code varchar(2) NOT NULL,
  eel_hty_code varchar(2) NULL,
  eel_area_division varchar(254) NULL,
  eel_qal_id int4 NOT NULL,
  eel_qal_comment text NULL,
  eel_comment text NULL,
  eel_datelastupdate date NULL,
  eel_missvaluequal varchar(2) NULL,
  eel_datasource varchar(100) NULL,
  eel_dta_code text DEFAULT 'Public'::text NULL,
  sto_wkg_code text NOT NULL
  CONSTRAINT ck_eel_missvaluequal CHECK ((((eel_missvaluequal)::text = 'NP'::text) OR ((eel_missvaluequal)::text = 'NR'::text) OR ((eel_missvaluequal)::text = 'NC'::text) OR ((eel_missvaluequal)::text = 'ND'::text))),
  CONSTRAINT ck_notnull_value_and_missvalue CHECK ((((eel_missvaluequal IS NULL) AND (eel_value IS NOT NULL)) OR ((eel_missvaluequal IS NOT NULL) AND (eel_value IS NULL)))),
  CONSTRAINT ck_qal_id_and_missvalue CHECK (((eel_missvaluequal IS NULL) OR (eel_qal_id <> 0))),
  CONSTRAINT ck_removed_typid CHECK (((COALESCE(eel_qal_id, 1) > 5) OR (eel_typ_id <> ALL (ARRAY[12, 7, 5])))),
  CONSTRAINT t_eelstock_eel_pkey PRIMARY KEY (eel_id),
  CONSTRAINT c_fk_area_code FOREIGN KEY (eel_area_division) REFERENCES "ref".tr_faoareas(f_division) ON UPDATE CASCADE,
  CONSTRAINT c_fk_cou_code FOREIGN KEY (eel_cou_code) REFERENCES "ref".tr_country_cou(cou_code),
  CONSTRAINT c_fk_eel_dta_code FOREIGN KEY (eel_dta_code) REFERENCES "ref".tr_dataaccess_dta(dta_code) ON UPDATE CASCADE,
  CONSTRAINT c_fk_emu FOREIGN KEY (eel_emu_nameshort,eel_cou_code) REFERENCES "ref".tr_emu_emu(emu_nameshort,emu_cou_code),
  CONSTRAINT c_fk_hty_code FOREIGN KEY (eel_hty_code) REFERENCES "ref".tr_habitattype_hty(hty_code) ON UPDATE CASCADE,
  CONSTRAINT c_fk_lfs_code FOREIGN KEY (eel_lfs_code) REFERENCES "ref".tr_lifestage_lfs(lfs_code) ON UPDATE CASCADE,
  CONSTRAINT c_fk_qal_id FOREIGN KEY (eel_qal_id) REFERENCES "ref".tr_quality_qal(qal_id) ON UPDATE CASCADE,
  CONSTRAINT c_fk_typ_id FOREIGN KEY (eel_typ_id) REFERENCES "ref".tr_typeseries_typ(typ_id) ON UPDATE CASCADE





);

COMMENT ON TABLE dat.t_stock_sto IS 
'Table including the stock data from the different schema, dateel, datnas.... This table should be empty, as there are no
constraints set and it''s getting its content by inheritance from other tables in other schema';
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';
COMMENT ON COLUMN dat.t_stock_sto.sto_year IS 'Year';
COMMENT ON COLUMN dat.t_stock_sto.sto_value IS 'Value';
COMMENT ON COLUMN dat.t_stock_sto_sto_wkg_code IS 'Code of the working group, one of
WGBAST, WGEEL, WGNAS, WKTRUTTA';

IS 'Variable code, primary key on both met_spe_code and met_var.';
COMMENT ON COLUMN ref.tr_metadata_met.met_spe_code 
COMMENT ON COLUMN sto_id



-- HERE IS THE CODE TO CREATE THE MAIN STOCK TABLE FOR WEEL

-- DROP TABLE datawg.t_eelstock_eel;

CREATE TABLE datawg.t_eelstock_eel (
  eel_id serial4 NOT NULL,
  eel_typ_id int4 NOT NULL,
  eel_year int4 NOT NULL,
  eel_value numeric NULL,
  eel_emu_nameshort varchar(20) NOT NULL,
  eel_cou_code varchar(2) NULL, -- we don't need that one IF we have an emu
  eel_lfs_code varchar(2) NOT NULL,
  eel_hty_code varchar(2) NULL,
  eel_area_division varchar(254) NULL,
  eel_qal_id int4 NOT NULL,
  eel_qal_comment text NULL,
  eel_comment text NULL,
  eel_datelastupdate date NULL,
  eel_missvaluequal varchar(2) NULL,
  eel_datasource varchar(100) NULL,
  eel_dta_code text DEFAULT 'Public'::text NULL,
  CONSTRAINT ck_eel_missvaluequal CHECK ((((eel_missvaluequal)::text = 'NP'::text) OR ((eel_missvaluequal)::text = 'NR'::text) OR ((eel_missvaluequal)::text = 'NC'::text) OR ((eel_missvaluequal)::text = 'ND'::text))),
  CONSTRAINT ck_notnull_value_and_missvalue CHECK ((((eel_missvaluequal IS NULL) AND (eel_value IS NOT NULL)) OR ((eel_missvaluequal IS NOT NULL) AND (eel_value IS NULL)))),
  CONSTRAINT ck_qal_id_and_missvalue CHECK (((eel_missvaluequal IS NULL) OR (eel_qal_id <> 0))),
  CONSTRAINT ck_removed_typid CHECK (((COALESCE(eel_qal_id, 1) > 5) OR (eel_typ_id <> ALL (ARRAY[12, 7, 5])))),
  CONSTRAINT t_eelstock_eel_pkey PRIMARY KEY (eel_id),
  CONSTRAINT c_fk_area_code FOREIGN KEY (eel_area_division) REFERENCES "ref".tr_faoareas(f_division) ON UPDATE CASCADE,
  CONSTRAINT c_fk_cou_code FOREIGN KEY (eel_cou_code) REFERENCES "ref".tr_country_cou(cou_code),
  CONSTRAINT c_fk_eel_dta_code FOREIGN KEY (eel_dta_code) REFERENCES "ref".tr_dataaccess_dta(dta_code) ON UPDATE CASCADE,
  CONSTRAINT c_fk_emu FOREIGN KEY (eel_emu_nameshort,eel_cou_code) REFERENCES "ref".tr_emu_emu(emu_nameshort,emu_cou_code),
  CONSTRAINT c_fk_hty_code FOREIGN KEY (eel_hty_code) REFERENCES "ref".tr_habitattype_hty(hty_code) ON UPDATE CASCADE,
  CONSTRAINT c_fk_lfs_code FOREIGN KEY (eel_lfs_code) REFERENCES "ref".tr_lifestage_lfs(lfs_code) ON UPDATE CASCADE,
  CONSTRAINT c_fk_qal_id FOREIGN KEY (eel_qal_id) REFERENCES "ref".tr_quality_qal(qal_id) ON UPDATE CASCADE,
  CONSTRAINT c_fk_typ_id FOREIGN KEY (eel_typ_id) REFERENCES "ref".tr_typeseries_typ(typ_id) ON UPDATE CASCADE
);
CREATE UNIQUE INDEX idx_eelstock_1 ON datawg.t_eelstock_eel USING btree (eel_year, eel_lfs_code, eel_emu_nameshort, eel_typ_id, eel_hty_code, eel_qal_id, eel_area_division) WHERE ((eel_hty_code IS NOT NULL) AND (eel_area_division IS NOT NULL));
CREATE UNIQUE INDEX idx_eelstock_2 ON datawg.t_eelstock_eel USING btree (eel_year, eel_lfs_code, eel_emu_nameshort, eel_typ_id, eel_qal_id, eel_area_division) WHERE ((eel_hty_code IS NULL) AND (eel_area_division IS NOT NULL));
CREATE UNIQUE INDEX idx_eelstock_3 ON datawg.t_eelstock_eel USING btree (eel_year, eel_lfs_code, eel_emu_nameshort, eel_typ_id, eel_hty_code, eel_qal_id) WHERE ((eel_hty_code IS NOT NULL) AND (eel_area_division IS NULL));
CREATE UNIQUE INDEX idx_eelstock_4 ON datawg.t_eelstock_eel USING btree (eel_year, eel_lfs_code, eel_emu_nameshort, eel_typ_id, eel_qal_id) WHERE ((eel_hty_code IS NULL) AND (eel_area_division IS NULL));

-- Table Triggers

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 update_eel_time BEFORE
INSERT
    OR
UPDATE
    ON
    datawg.t_eelstock_eel FOR EACH ROW EXECUTE FUNCTION datawg.update_eel_last_update();
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();

While creating the table, we stumbled on some issues (which we have put on the github site for details):

Some of the variables in salmoglob have no year dimension, this leads to dropping the non null constraint on year. We need to check for possible impact in the eel db.

Import the stock_sto

Code to import salmoglob main db into the new database.
# TODO create tr_area_are
# tr_metadata_met

stock <- dbGetQuery(con_salmoglob, "SELECT * FROM database")

# TODO HERE .....

WORK IN PROGRESS….

This document is still in construction Structure of the db (still in construction)

Acknowledgements

  • Data source : EuroGeographics and UN-FAO for countries

References

ICES. 2024. “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.
 

EU is not reponsible for the content of the project