Skip to content

Commit eab9624

Browse files
committed
Add mz_cluster_blue_green_lineage
We need this view+index to determine the logical identity of clusters between blue green deployments in the Console.
1 parent dd25527 commit eab9624

File tree

8 files changed

+150
-6
lines changed

8 files changed

+150
-6
lines changed

doc/user/content/sql/system-catalog/mz_internal.md

Lines changed: 11 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -131,6 +131,17 @@ the most recent status for each AWS PrivateLink connection in the system.
131131
| `last_status_change_at` | [`timestamp with time zone`] | Wall-clock timestamp of the connection status change.|
132132
| `status` | [`text`] | | The status of the connection: one of `pending-service-discovery`, `creating-endpoint`, `recreating-endpoint`, `updating-endpoint`, `available`, `deleted`, `deleting`, `expired`, `failed`, `pending`, `pending-acceptance`, `rejected`, or `unknown`. |
133133

134+
## `mz_cluster_blue_green_lineage`
135+
136+
The `mz_cluster_blue_green_lineage` table shows the blue/green deployment lineage of all clusters in [`mz_clusters`](../mz_catalog/#mz_clusters). It determines all cluster IDs that are logically the same cluster.
137+
138+
<!-- RELATION_SPEC mz_internal.mz_cluster_blue_green_lineage -->
139+
| Field | Type | Meaning |
140+
|-------------------------------------|--------------|----------------------------------------------------------------|
141+
| `cluster_id` | [`text`] | The ID of the cluster. Corresponds to [`mz_clusters.id`](../mz_catalog/#mz_clusters). |
142+
| `current_deployment_cluster_id` | [`text`] | The cluster ID of the last cluster in `cluster_id`'s blue/green lineage. |
143+
| `cluster_name` | [`text`] | The name of the cluster |
144+
134145
## `mz_cluster_schedules`
135146

136147
The `mz_cluster_schedules` table shows the `SCHEDULE` option specified for each cluster.

src/catalog/src/builtin.rs

Lines changed: 121 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -8248,6 +8248,116 @@ FROM max_memory
82488248
}
82498249
});
82508250

8251+
/**
8252+
* Traces the blue/green deployment lineage in the audit log to determine all cluster
8253+
* IDs that are logically the same cluster.
8254+
* cluster_id: The ID of a cluster.
8255+
* current_deployment_cluster_id: The cluster ID of the last cluster in
8256+
* cluster_id's blue/green lineage.
8257+
* cluster_name: The name of the cluster.
8258+
* The approach taken is as follows. First, find all extant clusters and add them
8259+
* to the result set. Per cluster, we do the following:
8260+
* 1. Find the most recent create or rename event. This moment represents when the
8261+
* cluster took on its final logical identity.
8262+
* 2. Look for a cluster that had the same name (or the same name with `_dbt_deploy`
8263+
* appended) that was dropped within one minute of that moment. That cluster is
8264+
* almost certainly the logical predecessor of the current cluster. Add the cluster
8265+
* to the result set.
8266+
* 3. Repeat the procedure until a cluster with no logical predecessor is discovered.
8267+
* Limiting the search for a dropped cluster to a window of one minute is a heuristic,
8268+
* but one that's likely to be pretty good one. If a name is reused after more
8269+
* than one minute, that's a good sign that it wasn't an automatic blue/green
8270+
* process, but someone turning on a new use case that happens to have the same
8271+
* name as a previous but logically distinct use case.
8272+
*/
8273+
pub static MZ_CLUSTER_BLUE_GREEN_LINEAGE: LazyLock<BuiltinView> = LazyLock::new(|| BuiltinView {
8274+
name: "mz_cluster_blue_green_lineage",
8275+
schema: MZ_INTERNAL_SCHEMA,
8276+
oid: oid::VIEW_MZ_CLUSTER_BLUE_GREEN_LINEAGE_OID,
8277+
column_defs: Some(r#"cluster_id, current_deployment_cluster_id, cluster_name"#),
8278+
sql: r#"WITH MUTUALLY RECURSIVE cluster_events (
8279+
cluster_id text,
8280+
cluster_name text,
8281+
event_type text,
8282+
occurred_at timestamptz
8283+
) AS (
8284+
SELECT coalesce(details->>'id', details->>'cluster_id') AS cluster_id,
8285+
coalesce(details->>'name', details->>'new_name') AS cluster_name,
8286+
event_type,
8287+
occurred_at
8288+
FROM mz_audit_events
8289+
WHERE (
8290+
event_type IN ('create', 'drop')
8291+
OR (
8292+
event_type = 'alter'
8293+
AND details ? 'new_name'
8294+
)
8295+
)
8296+
AND object_type = 'cluster'
8297+
AND mz_now() < occurred_at + INTERVAL '30 days'
8298+
),
8299+
mz_cluster_blue_green_lineage (
8300+
cluster_id text,
8301+
current_deployment_cluster_id text,
8302+
cluster_name text
8303+
) AS (
8304+
SELECT c.id,
8305+
c.id,
8306+
c.name
8307+
FROM mz_clusters c
8308+
WHERE c.id LIKE 'u%'
8309+
UNION
8310+
SELECT *
8311+
FROM dropped_clusters
8312+
),
8313+
-- Closest create or rename event based on the current clusters in the result set
8314+
most_recent_create_or_rename (
8315+
cluster_id text,
8316+
current_deployment_cluster_id text,
8317+
cluster_name text,
8318+
occurred_at timestamptz
8319+
) AS (
8320+
SELECT DISTINCT ON (e.cluster_id) e.cluster_id,
8321+
c.current_deployment_cluster_id,
8322+
e.cluster_name,
8323+
e.occurred_at
8324+
FROM mz_cluster_blue_green_lineage c
8325+
JOIN cluster_events e ON c.cluster_id = e.cluster_id
8326+
AND c.cluster_name = e.cluster_name
8327+
WHERE e.event_type <> 'drop'
8328+
ORDER BY e.cluster_id,
8329+
e.occurred_at DESC
8330+
),
8331+
-- Clusters that were dropped most recently within 1 minute of most_recent_create_or_rename
8332+
dropped_clusters (
8333+
cluster_id text,
8334+
current_deployment_cluster_id text,
8335+
cluster_name text
8336+
) AS (
8337+
SELECT DISTINCT ON (cr.cluster_id) e.cluster_id,
8338+
cr.current_deployment_cluster_id,
8339+
cr.cluster_name
8340+
FROM most_recent_create_or_rename cr
8341+
JOIN cluster_events e ON e.occurred_at BETWEEN cr.occurred_at - interval '1 minute'
8342+
AND cr.occurred_at + interval '1 minute'
8343+
AND (
8344+
e.cluster_name = cr.cluster_name
8345+
OR e.cluster_name = cr.cluster_name || '_dbt_deploy'
8346+
)
8347+
WHERE e.event_type = 'drop'
8348+
ORDER BY cr.cluster_id,
8349+
abs(
8350+
extract(
8351+
epoch
8352+
FROM cr.occurred_at - e.occurred_at
8353+
)
8354+
)
8355+
)
8356+
SELECT *
8357+
FROM mz_cluster_blue_green_lineage"#,
8358+
access: vec![PUBLIC_SELECT],
8359+
});
8360+
82518361
pub const MZ_SHOW_DATABASES_IND: BuiltinIndex = BuiltinIndex {
82528362
name: "mz_show_databases_ind",
82538363
schema: MZ_INTERNAL_SCHEMA,
@@ -8482,6 +8592,15 @@ ON mz_internal.mz_console_cluster_utilization_overview (cluster_id)",
84828592
is_retained_metrics_object: false,
84838593
};
84848594

8595+
pub const MZ_CLUSTER_BLUE_GREEN_LINEAGE_IND: BuiltinIndex = BuiltinIndex {
8596+
name: "mz_cluster_blue_green_lineage_ind",
8597+
schema: MZ_INTERNAL_SCHEMA,
8598+
oid: oid::INDEX_MZ_CLUSTER_BLUE_GREEN_LINEAGE_IND_OID,
8599+
sql: "IN CLUSTER mz_catalog_server
8600+
ON mz_internal.mz_cluster_blue_green_lineage (cluster_id)",
8601+
is_retained_metrics_object: false,
8602+
};
8603+
84858604
pub const MZ_CLUSTERS_IND: BuiltinIndex = BuiltinIndex {
84868605
name: "mz_clusters_ind",
84878606
schema: MZ_CATALOG_SCHEMA,
@@ -9420,6 +9539,7 @@ pub static BUILTINS_STATIC: LazyLock<Vec<Builtin<NameReference>>> = LazyLock::ne
94209539
Builtin::View(&MZ_HYDRATION_STATUSES),
94219540
Builtin::View(&MZ_SHOW_CLUSTER_REPLICAS),
94229541
Builtin::View(&MZ_SHOW_NETWORK_POLICIES),
9542+
Builtin::View(&MZ_CLUSTER_BLUE_GREEN_LINEAGE),
94239543
Builtin::Index(&MZ_SHOW_DATABASES_IND),
94249544
Builtin::Index(&MZ_SHOW_SCHEMAS_IND),
94259545
Builtin::Index(&MZ_SHOW_CONNECTIONS_IND),
@@ -9475,6 +9595,7 @@ pub static BUILTINS_STATIC: LazyLock<Vec<Builtin<NameReference>>> = LazyLock::ne
94759595
Builtin::Index(&MZ_SECRETS_IND),
94769596
Builtin::Index(&MZ_VIEWS_IND),
94779597
Builtin::Index(&MZ_CONSOLE_CLUSTER_UTILIZATION_OVERVIEW_IND),
9598+
Builtin::Index(&MZ_CLUSTER_BLUE_GREEN_LINEAGE_IND),
94789599
Builtin::View(&MZ_RECENT_STORAGE_USAGE),
94799600
Builtin::Index(&MZ_RECENT_STORAGE_USAGE_IND),
94809601
Builtin::Connection(&MZ_ANALYTICS),

src/environmentd/tests/testdata/http/ws

Lines changed: 2 additions & 2 deletions
Large diffs are not rendered by default.

src/pgrepr-consts/src/oid.rs

Lines changed: 2 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -768,3 +768,5 @@ pub const LOG_MZ_COMPUTE_DATAFLOW_GLOBAL_IDS_PER_WORKER_OID: u32 = 17045;
768768
pub const VIEW_MZ_LIR_MAPPING_OID: u32 = 17046;
769769
pub const VIEW_MZ_DATAFLOW_GLOBAL_IDS_OID: u32 = 17047;
770770
pub const NETWORK_POLICIES_DEFAULT_POLICY_OID: u32 = 17048;
771+
pub const VIEW_MZ_CLUSTER_BLUE_GREEN_LINEAGE_OID: u32 = 17049;
772+
pub const INDEX_MZ_CLUSTER_BLUE_GREEN_LINEAGE_IND_OID: u32 = 17050;

test/sqllogictest/cluster.slt

Lines changed: 2 additions & 2 deletions
Original file line numberDiff line numberDiff line change
@@ -425,15 +425,15 @@ CREATE CLUSTER test REPLICAS (foo (SIZE '1'));
425425
query I
426426
SELECT COUNT(name) FROM mz_indexes;
427427
----
428-
285
428+
286
429429

430430
statement ok
431431
DROP CLUSTER test CASCADE
432432

433433
query T
434434
SELECT COUNT(name) FROM mz_indexes;
435435
----
436-
254
436+
255
437437

438438
simple conn=mz_system,user=mz_system
439439
ALTER CLUSTER quickstart OWNER TO materialize

test/sqllogictest/information_schema_tables.slt

Lines changed: 4 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -281,6 +281,10 @@ mz_aws_privatelink_connection_statuses
281281
VIEW
282282
materialize
283283
mz_internal
284+
mz_cluster_blue_green_lineage
285+
VIEW
286+
materialize
287+
mz_internal
284288
mz_cluster_replica_history
285289
VIEW
286290
materialize

test/sqllogictest/mz_catalog_server_index_accounting.slt

Lines changed: 6 additions & 2 deletions
Original file line numberDiff line numberDiff line change
@@ -37,6 +37,7 @@ mz_arrangement_heap_capacity_raw_s2_primary_idx CREATE␠INDEX␠"mz_arrangemen
3737
mz_arrangement_heap_size_raw_s2_primary_idx CREATE␠INDEX␠"mz_arrangement_heap_size_raw_s2_primary_idx"␠IN␠CLUSTER␠[s2]␠ON␠"mz_introspection"."mz_arrangement_heap_size_raw"␠("operator_id",␠"worker_id")
3838
mz_arrangement_records_raw_s2_primary_idx CREATE␠INDEX␠"mz_arrangement_records_raw_s2_primary_idx"␠IN␠CLUSTER␠[s2]␠ON␠"mz_introspection"."mz_arrangement_records_raw"␠("operator_id",␠"worker_id")
3939
mz_arrangement_sharing_raw_s2_primary_idx CREATE␠INDEX␠"mz_arrangement_sharing_raw_s2_primary_idx"␠IN␠CLUSTER␠[s2]␠ON␠"mz_introspection"."mz_arrangement_sharing_raw"␠("operator_id",␠"worker_id")
40+
mz_cluster_blue_green_lineage_ind CREATE␠INDEX␠"mz_cluster_blue_green_lineage_ind"␠IN␠CLUSTER␠[s2]␠ON␠[s717␠AS␠"mz_internal"."mz_cluster_blue_green_lineage"]␠("cluster_id")
4041
mz_cluster_replica_history_ind CREATE␠INDEX␠"mz_cluster_replica_history_ind"␠IN␠CLUSTER␠[s2]␠ON␠[s579␠AS␠"mz_internal"."mz_cluster_replica_history"]␠("dropped_at")
4142
mz_cluster_replica_metrics_history_ind CREATE␠INDEX␠"mz_cluster_replica_metrics_history_ind"␠IN␠CLUSTER␠[s2]␠ON␠[s492␠AS␠"mz_internal"."mz_cluster_replica_metrics_history"]␠("replica_id")
4243
mz_cluster_replica_metrics_ind CREATE␠INDEX␠"mz_cluster_replica_metrics_ind"␠IN␠CLUSTER␠[s2]␠ON␠[s491␠AS␠"mz_internal"."mz_cluster_replica_metrics"]␠("replica_id")
@@ -74,7 +75,7 @@ mz_message_batch_counts_received_raw_s2_primary_idx CREATE␠INDEX␠"mz_messag
7475
mz_message_batch_counts_sent_raw_s2_primary_idx CREATE␠INDEX␠"mz_message_batch_counts_sent_raw_s2_primary_idx"␠IN␠CLUSTER␠[s2]␠ON␠"mz_introspection"."mz_message_batch_counts_sent_raw"␠("channel_id",␠"from_worker_id",␠"to_worker_id")
7576
mz_message_counts_received_raw_s2_primary_idx CREATE␠INDEX␠"mz_message_counts_received_raw_s2_primary_idx"␠IN␠CLUSTER␠[s2]␠ON␠"mz_introspection"."mz_message_counts_received_raw"␠("channel_id",␠"from_worker_id",␠"to_worker_id")
7677
mz_message_counts_sent_raw_s2_primary_idx CREATE␠INDEX␠"mz_message_counts_sent_raw_s2_primary_idx"␠IN␠CLUSTER␠[s2]␠ON␠"mz_introspection"."mz_message_counts_sent_raw"␠("channel_id",␠"from_worker_id",␠"to_worker_id")
77-
mz_notices_ind CREATE␠INDEX␠"mz_notices_ind"␠IN␠CLUSTER␠[s2]␠ON␠[s780␠AS␠"mz_internal"."mz_notices"]␠("id")
78+
mz_notices_ind CREATE␠INDEX␠"mz_notices_ind"␠IN␠CLUSTER␠[s2]␠ON␠[s782␠AS␠"mz_internal"."mz_notices"]␠("id")
7879
mz_object_dependencies_ind CREATE␠INDEX␠"mz_object_dependencies_ind"␠IN␠CLUSTER␠[s2]␠ON␠[s454␠AS␠"mz_internal"."mz_object_dependencies"]␠("object_id")
7980
mz_object_history_ind CREATE␠INDEX␠"mz_object_history_ind"␠IN␠CLUSTER␠[s2]␠ON␠[s518␠AS␠"mz_internal"."mz_object_history"]␠("id")
8081
mz_object_lifetimes_ind CREATE␠INDEX␠"mz_object_lifetimes_ind"␠IN␠CLUSTER␠[s2]␠ON␠[s519␠AS␠"mz_internal"."mz_object_lifetimes"]␠("id")
@@ -83,7 +84,7 @@ mz_objects_ind CREATE␠INDEX␠"mz_objects_ind"␠IN␠CLUSTER␠[s2]␠ON␠[
8384
mz_peek_durations_histogram_raw_s2_primary_idx CREATE␠INDEX␠"mz_peek_durations_histogram_raw_s2_primary_idx"␠IN␠CLUSTER␠[s2]␠ON␠"mz_introspection"."mz_peek_durations_histogram_raw"␠("worker_id",␠"type",␠"duration_ns")
8485
mz_recent_activity_log_thinned_ind CREATE␠INDEX␠"mz_recent_activity_log_thinned_ind"␠IN␠CLUSTER␠[s2]␠ON␠[s678␠AS␠"mz_internal"."mz_recent_activity_log_thinned"]␠("sql_hash")
8586
mz_recent_sql_text_ind CREATE␠INDEX␠"mz_recent_sql_text_ind"␠IN␠CLUSTER␠[s2]␠ON␠[s674␠AS␠"mz_internal"."mz_recent_sql_text"]␠("sql_hash")
86-
mz_recent_storage_usage_ind CREATE␠INDEX␠"mz_recent_storage_usage_ind"␠IN␠CLUSTER␠[s2]␠ON␠[s772␠AS␠"mz_catalog"."mz_recent_storage_usage"]␠("object_id")
87+
mz_recent_storage_usage_ind CREATE␠INDEX␠"mz_recent_storage_usage_ind"␠IN␠CLUSTER␠[s2]␠ON␠[s774␠AS␠"mz_catalog"."mz_recent_storage_usage"]␠("object_id")
8788
mz_roles_ind CREATE␠INDEX␠"mz_roles_ind"␠IN␠CLUSTER␠[s2]␠ON␠[s477␠AS␠"mz_catalog"."mz_roles"]␠("id")
8889
mz_scheduling_elapsed_raw_s2_primary_idx CREATE␠INDEX␠"mz_scheduling_elapsed_raw_s2_primary_idx"␠IN␠CLUSTER␠[s2]␠ON␠"mz_introspection"."mz_scheduling_elapsed_raw"␠("id",␠"worker_id")
8990
mz_scheduling_parks_histogram_raw_s2_primary_idx CREATE␠INDEX␠"mz_scheduling_parks_histogram_raw_s2_primary_idx"␠IN␠CLUSTER␠[s2]␠ON␠"mz_introspection"."mz_scheduling_parks_histogram_raw"␠("worker_id",␠"slept_for_ns",␠"requested_ns")
@@ -203,6 +204,9 @@ mz_audit_events object_type
203204
mz_audit_events occurred_at
204205
mz_audit_events user
205206
mz_base_types id
207+
mz_cluster_blue_green_lineage cluster_id
208+
mz_cluster_blue_green_lineage cluster_name
209+
mz_cluster_blue_green_lineage current_deployment_cluster_id
206210
mz_cluster_replica_frontiers object_id
207211
mz_cluster_replica_frontiers replica_id
208212
mz_cluster_replica_frontiers write_frontier

test/sqllogictest/oid.slt

Lines changed: 2 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -1153,3 +1153,5 @@ SELECT oid, name FROM mz_objects WHERE id LIKE 's%' AND oid < 20000 ORDER BY oid
11531153
17045 mz_compute_dataflow_global_ids_per_worker
11541154
17046 mz_lir_mapping
11551155
17047 mz_dataflow_global_ids
1156+
17049 mz_cluster_blue_green_lineage
1157+
17050 mz_cluster_blue_green_lineage_ind

0 commit comments

Comments
 (0)