mirror of https://github.com/citusdata/citus.git
Fix citus_shards with tables with spaces
Tables with spaces were reporting NULL as the `shard_size`. This fixes that by supporting a trailing `"` in the regex that extracts the shardid from the shard name.release-11.2-citus_shards-fix
parent
ebfcdc66a8
commit
a29adf9b9d
|
@ -1,6 +1,6 @@
|
|||
# Citus extension
|
||||
comment = 'Citus distributed database'
|
||||
default_version = '11.2-2'
|
||||
default_version = '11.2-3'
|
||||
module_pathname = '$libdir/citus'
|
||||
relocatable = false
|
||||
schema = pg_catalog
|
||||
|
|
|
@ -0,0 +1,2 @@
|
|||
-- citus--11.2-2--11.2-3
|
||||
#include "udfs/citus_shards/11.2-3.sql"
|
|
@ -0,0 +1,2 @@
|
|||
-- citus--11.2-2--11.2-3
|
||||
-- empty on purpose because the new function is better
|
|
@ -0,0 +1,45 @@
|
|||
CREATE OR REPLACE VIEW pg_catalog.citus_shards AS
|
||||
SELECT
|
||||
pg_dist_shard.logicalrelid AS table_name,
|
||||
pg_dist_shard.shardid,
|
||||
shard_name(pg_dist_shard.logicalrelid, pg_dist_shard.shardid) as shard_name,
|
||||
CASE WHEN partkey IS NOT NULL THEN 'distributed' WHEN repmodel = 't' THEN 'reference' ELSE 'local' END AS citus_table_type,
|
||||
colocationid AS colocation_id,
|
||||
pg_dist_node.nodename,
|
||||
pg_dist_node.nodeport,
|
||||
size as shard_size
|
||||
FROM
|
||||
pg_dist_shard
|
||||
JOIN
|
||||
pg_dist_placement
|
||||
ON
|
||||
pg_dist_shard.shardid = pg_dist_placement.shardid
|
||||
JOIN
|
||||
pg_dist_node
|
||||
ON
|
||||
pg_dist_placement.groupid = pg_dist_node.groupid
|
||||
JOIN
|
||||
pg_dist_partition
|
||||
ON
|
||||
pg_dist_partition.logicalrelid = pg_dist_shard.logicalrelid
|
||||
LEFT JOIN
|
||||
(SELECT (regexp_matches(table_name,'_(\d+)"?$'))[1]::int as shard_id, max(size) as size from citus_shard_sizes() GROUP BY shard_id) as shard_sizes
|
||||
ON
|
||||
pg_dist_shard.shardid = shard_sizes.shard_id
|
||||
WHERE
|
||||
pg_dist_placement.shardstate = 1
|
||||
AND
|
||||
-- filter out tables owned by extensions
|
||||
pg_dist_partition.logicalrelid NOT IN (
|
||||
SELECT
|
||||
objid
|
||||
FROM
|
||||
pg_depend
|
||||
WHERE
|
||||
classid = 'pg_class'::regclass AND refclassid = 'pg_extension'::regclass AND deptype = 'e'
|
||||
)
|
||||
ORDER BY
|
||||
pg_dist_shard.logicalrelid::text, shardid
|
||||
;
|
||||
|
||||
GRANT SELECT ON pg_catalog.citus_shards TO public;
|
|
@ -23,7 +23,7 @@ JOIN
|
|||
ON
|
||||
pg_dist_partition.logicalrelid = pg_dist_shard.logicalrelid
|
||||
LEFT JOIN
|
||||
(SELECT (regexp_matches(table_name,'_(\d+)$'))[1]::int as shard_id, max(size) as size from citus_shard_sizes() GROUP BY shard_id) as shard_sizes
|
||||
(SELECT (regexp_matches(table_name,'_(\d+)"?$'))[1]::int as shard_id, max(size) as size from citus_shard_sizes() GROUP BY shard_id) as shard_sizes
|
||||
ON
|
||||
pg_dist_shard.shardid = shard_sizes.shard_id
|
||||
WHERE
|
||||
|
|
|
@ -0,0 +1,37 @@
|
|||
CREATE SCHEMA citus_shards;
|
||||
SET search_path TO citus_shards;
|
||||
SET citus.shard_count TO 4;
|
||||
SET citus.shard_replication_factor TO 1;
|
||||
SET citus.next_shard_id TO 99456900;
|
||||
ALTER SEQUENCE pg_catalog.pg_dist_colocationid_seq RESTART 456900;
|
||||
CREATE TABLE t1 (i int);
|
||||
SELECT create_distributed_table('t1', 'i');
|
||||
create_distributed_table
|
||||
---------------------------------------------------------------------
|
||||
|
||||
(1 row)
|
||||
|
||||
CREATE TABLE "t with space" (i int);
|
||||
SELECT create_distributed_table('"t with space"', 'i');
|
||||
create_distributed_table
|
||||
---------------------------------------------------------------------
|
||||
|
||||
(1 row)
|
||||
|
||||
INSERT INTO t1 SELECT generate_series(1, 100);
|
||||
INSERT INTO "t with space" SELECT generate_series(1, 1000);
|
||||
SELECT * FROM citus_shards;
|
||||
table_name | shardid | shard_name | citus_table_type | colocation_id | nodename | nodeport | shard_size
|
||||
---------------------------------------------------------------------
|
||||
"t with space" | 99456904 | citus_shards."t with space_99456904" | distributed | 456900 | localhost | 57637 | 40960
|
||||
"t with space" | 99456905 | citus_shards."t with space_99456905" | distributed | 456900 | localhost | 57638 | 40960
|
||||
"t with space" | 99456906 | citus_shards."t with space_99456906" | distributed | 456900 | localhost | 57637 | 40960
|
||||
"t with space" | 99456907 | citus_shards."t with space_99456907" | distributed | 456900 | localhost | 57638 | 40960
|
||||
t1 | 99456900 | citus_shards.t1_99456900 | distributed | 456900 | localhost | 57637 | 8192
|
||||
t1 | 99456901 | citus_shards.t1_99456901 | distributed | 456900 | localhost | 57638 | 8192
|
||||
t1 | 99456902 | citus_shards.t1_99456902 | distributed | 456900 | localhost | 57637 | 8192
|
||||
t1 | 99456903 | citus_shards.t1_99456903 | distributed | 456900 | localhost | 57638 | 8192
|
||||
(8 rows)
|
||||
|
||||
SET client_min_messages TO WARNING;
|
||||
DROP SCHEMA citus_shards CASCADE;
|
|
@ -45,6 +45,8 @@ test: multi_metadata_attributes
|
|||
|
||||
test: multi_read_from_secondaries
|
||||
|
||||
test: citus_shards
|
||||
|
||||
# ----------
|
||||
# multi_citus_tools tests utility functions written for citus tools
|
||||
# ----------
|
||||
|
|
|
@ -0,0 +1,17 @@
|
|||
CREATE SCHEMA citus_shards;
|
||||
SET search_path TO citus_shards;
|
||||
SET citus.shard_count TO 4;
|
||||
SET citus.shard_replication_factor TO 1;
|
||||
SET citus.next_shard_id TO 99456900;
|
||||
ALTER SEQUENCE pg_catalog.pg_dist_colocationid_seq RESTART 456900;
|
||||
|
||||
CREATE TABLE t1 (i int);
|
||||
SELECT create_distributed_table('t1', 'i');
|
||||
CREATE TABLE "t with space" (i int);
|
||||
SELECT create_distributed_table('"t with space"', 'i');
|
||||
INSERT INTO t1 SELECT generate_series(1, 100);
|
||||
INSERT INTO "t with space" SELECT generate_series(1, 1000);
|
||||
SELECT * FROM citus_shards;
|
||||
|
||||
SET client_min_messages TO WARNING;
|
||||
DROP SCHEMA citus_shards CASCADE;
|
Loading…
Reference in New Issue