diff --git a/db/migrations/20230320140259_create_tables.sql b/db/migrations/20230320140259_create_tables.sql deleted file mode 100644 index c408d83..0000000 --- a/db/migrations/20230320140259_create_tables.sql +++ /dev/null @@ -1,104 +0,0 @@ --- migrate:up - -create table colony( - name text primary key, - geometry geometry(point, 4326), - country text, - plot text, - nest_id text -); - -create table animal( - id int primary key, - species text not null, - morph text, - subspecies text -); - -create table ring( - id int primary key, - euring_code text, - colour_ring_colour text, - colour_ring_code text, - animal int references animal(id) not null -); - -create table survey( - ring int references ring(id), - year smallint not null, - - total_mass_g int, - - age text, - sex text, - sexing_method text, - - mass_deployment_g int, - mass_retrieval_g int, - scull_mm decimal, - tarsus_mm decimal, - wing_mm decimal, - culmen_mm decimal, - gonys_mm decimal, - - breeding_stage_deployment text, - eggs_deployment text, - chicks_deployment text, - breeding_stage_retrieval text, - eggs_retrieval text, - chicks_retrieval text, - - further_chick_measures_available text, - - colony text references colony(name), - - sample_blood bool, - sample_feather bool, - sample_other bool, - sample_notes text, - logging_for_seatrack bool, - - notes text, - other text, - data_responsible text, - - primary key (year, ring) -); - -create table logger( - id text primary key, - type text not null, - model text -); - -create table deployment( - logger text references logger(id) not null, - animal int references animal(id) not null, - - status text, - - sampling_freq_s decimal, - mass_g decimal, - attachment_method text, - mount_method text, - startup timestamp with time zone, - deployment timestamp with time zone, - retrieval timestamp with time zone, - filename text, - notes text -); - -create table chick( - id integer primary key generated always as identity, - - animal int references animal(id) not null, - year smallint not null, - - mass_deployment int, - age_deployment text, - mass_retrieval int, - age_retrieval text -); - --- migrate:down - diff --git a/db/migrations/20230321115200_add_postgrest_users.sql b/db/migrations/20230321115200_add_postgrest_users.sql deleted file mode 100644 index 0c825e3..0000000 --- a/db/migrations/20230321115200_add_postgrest_users.sql +++ /dev/null @@ -1,11 +0,0 @@ --- migrate:up - -create role web_anon nologin; -grant select on colony, animal, ring, survey, logger, deployment, chick to web_anon; - -create role writer nologin; -grant insert on colony, animal, ring, survey, logger, deployment, chick, import_entry to writer; -grant usage, select on sequence chick_id_seq to writer; - --- migrate:down - diff --git a/db/migrations/20230320135310_add_postgis.sql b/db/migrations/20231011105311_postgis.sql similarity index 98% rename from db/migrations/20230320135310_add_postgis.sql rename to db/migrations/20231011105311_postgis.sql index 6ff89db..a8a7549 100644 --- a/db/migrations/20230320135310_add_postgis.sql +++ b/db/migrations/20231011105311_postgis.sql @@ -3,4 +3,3 @@ create extension if not exists postgis; -- migrate:down - diff --git a/db/migrations/20231011106000_users.sql b/db/migrations/20231011106000_users.sql new file mode 100644 index 0000000..4d00f78 --- /dev/null +++ b/db/migrations/20231011106000_users.sql @@ -0,0 +1,6 @@ +-- migrate:up + +create role web_anon nologin; +create role writer nologin; + +-- migrate:down diff --git a/db/migrations/20230320140331_create_import_table.sql b/db/migrations/20231011107000_import_table.sql similarity index 56% rename from db/migrations/20230320140331_create_import_table.sql rename to db/migrations/20231011107000_import_table.sql index d039db3..0038215 100644 --- a/db/migrations/20230320140331_create_import_table.sql +++ b/db/migrations/20231011107000_import_table.sql @@ -1,13 +1,139 @@ -- migrate:up -create function import_entry() returns trigger language plpgsql +create table import( + species text null, + morph text null, + subspecies text null, + ring_number text null, + euring_code text null, + colour_ring_colour text null, + colour_ring_code text null, + gps_startup_date text null, + gps_startup_time text null, + gps_deployment_date text null, + gps_deployment_time text null, + gps_retrieval_date text null, + gps_retrieval_time text null, + time_zone_startup_deployment_recapture text null, + gps_time_zone text null, + gps_logger_model text null, + gps_logger_id text null, + gps_status text null, + gps_data_collected text null, + gps_raw_datafile_name text null, + gps_record_frequency_sec text null, + mass_gps_logger_g text null, + gps_attachment_method text null, + gps_mount_method text null, + total_logger_mass_all_loggers_g text null, + gps_logger_comment text null, + age text null, + sex text null, + sexing_method text null, + mass_deployment text null, + mass_retrieval text null, + scull text null, + tarsus text null, + wing text null, + culmen text null, + gonys text null, + breeding_stage_deployment text null, + eggs_deployment text null, + chicks_deployment text null, + breeding_stage_retrieval text null, + eggs_retrieval text null, + chicks_retrieval text null, + chick1_age_deployment text null, + chick2_age_deployment text null, + chick3_age_deployment text null, + chick1_mass_deployment text null, + chick2_mass_deployment text null, + chick3_mass_deployment text null, + chick1_age_retrieval text null, + chick2_age_retrieval text null, + chick3_age_retrieval text null, + chick1_mass_retrieval text null, + chick2_mass_retrieval text null, + chick3_mass_retrieval text null, + further_chick_measures_available text null, + more_information_on_breeding_success_available text null, + country text null, + colony text null, + colony_latitude text null, + colony_longitude text null, + plot text null, + nest_id text null, + blood_sample text null, + feather_sample text null, + other_samples text null, + comments_samples text null, + logging_for_seatrack text null, + gls_logger_model text null, + gls_logger_id text null, + gls_status text null, + gls_data_collected text null, + gls_record_frequency_min text null, + gls_logger_mass_g text null, + gls_attachment_method text null, + gls_mount_method text null, + gls_startup_date_gmt text null, + gls_startup_time_gmt text null, + gls_deployment_date text null, + gls_deployment_time text null, + gls_retrieval_date text null, + gls_retrieval_time text null, + gls_deployment_retrieval_time_zone text null, + gls_time_zone text null, + gls_raw_datafile_name text null, + gls_comments text null, + tdr_logger_model text null, + tdr_logger_id text null, + tdr_status text null, + tdr_data_collected text null, + tdr_record_frequency_sec text null, + tdr_mass_g text null, + tdr_attachment_method text null, + tdr_mount_method text null, + tdr_startup_date text null, + tdr_startup_time text null, + tdr_deployment_date text null, + tdr_deployment_time text null, + tdr_retrieval_date text null, + tdr_retrieval_time text null, + tdr_startup_deployment_retrieval_time_zone text null, + tdr_time_zone text null, + tdr_raw_datafile_name text null, + tdr_comment text null, + accelerometer_logger_model text null, + accelerometer_logger_id text null, + accelerometer_status text null, + accelerometer_data_collected text null, + accelerometer_record_frequency_millisec text null, + accelerometer_mass_g text null, + accelerometer_attachment_method text null, + accelerometer_mount_method text null, + accelerometer_startup_date text null, + accelerometer_startup_time text null, + accelerometer_deployment_date text null, + accelerometer_deployment_time text null, + accelerometer_retrieval_date text null, + accelerometer_retrieval_time text null, + accelerometer_startup_deployment_retrieval_time_zone text null, + accelerometer_time_zone text null, + accelerometer_raw_datafile_name text null, + accelerometer_comment text null, + comment text null, + other text null, + old_ring_number text null, + funding_source text null, + data_responsible text null +); + +grant insert on import to writer; + +create function import_table_null_if_empty() returns trigger language plpgsql as $$ -declare - animal int; - year smallint; - ring int; begin - -- Convert empty strings into nulls new.species = nullif(new.species, ''); new.morph = nullif(new.morph, ''); new.subspecies = nullif(new.subspecies, ''); @@ -22,12 +148,10 @@ begin new.gps_retrieval_date = nullif(new.gps_retrieval_date, ''); new.gps_retrieval_time = nullif(new.gps_retrieval_time, ''); new.time_zone_startup_deployment_recapture = nullif(new.time_zone_startup_deployment_recapture, ''); - new.gps_end_date = nullif(new.gps_end_date, ''); - new.gps_end_time = nullif(new.gps_end_time, ''); new.gps_time_zone = nullif(new.gps_time_zone, ''); - new.logger_status = nullif(new.logger_status, ''); new.gps_logger_model = nullif(new.gps_logger_model, ''); new.gps_logger_id = nullif(new.gps_logger_id, ''); + new.gps_status = nullif(new.gps_status, ''); new.gps_data_collected = nullif(new.gps_data_collected, ''); new.gps_raw_datafile_name = nullif(new.gps_raw_datafile_name, ''); new.gps_record_frequency_sec = nullif(new.gps_record_frequency_sec, ''); @@ -65,6 +189,7 @@ begin new.chick2_mass_retrieval = nullif(new.chick2_mass_retrieval, ''); new.chick3_mass_retrieval = nullif(new.chick3_mass_retrieval, ''); new.further_chick_measures_available = nullif(new.further_chick_measures_available, ''); + new.more_information_on_breeding_success_available = nullif(new.more_information_on_breeding_success_available, ''); new.country = nullif(new.country, ''); new.colony = nullif(new.colony, ''); new.colony_latitude = nullif(new.colony_latitude, ''); @@ -78,6 +203,8 @@ begin new.logging_for_seatrack = nullif(new.logging_for_seatrack, ''); new.gls_logger_model = nullif(new.gls_logger_model, ''); new.gls_logger_id = nullif(new.gls_logger_id, ''); + new.gls_status = nullif(new.gls_status, ''); + new.gls_data_collected = nullif(new.gls_data_collected, ''); new.gls_record_frequency_min = nullif(new.gls_record_frequency_min, ''); new.gls_logger_mass_g = nullif(new.gls_logger_mass_g, ''); new.gls_attachment_method = nullif(new.gls_attachment_method, ''); @@ -92,8 +219,10 @@ begin new.gls_time_zone = nullif(new.gls_time_zone, ''); new.gls_raw_datafile_name = nullif(new.gls_raw_datafile_name, ''); new.gls_comments = nullif(new.gls_comments, ''); - new.tdr_model = nullif(new.tdr_model, ''); + new.tdr_logger_model = nullif(new.tdr_logger_model, ''); new.tdr_logger_id = nullif(new.tdr_logger_id, ''); + new.tdr_status = nullif(new.tdr_status, ''); + new.tdr_data_collected = nullif(new.tdr_data_collected, ''); new.tdr_record_frequency_sec = nullif(new.tdr_record_frequency_sec, ''); new.tdr_mass_g = nullif(new.tdr_mass_g, ''); new.tdr_attachment_method = nullif(new.tdr_attachment_method, ''); @@ -108,8 +237,10 @@ begin new.tdr_time_zone = nullif(new.tdr_time_zone, ''); new.tdr_raw_datafile_name = nullif(new.tdr_raw_datafile_name, ''); new.tdr_comment = nullif(new.tdr_comment, ''); - new.accelerometer_model = nullif(new.accelerometer_model, ''); + new.accelerometer_logger_model = nullif(new.accelerometer_logger_model, ''); new.accelerometer_logger_id = nullif(new.accelerometer_logger_id, ''); + new.accelerometer_status = nullif(new.accelerometer_status, ''); + new.accelerometer_data_collected = nullif(new.accelerometer_data_collected, ''); new.accelerometer_record_frequency_millisec = nullif(new.accelerometer_record_frequency_millisec, ''); new.accelerometer_mass_g = nullif(new.accelerometer_mass_g, ''); new.accelerometer_attachment_method = nullif(new.accelerometer_attachment_method, ''); @@ -127,253 +258,8 @@ begin new.comment = nullif(new.comment, ''); new.other = nullif(new.other, ''); new.old_ring_number = nullif(new.old_ring_number, ''); + new.funding_source = nullif(new.funding_source, ''); new.data_responsible = nullif(new.data_responsible, ''); - -- Populate tables - insert into colony values( - new.colony, - ST_SetSRID(ST_MakePoint( - (new.colony_latitude)::float, - (new.colony_longitude)::float - ), 4326), - new.country, - new.plot, - new.nest_id - ) on conflict do nothing; - -- TODO: consider multiple changes - if new.old_ring_number is null then - animal = (new.ring_number)::int; - else - select animal.id into strict animal - from ring - join animal on ring.animal = animal.id - where ring.id = new.old_ring_number; - end if; - year = extract(year from date (new.gps_startup_date)); - insert into animal values( - animal, - new.species, - new.morph, - new.subspecies - ) on conflict do nothing; - insert into ring values( - (new.ring_number)::int, - new.euring_code, - new.colour_ring_colour, - new.colour_ring_code, - animal - ) on conflict do nothing; - insert into survey values( - animal, - year, - - (new.total_logger_mass_all_loggers_g)::decimal, - - new.age, - new.sex, - new.sexing_method, - - (new.mass_deployment)::int, - (new.mass_retrieval)::int, - (new.scull)::decimal, - (new.tarsus)::decimal, - (new.wing)::decimal, - (new.culmen)::decimal, - (new.gonys)::decimal, - - new.breeding_stage_deployment, - (new.eggs_deployment)::int, - (new.chicks_deployment)::int, - new.breeding_stage_retrieval, - (new.eggs_retrieval)::int, - (new.chicks_retrieval)::int, - - new.further_chick_measures_available, - - new.colony, - - (new.blood_sample)::bool, - (new.feather_sample)::bool, - (new.other_samples)::bool, - new.comments_samples, - (new.logging_for_seatrack)::bool, - - new.comment, - new.other, - new.data_responsible - ); - - if new.chick1_mass_retrieval is not null then - insert into chick values( - default, - animal, - year, - (new.chick1_mass_deployment)::decimal, - new.chick1_age_deployment, - (new.chick1_mass_retrieval)::decimal, - new.chick1_age_retrieval - ); - end if; - - if new.chick2_mass_retrieval is not null then - insert into chick values( - default, - animal, - year, - (new.chick2_mass_deployment)::decimal, - new.chick2_age_deployment, - (new.chick2_mass_retrieval)::decimal, - new.chick2_age_retrieval - ); - end if; - - if new.chick3_mass_retrieval is not null then - insert into chick values( - default, - animal, - year, - (new.chick3_mass_deployment)::decimal, - new.chick3_age_deployment, - (new.chick3_mass_retrieval)::decimal, - new.chick3_age_retrieval - ); - end if; - - if new.gps_startup_date is not null then - insert into logger values( - new.gps_logger_id, - 'gps', - new.gps_logger_model - ) on conflict do nothing; - insert into deployment values( - new.gps_logger_id, - animal, - new.logger_status, - (new.gps_record_frequency_sec)::int*1000, - (new.mass_gps_logger_g)::decimal, - new.gps_attachment_method, - new.gps_mount_method, - concat( - new.gps_startup_date, ' ', - new.gps_startup_time, ' ', - new.time_zone_startup_deployment_recapture - )::timestamptz, - concat( - new.gps_deployment_date, ' ', - new.gps_deployment_time, ' ', - new.time_zone_startup_deployment_recapture - )::timestamptz, - case when new.gps_retrieval_date is null then null else - concat( - new.gps_retrieval_date, ' ', - new.gps_retrieval_time, ' ', - new.time_zone_startup_deployment_recapture - )::timestamptz end, - new.gps_raw_datafile_name, - new.gps_logger_comment - ); - end if; - if new.gls_startup_date_gmt is not null then - insert into logger values( - new.gls_logger_id, - 'gls', - new.gls_logger_model - ) on conflict do nothing; - insert into deployment values( - new.gls_logger_id, - animal, - null, -- no status? - (new.gls_record_frequency_min)::int*60*1000, - (new.gls_logger_mass_g)::decimal, - new.gls_attachment_method, - new.gls_mount_method, - concat( - new.gls_startup_date_gmt, ' ', - new.gls_startup_time_gmt, ' ', - 'UTC' - )::timestamptz, - concat( - new.gls_deployment_date, ' ', - new.gls_deployment_time, ' ', - new.gls_deployment_retrieval_time_zone - )::timestamptz, - case when new.gls_retrieval_date is null then null else - concat( - new.gls_retrieval_date, ' ', - new.gls_retrieval_time, ' ', - new.gls_deployment_retrieval_time_zone - )::timestamptz end, - new.gls_raw_datafile_name, - new.gls_comments - ); - end if; - if new.tdr_startup_date is not null then - insert into logger values( - new.tdr_logger_id, - 'tdr', - new.tdr_model - ) on conflict do nothing; - insert into deployment values( - new.tdr_logger_id, - animal, - null, -- no status? - (new.tdr_record_frequency_sec)::int*1000, - (new.tdr_mass_g)::decimal, - new.tdr_attachment_method, - new.tdr_mount_method, - concat( - new.tdr_startup_date, ' ', - new.tdr_startup_time, ' ', - new.tdr_startup_deployment_retrieval_time_zone - )::timestamptz, - concat( - new.tdr_deployment_date, ' ', - new.tdr_deployment_time, ' ', - new.tdr_startup_deployment_retrieval_time_zone - )::timestamptz, - case when new.tdr_retrieval_date is null then null else - concat( - new.tdr_retrieval_date, ' ', - new.tdr_retrieval_time, ' ', - new.tdr_startup_deployment_retrieval_time_zone - )::timestamptz end, - new.tdr_raw_datafile_name, - new.tdr_comment - ); - end if; - if new.accelerometer_startup_date is not null then - insert into logger values( - new.accelerometer_logger_id, - 'accelerometer', - new.accelerometer_model - ) on conflict do nothing; - insert into deployment values( - new.accelerometer_logger_id, - animal, - null, -- no status? - (new.accelerometer_record_frequency_millisec)::int, - (new.accelerometer_mass_g)::decimal, - new.accelerometer_attachment_method, - new.accelerometer_mount_method, - concat( - new.accelerometer_startup_date, ' ', - new.accelerometer_startup_time, ' ', - new.accelerometer_startup_deployment_retrieval_time_zone - )::timestamptz, - concat( - new.accelerometer_deployment_date, ' ', - new.accelerometer_deployment_time, ' ', - new.accelerometer_startup_deployment_retrieval_time_zone - )::timestamptz, - case when new.accelerometer_retrieval_date is null then null else - concat( - new.accelerometer_retrieval_date, ' ', - new.accelerometer_retrieval_time, ' ', - new.accelerometer_startup_deployment_retrieval_time_zone - )::timestamptz end, - new.accelerometer_raw_datafile_name, - new.accelerometer_comment - ); - end if; return null; exception when others then @@ -384,133 +270,9 @@ exception end; $$; -create table import_entry( - species text null, - morph text null, - subspecies text null, - ring_number text null, - euring_code text null, - colour_ring_colour text null, - colour_ring_code text null, - gps_startup_date text null, - gps_startup_time text null, - gps_deployment_date text null, - gps_deployment_time text null, - gps_retrieval_date text null, - gps_retrieval_time text null, - time_zone_startup_deployment_recapture text null, - gps_end_date text null, - gps_end_time text null, - gps_time_zone text null, - logger_status text null, - gps_logger_model text null, - gps_logger_id text null, - gps_data_collected text null, - gps_raw_datafile_name text null, - gps_record_frequency_sec text null, - mass_gps_logger_g text null, - gps_attachment_method text null, - gps_mount_method text null, - total_logger_mass_all_loggers_g text null, - gps_logger_comment text null, - age text null, - sex text null, - sexing_method text null, - mass_deployment text null, - mass_retrieval text null, - scull text null, - tarsus text null, - wing text null, - culmen text null, - gonys text null, - breeding_stage_deployment text null, - eggs_deployment text null, - chicks_deployment text null, - breeding_stage_retrieval text null, - eggs_retrieval text null, - chicks_retrieval text null, - chick1_age_deployment text null, - chick2_age_deployment text null, - chick3_age_deployment text null, - chick1_mass_deployment text null, - chick2_mass_deployment text null, - chick3_mass_deployment text null, - chick1_age_retrieval text null, - chick2_age_retrieval text null, - chick3_age_retrieval text null, - chick1_mass_retrieval text null, - chick2_mass_retrieval text null, - chick3_mass_retrieval text null, - further_chick_measures_available text null, - country text null, - colony text null, - colony_latitude text null, - colony_longitude text null, - plot text null, - nest_id text null, - blood_sample text null, - feather_sample text null, - other_samples text null, - comments_samples text null, - logging_for_seatrack text null, - gls_logger_model text null, - gls_logger_id text null, - gls_record_frequency_min text null, - gls_logger_mass_g text null, - gls_attachment_method text null, - gls_mount_method text null, - gls_startup_date_gmt text null, - gls_startup_time_gmt text null, - gls_deployment_date text null, - gls_deployment_time text null, - gls_retrieval_date text null, - gls_retrieval_time text null, - gls_deployment_retrieval_time_zone text null, - gls_time_zone text null, - gls_raw_datafile_name text null, - gls_comments text null, - tdr_model text null, - tdr_logger_id text null, - tdr_record_frequency_sec text null, - tdr_mass_g text null, - tdr_attachment_method text null, - tdr_mount_method text null, - tdr_startup_date text null, - tdr_startup_time text null, - tdr_deployment_date text null, - tdr_deployment_time text null, - tdr_retrieval_date text null, - tdr_retrieval_time text null, - tdr_startup_deployment_retrieval_time_zone text null, - tdr_time_zone text null, - tdr_raw_datafile_name text null, - tdr_comment text null, - accelerometer_model text null, - accelerometer_logger_id text null, - accelerometer_record_frequency_millisec text null, - accelerometer_mass_g text null, - accelerometer_attachment_method text null, - accelerometer_mount_method text null, - accelerometer_startup_date text null, - accelerometer_startup_time text null, - accelerometer_deployment_date text null, - accelerometer_deployment_time text null, - accelerometer_retrieval_date text null, - accelerometer_retrieval_time text null, - accelerometer_startup_deployment_retrieval_time_zone text null, - accelerometer_time_zone text null, - accelerometer_raw_datafile_name text null, - accelerometer_comment text null, - comment text null, - other text null, - old_ring_number text null, - data_responsible text null -); - -create trigger import_entry - before insert on import_entry +create trigger priority1_import_table_null_if_empty + before insert on import for each row - execute function import_entry(); + execute function import_table_null_if_empty(); -- migrate:down - diff --git a/db/migrations/20231011110157_animal_and_ring.sql b/db/migrations/20231011110157_animal_and_ring.sql new file mode 100644 index 0000000..eec51db --- /dev/null +++ b/db/migrations/20231011110157_animal_and_ring.sql @@ -0,0 +1,77 @@ +-- migrate:up + +create table animal( + id int primary key, + species text not null, + morph text, + subspecies text +); + +create table ring( + id int primary key, + euring_code text, + colour_ring_colour text, + colour_ring_code text, + animal int references animal(id) not null +); + +grant select on animal, ring to web_anon; +grant insert on animal, ring to writer; + +create function get_animal( + ring_number int, + old_ring_number int +) returns int language plpgsql +as $$ +declare + animal int; +begin + if old_ring_number is null then + animal = ring_number; + else + select animal into strict animal + from ring + where id = old_ring_number; + end if; + return animal; +end; +$$; + +create function import_animal_and_ring() returns trigger language plpgsql +as $$ +declare + animal int; +begin + animal = get_animal( + (new.ring_number)::int, + (new.old_ring_number)::int + ); + insert into animal values( + animal, + new.species, + new.morph, + new.subspecies + ) on conflict do nothing; + insert into ring values( + (new.ring_number)::int, + new.euring_code, + new.colour_ring_colour, + new.colour_ring_code, + animal + ) on conflict do nothing; + return null; +exception + when others then + raise exception using + errcode = sqlstate, + message = sqlerrm, + detail = new; +end; +$$; + +create trigger priority2_import_animal_and_ring + before insert on import + for each row + execute function import_animal_and_ring(); + +-- migrate:down diff --git a/db/migrations/20231011110410_colony.sql b/db/migrations/20231011110410_colony.sql new file mode 100644 index 0000000..c80cc66 --- /dev/null +++ b/db/migrations/20231011110410_colony.sql @@ -0,0 +1,42 @@ +-- migrate:up + +create table colony( + name text primary key, + geometry geometry(point, 4326), + country text, + plot text, + nest_id text +); + +grant select on colony to web_anon; +grant insert on colony to writer; + +create function import_colony() returns trigger language plpgsql +as $$ +begin + insert into colony values( + colony, + ST_SetSRID(ST_MakePoint( + colony_latitude::float, + colony_longitude::float + ), 4326), + country, + plot, + nest_id + ) on conflict do nothing; + return null; +exception + when others then + raise exception using + errcode = sqlstate, + message = sqlerrm, + detail = new; +end; +$$; + +create trigger priority2_import_colony + before insert on import + for each row + execute function import_colony(); + +-- migrate:down diff --git a/db/migrations/20231011111640_deployment_and_chick.sql b/db/migrations/20231011111640_deployment_and_chick.sql new file mode 100644 index 0000000..b99ab5d --- /dev/null +++ b/db/migrations/20231011111640_deployment_and_chick.sql @@ -0,0 +1,144 @@ +-- migrate:up + +create table deployment( + ring int references ring(id), + date date not null, + total_logger_mass_all_loggers_g int, + age text, + sex text, + sexing_method text, + mass_deployment_g int, + mass_retrieval_g int, + scull_mm decimal, + tarsus_mm decimal, + wing_mm decimal, + culmen_mm decimal, + gonys_mm decimal, + breeding_stage_deployment text, + eggs_deployment text, + chicks_deployment text, + breeding_stage_retrieval text, + eggs_retrieval text, + chicks_retrieval text, + further_chick_measures_available text, + colony text references colony(name), + sample_blood bool, + sample_feather bool, + sample_other bool, + sample_notes text, + comment text, + other text, + data_responsible text, + primary key (date, ring) +); + +create table chick( + id integer primary key generated always as identity, + animal int references animal(id) not null, + date date not null, + mass_deployment int, + age_deployment text, + mass_retrieval int, + age_retrieval text +); + +grant select on deployment, chick to web_anon; +grant insert on deployment, chick to writer; +grant usage, select on sequence chick_id_seq to writer; + +create function import_deployment_and_chick() returns trigger language plpgsql +as $$ +declare + animal int; + date date; +begin + animal = get_animal( + (new.ring_number)::int, + (new.old_ring_number)::int + ); + date = coalesce( + new.gps_deployment_date, + new.gls_deployment_date, + new.tdr_deployment_date, + new.accelerometer_deployment_date + )::date; + insert into deployment values( + animal, + date, + (new.total_logger_mass_all_loggers_g)::decimal, + new.age, + new.sex, + new.sexing_method, + (new.mass_deployment)::int, + (new.mass_retrieval)::int, + (new.scull)::decimal, + (new.tarsus)::decimal, + (new.wing)::decimal, + (new.culmen)::decimal, + (new.gonys)::decimal, + new.breeding_stage_deployment, + (new.eggs_deployment)::int, + (new.chicks_deployment)::int, + new.breeding_stage_retrieval, + (new.eggs_retrieval)::int, + (new.chicks_retrieval)::int, + new.further_chick_measures_available, + new.colony, + (new.blood_sample)::bool, + (new.feather_sample)::bool, + (new.other_samples)::bool, + new.comments_samples, + (new.logging_for_seatrack)::bool, + new.comment, + new.other, + new.data_responsible + ); + if new.chick1_mass_retrieval is not null then + insert into chick values( + default, + animal, + year, + (new.chick1_mass_deployment)::decimal, + new.chick1_age_deployment, + (new.chick1_mass_retrieval)::decimal, + new.chick1_age_retrieval + ); + end if; + if new.chick2_mass_retrieval is not null then + insert into chick values( + default, + animal, + year, + (new.chick2_mass_deployment)::decimal, + new.chick2_age_deployment, + (new.chick2_mass_retrieval)::decimal, + new.chick2_age_retrieval + ); + end if; + if new.chick3_mass_retrieval is not null then + insert into chick values( + default, + animal, + year, + (new.chick3_mass_deployment)::decimal, + new.chick3_age_deployment, + (new.chick3_mass_retrieval)::decimal, + new.chick3_age_retrieval + ); + end if; + return null; +exception + when others then + raise exception using + errcode = sqlstate, + message = sqlerrm, + detail = new; +end; +$$; + +create trigger priority2_import_deployment_and_chick + before insert on import + for each row + execute function import_deployment_and_chick(); + +-- migrate:down diff --git a/db/migrations/20231011112823_logger.sql b/db/migrations/20231011112823_logger.sql new file mode 100644 index 0000000..b52b628 --- /dev/null +++ b/db/migrations/20231011112823_logger.sql @@ -0,0 +1,198 @@ +-- migrate:up + +create table logger( + id text primary key, + type text not null, + model text +); + +create table logger_instrumentation( + id integer primary key generated always as identity, + logger text references logger(id) not null, + animal int references animal(id) not null, + status text, + sampling_freq_s decimal, + mass_g decimal, + attachment_method text, + mount_method text, + startup timestamp with time zone, + deployment timestamp with time zone, + retrieval timestamp with time zone, + filename text, + data_stored_externally text, + comment text +); + +grant select on logger, logger_instrumentation to web_anon; +grant insert on logger, logger_instrumentation to writer; +grant usage, select on sequence logger_instrumentation_id_seq to writer; + +create function import_logger_and_logger_instrumentation() returns trigger language plpgsql +as $$ +declare + animal int; +begin + animal = get_animal( + (new.ring_number)::int, + (new.old_ring_number)::int + ); + if new.gps_deployment_date is not null then + insert into logger values( + new.gps_logger_id, + 'gps', + new.gps_logger_model + ) on conflict do nothing; + insert into logger_instrumentation values( + default, + new.gps_logger_id, + animal, + new.gps_status, + (new.gps_record_frequency_sec)::decimal, + (new.mass_gps_logger_g)::decimal, + new.gps_attachment_method, + new.gps_mount_method, + concat( + new.gps_startup_date, ' ', + new.gps_startup_time, ' ', + new.time_zone_startup_deployment_recapture + )::timestamptz, + concat( + new.gps_deployment_date, ' ', + new.gps_deployment_time, ' ', + new.time_zone_startup_deployment_recapture + )::timestamptz, + case when new.gps_retrieval_date is null then null else + concat( + new.gps_retrieval_date, ' ', + new.gps_retrieval_time, ' ', + new.time_zone_startup_deployment_recapture + )::timestamptz end, + new.gps_raw_datafile_name, + null, + new.gps_logger_comment + ); + end if; + if new.gls_deployment_date is not null then + insert into logger values( + new.gls_logger_id, + 'gls', + new.gls_logger_model + ) on conflict do nothing; + insert into logger_instrumentation values( + default, + new.gls_logger_id, + animal, + new.gls_status, + (new.gls_record_frequency_min)::decimal*60, + (new.gls_logger_mass_g)::decimal, + new.gls_attachment_method, + new.gls_mount_method, + concat( + new.gls_startup_date_gmt, ' ', + new.gls_startup_time_gmt, ' ', + 'UTC' + )::timestamptz, + concat( + new.gls_deployment_date, ' ', + new.gls_deployment_time, ' ', + new.gls_deployment_retrieval_time_zone + )::timestamptz, + case when new.gls_retrieval_date is null then null else + concat( + new.gls_retrieval_date, ' ', + new.gls_retrieval_time, ' ', + new.gls_deployment_retrieval_time_zone + )::timestamptz end, + new.gls_raw_datafile_name, + case when logging_for_seatrack::bool then 'seatrack' else null end, + new.gls_comments + ); + end if; + if new.tdr_deployment_date is not null then + insert into logger values( + new.tdr_logger_id, + 'tdr', + new.tdr_model + ) on conflict do nothing; + insert into logger_instrumentation values( + default, + new.tdr_logger_id, + animal, + new.tdr_status, + (new.tdr_record_frequency_sec)::decimal, + (new.tdr_mass_g)::decimal, + new.tdr_attachment_method, + new.tdr_mount_method, + concat( + new.tdr_startup_date, ' ', + new.tdr_startup_time, ' ', + new.tdr_startup_deployment_retrieval_time_zone + )::timestamptz, + concat( + new.tdr_deployment_date, ' ', + new.tdr_deployment_time, ' ', + new.tdr_startup_deployment_retrieval_time_zone + )::timestamptz, + case when new.tdr_retrieval_date is null then null else + concat( + new.tdr_retrieval_date, ' ', + new.tdr_retrieval_time, ' ', + new.tdr_startup_deployment_retrieval_time_zone + )::timestamptz end, + new.tdr_raw_datafile_name, + null, + new.tdr_comment + ); + end if; + if new.accelerometer_deployment_date is not null then + insert into logger values( + new.accelerometer_logger_id, + 'accelerometer', + new.accelerometer_model + ) on conflict do nothing; + insert into deployment values( + default, + new.accelerometer_logger_id, + animal, + new.accelerometer_status, + (new.accelerometer_record_frequency_millisec)::decimal/1000, + (new.accelerometer_mass_g)::decimal, + new.accelerometer_attachment_method, + new.accelerometer_mount_method, + concat( + new.accelerometer_startup_date, ' ', + new.accelerometer_startup_time, ' ', + new.accelerometer_startup_deployment_retrieval_time_zone + )::timestamptz, + concat( + new.accelerometer_deployment_date, ' ', + new.accelerometer_deployment_time, ' ', + new.accelerometer_startup_deployment_retrieval_time_zone + )::timestamptz, + case when new.accelerometer_retrieval_date is null then null else + concat( + new.accelerometer_retrieval_date, ' ', + new.accelerometer_retrieval_time, ' ', + new.accelerometer_startup_deployment_retrieval_time_zone + )::timestamptz end, + new.accelerometer_raw_datafile_name, + null, + new.accelerometer_comment + ); + end if; + return null; +exception + when others then + raise exception using + errcode = sqlstate, + message = sqlerrm, + detail = new; +end; +$$; + +create trigger priority2_import_logger_and_logger_instrumentation + before insert on import + for each row + execute function import_logger_and_logger_instrumentation(); + +-- migrate:down diff --git a/wizard/wizard.py b/wizard/wizard.py index d404c80..d363c78 100755 --- a/wizard/wizard.py +++ b/wizard/wizard.py @@ -20,16 +20,21 @@ logging.debug(os.environ) DEFAULT_OPTIONS = { + "encoding": "UTF-8", + "separator": ",", "ignoreLines": -1, "headerLines": 1, "skipDataLines": 0, "limit": -1, "storeBlankRows": True, + "guessCellValueTypes": False, + "processQuotes": True, + "quoteCharacter": '"', "storeBlankCellsAsNulls": True, "includeFileSources": False, "includeArchiveFileName": False, + "trimStrings": False, "disableAutoPreview": False, - "forceText": True, } @@ -165,7 +170,7 @@ def wizard(): if POSTGREST_TOKEN: headers["Authorization"] = "Bearer " + POSTGREST_TOKEN response = requests.post( - POSTGREST_URL + "/import_entry", + POSTGREST_URL + "/import", headers=headers, data=clean_csv, )