Skip to content

Commit

Permalink
Improved dashboard queries to show unsupported storage types. (#398)
Browse files Browse the repository at this point in the history
  • Loading branch information
larsgeorge-db authored Oct 6, 2023
1 parent 4453b4c commit 8df6153
Show file tree
Hide file tree
Showing 2 changed files with 23 additions and 8 deletions.
7 changes: 5 additions & 2 deletions src/databricks/labs/ucx/assessment/queries/all_tables.sql
Original file line number Diff line number Diff line change
Expand Up @@ -6,9 +6,12 @@ SELECT `database`,
UPPER(table_format) AS format,
IF(object_type IN ("MANAGED", "EXTERNAL"), "TABLE", "VIEW") AS table_view,
CASE
WHEN STARTSWITH(location, "/dbfs/")
AND NOT STARTSWITH(location, "/dbfs/mnt") THEN "DBFS ROOT"
WHEN STARTSWITH(location, "dbfs:/mnt") THEN "DBFS MOUNT"
WHEN STARTSWITH(location, "/dbfs/mnt") THEN "DBFS MOUNT"
WHEN STARTSWITH(location, "dbfs:/") THEN "DBFS ROOT"
WHEN STARTSWITH(location, "/dbfs/") THEN "DBFS ROOT"
WHEN STARTSWITH(location, "wasb") THEN "UNSUPPORTED"
WHEN STARTSWITH(location, "adl") THEN "UNSUPPORTED"
ELSE "EXTERNAL"
END AS storage,
IF(format = "delta", "Yes", "No") AS is_delta,
Expand Down
24 changes: 18 additions & 6 deletions src/databricks/labs/ucx/assessment/queries/database_summary.sql
Original file line number Diff line number Diff line change
Expand Up @@ -3,22 +3,34 @@
SELECT `database`,
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,
CASE
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_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
FROM
(SELECT DATABASE,
(SELECT `database`,
name,
object_type,
UPPER(table_format) AS format,
LOCATION,
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,
IF(STARTSWITH(location, "/dbfs/") AND NOT STARTSWITH(location, "/dbfs/mnt"), 1, 0) AS is_dbfs_root,
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(UPPER(format) = "DELTA", 1, 0) AS is_delta
FROM $inventory.tables)
GROUP BY `database`
Expand Down

0 comments on commit 8df6153

Please sign in to comment.