Skip to content

Commit

Permalink
fix filename presence logic
Browse files Browse the repository at this point in the history
  • Loading branch information
nicokant committed Jan 17, 2024
1 parent 0e5624f commit 66f8ea8
Show file tree
Hide file tree
Showing 2 changed files with 229 additions and 11 deletions.
199 changes: 199 additions & 0 deletions db/migrations/20240117105114_logger_filename_required_logic.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,199 @@
-- migrate:up
alter table logger_instrumentation alter column filename drop not null;

create function safe_cast_bool(p_in text)
returns bool
as
$$
begin
begin
return $1::bool;
exception
when others then
return null;
end;
end;
$$
language plpgsql;

create or replace function import() returns trigger language plpgsql
as $$
begin
-- perform some checks
if safe_cast_bool(new.gps_data_collected) and new.gps_raw_datafile_name is null then
raise exception 'gps_raw_datafile_name cannot be empty if gps_data_collected is "Yes"';
end if;

if safe_cast_bool(new.gls_data_collected) and not safe_cast_bool(new.logging_for_seatrack) and new.gls_raw_datafile_name is null then
raise exception 'gls_raw_datafile_name cannot be empty if gls_data_collected is "Yes"';
end if;

if safe_cast_bool(new.tdr_data_collected) and new.tdr_raw_datafile_name is null then
raise exception 'tdr_raw_datafile_name cannot be empty if tdr_data_collected is "Yes"';
end if;

if safe_cast_bool(new.other_sensor_data_collected) and new.other_sensor_raw_datafile_name is null then
raise exception 'other_sensor_raw_datafile_name cannot be empty if other_sensor_data_collected is "Yes"';
end if;

if new.ring_number is null then
new.ring_number = 'AUTO_' || nextval('auto_ring_id_seq')::text;
end if;
if new.gps_deployment_date is not null and new.gps_logger_id is null then
new.gps_logger_id = 'AUTO_' || nextval('auto_logger_id_seq')::text;
end if;
if new.gls_deployment_date is not null and new.gls_logger_id is null then
new.gls_logger_id = 'AUTO_' || nextval('auto_logger_id_seq')::text;
end if;
if new.tdr_deployment_date is not null and new.tdr_logger_id is null then
new.tdr_logger_id = 'AUTO_' || nextval('auto_logger_id_seq')::text;
end if;
if new.other_sensor_deployment_date is not null and new.other_sensor_logger_id is null then
new.other_sensor_logger_id = 'AUTO_' || nextval('auto_logger_id_seq')::text;
end if;
perform import_animal_and_ring(new);
perform import_colony(new);
perform import_deployment_and_chick(new);
perform import_logger_and_logger_instrumentation(new);
return null;
exception
when others then
raise exception using
errcode = sqlstate,
message = sqlerrm,
detail = row_to_json(new);
end;
$$;

create or replace function import_logger_and_logger_instrumentation(new import) returns void language plpgsql
as $$
begin
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,
new.ring_number,
new.gps_status,
(new.gps_record_frequency_sec)::decimal,
(new.mass_gps_logger_g)::decimal,
new.gps_attachment_method,
new.gps_mount_method,
(new.gps_startup_date::date +
new.gps_startup_time::time) at time zone
new.gps_deployment_retrieval_time_zone,
(new.gps_deployment_date::date +
new.gps_deployment_time::time) at time zone
new.gps_deployment_retrieval_time_zone,
case when new.gps_retrieval_date is null then null else
(new.gps_retrieval_date::date +
new.gps_retrieval_time::time) at time zone
new.gps_deployment_retrieval_time_zone
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,
new.ring_number,
new.gls_status,
(new.gls_record_frequency_min)::decimal*60,
(new.gls_logger_mass_g)::decimal,
new.gls_attachment_method,
new.gls_mount_method,
(new.gls_startup_date_gmt::date +
new.gls_startup_time_gmt::time) at time zone
'UTC',
(new.gls_deployment_date::date +
new.gls_deployment_time::time) at time zone
new.gls_deployment_retrieval_time_zone,
case when new.gls_retrieval_date is null then null else
(new.gls_retrieval_date::date +
new.gls_retrieval_time::time) at time zone
new.gls_deployment_retrieval_time_zone
end,
new.gls_raw_datafile_name,
case when safe_cast_bool(new.logging_for_seatrack) 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_logger_model
) on conflict do nothing;
insert into logger_instrumentation values(
default,
new.tdr_logger_id,
new.ring_number,
new.tdr_status,
(new.tdr_record_frequency_sec)::decimal,
(new.tdr_mass_g)::decimal,
new.tdr_attachment_method,
new.tdr_mount_method,
(new.tdr_startup_date::date +
new.tdr_startup_time::time) at time zone
new.tdr_startup_deployment_retrieval_time_zone,
(new.tdr_deployment_date::date +
new.tdr_deployment_time::time) at time zone
new.tdr_startup_deployment_retrieval_time_zone,
case when new.tdr_retrieval_date is null then null else
(new.tdr_retrieval_date::date +
new.tdr_retrieval_time::time) at time zone
new.tdr_startup_deployment_retrieval_time_zone
end,
new.tdr_raw_datafile_name,
null,
new.tdr_comment
);
end if;
if new.other_sensor_deployment_date is not null then
insert into logger values(
new.other_sensor_logger_id,
'other_sensor',
new.other_sensor_logger_model
) on conflict do nothing;
insert into deployment values(
default,
new.other_sensor_logger_id,
new.ring_number,
new.other_sensor_status,
(new.other_sensor_record_frequency_millisec)::decimal/1000,
(new.other_sensor_logger_mass_g)::decimal,
new.other_sensor_attachment_method,
new.other_sensor_mount_method,
(new.other_sensor_startup_date::date +
new.other_sensor_startup_time::time) at time zone
new.other_sensor_startup_deployment_retrieval_time_zone,
(new.other_sensor_deployment_time::date +
new.other_sensor_deployment_time::time) at time zone
new.other_sensor_startup_deployment_retrieval_time_zone,
case when new.other_sensor_retrieval_date is null then null else
(new.other_sensor_retrieval_date::date +
new.other_sensor_retrieval_time::time) at time zone
new.other_sensor_startup_deployment_retrieval_time_zone
end,
new.other_sensor_raw_datafile_name,
null,
new.other_sensor_comment
);
end if;
end;
$$;

-- migrate:down

41 changes: 30 additions & 11 deletions db/schema.sql
Original file line number Diff line number Diff line change
Expand Up @@ -102,20 +102,20 @@ CREATE FUNCTION public.import() RETURNS trigger
AS $$
begin
-- perform some checks
if new.gps_deployment_date is not null and new.gps_raw_datafile_name is null then
raise exception 'gps_raw_datafile_name cannot be empty if gps_deployment_date is defined';
if safe_cast_bool(new.gps_data_collected) and new.gps_raw_datafile_name is null then
raise exception 'gps_raw_datafile_name cannot be empty if gps_data_collected is "Yes"';
end if;

if new.gls_deployment_date is not null and new.gls_raw_datafile_name is null then
raise exception 'gls_raw_datafile_name cannot be empty if gls_deployment_date is defined';
if safe_cast_bool(new.gls_data_collected) and not safe_cast_bool(new.logging_for_seatrack) and new.gls_raw_datafile_name is null then
raise exception 'gls_raw_datafile_name cannot be empty if gls_data_collected is "Yes"';
end if;

if new.tdr_deployment_date is not null and new.tdr_raw_datafile_name is null then
raise exception 'tdr_raw_datafile_name cannot be empty if tdr_deployment_date is defined';
if safe_cast_bool(new.tdr_data_collected) and new.tdr_raw_datafile_name is null then
raise exception 'tdr_raw_datafile_name cannot be empty if tdr_data_collected is "Yes"';
end if;

if new.other_sensor_deployment_date is not null and new.other_sensor_raw_datafile_name is null then
raise exception 'other_sensor_raw_datafile_name cannot be empty if other_sensor_deployment_date is defined';
if safe_cast_bool(new.other_sensor_data_collected) and new.other_sensor_raw_datafile_name is null then
raise exception 'other_sensor_raw_datafile_name cannot be empty if other_sensor_data_collected is "Yes"';
end if;

if new.ring_number is null then
Expand Down Expand Up @@ -499,7 +499,7 @@ begin
new.gls_deployment_retrieval_time_zone
end,
new.gls_raw_datafile_name,
case when logging_for_seatrack::bool then 'seatrack' else null end,
case when safe_cast_bool(new.logging_for_seatrack) then 'seatrack' else null end,
new.gls_comments
);
end if;
Expand Down Expand Up @@ -654,6 +654,24 @@ end;
$$;


--
-- Name: safe_cast_bool(text); Type: FUNCTION; Schema: public; Owner: -
--

CREATE FUNCTION public.safe_cast_bool(p_in text) RETURNS boolean
LANGUAGE plpgsql
AS $_$
begin
begin
return $1::bool;
exception
when others then
return null;
end;
end;
$_$;


--
-- Name: animal; Type: TABLE; Schema: public; Owner: -
--
Expand Down Expand Up @@ -897,7 +915,7 @@ CREATE TABLE public.logger_instrumentation (
startup timestamp with time zone,
deployment timestamp with time zone,
retrieval timestamp with time zone,
filename text NOT NULL,
filename text,
data_stored_externally text,
comment text
);
Expand Down Expand Up @@ -1122,4 +1140,5 @@ INSERT INTO public.schema_migrations (version) VALUES
('20240116110423'),
('20240117072241'),
('20240117081051'),
('20240117093556');
('20240117093556'),
('20240117105114');

0 comments on commit 66f8ea8

Please sign in to comment.