-
Notifications
You must be signed in to change notification settings - Fork 87
Commit
This commit does not belong to any branch on this repository, and may belong to a fork outside of the repository.
Added more views to assessment dashboard (#474)
This PR has the following improvements for views and tables: - `assessment/queries` are renamed and refactored to more efficiently fit the grid - introduced `assessment/views` to hold common views that could be reused by multiple commands and widgets. - introduced `crawlers.SchemaDeployer`, that is (re-)creating views and tables **upon installation** (and not on the assessment step). - added `search_by` field for table widgets - improved parallelism for fetching grants - removed (now redundant) `setup_schema` and `setup_view` tasks from `assessment` workflow <img width="1981" alt="_UCX__serge_smertin__UCX_Assessment" src="https://github.com/databrickslabs/ucx/assets/259697/7addb0bb-b301-47ea-b351-9b75cd0a5d9d"> <img width="1985" alt="_UCX__serge_smertin__UCX_Assessment" src="https://github.com/databrickslabs/ucx/assets/259697/88effab7-59bb-46aa-af9b-bd9185d4f817">
- Loading branch information
1 parent
7ff8d5d
commit ed9775a
Showing
34 changed files
with
336 additions
and
274 deletions.
There are no files selected for viewing
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
2 changes: 1 addition & 1 deletion
2
...ssment/azure/azure_service_principals.sql → ...t/azure/05_0_azure_service_principals.sql
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
6 changes: 6 additions & 0 deletions
6
src/databricks/labs/ucx/queries/assessment/main/00_0_compatibility.sql
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,6 @@ | ||
-- viz type=counter, name=Workspace UC readiness, counter_label=UC readiness, value_column=readiness | ||
-- widget row=0, col=0, size_x=1, size_y=3 | ||
WITH raw AS ( | ||
SELECT object_type, object_id, IF(failures == '[]', 1, 0) AS ready FROM $inventory.objects | ||
) | ||
SELECT CONCAT(ROUND(SUM(ready) / COUNT(*) * 100, 1), '%') AS readiness FROM raw |
2 changes: 1 addition & 1 deletion
2
...assessment/main/count_total_databases.sql → ...sment/main/00_1_count_total_databases.sql
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -1,4 +1,4 @@ | ||
-- viz type=counter, name=Total Database Count, counter_label=Total Databases, value_column=count_total_databases | ||
-- widget col=0, row=0, size_x=1, size_y=3 | ||
-- widget row=0, col=1, size_x=1, size_y=3 | ||
SELECT COUNT(DISTINCT `database`) AS count_total_databases | ||
FROM $inventory.tables |
File renamed without changes.
4 changes: 4 additions & 0 deletions
4
src/databricks/labs/ucx/queries/assessment/main/00_3_count_external_locations.sql
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,4 @@ | ||
-- viz type=counter, name=Storage Locations, counter_label=Storage Locations, value_column=count_total | ||
-- widget row=0, col=4, size_x=1, size_y=3 | ||
SELECT count(*) AS count_total | ||
FROM $inventory.external_locations |
2 changes: 1 addition & 1 deletion
2
...es/assessment/main/count_total_tables.sql → ...sessment/main/00_4_count_total_tables.sql
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -1,4 +1,4 @@ | ||
-- viz type=counter, name=Total Table Count, counter_label=Total Tables, value_column=count_total_tables | ||
-- widget col=1, row=0, size_x=1, size_y=3 | ||
-- widget row=0, col=3, size_x=1, size_y=3 | ||
SELECT count(*) AS count_total_tables | ||
FROM $inventory.tables |
9 changes: 9 additions & 0 deletions
9
src/databricks/labs/ucx/queries/assessment/main/01_0_object_readiness.sql
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,9 @@ | ||
-- viz type=table, name=Object Type Readiness, columns=object_type,readiness | ||
-- widget title=Readiness, row=1, col=0, size_x=1, size_y=8 | ||
WITH raw AS ( | ||
SELECT object_type, object_id, IF(failures == '[]', 1, 0) AS ready FROM $inventory.objects | ||
) | ||
SELECT object_type, CONCAT(ROUND(SUM(ready) / COUNT(*) * 100, 1), '%') AS readiness | ||
FROM raw | ||
GROUP BY object_type | ||
ORDER BY readiness DESC |
7 changes: 7 additions & 0 deletions
7
src/databricks/labs/ucx/queries/assessment/main/01_1_failure_summary.sql
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,7 @@ | ||
-- viz type=table, name=Failure Summary, search_by=failure, columns=failure,count | ||
-- widget title=Failure Summary, row=1, col=1, size_x=2, size_y=8 | ||
WITH raw AS ( | ||
SELECT EXPLODE(FROM_JSON(failures, 'array<string>')) AS failure FROM $inventory.objects WHERE failures <> '[]' | ||
) | ||
SELECT failure, COUNT(*) AS count FROM raw GROUP BY failure | ||
ORDER BY count DESC, failure DESC |
8 changes: 3 additions & 5 deletions
8
...cx/queries/assessment/main/all_tables.sql → ...eries/assessment/main/01_3_all_tables.sql
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
53 changes: 53 additions & 0 deletions
53
src/databricks/labs/ucx/queries/assessment/main/02_0_database_summary.sql
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,53 @@ | ||
-- viz type=table, name=Database Summary, search_by=database, columns=database,upgrade,tables,views,dbfs_root,delta_tables,total_grants,granted_principals,database_grants,table_grants,service_principal_grants,user_grants,group_grants | ||
-- widget title=Database Summary, col=0, row=2, size_x=6, size_y=8 | ||
WITH table_stats AS ( | ||
SELECT | ||
`database`, | ||
object_type, | ||
UPPER(table_format) AS `format`, | ||
`location`, | ||
IF(object_type IN ("MANAGED", "EXTERNAL"), 1, 0) AS is_table, | ||
IF(object_type = "VIEW", 1, 0) AS is_view, | ||
CASE | ||
WHEN STARTSWITH(location, "dbfs:/") AND NOT STARTSWITH(location, "dbfs:/mnt") THEN 1 | ||
WHEN STARTSWITH(location, "/dbfs/") AND NOT STARTSWITH(location, "/dbfs/mnt") THEN 1 | ||
ELSE 0 | ||
END AS is_dbfs_root, | ||
CASE | ||
WHEN STARTSWITH(location, "wasb") THEN 1 | ||
WHEN STARTSWITH(location, "adl") THEN 1 | ||
ELSE 0 | ||
END AS is_unsupported, | ||
IF(format = "DELTA", 1, 0) AS is_delta | ||
FROM $inventory.tables | ||
), database_stats AS ( | ||
SELECT `database`, | ||
CASE | ||
WHEN SUM(is_table) = 0 AND SUM(is_view) > 0 THEN "View Migration Required" | ||
WHEN SUM(is_dbfs_root)/SUM(is_table) > .3 THEN "Asset Replication Required" | ||
WHEN SUM(is_delta)/SUM(is_table) < .7 THEN "Some Non Delta Assets" | ||
WHEN SUM(is_unsupported)/SUM(is_table) > .7 THEN "Storage Migration Required" | ||
ELSE "In Place Sync" | ||
END AS upgrade, | ||
SUM(is_table) AS tables, | ||
SUM(is_view) AS views, | ||
SUM(is_unsupported) AS unsupported, | ||
SUM(is_dbfs_root) AS dbfs_root, | ||
SUM(is_delta) AS delta_tables | ||
FROM table_stats | ||
GROUP BY `database` | ||
), grant_stats AS ( | ||
SELECT | ||
`database`, | ||
COUNT(*) AS total_grants, | ||
COUNT(DISTINCT principal) AS granted_principals, | ||
SUM(IF(object_type == 'DATABASE', 1, 0)) AS database_grants, | ||
SUM(IF(object_type == 'TABLE', 1, 0)) AS table_grants, | ||
SUM(IF(principal_type == 'service-principal', 1, 0)) AS service_principal_grants, | ||
SUM(IF(principal_type == 'user', 1, 0)) AS user_grants, | ||
SUM(IF(principal_type == 'group', 1, 0)) AS group_grants | ||
FROM $inventory.grant_detail | ||
GROUP BY `database` | ||
) | ||
SELECT * FROM database_stats FULL JOIN grant_stats USING (`database`) | ||
ORDER BY tables DESC |
2 changes: 1 addition & 1 deletion
2
...es/assessment/main/external_locations.sql → ...sessment/main/03_0_external_locations.sql
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -1,4 +1,4 @@ | ||
-- viz type=table, name=External Locations, columns=location | ||
-- widget title=External Locations, col=0, row=17, size_x=3, size_y=8 | ||
-- widget title=External Locations, row=3, col=0, size_x=3, size_y=8 | ||
SELECT location | ||
FROM $inventory.external_locations |
2 changes: 1 addition & 1 deletion
2
.../queries/assessment/main/mount_points.sql → ...ies/assessment/main/03_3_mount_points.sql
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -1,5 +1,5 @@ | ||
-- viz type=table, name=Mount Points, columns=name,source | ||
-- widget title=Mount Points, col=3, row=17, size_x=3, size_y=8 | ||
-- widget title=Mount Points, row=3, col=3, size_x=3, size_y=8 | ||
SELECT name, | ||
source | ||
FROM $inventory.mounts |
9 changes: 9 additions & 0 deletions
9
src/databricks/labs/ucx/queries/assessment/main/04_0_clusters.sql
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,9 @@ | ||
-- viz type=table, name=Clusters, columns=failure,cluster_name,cluster_id,creator | ||
-- widget title=Incompatible clusters, row=4, col=0, size_x=3, size_y=8 | ||
SELECT EXPLODE(FROM_JSON(failures, 'array<string>')) AS failure, | ||
cluster_id, | ||
cluster_name, | ||
creator | ||
FROM $inventory.clusters | ||
WHERE NOT STARTSWITH(cluster_name, "job-") | ||
ORDER BY cluster_id DESC |
10 changes: 10 additions & 0 deletions
10
src/databricks/labs/ucx/queries/assessment/main/04_3_jobs.sql
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,10 @@ | ||
-- viz type=table, name=Jobs, columns=failure,job_id,job_name,creator | ||
-- widget title=Incompatible jobs, row=4, col=3, size_x=3, size_y=8 | ||
SELECT | ||
EXPLODE(FROM_JSON(failures, 'array<string>')) AS failure, | ||
job_id, | ||
job_name, | ||
creator | ||
FROM $inventory.jobs | ||
WHERE job_name not like '[UCX]%' | ||
ORDER BY job_id DESC |
Oops, something went wrong.