Commit b802f69a authored by Matthieu Muffato's avatar Matthieu Muffato
Browse files

Extended the new view to all engines, and registered a schema change

parent 872d170c
-- ---------------------------------------------------------------------------------------------------
SET @expected_version = 93;
-- 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> -------------------------------------------------
CREATE OR REPLACE VIEW beekeeper_activity AS
SELECT b.beekeeper_id, b.meadow_user, b.meadow_host, b.sleep_minutes, b.loop_limit, b.is_blocked,
b.cause_of_death, COUNT(*) AS loops_executed,
MAX(lm.when_logged) AS last_heartbeat,
IF(cause_of_death IS NULL, TIMEDIFF(now(), max(lm.when_logged)), NULL) AS time_since_last_heartbeat,
IF(cause_of_death IS NULL, TIMEDIFF(SEC_TO_TIME(sleep_minutes * 60), TIMEDIFF(now(), max(lm.when_logged))) < 0, NULL) AS is_overdue
FROM beekeeper b
LEFT JOIN log_message lm
ON b.beekeeper_id = lm.beekeeper_id
GROUP BY b.beekeeper_id;
-- ----------------------------------</actual_patch> -------------------------------------------------
-- increase the schema version by one and register the patch:
UPDATE hive_meta SET meta_value=meta_value+1 WHERE meta_key='hive_sql_schema_version';
INSERT INTO hive_meta (meta_key, meta_value) SELECT CONCAT("patched_to_", meta_value), CURRENT_TIMESTAMP FROM hive_meta WHERE meta_key = "hive_sql_schema_version";
-- ---------------------------------------------------------------------------------------------------
\set expected_version 93
\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 VIEW IF EXISTS beekeeper_activity;
CREATE OR REPLACE VIEW beekeeper_activity AS
SELECT b.beekeeper_id, b.meadow_user, b.meadow_host, b.sleep_minutes, b.loop_limit, b.is_blocked,
b.cause_of_death, COUNT(*) AS loops_executed,
MAX(lm.when_logged) AS last_heartbeat,
now() - max(lm.when_logged) AS time_since_last_heartbeat,
JUSTIFY_INTERVAL( (sleep_minutes * 60|| 'seconds')::interval) -
(now() - max(lm.when_logged)) < INTERVAL '0' AS is_overdue
FROM beekeeper b
LEFT JOIN log_message lm
ON b.beekeeper_id = lm.beekeeper_id
GROUP BY b.beekeeper_id;
-- ----------------------------------</actual_patch> -------------------------------------------------
-- increase the schema version by one and register the patch:
UPDATE hive_meta SET meta_value= (CAST(meta_value AS INTEGER) + 1) WHERE meta_key='hive_sql_schema_version';
INSERT INTO hive_meta (meta_key, meta_value) SELECT 'patched_to_' || meta_value, CURRENT_TIMESTAMP FROM hive_meta WHERE meta_key = 'hive_sql_schema_version';
-- ---------------------------------------------------------------------------------------------------
CREATE TEMPORARY VIEW exp_ver AS SELECT "93" 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> -------------------------------------------------
DROP VIEW IF EXISTS beekeeper_activity;
CREATE VIEW IF NOT EXISTS beekeeper_activity AS
SELECT b.beekeeper_id, b.meadow_user, b.meadow_host, b.sleep_minutes, b.loop_limit, b.is_blocked,
b.cause_of_death, COUNT(*) AS loops_executed,
MAX(lm.when_logged) AS last_heartbeat,
STRFTIME('%s', 'now') - STRFTIME('%s', MAX(lm.when_logged)) AS time_since_last_heartbeat,
((sleep_minutes * 60) -
(STRFTIME('%s', 'now') - STRFTIME('%s', MAX(lm.when_logged)))) < 0 AS is_overdue
FROM beekeeper b
LEFT JOIN log_message lm
ON b.beekeeper_id = lm.beekeeper_id
GROUP BY b.beekeeper_id;
-- ----------------------------------</actual_patch> -------------------------------------------------
-- increase the schema version by one and register the patch:
UPDATE hive_meta SET meta_value=meta_value+1 WHERE meta_key='hive_sql_schema_version';
INSERT INTO hive_meta (meta_key, meta_value) SELECT 'patched_to_' || meta_value, CURRENT_TIMESTAMP FROM hive_meta WHERE meta_key = 'hive_sql_schema_version';
......@@ -112,7 +112,7 @@ CREATE OR REPLACE VIEW live_roles AS
-- and is_overdue;
CREATE OR REPLACE VIEW beekeeper_activity AS
SELECT b.beekeeper_id, b.meadow_host, b.sleep_minutes, b.loop_limit, b.is_blocked,
SELECT b.beekeeper_id, b.meadow_user, b.meadow_host, b.sleep_minutes, b.loop_limit, b.is_blocked,
b.cause_of_death, COUNT(*) AS loops_executed,
MAX(lm.when_logged) AS last_heartbeat,
now() - max(lm.when_logged) AS time_since_last_heartbeat,
......
......@@ -118,7 +118,7 @@ CREATE VIEW IF NOT EXISTS live_roles AS
DROP VIEW IF EXISTS beekeeper_activity;
CREATE VIEW IF NOT EXISTS beekeeper_activity AS
SELECT b.beekeeper_id, b.meadow_host, b.sleep_minutes, b.loop_limit, b.is_blocked,
SELECT b.beekeeper_id, b.meadow_user, b.meadow_host, b.sleep_minutes, b.loop_limit, b.is_blocked,
b.cause_of_death, COUNT(*) AS loops_executed,
MAX(lm.when_logged) AS last_heartbeat,
STRFTIME('%s', 'now') - STRFTIME('%s', MAX(lm.when_logged)) AS time_since_last_heartbeat,
......
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