Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

Résolution de plusieurs petits bugs sur les préavis #3562

Merged
merged 3 commits into from
Aug 21, 2024
Merged
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
Original file line number Diff line number Diff line change
Expand Up @@ -117,6 +117,19 @@ interface DBLogbookReportRepository :
AND (:tripSegmentCodesAsSqlArrayString IS NULL OR trip_segment_codes && CAST(:tripSegmentCodesAsSqlArrayString AS TEXT[]))
),

acknowledged_report_ids AS (
SELECT DISTINCT referenced_report_id
FROM logbook_reports lr
WHERE
-- This filter helps Timescale optimize the query since `operation_datetime_utc` is indexed
lr.operation_datetime_utc
BETWEEN CAST(:willArriveAfter AS TIMESTAMP) - INTERVAL '48 hours'
AND CAST(:willArriveBefore AS TIMESTAMP) + INTERVAL '48 hours'

AND lr.operation_type = 'RET'
AND lr.value->>'returnStatus' = '000'
),

del_pno_logbook_reports AS (
SELECT
lr.*,
Expand All @@ -134,19 +147,10 @@ interface DBLogbookReportRepository :
AND CAST(:willArriveBefore AS TIMESTAMP) + INTERVAL '48 hours'

AND lr.operation_type = 'DEL'
),

acknowledged_report_ids AS (
SELECT DISTINCT referenced_report_id
FROM logbook_reports lr
WHERE
-- This filter helps Timescale optimize the query since `operation_datetime_utc` is indexed
lr.operation_datetime_utc
BETWEEN CAST(:willArriveAfter AS TIMESTAMP) - INTERVAL '48 hours'
AND CAST(:willArriveBefore AS TIMESTAMP) + INTERVAL '48 hours'

AND lr.operation_type = 'RET'
AND lr.value->>'returnStatus' = '000'
AND (
lr.operation_number IN (SELECT referenced_report_id FROM acknowledged_report_ids)
OR fdacplr.flag_state NOT IN ('FRA', 'GUF', 'VEN') -- flag_states for which we received RET messages
)
)

SELECT *
Expand All @@ -159,9 +163,6 @@ interface DBLogbookReportRepository :

SELECT *
FROM del_pno_logbook_reports
WHERE
operation_number IN (SELECT referenced_report_id FROM acknowledged_report_ids)
OR flag_state NOT IN ('FRA', 'GUF', 'VEN') -- flag_states for which we received RET messages
""",
nativeQuery = true,
)
Expand Down
30 changes: 21 additions & 9 deletions datascience/src/pipeline/queries/monitorfish/pnos_to_generate.sql
Original file line number Diff line number Diff line change
@@ -1,5 +1,7 @@
WITH deleted_messages AS (
SELECT referenced_report_id
SELECT
operation_number,
referenced_report_id
FROM logbook_reports
WHERE
operation_datetime_utc >= :start_datetime_utc - INTERVAL '4 hours'
Expand All @@ -15,9 +17,16 @@ acknowledged_messages AS (
AND operation_datetime_utc < :end_datetime_utc + INTERVAL '8 hours'
AND operation_type ='RET'
AND value->>'returnStatus' = '000'
),

acknowledged_deleted_messages AS (
SELECT referenced_report_id
FROM deleted_messages
WHERE
operation_number IN (SELECT referenced_report_id FROM acknowledged_messages)
)

(SELECT
(SELECT DISTINCT ON (r.report_id) -- In rare cases the same PNO with the same data and the same report_id is sent multiple times in messages with different operation numbers
r.id,
r.operation_datetime_utc,
r.report_id,
Expand Down Expand Up @@ -65,20 +74,23 @@ WHERE
(value->>'isBeingSent')::BOOLEAN IS true
OR report_id NOT IN (SELECT report_id FROM prior_notification_pdf_documents)
)
AND report_id NOT IN (SELECT referenced_report_id FROM deleted_messages)
AND NOT (
report_id IN (SELECT referenced_report_id FROM acknowledged_deleted_messages)
OR (
report_id IN (SELECT referenced_report_id FROM deleted_messages)
AND r.flag_state NOT IN ('FRA', 'GUF', 'VEN')
)
)
AND (
transmission_format = 'FLUX'
r.flag_state NOT IN ('FRA', 'GUF', 'VEN') -- Flag states for which we receive RET
OR report_id IN (SELECT referenced_report_id FROM acknowledged_messages)
OR (value->>'isVerified')::BOOLEAN IS true
OR (
transmission_format = 'ERS'
AND report_id IN (SELECT referenced_report_id FROM acknowledged_messages)
)
)
AND (
(value->>'isInvalidated') IS NULL
OR (value->>'isInvalidated')::BOOLEAN IS false
)
ORDER BY id)
ORDER BY report_id)

UNION ALL

Expand Down
Loading