@@ -8248,6 +8248,116 @@ FROM max_memory
8248
8248
}
8249
8249
} ) ;
8250
8250
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
+
8251
8361
pub const MZ_SHOW_DATABASES_IND : BuiltinIndex = BuiltinIndex {
8252
8362
name : "mz_show_databases_ind" ,
8253
8363
schema : MZ_INTERNAL_SCHEMA ,
@@ -8482,6 +8592,15 @@ ON mz_internal.mz_console_cluster_utilization_overview (cluster_id)",
8482
8592
is_retained_metrics_object : false ,
8483
8593
} ;
8484
8594
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
+
8485
8604
pub const MZ_CLUSTERS_IND : BuiltinIndex = BuiltinIndex {
8486
8605
name : "mz_clusters_ind" ,
8487
8606
schema : MZ_CATALOG_SCHEMA ,
@@ -9420,6 +9539,7 @@ pub static BUILTINS_STATIC: LazyLock<Vec<Builtin<NameReference>>> = LazyLock::ne
9420
9539
Builtin :: View ( & MZ_HYDRATION_STATUSES ) ,
9421
9540
Builtin :: View ( & MZ_SHOW_CLUSTER_REPLICAS ) ,
9422
9541
Builtin :: View ( & MZ_SHOW_NETWORK_POLICIES ) ,
9542
+ Builtin :: View ( & MZ_CLUSTER_BLUE_GREEN_LINEAGE ) ,
9423
9543
Builtin :: Index ( & MZ_SHOW_DATABASES_IND ) ,
9424
9544
Builtin :: Index ( & MZ_SHOW_SCHEMAS_IND ) ,
9425
9545
Builtin :: Index ( & MZ_SHOW_CONNECTIONS_IND ) ,
@@ -9475,6 +9595,7 @@ pub static BUILTINS_STATIC: LazyLock<Vec<Builtin<NameReference>>> = LazyLock::ne
9475
9595
Builtin :: Index ( & MZ_SECRETS_IND ) ,
9476
9596
Builtin :: Index ( & MZ_VIEWS_IND ) ,
9477
9597
Builtin :: Index ( & MZ_CONSOLE_CLUSTER_UTILIZATION_OVERVIEW_IND ) ,
9598
+ Builtin :: Index ( & MZ_CLUSTER_BLUE_GREEN_LINEAGE_IND ) ,
9478
9599
Builtin :: View ( & MZ_RECENT_STORAGE_USAGE ) ,
9479
9600
Builtin :: Index ( & MZ_RECENT_STORAGE_USAGE_IND ) ,
9480
9601
Builtin :: Connection ( & MZ_ANALYTICS ) ,
0 commit comments