mirror of https://github.com/citusdata/citus.git
51 lines
1.5 KiB
SQL
51 lines
1.5 KiB
SQL
CREATE OR REPLACE VIEW citus.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 colocationid IN (SELECT colocationid FROM pg_dist_tenant_schema) THEN 'schema'
|
|
WHEN partkey IS NOT NULL THEN 'distributed'
|
|
WHEN repmodel = 't' THEN 'reference'
|
|
WHEN colocationid = 0 THEN 'local'
|
|
ELSE 'distributed' 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 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
|
|
;
|
|
|
|
ALTER VIEW citus.citus_shards SET SCHEMA pg_catalog;
|
|
GRANT SELECT ON pg_catalog.citus_shards TO public;
|