Commit c57ebbb3 authored by Leo Gordon's avatar Leo Gordon
Browse files

schema_change: improved[mysql]/added[pgsql] time_analysis() stored procedure,...

schema_change: improved[mysql]/added[pgsql] time_analysis() stored procedure, taking into account running roles
parent 31f0dec8
-- ---------------------------------------------------------------------------------------------------
-- improved time_analysis() function for timing individual analyses or groups (takes into account running roles)
-- ---------------------------------------------------------------------------------------------------
SET @expected_version = 67;
-- make MySQL stop immediately after it encounters division by zero:
SET SESSION sql_mode='TRADITIONAL';
-- warn that we detected the schema version mismatch:
SELECT CONCAT( 'The patch only applies to schema version ',
@expected_version,
', but the current schema version is ',
meta_value,
', so skipping the rest.') AS ''
FROM hive_meta WHERE meta_key='hive_sql_schema_version' AND meta_value<>@expected_version;
-- cause division by zero only if current version differs from the expected one:
INSERT INTO hive_meta (meta_key, meta_value)
SELECT 'this_should_never_be_inserted', 1 FROM hive_meta WHERE NOT 1/(meta_key<>'hive_sql_schema_version' OR meta_value=@expected_version);
SELECT CONCAT( 'The patch seems to be compatible with schema version ',
@expected_version,
', applying the patch...') AS '';
-- Now undo the change so that we could patch potentially non-TRADITIONAL schema:
SET SESSION sql_mode='';
-- ----------------------------------<actual_patch> -------------------------------------------------
DROP PROCEDURE IF EXISTS time_analysis;
CREATE PROCEDURE time_analysis(IN analyses_pattern CHAR(64))
READS SQL DATA
SELECT
COUNT(*)-COUNT(when_finished) AS still_running,
(UNIX_TIMESTAMP(CASE WHEN COUNT(*)>COUNT(when_finished) THEN CURRENT_TIMESTAMP ELSE max(when_finished) END) - UNIX_TIMESTAMP(min(when_started)))/60 AS measured_in_minutes,
(UNIX_TIMESTAMP(CASE WHEN COUNT(*)>COUNT(when_finished) THEN CURRENT_TIMESTAMP ELSE max(when_finished) END) - UNIX_TIMESTAMP(min(when_started)))/3600 AS measured_in_hours,
(UNIX_TIMESTAMP(CASE WHEN COUNT(*)>COUNT(when_finished) THEN CURRENT_TIMESTAMP ELSE max(when_finished) END) - UNIX_TIMESTAMP(min(when_started)))/3600/24 AS measured_in_days
FROM role JOIN analysis_base USING (analysis_id)
WHERE logic_name LIKE analyses_pattern;
-- ----------------------------------</actual_patch> -------------------------------------------------
-- increase the schema version by one:
UPDATE hive_meta SET meta_value=meta_value+1 WHERE meta_key='hive_sql_schema_version';
-- ---------------------------------------------------------------------------------------------------
-- added time_analysis() function for timing individual analyses or groups
-- ---------------------------------------------------------------------------------------------------
\set expected_version 67
\set ON_ERROR_STOP on
-- warn that we detected the schema version mismatch:
SELECT ('The patch only applies to schema version '
|| CAST(:expected_version AS VARCHAR)
|| ', but the current schema version is '
|| meta_value
|| ', so skipping the rest.') as incompatible_msg
FROM hive_meta WHERE meta_key='hive_sql_schema_version' AND meta_value!=CAST(:expected_version AS VARCHAR);
-- cause division by zero only if current version differs from the expected one:
INSERT INTO hive_meta (meta_key, meta_value)
SELECT 'this_should_never_be_inserted', 1 FROM hive_meta WHERE 1 != 1/CAST( (meta_key!='hive_sql_schema_version' OR meta_value=CAST(:expected_version AS VARCHAR)) AS INTEGER );
SELECT ('The patch seems to be compatible with schema version '
|| CAST(:expected_version AS VARCHAR)
|| ', applying the patch...') AS compatible_msg;
-- ----------------------------------<actual_patch> -------------------------------------------------
DROP FUNCTION IF EXISTS time_analysis(VARCHAR);
CREATE FUNCTION time_analysis(analyses_pattern VARCHAR,
OUT still_running BIGINT,
OUT measured_in_minutes DOUBLE PRECISION,
OUT measured_in_hours DOUBLE PRECISION,
OUT measured_in_days DOUBLE PRECISION)
AS $$
SELECT COUNT(*)-COUNT(when_finished),
EXTRACT(EPOCH FROM (CASE WHEN COUNT(*)>COUNT(when_finished) THEN CURRENT_TIMESTAMP ELSE max(when_finished) END) - min(when_started))/60,
EXTRACT(EPOCH FROM (CASE WHEN COUNT(*)>COUNT(when_finished) THEN CURRENT_TIMESTAMP ELSE max(when_finished) END) - min(when_started))/3600,
EXTRACT(EPOCH FROM (CASE WHEN COUNT(*)>COUNT(when_finished) THEN CURRENT_TIMESTAMP ELSE max(when_finished) END) - min(when_started))/3600/24
FROM role JOIN analysis_base USING (analysis_id)
WHERE logic_name like analyses_pattern;
$$ LANGUAGE SQL;
-- ----------------------------------</actual_patch> -------------------------------------------------
-- increase the schema version by one:
UPDATE hive_meta SET meta_value= (CAST(meta_value AS INTEGER) + 1) WHERE meta_key='hive_sql_schema_version';
-- ---------------------------------------------------------------------------------------------------
-- in the absence of stored procedures in SQLite this is just a No-op patch
-- ---------------------------------------------------------------------------------------------------
CREATE TEMPORARY VIEW exp_ver AS SELECT "67" AS expected_version;
.bail ON
SELECT ('The patch only applies to schema version '
|| expected_version
|| ', but the current schema version is '
|| meta_value
|| ', skipping the rest.') AS ''
FROM hive_meta JOIN exp_ver WHERE meta_key='hive_sql_schema_version' AND meta_value<>expected_version;
INSERT INTO hive_meta (meta_key, meta_value)
SELECT hm.* FROM hive_meta AS hm JOIN exp_ver WHERE meta_key='hive_sql_schema_version' AND meta_value<>expected_version;
SELECT ('The patch seems to be compatible with schema version '
|| expected_version
|| ', applying the patch...') AS '' FROM exp_ver;
-- ----------------------------------<actual_patch> -------------------------------------------------
-- ----------------------------------</actual_patch> -------------------------------------------------
-- increase the schema version by one:
UPDATE hive_meta SET meta_value=meta_value+1 WHERE meta_key='hive_sql_schema_version';
...@@ -85,23 +85,23 @@ CREATE OR REPLACE VIEW resource_usage_stats AS ...@@ -85,23 +85,23 @@ CREATE OR REPLACE VIEW resource_usage_stats AS
ORDER BY a.analysis_id, w.meadow_type, rc.resource_class_id, u.exit_status; ORDER BY a.analysis_id, w.meadow_type, rc.resource_class_id, u.exit_status;
#### time an analysis or group of analyses (given by a name pattern) ###################################### -- time an analysis or group of analyses (given by a name pattern) ----------------------------------------
# You'll get better precision when the analyses involved have been done or failed rather than still running. --
# -- Usage:
# Usage: -- call time_analysis('%'); # time the whole pipeline
# call time_analysis('%'); # time the whole pipeline -- call time_analysis('load_uniprot%'); # time the group of analyses dealing with loading Uniprot members
# call time_analysis('load_uniprot%'); # time the group of analyses dealing with loading Uniprot members -- call time_analysis('mcl'); # time one specific analysis
# call time_analysis('mcl'); # time one specific analysis
DROP PROCEDURE IF EXISTS time_analysis; DROP PROCEDURE IF EXISTS time_analysis;
CREATE PROCEDURE time_analysis(IN param_logic_name_pattern char(64)) CREATE PROCEDURE time_analysis(IN analyses_pattern CHAR(64))
READS SQL DATA READS SQL DATA
SELECT SELECT
(UNIX_TIMESTAMP(max(when_finished))-UNIX_TIMESTAMP(min(when_started)))/60 AS measured_in_minutes, COUNT(*)-COUNT(when_finished) AS still_running,
(UNIX_TIMESTAMP(max(when_finished))-UNIX_TIMESTAMP(min(when_started)))/3600 AS measured_in_hours, (UNIX_TIMESTAMP(CASE WHEN COUNT(*)>COUNT(when_finished) THEN CURRENT_TIMESTAMP ELSE max(when_finished) END) - UNIX_TIMESTAMP(min(when_started)))/60 AS measured_in_minutes,
(UNIX_TIMESTAMP(max(when_finished))-UNIX_TIMESTAMP(min(when_started)))/3600/24 AS measured_in_days (UNIX_TIMESTAMP(CASE WHEN COUNT(*)>COUNT(when_finished) THEN CURRENT_TIMESTAMP ELSE max(when_finished) END) - UNIX_TIMESTAMP(min(when_started)))/3600 AS measured_in_hours,
(UNIX_TIMESTAMP(CASE WHEN COUNT(*)>COUNT(when_finished) THEN CURRENT_TIMESTAMP ELSE max(when_finished) END) - UNIX_TIMESTAMP(min(when_started)))/3600/24 AS measured_in_days
FROM role JOIN analysis_base USING (analysis_id) FROM role JOIN analysis_base USING (analysis_id)
WHERE logic_name like param_logic_name_pattern; WHERE logic_name LIKE analyses_pattern;
#### searches for a given string in job.input_id or analysis_data.data, and returns the matching jobs. #### searches for a given string in job.input_id or analysis_data.data, and returns the matching jobs.
......
...@@ -84,3 +84,25 @@ CREATE OR REPLACE VIEW resource_usage_stats AS ...@@ -84,3 +84,25 @@ CREATE OR REPLACE VIEW resource_usage_stats AS
GROUP BY a.analysis_id, w.meadow_type, rc.resource_class_id, u.exit_status GROUP BY a.analysis_id, w.meadow_type, rc.resource_class_id, u.exit_status
ORDER BY a.analysis_id, w.meadow_type, rc.resource_class_id, u.exit_status; ORDER BY a.analysis_id, w.meadow_type, rc.resource_class_id, u.exit_status;
-- time an analysis or group of analyses (given by a name pattern) ----------------------------------------
--
-- Usage:
-- SELECT * FROM time_analysis('%');
-- SELECT * FROM time_analysis('alignment_chains%');
DROP FUNCTION IF EXISTS time_analysis(VARCHAR);
CREATE FUNCTION time_analysis(analyses_pattern VARCHAR,
OUT still_running BIGINT,
OUT measured_in_minutes DOUBLE PRECISION,
OUT measured_in_hours DOUBLE PRECISION,
OUT measured_in_days DOUBLE PRECISION)
AS $$
SELECT COUNT(*)-COUNT(when_finished),
EXTRACT(EPOCH FROM (CASE WHEN COUNT(*)>COUNT(when_finished) THEN CURRENT_TIMESTAMP ELSE max(when_finished) END) - min(when_started))/60,
EXTRACT(EPOCH FROM (CASE WHEN COUNT(*)>COUNT(when_finished) THEN CURRENT_TIMESTAMP ELSE max(when_finished) END) - min(when_started))/3600,
EXTRACT(EPOCH FROM (CASE WHEN COUNT(*)>COUNT(when_finished) THEN CURRENT_TIMESTAMP ELSE max(when_finished) END) - min(when_started))/3600/24
FROM role JOIN analysis_base USING (analysis_id)
WHERE logic_name like analyses_pattern;
$$ LANGUAGE SQL;
Markdown is supported
0% or .
You are about to add 0 people to the discussion. Proceed with caution.
Finish editing this message first!
Please register or to comment