Skip to content

Commit

Permalink
Merge branch 'develop' into generic_merge
Browse files Browse the repository at this point in the history
  • Loading branch information
IanMayo authored Feb 16, 2021
2 parents 7f9f68c + a9e9555 commit 7491910
Show file tree
Hide file tree
Showing 4 changed files with 347 additions and 0 deletions.
69 changes: 69 additions & 0 deletions pepys_import/database/stored_procedures/Comments_for.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,69 @@
--DROPING EXISTING PEPYS.COMMENTS_FOR FUNCTION
DROP FUNCTION IF EXISTS PEPYS.COMMENTS_FOR;

--CREATING PEPYS.COMMENTS_FOR FUNCTION
CREATE FUNCTION PEPYS.COMMENTS_FOR(
INP_START_TIME TEXT,
INP_END_TIME TEXT,
INP_COMMENT_SEARCH_STRING TEXT,
INP_SOURCE_ID TEXT[],
INP_PLATFORM_ID TEXT[],
INP_PAGE_NO INTEGER DEFAULT 1,
INP_PAGE_SIZE INTEGER DEFAULT 100)
RETURNS TABLE (
comment_id UUID,
comment_time TIMESTAMP WITHOUT TIME ZONE,
platform_name varchar(150),
platformtype_name varchar(150),
nationality_name varchar(150),
content text,
comment_type_name varchar(150))
AS
$$
--Name: Comments_For
--Version: v0.15
with
ui_filter_input as
(select
inp_start_time start_time, --Input should be same as for Phase 1
inp_end_time end_time, --Input should be same as for Phase 1
inp_comment_search_string comment_search_string, --Input should be same as for Phase 1
inp_source_id::text[] source_id, --Input from Phase 2 of import, can be set as null: null as source_id
inp_platform_id::text[] platform_id, --Input from Phase 2 of import, can be set as null: null as platform_id
--null as platform_id, --Example on how to provide null
inp_page_no page_no, --Pagination input. Page No For ex. if there are 1000 records paginated into pages of 100 records each, 1 here will return the first page or first 100 records
inp_page_size page_size --Pagination input - No. of records per page
),
processed_ui_filter_values as
(select
case when (trim(ui_input.start_time)='' OR ui_input.start_time is null) then '1000-01-01 00:00:00.000000'::timestamp else to_timestamp(ui_input.start_time, 'YYYY-MM-DD HH24:MI:SS.US') end as start_time,
case when (trim(ui_input.end_time)='' OR ui_input.end_time is null) then '9999-12-12 23:59:59.000000'::timestamp else to_timestamp(ui_input.end_time, 'YYYY-MM-DD HH24:MI:SS.US') end as end_time,
case when (trim(ui_input.comment_search_string)='' OR ui_input.comment_search_string is null) then null::varchar else '%'||upper(ui_input.comment_search_string)||'%' end as comment_search_string,
case when (coalesce(array_length(ui_input.source_id,1),0)::int = 0) then null else ui_input.source_id end as source_id,
case when (coalesce(array_length(ui_input.platform_id,1),0)::int = 0) then null else ui_input.platform_id end as platform_id,
case when (ui_input.page_no is null OR ui_input.page_no <=0) then 1 else ui_input.page_no end as page_no,
case when (ui_input.page_size is null OR ui_input.page_size <=0) then 100 else ui_input.page_size end as page_size
from
ui_filter_input as ui_input
)
select filtered_comments.comment_id, filtered_comments.time, Platforms.name,
PlatformTypes.name, Nationalities.name,
filtered_comments.content, CommentTypes.name from
pepys."Comments" as filtered_comments inner join
pepys."Platforms" as Platforms on filtered_comments.platform_id=Platforms.platform_id inner join
pepys."PlatformTypes" as PlatformTypes on Platforms.platform_type_id = PlatformTypes.platform_type_id inner join
pepys."Nationalities" as Nationalities on Platforms.nationality_id = Nationalities.nationality_id inner join
pepys."CommentTypes" as CommentTypes on filtered_comments.comment_type_id = CommentTypes.comment_type_id
WHERE
--Start and End Time criteria from the UI
tsrange((select start_time::timestamp from processed_ui_filter_values), (select end_time::timestamp from processed_ui_filter_values), '[]') @> filtered_comments.time AND
--Comment search criteria from the UI
((select comment_search_string from processed_ui_filter_values) is null OR upper(filtered_comments.content) like (select comment_search_string from processed_ui_filter_values)) AND
--Source criteria from the UI
((select source_id from processed_ui_filter_values) is null OR filtered_comments.source_id in (select unnest(source_id::uuid[]) from processed_ui_filter_values)) AND
--Platform criteria from the UI
((select platform_id from processed_ui_filter_values) is null OR filtered_comments.platform_id in (select unnest(platform_id::uuid[]) from processed_ui_filter_values))
--Sort clause for pagination
order by filtered_comments.comment_id asc limit (select page_size from processed_ui_filter_values) offset (select page_size*(page_no -1) from processed_ui_filter_values);
$$
LANGUAGE SQL;
76 changes: 76 additions & 0 deletions pepys_import/database/stored_procedures/Contacts_for.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,76 @@
--DROPING EXISTING PEPYS.CONTACTS_FOR FUNCTION
DROP FUNCTION IF EXISTS PEPYS.CONTACTS_FOR;

--CREATING PEPYS.CONTACTS_FOR FUNCTION
CREATE FUNCTION PEPYS.CONTACTS_FOR(
INP_START_TIME TEXT,
INP_END_TIME TEXT,
INP_LOCATION TEXT,
INP_SENSOR_ID TEXT[],
INP_SOURCE_ID TEXT[],
INP_PLATFORM_ID TEXT[],
INP_PAGE_NO INTEGER DEFAULT 1,
INP_PAGE_SIZE INTEGER DEFAULT 100)
RETURNS TABLE (
contact_id UUID,
contact_time TIMESTAMP WITHOUT TIME ZONE,
sensor_name varchar(150),
platform_name varchar(150),
platformtype_name varchar(150),
nationality_name varchar(150),
bearing double precision,
range double precision,
contact_location public.geometry(Point,4326))
AS
$$
--Name: Contacts_For
--Version: v0.15
with
ui_filter_input as
(select
inp_start_time start_time, --Input should be same as for Phase 1
inp_end_time end_time, --Input should be same as for Phase 1
inp_location "location", --Input should be same as for Phase 1
inp_sensor_id::text[] sensor_id, --Input from Phase 2 of import, can be set as null: null as sensor_id
inp_source_id::text[] source_id, --Input from Phase 2 of import, can be set as null: null as source_id
inp_platform_id::text[] platform_id, --Input from Phase 2 of import, can be set as null: null as platform_id
--null as platform_id, --Example on how to provide null
inp_page_no page_no, --Pagination input. Page No For ex. if there are 1000 records paginated into pages of 100 records each, 1 here will return the first page or first 100 records
inp_page_size page_size --Pagination input - No. of records per page
),
processed_ui_filter_values as
(select
case when (trim(ui_input.start_time)='' OR ui_input.start_time is null) then '1000-01-01 00:00:00.000000'::timestamp else to_timestamp(ui_input.start_time, 'YYYY-MM-DD HH24:MI:SS.US') end as start_time,
case when (trim(ui_input.end_time)='' OR ui_input.end_time is null) then '9999-12-12 23:59:59.000000'::timestamp else to_timestamp(ui_input.end_time, 'YYYY-MM-DD HH24:MI:SS.US') end as end_time,
case when (trim(ui_input.location)='' OR ui_input.location is null) then null else ST_GeomFromText(ui_input.location) end as location,
case when (coalesce(array_length(ui_input.sensor_id,1),0)::int = 0) then null else ui_input.sensor_id end as sensor_id,
case when (coalesce(array_length(ui_input.source_id,1),0)::int = 0) then null else ui_input.source_id end as source_id,
case when (coalesce(array_length(ui_input.platform_id,1),0)::int = 0) then null else ui_input.platform_id end as platform_id,
case when (ui_input.page_no is null OR ui_input.page_no <=0) then 1 else ui_input.page_no end as page_no,
case when (ui_input.page_size is null OR ui_input.page_size <=0) then 100 else ui_input.page_size end as page_size
from
ui_filter_input as ui_input
)
select filtered_contacts.contact_id, filtered_contacts.time, Sensors.name, Platforms.name,
PlatformTypes.name, Nationalities.name,
filtered_contacts.bearing, filtered_contacts.range, filtered_contacts.location from
pepys."Contacts" as filtered_contacts inner join
pepys."Sensors" as Sensors on filtered_contacts.sensor_id = Sensors.sensor_id inner join
pepys."Platforms" as Platforms on Sensors.host=Platforms.platform_id inner join
pepys."PlatformTypes" as PlatformTypes on Platforms.platform_type_id = PlatformTypes.platform_type_id inner join
pepys."Nationalities" as Nationalities on Platforms.nationality_id = Nationalities.nationality_id
WHERE
--Start and End Time criteria from the UI
tsrange((select start_time::timestamp from processed_ui_filter_values), (select end_time::timestamp from processed_ui_filter_values), '[]') @> filtered_contacts.time AND
--Spatial criteria from the UI
((select location from processed_ui_filter_values) is null OR ST_Contains((select location from processed_ui_filter_values),filtered_contacts.location)) AND
--Sensor criteria from the UI
((select sensor_id from processed_ui_filter_values) is null OR filtered_contacts.sensor_id in (select unnest(sensor_id::uuid[]) from processed_ui_filter_values)) AND
--Source criteria from the UI
((select source_id from processed_ui_filter_values) is null OR filtered_contacts.source_id in (select unnest(source_id::uuid[]) from processed_ui_filter_values)) AND
--Platform criteria from the UI
((select platform_id from processed_ui_filter_values) is null OR Platforms.platform_id in (select unnest(platform_id::uuid[]) from processed_ui_filter_values))
--Sort clause for pagination
order by filtered_contacts.contact_id asc limit (select page_size from processed_ui_filter_values) offset (select page_size*(page_no -1) from processed_ui_filter_values);
$$
LANGUAGE SQL;
124 changes: 124 additions & 0 deletions pepys_import/database/stored_procedures/Datafiles_for.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,124 @@
--DROPING EXISTING PEPYS.DATAFILES_FOR FUNCTION
DROP FUNCTION IF EXISTS PEPYS.DATAFILES_FOR;

--CREATING PEPYS.DATAFILES_FOR FUNCTION
CREATE FUNCTION PEPYS.DATAFILES_FOR(
INP_START_TIME TEXT,
INP_END_TIME TEXT,
INP_LOCATION TEXT,
INP_DATA_TYPES TEXT[],
INP_COMMENT_SEARCH_STRING TEXT)
RETURNS TABLE (
PLATFORM_NAME varchar(150),
PLATFORM_ID UUID,
DATATYPE text,
SENSOR_NAME varchar(150),
SENSOR_ID UUID,
REFERENCE varchar(150),
DATAFILE_ID UUID,
AGG_COUNT BIGINT)
AS
$$
--Name: Datafiles_For
--Version: v0.15
with
ui_filter_input as
(select
INP_START_TIME START_TIME,
INP_END_TIME END_TIME,
INP_LOCATION "location",
INP_DATA_TYPES::text[] DATA_TYPES,
INP_COMMENT_SEARCH_STRING COMMENT_SEARCH_STRING
),
processed_ui_filter_values as
(select
case when (trim(ui_input.start_time)='' OR ui_input.start_time is null) then '1000-01-01 00:00:00.000000'::timestamp else to_timestamp(ui_input.start_time, 'YYYY-MM-DD HH24:MI:SS.US') end as start_time,
case when (trim(ui_input.end_time)='' OR ui_input.end_time is null) then '9999-12-12 23:59:59.000000'::timestamp else to_timestamp(ui_input.end_time, 'YYYY-MM-DD HH24:MI:SS.US') end as end_time,
case when (trim(ui_input.location)='' OR ui_input.location is null) then null else ST_GeomFromText(ui_input.location) end as location,
case when (coalesce(array_length(ui_input.data_types,1),0)::int = 0) then string_to_array('NO_DATA_TYPE_SELECTED',',') else ui_input.data_types end as data_types,
case when (trim(ui_input.comment_search_string)='' OR ui_input.comment_search_string is null) then null::varchar else '%'||upper(ui_input.comment_search_string)||'%' end as comment_search_string
from
ui_filter_input as ui_input
),
state_aggregation_data as
(select
States.sensor_id, States.source_id, count(1) as state_agg_count
from pepys."States" as States
WHERE
--Data Type criteria from the UI
array_position((select data_types from processed_ui_filter_values),'STATES') > 0 AND
--Start and End Time criteria from the UI
tsrange((select start_time::timestamp from processed_ui_filter_values), (select end_time::timestamp from processed_ui_filter_values), '[]') @> States.time AND
--Spatial criteria from the UI
((select location from processed_ui_filter_values) is null OR ST_Contains((select location from processed_ui_filter_values),States.location))
group by States.sensor_id, States.source_id
),
state_measurement_data AS
(SELECT
Platforms.name as "PLATFORM_NAME", Platforms.platform_id, 'STATES' AS datatype, Sensors.name as "SENSOR_NAME", Sensors.sensor_id, Datafiles.reference, Datafiles.datafile_id, sad.state_agg_count
from
state_aggregation_data as sad inner join
pepys."Sensors" as Sensors on Sensors.sensor_id = sad.sensor_id inner join
pepys."Platforms" as Platforms on Platforms.platform_id=Sensors.host INNER JOIN
pepys."Datafiles" AS Datafiles on Datafiles.datafile_id=sad.source_id
),
contact_aggregation_data as
(select
Contacts.sensor_id, Contacts.source_id, count(1) as contact_agg_count
from pepys."Contacts" as Contacts
WHERE
--Data Type criteria from the UI
array_position((select data_types from processed_ui_filter_values),'CONTACTS') > 0 AND
--Start and End Time criteria from the UI
tsrange((select start_time::timestamp from processed_ui_filter_values), (select end_time::timestamp from processed_ui_filter_values), '[]') @> Contacts.time AND
--Spatial criteria from the UI
((select location from processed_ui_filter_values) is null OR ST_Contains((select location from processed_ui_filter_values),Contacts.location))
group by Contacts.sensor_id, Contacts.source_id
),
contact_measurement_data AS
(SELECT
Platforms.name as "PLATFORM_NAME", Platforms.platform_id, 'CONTACTS' AS datatype, Sensors.name as "SENSOR_NAME", Sensors.sensor_id, Datafiles.reference, Datafiles.datafile_id, cad.contact_agg_count
from
contact_aggregation_data as cad inner join
pepys."Sensors" as Sensors on Sensors.sensor_id = cad.sensor_id inner join
pepys."Platforms" as Platforms on Platforms.platform_id=Sensors.host INNER JOIN
pepys."Datafiles" AS Datafiles on Datafiles.datafile_id=cad.source_id
),
comment_aggregation_data as
(select
Comments.platform_id, Comments.source_id, count(1) as comment_agg_count
from pepys."Comments" as Comments
WHERE
--Data Type criteria from the UI
array_position((select data_types from processed_ui_filter_values),'COMMENTS') > 0 AND
--Start and End Time criteria from the UI
tsrange((select start_time::timestamp from processed_ui_filter_values), (select end_time::timestamp from processed_ui_filter_values), '[]') @> Comments.time AND
--Comment search criteria from the UI
((select comment_search_string from processed_ui_filter_values) is null OR upper(Comments.content) like (select comment_search_string from processed_ui_filter_values))
group by Comments.platform_id, Comments.source_id
),
comment_measurement_data AS
(SELECT
Platforms.name as "PLATFORM_NAME", Platforms.platform_id, 'COMMENTS' AS datatype, null as "SENSOR_NAME", null::uuid, Datafiles.reference, Datafiles.datafile_id, cad.comment_agg_count
from
comment_aggregation_data as cad inner join
pepys."Platforms" as Platforms on Platforms.platform_id=cad.platform_id INNER JOIN
pepys."Datafiles" AS Datafiles on Datafiles.datafile_id=cad.source_id
),
consolidated_measurement_data as
(
select * from state_measurement_data
union all
select * from contact_measurement_data
union all
select * from comment_measurement_data
)
SELECT * FROM consolidated_measurement_data cmd
--Sorting based on Platform Name, Data Type, Sensor Name, and Datafile Reference
order by
cmd."PLATFORM_NAME" ASC,
cmd.datatype ASC,
cmd."SENSOR_NAME" ASC,
cmd.reference ASC;
$$
LANGUAGE SQL;
78 changes: 78 additions & 0 deletions pepys_import/database/stored_procedures/States_for.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,78 @@
--DROPING EXISTING PEPYS.STATES_FOR FUNCTION
DROP FUNCTION IF EXISTS PEPYS.STATES_FOR;

--CREATING PEPYS.STATES_FOR FUNCTION
CREATE FUNCTION PEPYS.STATES_FOR(
INP_START_TIME TEXT,
INP_END_TIME TEXT,
INP_LOCATION TEXT,
INP_SENSOR_ID TEXT[],
INP_SOURCE_ID TEXT[],
INP_PLATFORM_ID TEXT[],
INP_PAGE_NO INTEGER DEFAULT 1,
INP_PAGE_SIZE INTEGER DEFAULT 100)
RETURNS TABLE (
state_id UUID,
state_time TIMESTAMP WITHOUT TIME ZONE,
sensor_name varchar(150),
platform_name varchar(150),
platformtype_name varchar(150),
nationality_name varchar(150),
state_location public.geometry(Point,4326),
elevation double precision,
heading double precision,
course double precision,
speed double precision)
AS
$$
--Name: States_For
--Version: v0.15
with
ui_filter_input as
(select
inp_start_time start_time, --Input should be same as for Phase 1
inp_end_time end_time, --Input should be same as for Phase 1
inp_location "location", --Input should be same as for Phase 1
inp_sensor_id::text[] sensor_id, --Input from Phase 2 of import, can be set as null: null as sensor_id
inp_source_id::text[] source_id, --Input from Phase 2 of import, can be set as null: null as source_id
inp_platform_id::text[] platform_id, --Input from Phase 2 of import, can be set as null: null as platform_id
--null as platform_id, --Example on how to provide null
inp_page_no page_no, --Pagination input. Page No For ex. if there are 1000 records paginated into pages of 100 records each, 1 here will return the first page or first 100 records
inp_page_size page_size --Pagination input - No. of records per page
),
processed_ui_filter_values as
(select
case when (trim(ui_input.start_time)='' OR ui_input.start_time is null) then '1000-01-01 00:00:00.000000'::timestamp else to_timestamp(ui_input.start_time, 'YYYY-MM-DD HH24:MI:SS.US') end as start_time,
case when (trim(ui_input.end_time)='' OR ui_input.end_time is null) then '9999-12-12 23:59:59.000000'::timestamp else to_timestamp(ui_input.end_time, 'YYYY-MM-DD HH24:MI:SS.US') end as end_time,
case when (trim(ui_input.location)='' OR ui_input.location is null) then null else ST_GeomFromText(ui_input.location) end as location,
case when (coalesce(array_length(ui_input.sensor_id,1),0)::int = 0) then null else ui_input.sensor_id end as sensor_id,
case when (coalesce(array_length(ui_input.source_id,1),0)::int = 0) then null else ui_input.source_id end as source_id,
case when (coalesce(array_length(ui_input.platform_id,1),0)::int = 0) then null else ui_input.platform_id end as platform_id,
case when (ui_input.page_no is null OR ui_input.page_no <=0) then 1 else ui_input.page_no end as page_no,
case when (ui_input.page_size is null OR ui_input.page_size <=0) then 100 else ui_input.page_size end as page_size
from
ui_filter_input as ui_input
)
select filtered_states.state_id, filtered_states.time, Sensors.name, Platforms.name,
PlatformTypes.name, Nationalities.name,
filtered_states.location, filtered_states.elevation, filtered_states.heading, filtered_states.course, filtered_states.speed from
pepys."States" as filtered_states inner join
pepys."Sensors" as Sensors on filtered_states.sensor_id = Sensors.sensor_id inner join
pepys."Platforms" as Platforms on Sensors.host=Platforms.platform_id inner join
pepys."PlatformTypes" as PlatformTypes on Platforms.platform_type_id = PlatformTypes.platform_type_id inner join
pepys."Nationalities" as Nationalities on Platforms.nationality_id = Nationalities.nationality_id
WHERE
--Start and End Time criteria from the UI
tsrange((select start_time::timestamp from processed_ui_filter_values), (select end_time::timestamp from processed_ui_filter_values), '[]') @> filtered_states.time AND
--Spatial criteria from the UI
((select location from processed_ui_filter_values) is null OR ST_Contains((select location from processed_ui_filter_values),filtered_states.location)) AND
--Sensor criteria from the UI
((select sensor_id from processed_ui_filter_values) is null OR filtered_states.sensor_id in (select unnest(sensor_id::uuid[]) from processed_ui_filter_values)) AND
--Source criteria from the UI
((select source_id from processed_ui_filter_values) is null OR filtered_states.source_id in (select unnest(source_id::uuid[]) from processed_ui_filter_values)) AND
--Platform criteria from the UI
((select platform_id from processed_ui_filter_values) is null OR Sensors.host in (select unnest(platform_id::uuid[]) from processed_ui_filter_values))
--Sort clause for pagination
order by filtered_states.state_id asc limit (select page_size from processed_ui_filter_values) offset (select page_size*(page_no -1) from processed_ui_filter_values);
$$
LANGUAGE SQL;

0 comments on commit 7491910

Please sign in to comment.