Last active
August 26, 2024 00:43
-
-
Save lefred/77ddbde301c72535381ae7af9f968322 to your computer and use it in GitHub Desktop.
MySQL Group Replication extra functions and views to sys schema
This file contains 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
USE sys; | |
DELIMITER $$ | |
CREATE FUNCTION IFZERO(a INT, b INT) | |
RETURNS INT | |
DETERMINISTIC | |
RETURN IF(a = 0, b, a)$$ | |
CREATE FUNCTION LOCATE2(needle TEXT(10000), haystack TEXT(10000), offset INT) | |
RETURNS INT | |
DETERMINISTIC | |
RETURN IFZERO(LOCATE(needle, haystack, offset), LENGTH(haystack) + 1)$$ | |
CREATE FUNCTION GTID_NORMALIZE(g TEXT(10000)) | |
RETURNS TEXT(10000) | |
DETERMINISTIC | |
RETURN GTID_SUBTRACT(g, '')$$ | |
CREATE FUNCTION GTID_COUNT(gtid_set TEXT(10000)) | |
RETURNS INT | |
DETERMINISTIC | |
BEGIN | |
DECLARE result BIGINT DEFAULT 0; | |
DECLARE colon_pos INT; | |
DECLARE next_dash_pos INT; | |
DECLARE next_colon_pos INT; | |
DECLARE next_comma_pos INT; | |
SET gtid_set = GTID_NORMALIZE(gtid_set); | |
SET colon_pos = LOCATE2(':', gtid_set, 1); | |
WHILE colon_pos != LENGTH(gtid_set) + 1 DO | |
SET next_dash_pos = LOCATE2('-', gtid_set, colon_pos + 1); | |
SET next_colon_pos = LOCATE2(':', gtid_set, colon_pos + 1); | |
SET next_comma_pos = LOCATE2(',', gtid_set, colon_pos + 1); | |
IF next_dash_pos < next_colon_pos AND next_dash_pos < next_comma_pos THEN | |
SET result = result + | |
SUBSTR(gtid_set, next_dash_pos + 1, | |
LEAST(next_colon_pos, next_comma_pos) - (next_dash_pos + 1)) - | |
SUBSTR(gtid_set, colon_pos + 1, next_dash_pos - (colon_pos + 1)) + 1; | |
ELSE | |
SET result = result + 1; | |
END IF; | |
SET colon_pos = next_colon_pos; | |
END WHILE; | |
RETURN result; | |
END$$ | |
CREATE FUNCTION gr_applier_queue_length() | |
RETURNS INT | |
DETERMINISTIC | |
BEGIN | |
RETURN (SELECT sys.gtid_count( GTID_SUBTRACT( (SELECT | |
Received_transaction_set FROM performance_schema.replication_connection_status | |
WHERE Channel_name = 'group_replication_applier' ), (SELECT | |
@@global.GTID_EXECUTED) ))); | |
END$$ | |
CREATE FUNCTION gr_member_in_primary_partition() | |
RETURNS VARCHAR(3) | |
DETERMINISTIC | |
BEGIN | |
RETURN (SELECT IF( MEMBER_STATE='ONLINE' AND ((SELECT COUNT(*) FROM | |
performance_schema.replication_group_members WHERE MEMBER_STATE != 'ONLINE') >= | |
((SELECT COUNT(*) FROM performance_schema.replication_group_members)/2) = 0), | |
'YES', 'NO' ) FROM performance_schema.replication_group_members JOIN | |
performance_schema.replication_group_member_stats USING(member_id)); | |
END$$ | |
CREATE VIEW gr_member_routing_candidate_status AS SELECT | |
sys.gr_member_in_primary_partition() as viable_candidate, | |
IF( (SELECT (SELECT GROUP_CONCAT(variable_value) FROM | |
performance_schema.global_variables WHERE variable_name IN ('read_only', | |
'super_read_only')) != 'OFF,OFF'), 'YES', 'NO') as read_only, | |
sys.gr_applier_queue_length() as transactions_behind, Count_Transactions_in_queue as 'transactions_to_cert' from performance_schema.replication_group_member_stats;$$ | |
DELIMITER ; |
子查询查询超过一行。
是因为mysql版本的问题。
你可以在replication_group_member_stats 表添加筛选当前主机的条件。
"Subquery returns more than 1 row"
you can do this:
add where
USE sys;
DELIMITER $$
DROP FUNCTION gr_member_in_primary_partition$$
DROP VIEW gr_member_routing_candidate_status$$
CREATE FUNCTION gr_member_in_primary_partition()
RETURNS VARCHAR(3)
DETERMINISTIC
BEGIN
RETURN (SELECT IF( MEMBER_STATE='ONLINE' AND ((SELECT COUNT(*) FROM
performance_schema.replication_group_members WHERE MEMBER_STATE != 'ONLINE') >=
((SELECT COUNT(*) FROM performance_schema.replication_group_members)/2) = 0),
'YES', 'NO' ) FROM performance_schema.replication_group_members JOIN
performance_schema.replication_group_member_stats rgms USING(member_id) WHERE rgms.MEMBER_ID=@@SERVER_UUID);
END$$
CREATE VIEW gr_member_routing_candidate_status AS SELECT
sys.gr_member_in_primary_partition() as viable_candidate,
IF( (SELECT (SELECT GROUP_CONCAT(variable_value) FROM
performance_schema.global_variables WHERE variable_name IN ('read_only',
'super_read_only')) != 'OFF,OFF'), 'YES', 'NO') as read_only,
sys.gr_applier_queue_length() as transactions_behind, Count_Transactions_in_queue as 'transactions_to_cert'
from performance_schema.replication_group_member_stats rgms
where rgms.MEMBER_ID=(select gv.VARIABLE_VALUE
from `performance_schema`.global_variables gv where gv.VARIABLE_NAME='server_uuid');$$
DELIMITER ;
select gr_member_in_primary_partition();
select * from gr_member_routing_candidate_status;
Sign up for free
to join this conversation on GitHub.
Already have an account?
Sign in to comment
Hi @lefred
I'm also seeing the same error as @dungdm93
SELECT * FROM performance_schema.replication_group_members;
+---------------------------+--------------------------------------+-------------+-------------+--------------+-------------+----------------+
| CHANNEL_NAME | MEMBER_ID | MEMBER_HOST | MEMBER_PORT | MEMBER_STATE | MEMBER_ROLE | MEMBER_VERSION |
+---------------------------+--------------------------------------+-------------+-------------+--------------+-------------+----------------+
| group_replication_applier | 08944f18-504f-11e8-bcfa-12262f7a10f8 | re-fn-sql-2 | 3306 | RECOVERING | SECONDARY | 8.0.11 |
| group_replication_applier | 2f9abf14-5038-11e8-8a6a-8a384fff7eff | re-fn-sql-3 | 3306 | ONLINE | SECONDARY | 8.0.11 |
| group_replication_applier | df64619a-5037-11e8-ba35-2a9e5f2f8438 | re-fn-sql-1 | 3306 | ONLINE | PRIMARY | 8.0.11 |
+---------------------------+--------------------------------------+-------------+-------------+--------------+-------------+----------------+
mysql> select * from gr_member_routing_candidate_status;
1242 - Subquery returns more than 1 row
Grateful for any assistance