Skip to content

Commit

Permalink
Update existing and add new SQL queries to the assessment step dashbo…
Browse files Browse the repository at this point in the history
…ard (#269)

Fixes #268

---------

Co-authored-by: FastLee <lbareket@gmail.com>
  • Loading branch information
larsgeorge-db and FastLee committed Sep 25, 2023
1 parent f7eab58 commit dfa350a
Show file tree
Hide file tree
Showing 12 changed files with 111 additions and 22 deletions.
16 changes: 16 additions & 0 deletions src/databricks/labs/ucx/assessment/queries/all_tables.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,16 @@
-- viz type=table, name=Table Types, columns=database,name,type,format,table_view,storage,is_delta,location
-- widget title=Table Types, col=0, row=3, size_x=6, size_y=6
SELECT `database`,
name,
object_type AS type,
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"
ELSE "EXTERNAL"
END AS storage,
IF(format = "delta", "Yes", "No") AS is_delta,
location
FROM $inventory.tables
9 changes: 9 additions & 0 deletions src/databricks/labs/ucx/assessment/queries/clusters.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,9 @@
-- viz type=table, name=Clusters, columns=cluster_id,cluster_name,creator,compatible,failures
-- widget title=Clusters, col=0, row=25, size_x=6, size_y=8
SELECT cluster_id,
cluster_name,
creator,
IF(success = 1, "Compatible", "Incompatible") AS compatible,
failures
FROM $inventory.clusters
WHERE NOT STARTSWITH(cluster_name, "job-")
Original file line number Diff line number Diff line change
@@ -0,0 +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
SELECT COUNT(DISTINCT `database`) AS count_total_databases
FROM hive_metastore.ucx.tables
Original file line number Diff line number Diff line change
@@ -0,0 +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
SELECT count(*) AS count_total_tables
FROM $inventory.tables
25 changes: 25 additions & 0 deletions src/databricks/labs/ucx/assessment/queries/database_summary.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,25 @@
-- viz type=table, name=Database Summary, columns=database,tables,views,dbfs_root,delta_tables,upgrade
-- widget title=Database Summary, col=0, row=9, size_x=6, size_y=8
SELECT `database`,
SUM(is_table) AS tables,
SUM(is_view) AS views,
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"
ELSE "In Place Sync"
END AS upgrade
FROM
(SELECT DATABASE,
name,
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,
IF(STARTSWITH(location, "/dbfs/") AND NOT STARTSWITH(location, "/dbfs/mnt"), 1, 0) AS is_dbfs_root,
IF(UPPER(format) = "DELTA", 1, 0) AS is_delta
FROM $inventory.tables)
GROUP BY `database`
ORDER BY `database`
Original file line number Diff line number Diff line change
@@ -0,0 +1,4 @@
-- viz type=table, name=External Locations, columns=location
-- widget title=External Locations, col=0, row=17, size_x=3, size_y=8
SELECT location
FROM hive_metastore.ucx.external_locations
9 changes: 9 additions & 0 deletions src/databricks/labs/ucx/assessment/queries/jobs.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,9 @@
-- viz type=table, name=Jobs, columns=job_id,job_name,creator,compatible,failures
-- widget title=Jobs, col=0, row=33, size_x=6, size_y=8
SELECT job_id,
job_name,
creator,
IF(success=1, "Compatible", "Incompatible") AS compatible,
failures
FROM $inventory.jobs
WHERE job_name not like '[UCX]%'
5 changes: 5 additions & 0 deletions src/databricks/labs/ucx/assessment/queries/mount_points.sql
Original file line number Diff line number Diff line change
@@ -0,0 +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
SELECT name,
source
FROM hive_metastore.ucx.mounts
11 changes: 0 additions & 11 deletions src/databricks/labs/ucx/assessment/queries/total_tables.sql

This file was deleted.

This file was deleted.

36 changes: 34 additions & 2 deletions src/databricks/labs/ucx/framework/dashboards.py
Original file line number Diff line number Diff line change
Expand Up @@ -130,7 +130,7 @@ def _install_widget(self, query: SimpleQuery):
def _get_widget_options(self, query: SimpleQuery):
self._pos += 1
widget_options = WidgetOptions(
title=query.widget["title"],
title=query.widget.get("title", ""),
description=query.widget.get("description", None),
position=WidgetPosition(
col=int(query.widget.get("col", 0)),
Expand Down Expand Up @@ -227,7 +227,7 @@ def _install_viz(self, query: SimpleQuery):
self._state[query.viz_key] = viz.id

def _get_viz_options(self, query: SimpleQuery):
viz_types = {"table": self._table_viz_args}
viz_types = {"table": self._table_viz_args, "counter": self._counter_viz_args}
if query.viz_type not in viz_types:
msg = f"{query.query}: unknown viz type: {query.viz_type}"
raise SyntaxError(msg)
Expand Down Expand Up @@ -270,6 +270,38 @@ def _table_viz_args(
},
}

@staticmethod
def _counter_viz_args(
name: str,
value_column: str,
*,
description: str | None = None,
counter_label: str | None = None,
value_row_number: int = 1,
target_row_number: int = 1,
string_decimal: int = 0,
string_decimal_char: str = ".",
string_thousand_separator: str = ",",
tooltip_format: str = "0,0.000",
count_row: bool = False,
) -> dict:
return {
"type": "COUNTER",
"name": name,
"description": description,
"options": {
"counterLabel": counter_label,
"counterColName": value_column,
"rowNumber": value_row_number,
"targetRowNumber": target_row_number,
"stringDecimal": string_decimal,
"stringDecChar": string_decimal_char,
"stringThouSep": string_thousand_separator,
"tooltipFormat": tooltip_format,
"countRow": count_row,
},
}

@staticmethod
def _parse_magic_comment(f, magic_comment, text):
viz_comment = next(_ for _ in text.splitlines() if _.startswith(magic_comment))
Expand Down
2 changes: 1 addition & 1 deletion tests/integration/framework/test_dashboards.py
Original file line number Diff line number Diff line change
Expand Up @@ -15,7 +15,7 @@
# logging.getLogger("databricks").setLevel("DEBUG")


def test_creating_widgets(ws: WorkspaceClient):
def test_creating_widgets(ws: WorkspaceClient, make_warehouse, make_schema):
pytest.skip()
dashboard_widgets_api = DashboardWidgetsAPI(ws.api_client)
query_visualizations_api = QueryVisualizationsExt(ws.api_client)
Expand Down

0 comments on commit dfa350a

Please sign in to comment.