-
Notifications
You must be signed in to change notification settings - Fork 21
[O2B-1365] Implement GAQ periods views #1808
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
Merged
Merged
Changes from all commits
Commits
Show all changes
59 commits
Select commit
Hold shift + click to select a range
03ca36e
use tf_timestamps
xsalonx 2436041
use miliseconds
xsalonx 06268f2
remove names
xsalonx d6e7fcb
use views
xsalonx 1658d1d
fix tests, preserve previous functionalties
xsalonx 068d48c
fix
xsalonx 4ee19e7
fix test
xsalonx 10be130
fix test
xsalonx a7a7b54
fix test
xsalonx 1ee8bab
fix seeders
xsalonx e152c6e
Merge branch 'main' into xsalonx/gaq/O2B-1365/just-gaq-views
xsalonx 3fb54a5
use timeframe timestamps
xsalonx e34e920
Merge branch 'tmp' into xsalonx/gaq/O2B-1365/just-gaq-views
xsalonx db84fcc
ref
xsalonx 5f900f8
Merge branch 'main' into xsalonx/gaq/O2B-1365/just-gaq-views
xsalonx 4199b3f
cleanup
xsalonx 53f093a
a
xsalonx 9de457c
cleanup; fix
xsalonx dc33aa6
a
xsalonx 86cb1fc
use correct field
xsalonx b56bc51
Merge branch 'main' into xsalonx/gaq/O2B-1365/just-gaq-views
martinboulais 4a9ea38
Update lib/database/migrations/20241127123000-create-gaq-views.js
xsalonx ccc1e9f
merge WIP
xsalonx b947915
WIP
xsalonx 0843796
WIP
xsalonx 85a99d3
use significance aggregate functions for gaq calculation
xsalonx 104bf3b
Merge branch 'main' into xsalonx/gaq/O2B-1365/just-gaq-views
xsalonx c7646f9
cleanup
xsalonx 9d82581
count periods of undefined quality
xsalonx d65a014
add QC and GAQ summaries typdefs
xsalonx ebe79c1
cleanup, test disable
xsalonx 95b6235
fix view name
xsalonx 2e33ad9
revert test changes
xsalonx 36a7615
cleanup
xsalonx 4868232
add diaply for debugging
xsalonx 9f7b448
fix sql queries
xsalonx cd11cfd
fixes
xsalonx df09904
try to fix test
xsalonx d544933
Merge branch 'x' into xsalonx/gaq/O2B-1365/just-gaq-views
xsalonx e66a585
fix
xsalonx 8b94ca3
fix
xsalonx 7c2e0d1
Revert "try to fix test"
xsalonx 4ad018e
Merge branch 'main' into xsalonx/gaq/O2B-1365/just-gaq-views
xsalonx 08cbbda
cleanup
xsalonx 686d09e
rename enum
xsalonx 009e635
move enum
xsalonx 71090a6
cleanup
xsalonx 93acd3f
fix
xsalonx df62090
Merge branch 'main' into xsalonx/gaq/O2B-1365/just-gaq-views
xsalonx b3c7e02
temporarly skipsome tests
xsalonx 2b0a0d3
cleanup
xsalonx 0379fd5
simplify
xsalonx e572efb
Merge branch 'main' into xsalonx/gaq/O2B-1365/just-gaq-views
xsalonx d0e4393
Merge branch 'main' of github.com:AliceO2Group/Bookkeeping into xsalo…
graduta f9889f6
Fix lint
graduta 810f663
remove unnecessary test skips
xsalonx d11eafc
rename
xsalonx d722819
linter
xsalonx 7f51328
Merge branch 'main' into xsalonx/gaq/O2B-1365/just-gaq-views
xsalonx File filter
Filter by extension
Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
There are no files selected for viewing
168 changes: 168 additions & 0 deletions
168
lib/database/migrations/v1/20250518123000-create-gaq-views.js
This file contains hidden or bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
| Original file line number | Diff line number | Diff line change |
|---|---|---|
| @@ -0,0 +1,168 @@ | ||
| 'use strict'; | ||
|
|
||
| const SELECT_RUNS_START_TIMESTAMPS_FOR_GAQ_PERIODS = ` | ||
| SELECT | ||
| gaqd.data_pass_id, | ||
| gaqd.run_number, | ||
| r.qc_time_start AS timestamp, | ||
| COALESCE(r.qc_time_start, '0001-01-01 00:00:00.000') AS ordering_timestamp, | ||
| r.qc_time_start AS qc_run_start, | ||
| r.qc_time_end AS qc_run_end | ||
| FROM global_aggregated_quality_detectors AS gaqd | ||
| INNER JOIN runs as r ON gaqd.run_number = r.run_number | ||
| INNER JOIN quality_control_flags AS qcf ON qcf.run_number = r.run_number | ||
| INNER JOIN data_pass_quality_control_flag AS dpqcf | ||
| ON dpqcf.quality_control_flag_id = qcf.id AND dpqcf.data_pass_id = gaqd.data_pass_id | ||
| `; | ||
|
|
||
| const SELECT_RUNS_END_TIMESTAMPS_FOR_GAQ_PERIODS = ` | ||
| SELECT | ||
| gaqd.data_pass_id, | ||
| gaqd.run_number, | ||
| r.qc_time_end AS timestamp, | ||
| COALESCE(r.qc_time_end, NOW(3)) AS ordering_timestamp, | ||
| r.qc_time_start AS qc_run_start, | ||
| r.qc_time_end AS qc_run_end | ||
| FROM global_aggregated_quality_detectors AS gaqd | ||
| INNER JOIN runs as r ON gaqd.run_number = r.run_number | ||
| INNER JOIN quality_control_flags AS qcf ON qcf.run_number = r.run_number | ||
| INNER JOIN data_pass_quality_control_flag AS dpqcf | ||
| ON dpqcf.quality_control_flag_id = qcf.id AND dpqcf.data_pass_id = gaqd.data_pass_id | ||
| `; | ||
|
|
||
| const SELECT_QCF_EFFECTIVE_PERIODS_START_TIMESTAMPS_FOR_GAQ_PERIODS = ` | ||
| SELECT gaqd.data_pass_id, | ||
| gaqd.run_number, | ||
| COALESCE(qcfep.\`from\`, r.qc_time_start) AS timestamp, | ||
| COALESCE(qcfep.\`from\`, r.qc_time_start, '0001-01-01 00:00:00.000') AS ordering_timestamp, | ||
| r.qc_time_start AS qc_run_start, | ||
| r.qc_time_end AS qc_run_end | ||
| FROM quality_control_flag_effective_periods AS qcfep | ||
| INNER JOIN quality_control_flags AS qcf ON qcf.id = qcfep.flag_id | ||
| INNER JOIN runs AS r ON qcf.run_number = r.run_number | ||
| INNER JOIN data_pass_quality_control_flag AS dpqcf ON dpqcf.quality_control_flag_id = qcf.id | ||
| -- Only flags of detectors which are defined in global_aggregated_quality_detectors | ||
| -- should be taken into account for calculation of gaq_effective_periods | ||
| INNER JOIN global_aggregated_quality_detectors AS gaqd | ||
| ON gaqd.data_pass_id = dpqcf.data_pass_id | ||
| AND gaqd.run_number = qcf.run_number | ||
| AND gaqd.detector_id = qcf.detector_id | ||
| `; | ||
|
|
||
| const SELECT_QCF_EFFECTIVE_PERIODS_END_TIMESTAMPS_FOR_GAQ_PERIODS = ` | ||
| SELECT gaqd.data_pass_id, | ||
| gaqd.run_number, | ||
| COALESCE(qcfep.\`to\`, r.qc_time_end) AS timestamp, | ||
| COALESCE(qcfep.\`to\`, r.qc_time_end, NOW(3)) AS ordering_timestamp, | ||
| r.qc_time_start AS qc_run_start, | ||
| r.qc_time_end AS qc_run_end | ||
| FROM quality_control_flag_effective_periods AS qcfep | ||
| INNER JOIN quality_control_flags AS qcf ON qcf.id = qcfep.flag_id | ||
| INNER JOIN runs AS r ON qcf.run_number = r.run_number | ||
| INNER JOIN data_pass_quality_control_flag AS dpqcf ON dpqcf.quality_control_flag_id = qcf.id | ||
| -- Only flags of detectors which are defined in global_aggregated_quality_detectors | ||
| -- should be taken into account for calculation of gaq_effective_periods | ||
| INNER JOIN global_aggregated_quality_detectors AS gaqd | ||
| ON gaqd.data_pass_id = dpqcf.data_pass_id | ||
| AND gaqd.run_number = qcf.run_number | ||
| AND gaqd.detector_id = qcf.detector_id | ||
| `; | ||
|
|
||
| const CREATE_GAQ_PERIODS_VIEW = ` | ||
| CREATE OR REPLACE VIEW gaq_periods AS | ||
| SELECT | ||
| data_pass_id, | ||
| run_number, | ||
| \`from\`, | ||
| \`to\`, | ||
| from_ordering_timestamp, | ||
| (UNIX_TIMESTAMP(\`to\`) - UNIX_TIMESTAMP(\`from\`)) / (UNIX_TIMESTAMP(qc_run_end) - UNIX_TIMESTAMP(qc_run_start)) AS coverage_ratio | ||
| FROM ( | ||
| SELECT | ||
| data_pass_id, | ||
| run_number, | ||
| LAG(timestamp) OVER w AS \`from\`, | ||
| timestamp AS \`to\`, | ||
| LAG(ordering_timestamp) OVER w AS from_ordering_timestamp, | ||
| qc_run_start, | ||
| qc_run_end | ||
| FROM ( | ||
| -- Two selects for runs' timestamps (in case QC flag's eff. period doesn't start at run's start or end at run's end ) | ||
| ( ${SELECT_RUNS_START_TIMESTAMPS_FOR_GAQ_PERIODS} ) | ||
| UNION | ||
| ( ${SELECT_RUNS_END_TIMESTAMPS_FOR_GAQ_PERIODS} ) | ||
| UNION | ||
| -- Two selects for timestamps of QC flags' effective periods | ||
| ( ${SELECT_QCF_EFFECTIVE_PERIODS_START_TIMESTAMPS_FOR_GAQ_PERIODS} ) | ||
| UNION | ||
| ( ${SELECT_QCF_EFFECTIVE_PERIODS_END_TIMESTAMPS_FOR_GAQ_PERIODS} ) | ||
|
|
||
| ORDER BY ordering_timestamp | ||
| ) AS ap | ||
| WINDOW w AS ( | ||
| PARTITION BY data_pass_id, | ||
| run_number | ||
| ORDER BY ap.ordering_timestamp | ||
| ) | ||
| ) as gaq_periods_with_last_nullish_row | ||
| WHERE gaq_periods_with_last_nullish_row.from_ordering_timestamp IS NOT NULL | ||
| `; | ||
|
|
||
| const DROP_GAQ_PERIODS_VIEW = 'DROP VIEW gaq_periods'; | ||
|
|
||
| const CREATE_QC_FLAG_BLOCK_SIGNIFCANCE_AGGREGATE_FUNCTION = ` | ||
| CREATE OR REPLACE AGGREGATE FUNCTION qc_flag_block_significance( | ||
| row_bad TINYINT(1), | ||
| row_mc_reproducible TINYINT(1) | ||
| ) RETURNS ENUM ('bad', 'mcr', 'good') | ||
| BEGIN | ||
| DECLARE mc_reproducible TINYINT(1) DEFAULT 0; | ||
| DECLARE bad TINYINT(1) DEFAULT 0; | ||
| DECLARE CONTINUE HANDLER FOR NOT FOUND RETURN IF(bad, 'bad', IF(mc_reproducible, 'mcr', 'good')); | ||
| LOOP | ||
| FETCH group NEXT ROW; | ||
| IF row_mc_reproducible THEN | ||
| SET mc_reproducible = 1; | ||
| ELSEIF row_bad THEN | ||
| SET bad = 1; | ||
| END IF; | ||
| END LOOP; | ||
| END | ||
| `; | ||
|
|
||
| const DROP_QC_FLAG_BLOCK_SIGNIFCANCE_AGGREGATE_FUNCTION = 'DROP FUNCTION qc_flag_block_significance'; | ||
|
|
||
| const CREATE_QC_FLAG_BLOCK_SIGNIFCANCE_COVERAGE_AGGREGATE_FUNCTION = ` | ||
| CREATE OR REPLACE AGGREGATE FUNCTION qc_flag_block_significance_coverage( | ||
| row_significance ENUM ('bad', 'mcr', 'good'), -- The significance of the row | ||
| coverage_ratio FLOAT, -- The coverage ratio of the row | ||
| significance ENUM ('bad', 'mcr', 'good') -- The significance to aggregate over | ||
| ) RETURNS FLOAT | ||
| BEGIN | ||
| DECLARE coverage FLOAT DEFAULT 0; | ||
| DECLARE CONTINUE HANDLER FOR NOT FOUND RETURN coverage; | ||
| LOOP | ||
| FETCH group NEXT ROW; | ||
| IF row_significance = significance THEN | ||
| SET coverage = coverage + coverage_ratio; | ||
| END IF; | ||
| END LOOP; | ||
| END | ||
| `; | ||
|
|
||
| const DROP_QC_FLAG_BLOCK_SIGNIFCANCE_COVERAGE_AGGREGATE_FUNCTION = 'DROP FUNCTION qc_flag_block_significance_coverage'; | ||
|
|
||
| /** @type {import('sequelize-cli').Migration} */ | ||
| module.exports = { | ||
| up: async (queryInterface) => queryInterface.sequelize.transaction(async (transaction) => { | ||
| await queryInterface.sequelize.query(CREATE_GAQ_PERIODS_VIEW, { transaction }); | ||
| await queryInterface.sequelize.query(CREATE_QC_FLAG_BLOCK_SIGNIFCANCE_AGGREGATE_FUNCTION, { transaction }); | ||
| await queryInterface.sequelize.query(CREATE_QC_FLAG_BLOCK_SIGNIFCANCE_COVERAGE_AGGREGATE_FUNCTION, { transaction }); | ||
| }), | ||
|
|
||
| down: async (queryInterface) => queryInterface.sequelize.transaction(async (transaction) => { | ||
| await queryInterface.sequelize.query(DROP_GAQ_PERIODS_VIEW, { transaction }); | ||
| await queryInterface.sequelize.query(DROP_QC_FLAG_BLOCK_SIGNIFCANCE_AGGREGATE_FUNCTION, { transaction }); | ||
| await queryInterface.sequelize.query(DROP_QC_FLAG_BLOCK_SIGNIFCANCE_COVERAGE_AGGREGATE_FUNCTION, { transaction }); | ||
| }), | ||
| }; | ||
Oops, something went wrong.
Add this suggestion to a batch that can be applied as a single commit.
This suggestion is invalid because no changes were made to the code.
Suggestions cannot be applied while the pull request is closed.
Suggestions cannot be applied while viewing a subset of changes.
Only one suggestion per line can be applied in a batch.
Add this suggestion to a batch that can be applied as a single commit.
Applying suggestions on deleted lines is not supported.
You must change the existing code in this line in order to create a valid suggestion.
Outdated suggestions cannot be applied.
This suggestion has been applied or marked resolved.
Suggestions cannot be applied from pending reviews.
Suggestions cannot be applied on multi-line comments.
Suggestions cannot be applied while the pull request is queued to merge.
Suggestion cannot be applied right now. Please check back later.
Uh oh!
There was an error while loading. Please reload this page.