Skip to content

Commit

Permalink
sql: enhance SHOW RANGES
Browse files Browse the repository at this point in the history
The output of `crdb_internal.ranges{,_no_leases}` and `SHOW
RANGES` was irreparably broken by the introduction of range coalescing
(ranges spanning multiple tables/databases).

Moreover, the start/end keys of SHOW RANGES were often empty or
NULL due to incorrect/excessive truncation.

This commit fixes this by introducing a new design for SHOW RANGES.

Its revised syntax is now:
```
  SHOW CLUSTER RANGES [WITH <options>]
  SHOW RANGES [FROM DATABASE <dbname> | FROM CURRENT_CATALOG] [ WITH <options> ]
  SHOW RANGES FROM TABLE <tablename> [ WITH <options> ]
  SHOW RANGES FROM INDEX <idxname> [ WITH <options> ]

  With <options> a combination of TABLES, INDEXES, DETAILS and EXPLAIN.

  Compare with the simplistic previous syntax:
  # SHOW RANGES FROM DATABASE <dbname>
  # SHOW RANGES FROM TABLE <tablename>
  # SHOW RANGES FROM INDEX <idxname>
```

In summary, we have:
- `SHOW CLUSTER RANGES` which includes all ranges, including those not
  belonging to any table.
- `SHOW RANGES [FROM DATABASE | FROM CURRENT_CATALOG]` which includes
  only ranges overlapping with any table in the target db.
  Note: `SHOW RANGES` without target (NEW!) is an alias for `SHOW RANGES FROM
  CURRENT_CATALOG`.
- `SHOW RANGES FROM TABLE` selects only ranges that overlap with the
  given table.
- `SHOW RANGES FROM INDEX` selects only ranges that overlap with the
  given index.

Then:

- if `WITH TABLES` is specified, the rows are duplicated to detail
  each table included in each range (1 row per range-table
  intersection).
- if `WITH INDEXES` is specified, the rows are duplicated to detail each
  index included in each range (1 row per range-index intersection).
- otherwise, there is just 1 row per range.

In summary:

| Statement                                          | Row identity                     | Before                     | After                            |
|----------------------------------------------------|----------------------------------|----------------------------|----------------------------------|
| `SHOW RANGES FROM DATABASE`                        | rangeID                          | Includes schema/table name | (CHANGE) No schema/table name    |
| `SHOW RANGES FROM TABLE`                           | rangeID                          | Includes index name        | (CHANGE) No index name           |
| `SHOW RANGES FROM INDEX`                           | rangeID                          | Includes index name        | Unchanged                        |
| `SHOW RANGES FROM DATABASE ... WITH TABLES` (NEW)  | rangeID, schema/table name       | N/A                        | Includes schema/table name       |
| `SHOW RANGES FROM DATABASE ... WITH INDEXES` (NEW) | rangeID, schema/table/index name | N/A                        | Includes schema/table/index name |
| `SHOW RANGES FROM TABLE ... WITH INDEXES` (NEW)    | rangeID, index name              | N/A                        | Includes index name              |
| `SHOW CLUSTER RANGES` (NEW)                        | rangeID                          | N/A                        |                                  |
| `SHOW CLUSTER RANGES WITH TABLES` (NEW)            | rangeID, schema/table name       | N/A                        | Includes db/schema/table name    |
| `SHOW CLUSTER RANGES WITH INDEXES` (NEW)           | rangeID, schema/table/index name | N/A                        | Includes db/sch/table/index name |

| Statement                                          | Start/end key column, before | Start/end key column, after           |
|----------------------------------------------------|------------------------------|---------------------------------------|
| `SHOW RANGES FROM DATABASE`                        | Truncates table/index IDs    | (CHANGE) Includes table/index ID      |
| `SHOW RANGES FROM TABLE`                           | Truncates table/index IDs    | (CHANGE) Includes table/index ID      |
| `SHOW RANGES FROM INDEX`                           | Truncates table/index IDs    | Unchanged                             |
| `SHOW RANGES FROM DATABASE ... WITH TABLES` (NEW)  | N/A                          | Includes table/index ID               |
| `SHOW RANGES FROM DATABASE ... WITH INDEXES` (NEW) | N/A                          | Includes table/index ID               |
| `SHOW RANGES FROM TABLE ... WITH INDEXES` (NEW)    | N/A                          | Truncates table ID, includes index ID |
| `SHOW CLUSTER RANGES` (NEW)                        | N/A                          | Includes table/index ID               |
| `SHOW CLUSTER RANGES WITH TABLES` (NEW)            | N/A                          | Includes table/index ID               |
| `SHOW CLUSTER RANGES WITH INDEXES` (NEW)           | N/A                          | Includes table/index ID               |

Then:
- if `WITH DETAILS` is specified, extra _expensive_ information is
  included in the result, as of `crdb_internal.ranges`.
  (requires more roundtrips; makes the operation slower overall)
- otherwise, only data from `crdb_internal.ranges_no_leases` is included.

Then:
- if `WITH EXPLAIN` is specified, the statement simply returns the
  text of the SQL query it would use if `WITH EXPLAIN` was not
  specified. This can be used for learning or troubleshooting.

See text of release notes below for details; also the explanatory
comment at the top of `pkg/sql/delegate/show_ranges.go`.

To test this, use for example the following setup:

```
> -- Enable merge of adjacent ranges with same zone config.
> set cluster setting spanconfig.host_coalesce_adjacent.enabled = true;
> -- Table t has two indexes with some split points.
> create table t(x int primary key, y int);
> create index sec_idx on t(y);
> alter index t@primary split at values(3);
> alter index t@sec_idx split at values(3);
> -- Tables u and v share a range with t@sec_idx.
> create table u(x int);
> create table v(x int);
> -- Make some other tables with forced split points due to different
> -- zone configs.
> create schema otherschema;
> create table otherschema.w(x int);
> create table otherschema.z(x int);
> alter table otherschema.w configure zone using num_replicas = 5;
> alter table otherschema.z configure zone using num_replicas = 7;
```

Example output for `SHOW RANGES FROM DATABASE`:

```
> show ranges from database defaultdb; -- 1 row per range
> show ranges from current_catalog; -- implicit db from session

    start_key    |    end_key     | range_id | ...
-----------------+----------------+----------+----
  /Table/104     | /Table/104/1/3 |       56 | ...
  /Table/104/1/3 | /Table/104/2   |       57 | ...
  /Table/104/2   | /Table/104/2/3 |       55 | ...
  /Table/104/2/3 | /Table/108     |       58 | ...
  /Table/108     | /Table/109     |       59 | ...
  /Table/109     | /Max           |       60 | ...
```

New syntax: `WITH TABLES` / `WITH INDEXES`:

```
> show ranges from database defaultdb with tables; -- 1 row per range/table intersection

    start_key    |    end_key     | range_id | schema_name | table_name | table_start_key |    table_end_key     | ...
-----------------+----------------+----------+-------------+------------+-----------------+----------------------+----
  /Table/104     | /Table/104/1/3 |       56 | public      | t          | /Table/104      | /Table/105           | ...
  /Table/104/1/3 | /Table/104/2   |       57 | public      | t          | /Table/104      | /Table/105           | ...
  /Table/104/2   | /Table/104/2/3 |       55 | public      | t          | /Table/104      | /Table/105           | ...
  /Table/104/2/3 | /Table/108     |       58 | public      | t          | /Table/104      | /Table/105           | ...
  /Table/104/2/3 | /Table/108     |       58 | public      | u          | /Table/105      | /Table/106           | ...
  /Table/104/2/3 | /Table/108     |       58 | public      | v          | /Table/106      | /Table/107           | ...
  /Table/108     | /Table/109     |       59 | otherschema | w          | /Table/108      | /Table/109           | ...
  /Table/109     | /Max           |       60 | otherschema | z          | /Table/109      | /Table/109/PrefixEnd | ...
```

```
> show ranges from database defaultdb with indexes; -- 1 row per range/index intersection

    start_key    |    end_key     | range_id | schema_name | table_name | index_name | index_start_key | index_end_key | ...
-----------------+----------------+----------+-------------+------------+------------+-----------------+---------------+----
  /Table/104     | /Table/104/1/3 |       56 | public      | t          | t_pkey     | /Table/104/1    | /Table/104/2  | ...
  /Table/104/1/3 | /Table/104/2   |       57 | public      | t          | t_pkey     | /Table/104/1    | /Table/104/2  | ...
  /Table/104/2   | /Table/104/2/3 |       55 | public      | t          | sec_idx    | /Table/104/2    | /Table/104/3  | ...
  /Table/104/2/3 | /Table/108     |       58 | public      | t          | sec_idx    | /Table/104/2    | /Table/104/3  | ...
  /Table/104/2/3 | /Table/108     |       58 | public      | u          | u_pkey     | /Table/105/1    | /Table/105/2  | ...
  /Table/104/2/3 | /Table/108     |       58 | public      | v          | v_pkey     | /Table/106/1    | /Table/106/2  | ...
  /Table/108     | /Table/109     |       59 | otherschema | w          | w_pkey     | /Table/108/1    | /Table/108/2  | ...
  /Table/109     | /Max           |       60 | otherschema | z          | z_pkey     | /Table/109/1    | /Table/109/2  | ...
```

Example output for `SHOW RANGES FROM TABLE`:

```
> show ranges from table t;

   start_key   |      end_key       | range_id | ...
---------------+--------------------+----------+----
  …/<TableMin> | …/1/3              |       56 | ...
  …/1/3        | …/2                |       57 | ...
  …/2          | …/2/3              |       55 | ...
  …/2/3        | <after:/Table/108> |       58 | ...
```

```
> show ranges from table u;

         start_key        |      end_key       | range_id | ...
--------------------------+--------------------+----------+----
  <before:/Table/104/2/3> | <after:/Table/108> |       58 | ...
```

```
> show ranges from table otherschema.w;

  start_key    |  end_key     | range_id | ...
---------------+--------------+----------+----
  …/<TableMin> | …/<TableMax> |       59 | ...
```

New syntax: `SHOW RANGES FROM TABLE ... WITH INDEXES`:

```
> show ranges from table t with indexes;

  start_key    |      end_key       | range_id | index_name | index_start_key | index_end_key | ...
---------------+--------------------+----------+------------+-----------------+---------------+----
  …/<TableMin> | …/1/3              |       56 | t_pkey     | …/1             | …/2           | ...
  …/1/3        | …/<IndexMax>       |       57 | t_pkey     | …/1             | …/2           | ...
  …/<IndexMin> | …/2/3              |       55 | sec_idx    | …/2             | …/3           | ...
  …/2/3        | <after:/Table/108> |       58 | sec_idx    | …/2             | …/3           | ...
```

```
> show ranges from table u with indexes;

         start_key        |      end_key       | range_id | index_name | index_start_key | index_end_key | ...
--------------------------+--------------------+----------+------------+-----------------+---------------+----
  <before:/Table/104/2/3> | <after:/Table/108> |       58 | u_pkey     | …/1             | …/2           | ...
```

```
> show ranges from table otherschema.w with indexes;

  start_key    |  end_key     | range_id | index_name | index_start_key | index_end_key | ...
---------------+--------------+----------+------------+-----------------+---------------+----
  …/<TableMin> | …/<TableMax> |       59 | w_pkey     | …/1             | …/2           | ...
```

Example output for `SHOW RANGES FROM INDEX`:

```
> show ranges from index t@t_pkey;

  start_key    |  end_key     | range_id | ...
---------------+--------------+----------+----
  …/<TableMin> | …/3          |       56 | ...
  …/3          | …/<IndexMax> |       57 | ...
```

```
> show ranges from index t@sec_idx;

  start_key    |      end_key       | range_id | ...
---------------+--------------------+----------+----
  …/<IndexMin> | …/3                |       55 | ...
  …/3          | <after:/Table/108> |       58 | ...
```

```
> show ranges from index u@u_pkey;

         start_key        |      end_key       | range_id | ...
--------------------------+--------------------+----------+----
  <before:/Table/104/2/3> | <after:/Table/108> |       58 | ...
```

```
> show ranges from index otherschema.w@w_pkey;

  start_key    |  end_key     | range_id | ...
---------------+--------------+----------+----
  …/<TableMin> | …/<TableMax> |       59 | ...
```

See release notes below for details.

----

**Backward-incompatible changes.**

Release note (backward-incompatible change): CockroachDB now supports
sharing storage ranges across multiple indexes/tables. As a result,
there is no more guarantee that there is at most one SQL object (e.g.
table/index/sequence/materialized view) per storage range.

Therefore, the columns `table_id`, `database_name`, `schema_name`,
`table_name` and `index_name` in `crdb_internal.ranges` and
`.ranges_no_leases` have become nonsensical: a range cannot be
attributed to a single table/index any more.

As a result:

- The aforementioned columns in the `crdb_internal` virtual tables
  have been marked as hidden, and will now report NULL.

- `SHOW RANGES FROM DATABASE` continues to report one row per range,
  but stops returning the database / schema / table / index name.

- `SHOW RANGES FROM TABLE` continues to report one row per range,
  but stops returning the index name.

Release note (backward-incompatible change): The format of the
columns `start_key` and `end_key` for `SHOW RANGES FROM DATABASE`
and `SHOW RANGES FROM TABLE` have been extended to include which
table/index the key belong to. This is necessary because a range
can now contain data from more than one table/index.

Release note (backward-incompatible change): The format of
the columns `start_key` and `end_key` for `SHOW RANGE ... FOR ROW`
has been changed to stay consistent with the output of `SHOW RANGES
FROM INDEX`.

Release note (backward-incompatible change): The output of `SHOW
RANGES` does not include `range_size`, `range_size_mb`, `lease_holder`
and `lease_holder_localities` any more by default. This ensures that
`SHOW RANGES` remains fast in the common case. Use the (NEW) option
`WITH DETAILS` to include these columns.

----

**Other changes.**

Release note (bug fix): In some cases the start/end key columns of the
output of `SHOW RANGES` was missing. This was corrected.

Release note (sql change): Two new virtual tables
`crdb_internal.index_spans` and `.table_spans` have been introduced,
which list the logical keyspace used by each index/table.

----

**New features.**

Release note (sql change): The following new statements are
introduced:

- `SHOW RANGES FROM CURRENT_CATALOG` and `SHOW RANGES` without
  parameter: alias for `SHOW RANGES FROM DATABASE` on the session's
  current database.

- `SHOW RANGES FROM DATABASE ... WITH TABLES`
  Reports at least one row per table. It's possible for the same
  range ID to be repeated across multiple rows, when a range spans
  multiple tables.

- `SHOW RANGES FROM DATABASE ... WITH INDEXES`
  Reports at least one row per index. It's possible for the same
  range ID to be repeated across multiple rows, when a range spans
  multiple indexes.

- `SHOW RANGES FROM TABLE ... WITH INDEXES`
  Reports at least one row per index. It's possible for the same
  range ID to be repeated across multiple rows, when a range spans
  multiple indexes.

- `SHOW CLUSTER RANGES [ WITH { INDEXES | TABLES } ]` Reports ranges
  across the entire cluster, including ranges that don't contain table
  data. The behavior of `WITH INDEXES` and `WITH TABLES` is the same
  as for `SHOW RANGES FROM DATABASE`.

Additionally, the following new options have been added to the `SHOW
RANGES` statement:

- `WITH DETAILS`: produce more details, using computations that
  require extra network roundtrips. Makes the operation slower
  overall.
- `WITH EXPLAIN`: produce the text of the SQL query used to
  run the statement.
  • Loading branch information
knz committed Dec 16, 2022
1 parent 5b23751 commit 2a3c34a
Show file tree
Hide file tree
Showing 68 changed files with 2,963 additions and 1,710 deletions.
9 changes: 6 additions & 3 deletions docs/generated/sql/bnf/show_ranges_stmt.bnf
Original file line number Diff line number Diff line change
@@ -1,4 +1,7 @@
show_ranges_stmt ::=
'SHOW' 'RANGES' 'FROM' 'TABLE' table_name
| 'SHOW' 'RANGES' 'FROM' 'INDEX' table_index_name
| 'SHOW' 'RANGES' 'FROM' 'DATABASE' database_name
'SHOW' 'RANGES' 'FROM' 'INDEX' table_index_name opt_show_ranges_options
| 'SHOW' 'RANGES' 'FROM' 'TABLE' table_name opt_show_ranges_options
| 'SHOW' 'RANGES' 'FROM' 'DATABASE' database_name opt_show_ranges_options
| 'SHOW' 'RANGES' 'FROM' 'CURRENT_CATALOG' opt_show_ranges_options
| 'SHOW' 'RANGES' opt_show_ranges_options
| 'SHOW' 'CLUSTER' 'RANGES' opt_show_ranges_options
16 changes: 13 additions & 3 deletions docs/generated/sql/bnf/stmt_block.bnf
Original file line number Diff line number Diff line change
Expand Up @@ -867,9 +867,12 @@ show_statements_stmt ::=
| 'SHOW' 'ALL' opt_cluster statements_or_queries

show_ranges_stmt ::=
'SHOW' 'RANGES' 'FROM' 'TABLE' table_name
| 'SHOW' 'RANGES' 'FROM' 'INDEX' table_index_name
| 'SHOW' 'RANGES' 'FROM' 'DATABASE' database_name
'SHOW' 'RANGES' 'FROM' 'INDEX' table_index_name opt_show_ranges_options
| 'SHOW' 'RANGES' 'FROM' 'TABLE' table_name opt_show_ranges_options
| 'SHOW' 'RANGES' 'FROM' 'DATABASE' database_name opt_show_ranges_options
| 'SHOW' 'RANGES' 'FROM' 'CURRENT_CATALOG' opt_show_ranges_options
| 'SHOW' 'RANGES' opt_show_ranges_options
| 'SHOW' 'CLUSTER' 'RANGES' opt_show_ranges_options

show_range_for_row_stmt ::=
'SHOW' 'RANGE' 'FROM' 'TABLE' table_name 'FOR' 'ROW' '(' expr_list ')'
Expand Down Expand Up @@ -1077,6 +1080,7 @@ unreserved_keyword ::=
| 'DEPENDS'
| 'DESTINATION'
| 'DETACHED'
| 'DETAILS'
| 'DISCARD'
| 'DOMAIN'
| 'DOUBLE'
Expand Down Expand Up @@ -1943,6 +1947,9 @@ statements_or_queries ::=
'STATEMENTS'
| 'QUERIES'

opt_show_ranges_options ::=
'WITH' show_ranges_options

opt_compact ::=
'COMPACT'
|
Expand Down Expand Up @@ -2634,6 +2641,9 @@ targets_roles ::=
| 'TYPE' type_name_list
| grant_targets

show_ranges_options ::=
( 'TABLES' | 'INDEXES' | 'DETAILS' | 'EXPLAIN' ) ( ( ',' 'TABLES' | ',' 'INDEXES' | ',' 'DETAILS' | ',' 'EXPLAIN' ) )*

partition ::=
'PARTITION' partition_name

Expand Down
2 changes: 2 additions & 0 deletions pkg/ccl/logictestccl/testdata/logic_test/crdb_internal_tenant
Original file line number Diff line number Diff line change
Expand Up @@ -54,6 +54,7 @@ crdb_internal gossip_liveness table admin NULL NULL
crdb_internal gossip_network table admin NULL NULL
crdb_internal gossip_nodes table admin NULL NULL
crdb_internal index_columns table admin NULL NULL
crdb_internal index_spans table admin NULL NULL
crdb_internal index_usage_statistics table admin NULL NULL
crdb_internal invalid_objects table admin NULL NULL
crdb_internal jobs table admin NULL NULL
Expand Down Expand Up @@ -92,6 +93,7 @@ crdb_internal super_regions table admin NULL NULL
crdb_internal table_columns table admin NULL NULL
crdb_internal table_indexes table admin NULL NULL
crdb_internal table_row_statistics table admin NULL NULL
crdb_internal table_spans table admin NULL NULL
crdb_internal tables table admin NULL NULL
crdb_internal tenant_usage_details view admin NULL NULL
crdb_internal transaction_contention_events table admin NULL NULL
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -256,29 +256,27 @@ statement ok
CREATE INDEX t_presplit_idx_member_id ON t_presplit (member_id) USING HASH WITH (bucket_count=8);

skipif config 3node-tenant
query TITTT colnames,retry
SELECT t.name, r.table_id, r.index_name, r.start_pretty, r.end_pretty
FROM crdb_internal.tables t
JOIN crdb_internal.ranges r ON t.table_id = r.table_id
WHERE t.name = 't_presplit'
AND t.state = 'PUBLIC'
AND r.split_enforced_until IS NOT NULL;
query TITTT colnames,retry,rowsort
SELECT table_name, table_id, index_name, start_key, end_key
FROM [SHOW RANGES FROM DATABASE test WITH INDEXES]
WHERE table_name = 't_presplit'
----
name table_id index_name start_pretty end_pretty
t_presplit 112 t_presplit_idx_member_id /Table/112/2 /Table/112/2/"new york"/0
t_presplit 112 t_presplit_idx_member_id /Table/112/2/"new york"/0 /Table/112/2/"new york"/1
t_presplit 112 t_presplit_idx_member_id /Table/112/2/"new york"/1 /Table/112/2/"new york"/2
t_presplit 112 t_presplit_idx_member_id /Table/112/2/"new york"/2 /Table/112/2/"new york"/3
t_presplit 112 t_presplit_idx_member_id /Table/112/2/"new york"/3 /Table/112/2/"new york"/4
t_presplit 112 t_presplit_idx_member_id /Table/112/2/"new york"/4 /Table/112/2/"new york"/5
t_presplit 112 t_presplit_idx_member_id /Table/112/2/"new york"/5 /Table/112/2/"new york"/6
t_presplit 112 t_presplit_idx_member_id /Table/112/2/"new york"/6 /Table/112/2/"new york"/7
t_presplit 112 t_presplit_idx_member_id /Table/112/2/"new york"/7 /Table/112/2/"seattle"/0
t_presplit 112 t_presplit_idx_member_id /Table/112/2/"seattle"/0 /Table/112/2/"seattle"/1
t_presplit 112 t_presplit_idx_member_id /Table/112/2/"seattle"/1 /Table/112/2/"seattle"/2
t_presplit 112 t_presplit_idx_member_id /Table/112/2/"seattle"/2 /Table/112/2/"seattle"/3
t_presplit 112 t_presplit_idx_member_id /Table/112/2/"seattle"/3 /Table/112/2/"seattle"/4
t_presplit 112 t_presplit_idx_member_id /Table/112/2/"seattle"/4 /Table/112/2/"seattle"/5
t_presplit 112 t_presplit_idx_member_id /Table/112/2/"seattle"/5 /Table/112/2/"seattle"/6
t_presplit 112 t_presplit_idx_member_id /Table/112/2/"seattle"/6 /Table/112/2/"seattle"/7
t_presplit 112 t_presplit_idx_member_id /Table/112/2/"seattle"/7 /Table/112/3/"new york"/0
table_name table_id index_name start_key end_key
t_presplit 112 t_presplit_pkey /Table/109/11/"seattle"/15 /Table/112/2
t_presplit 112 t_presplit_idx_member_id /Table/112/2 /Table/112/2/"new york"/0
t_presplit 112 t_presplit_idx_member_id /Table/112/2/"new york"/0 /Table/112/2/"new york"/1
t_presplit 112 t_presplit_idx_member_id /Table/112/2/"new york"/1 /Table/112/2/"new york"/2
t_presplit 112 t_presplit_idx_member_id /Table/112/2/"new york"/2 /Table/112/2/"new york"/3
t_presplit 112 t_presplit_idx_member_id /Table/112/2/"new york"/3 /Table/112/2/"new york"/4
t_presplit 112 t_presplit_idx_member_id /Table/112/2/"new york"/4 /Table/112/2/"new york"/5
t_presplit 112 t_presplit_idx_member_id /Table/112/2/"new york"/5 /Table/112/2/"new york"/6
t_presplit 112 t_presplit_idx_member_id /Table/112/2/"new york"/6 /Table/112/2/"new york"/7
t_presplit 112 t_presplit_idx_member_id /Table/112/2/"new york"/7 /Table/112/2/"seattle"/0
t_presplit 112 t_presplit_idx_member_id /Table/112/2/"seattle"/0 /Table/112/2/"seattle"/1
t_presplit 112 t_presplit_idx_member_id /Table/112/2/"seattle"/1 /Table/112/2/"seattle"/2
t_presplit 112 t_presplit_idx_member_id /Table/112/2/"seattle"/2 /Table/112/2/"seattle"/3
t_presplit 112 t_presplit_idx_member_id /Table/112/2/"seattle"/3 /Table/112/2/"seattle"/4
t_presplit 112 t_presplit_idx_member_id /Table/112/2/"seattle"/4 /Table/112/2/"seattle"/5
t_presplit 112 t_presplit_idx_member_id /Table/112/2/"seattle"/5 /Table/112/2/"seattle"/6
t_presplit 112 t_presplit_idx_member_id /Table/112/2/"seattle"/6 /Table/112/2/"seattle"/7
t_presplit 112 t_presplit_idx_member_id /Table/112/2/"seattle"/7 /Table/112/3/"new york"/0
Original file line number Diff line number Diff line change
Expand Up @@ -262,7 +262,7 @@ ap-southeast-2 23
query TT
SELECT start_key, end_key FROM [SHOW RANGE FROM TABLE regional_by_row_table FOR ROW ('ap-southeast-2', 1)]
----
NULL NULL
<before:/Table/53> <after:/Table/110/5>

query TIIII
SELECT crdb_region, pk, pk2, a, b FROM regional_by_row_table
Expand Down Expand Up @@ -392,12 +392,12 @@ ALTER TABLE regional_by_row_table SPLIT AT VALUES ('ca-central-1', 0), ('us-east
ALTER TABLE regional_by_row_table EXPERIMENTAL_RELOCATE VALUES (ARRAY[1], 'ap-southeast-2', 0), (ARRAY[4], 'ca-central-1', 0), (ARRAY[7], 'us-east-1', 0);

query TTTI colnames,rowsort
SELECT start_key, end_key, replicas, lease_holder FROM [SHOW RANGES FROM INDEX regional_by_row_table@primary]
SELECT start_key, end_key, replicas, lease_holder FROM [SHOW RANGES FROM INDEX regional_by_row_table@primary WITH DETAILS]
----
start_key end_key replicas lease_holder
NULL /"\x80"/0 {1} 1
/"\x80"/0 /"\xc0"/0 {4} 4
/"\xc0"/0 NULL {7} 7
start_key end_key replicas lease_holder
<before:/Table/53> …/"\x80"/0 {1} 1
/"\x80"/0 /"\xc0"/0 {4} 4
/"\xc0"/0 <after:/Table/110/5> {7} 7

statement ok
SET locality_optimized_partitioned_index_scan = false
Expand Down Expand Up @@ -640,12 +640,12 @@ ALTER TABLE child SPLIT AT VALUES ('ca-central-1', 0), ('us-east-1', 0);
ALTER TABLE child EXPERIMENTAL_RELOCATE VALUES (ARRAY[1], 'ap-southeast-2', 0), (ARRAY[4], 'ca-central-1', 0), (ARRAY[7], 'us-east-1', 0);

query TTTI colnames,rowsort
SELECT start_key, end_key, replicas, lease_holder FROM [SHOW RANGES FROM INDEX child@primary]
SELECT start_key, end_key, replicas, lease_holder FROM [SHOW RANGES FROM INDEX child@primary WITH DETAILS]
----
start_key end_key replicas lease_holder
NULL /"\x80"/0 {1} 1
/"\x80"/0 /"\xc0"/0 {4} 4
/"\xc0"/0 NULL {7} 7
start_key end_key replicas lease_holder
<before:/Table/110/5> …/"\x80"/0 {1} 1
/"\x80"/0 /"\xc0"/0 {4} 4
/"\xc0"/0 <after:/Max> {7} 7

statement ok
SET locality_optimized_partitioned_index_scan = false
Expand Down
81 changes: 81 additions & 0 deletions pkg/sql/catalog/colinfo/result_columns.go
Original file line number Diff line number Diff line change
Expand Up @@ -11,6 +11,8 @@
package colinfo

import (
"fmt"

"github.com/cockroachdb/cockroach/pkg/sql/catalog"
"github.com/cockroachdb/cockroach/pkg/sql/catalog/descpb"
"github.com/cockroachdb/cockroach/pkg/sql/sem/tree"
Expand Down Expand Up @@ -293,3 +295,82 @@ var TenantColumnsWithReplication = ResultColumns{
{Name: "retained_time", Typ: types.Timestamp},
{Name: "replication_start_time", Typ: types.Timestamp},
}

// RangesNoLeases is the schema for crdb_internal.ranges_no_leases.
var RangesNoLeases = ResultColumns{
{Name: "range_id", Typ: types.Int},
{Name: "start_key", Typ: types.Bytes},
{Name: "start_pretty", Typ: types.String},
{Name: "end_key", Typ: types.Bytes},
{Name: "end_pretty", Typ: types.String},
{Hidden: true, Name: "table_id", Typ: types.Int},
{Hidden: true, Name: "database_name", Typ: types.String},
{Hidden: true, Name: "schema_name", Typ: types.String},
{Hidden: true, Name: "table_name", Typ: types.String},
{Hidden: true, Name: "index_name", Typ: types.String},
{Name: "replicas", Typ: types.IntArray},
{Name: "replica_localities", Typ: types.StringArray},
{Name: "voting_replicas", Typ: types.IntArray},
{Name: "non_voting_replicas", Typ: types.IntArray},
{Name: "learner_replicas", Typ: types.IntArray},
{Name: "split_enforced_until", Typ: types.Timestamp},
}

// Ranges is the schema for crdb_internal.ranges.
var Ranges = ResultColumns{
// All the first columns from Ranges are really those from
// RangesNoLeases. So we would really like to include RangesNoLeases
// as a prefix here with a simple Go append().
//
// Unfortunately, the result type of crdb_internal.ranges for the
// arrays is INT2VECTOR, which gives them zero-indexing. This is
// weird! crdb_internal.ranges_no_leases use regular INT[]. So the
// indexing behavior between crdb_internal.ranges and
// crdb_internal.ranges_no_leases is inconsistent. See:
// https://github.com/cockroachdb/cockroach/issues/93788
//
// Until that bug is fixed, we need to list the columns explicitly,
// with a run-time check below (in the init function) that they are
// consistent.
{Name: "range_id", Typ: types.Int},
{Name: "start_key", Typ: types.Bytes},
{Name: "start_pretty", Typ: types.String},
{Name: "end_key", Typ: types.Bytes},
{Name: "end_pretty", Typ: types.String},
{Hidden: true, Name: "table_id", Typ: types.Int},
{Hidden: true, Name: "database_name", Typ: types.String},
{Hidden: true, Name: "schema_name", Typ: types.String},
{Hidden: true, Name: "table_name", Typ: types.String},
{Hidden: true, Name: "index_name", Typ: types.String},
{Name: "replicas", Typ: types.Int2Vector},
{Name: "replica_localities", Typ: types.StringArray},
{Name: "voting_replicas", Typ: types.Int2Vector},
{Name: "non_voting_replicas", Typ: types.Int2Vector},
{Name: "learner_replicas", Typ: types.Int2Vector},
{Name: "split_enforced_until", Typ: types.Timestamp},

// The following columns are computed by RangesExtraRenders below.
{Name: "lease_holder", Typ: types.Int},
{Name: "range_size", Typ: types.Int},
}

func init() {
// This check can be removed once Ranges can be constructed
// using append(RangesNoLeases, ...).
for i, c := range RangesNoLeases {
if c.Name != Ranges[i].Name ||
c.Hidden != Ranges[i].Hidden {
panic(fmt.Sprintf("inconsistent definitions: %#v vs %#v", c, Ranges[i]))
}
}
}

// RangesExtraRenders describes the extra projections in
// crdb_internal.ranges not included in crdb_internal.ranges_no_leases.
const RangesExtraRenders = `
crdb_internal.lease_holder(start_key) AS lease_holder,
(crdb_internal.range_stats(start_key)->>'key_bytes')::INT +
(crdb_internal.range_stats(start_key)->>'val_bytes')::INT +
coalesce((crdb_internal.range_stats(start_key)->>'range_key_bytes')::INT, 0) +
coalesce((crdb_internal.range_stats(start_key)->>'range_val_bytes')::INT, 0) AS range_size
`
Loading

0 comments on commit 2a3c34a

Please sign in to comment.