Adds check_database_on_all_nodes

pull/7240/head
gindibay 2023-11-16 05:13:10 +03:00
parent ed9021ca90
commit 56bc813bd0
3 changed files with 110 additions and 7 deletions

View File

@ -556,3 +556,58 @@ BEGIN
ORDER BY node_type;
END;
$func$ LANGUAGE plpgsql;
$func$ LANGUAGE plpgsql;
-- For all nodes, returns database properties of given database, except
-- oid, datfrozenxid and datminmxid.
--
-- Also returns whether the node has a pg_dist_object record for the database
-- and whether there are any stale pg_dist_object records for a database.
CREATE OR REPLACE FUNCTION check_database_on_all_nodes(p_database_name text)
RETURNS TABLE (node_type text, result text)
AS $func$
BEGIN
RETURN QUERY
SELECT
CASE WHEN (groupid = 0 AND groupid = (SELECT groupid FROM pg_dist_local_group)) THEN 'coordinator (local)'
WHEN (groupid = 0) THEN 'coordinator (remote)'
WHEN (groupid = (SELECT groupid FROM pg_dist_local_group)) THEN 'worker node (local)'
ELSE 'worker node (remote)'
END AS node_type,
q2.result
FROM run_command_on_all_nodes(
format(
$$
SELECT to_jsonb(q.*)
FROM (
SELECT
(
SELECT to_jsonb(database_properties.*)
FROM (
SELECT datname, pa.rolname as database_owner,
pg_encoding_to_char(pd.encoding) as encoding, datlocprovider,
datistemplate, datallowconn, datconnlimit,
pt.spcname AS tablespace, datcollate, datctype, daticulocale,
datcollversion, datacl
FROM pg_database pd
JOIN pg_authid pa ON pd.datdba = pa.oid
JOIN pg_tablespace pt ON pd.dattablespace = pt.oid
WHERE datname = '%s'
) database_properties
) AS database_properties,
(
SELECT COUNT(*)=1
FROM pg_dist_object WHERE objid = (SELECT oid FROM pg_database WHERE datname = '%s')
) AS pg_dist_object_record_for_db_exists,
(
SELECT COUNT(*) > 0
FROM pg_dist_object
WHERE classid = 1262 AND objid NOT IN (SELECT oid FROM pg_database)
) AS stale_pg_dist_object_record_for_a_db_exists
) q
$$,
p_database_name, p_database_name
)
) q2
JOIN pg_dist_node USING (nodeid);
END;
$func$ LANGUAGE plpgsql;

View File

@ -47,15 +47,8 @@ ALTER ROLE CURRENT_USER WITH PASSWORD 'dummypassword';
-- Show that, with no MX tables, activate node snapshot contains only the delete commands,
-- pg_dist_node entries, pg_dist_object entries and roles.
select pdo.*, pd.datname
from pg_dist_object pdo
left outer join pg_database pd on pdo.objid = pd.oid;
SELECT unnest(activate_node_snapshot()) order by 1;
-- Create a test table with constraints and SERIAL and default from user defined sequence
CREATE SEQUENCE user_defined_seq;
CREATE TABLE mx_test_table (col_1 int UNIQUE, col_2 text NOT NULL, col_3 BIGSERIAL, col_4 BIGINT DEFAULT nextval('user_defined_seq'));

View File

@ -581,3 +581,58 @@ BEGIN
ORDER BY node_type;
END;
$func$ LANGUAGE plpgsql;
-- For all nodes, returns database properties of given database, except
-- oid, datfrozenxid and datminmxid.
--
-- Also returns whether the node has a pg_dist_object record for the database
-- and whether there are any stale pg_dist_object records for a database.
CREATE OR REPLACE FUNCTION check_database_on_all_nodes(p_database_name text)
RETURNS TABLE (node_type text, result text)
AS $func$
BEGIN
RETURN QUERY
SELECT
CASE WHEN (groupid = 0 AND groupid = (SELECT groupid FROM pg_dist_local_group)) THEN 'coordinator (local)'
WHEN (groupid = 0) THEN 'coordinator (remote)'
WHEN (groupid = (SELECT groupid FROM pg_dist_local_group)) THEN 'worker node (local)'
ELSE 'worker node (remote)'
END AS node_type,
q2.result
FROM run_command_on_all_nodes(
format(
$$
SELECT to_jsonb(q.*)
FROM (
SELECT
(
SELECT to_jsonb(database_properties.*)
FROM (
SELECT datname, pa.rolname as database_owner,
pg_encoding_to_char(pd.encoding) as encoding, datlocprovider,
datistemplate, datallowconn, datconnlimit,
pt.spcname AS tablespace, datcollate, datctype, daticulocale,
datcollversion, datacl
FROM pg_database pd
JOIN pg_authid pa ON pd.datdba = pa.oid
JOIN pg_tablespace pt ON pd.dattablespace = pt.oid
WHERE datname = '%s'
) database_properties
) AS database_properties,
(
SELECT COUNT(*)=1
FROM pg_dist_object WHERE objid = (SELECT oid FROM pg_database WHERE datname = '%s')
) AS pg_dist_object_record_for_db_exists,
(
SELECT COUNT(*) > 0
FROM pg_dist_object
WHERE classid = 1262 AND objid NOT IN (SELECT oid FROM pg_database)
) AS stale_pg_dist_object_record_for_a_db_exists
) q
$$,
p_database_name, p_database_name
)
) q2
JOIN pg_dist_node USING (nodeid);
END;
$func$ LANGUAGE plpgsql;