Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

Lantern 835 improve dashboard load time #486

Open
wants to merge 3 commits into
base: main
Choose a base branch
from
Open
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
Original file line number Diff line number Diff line change
@@ -0,0 +1,5 @@
BEGIN;

DROP MATERIALIZED VIEW IF EXISTS mv_endpoint_totals;

COMMIT;
25 changes: 25 additions & 0 deletions db/migration/migrations/000034_add_mv_endpoint_totals.up.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,25 @@
BEGIN;

DROP MATERIALIZED VIEW IF EXISTS mv_endpoint_totals;

CREATE MATERIALIZED VIEW mv_endpoint_totals AS
WITH latest_metadata AS (
SELECT max(fhir_endpoints_metadata.updated_at) AS last_updated
FROM fhir_endpoints_metadata
),
totals AS (
SELECT
(SELECT count(DISTINCT fhir_endpoints.url) FROM fhir_endpoints) AS all_endpoints,
(SELECT count(DISTINCT fhir_endpoints_info.url)
FROM fhir_endpoints_info
WHERE fhir_endpoints_info.requested_fhir_version = 'None') AS indexed_endpoints
)
SELECT
now() AS aggregation_date,
totals.all_endpoints,
totals.indexed_endpoints,
totals.all_endpoints - totals.indexed_endpoints AS nonindexed_endpoints,
(SELECT latest_metadata.last_updated FROM latest_metadata) AS last_updated
FROM totals;

COMMIT;
5 changes: 5 additions & 0 deletions db/migration/migrations/000035_response_tally_mv.down.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,5 @@
BEGIN;

DROP MATERIALIZED VIEW IF EXISTS response_tally_mv;

COMMIT;
39 changes: 39 additions & 0 deletions db/migration/migrations/000035_response_tally_mv.up.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,39 @@
BEGIN;

DROP MATERIALIZED VIEW IF EXISTS response_tally_mv;

CREATE MATERIALIZED VIEW response_tally_mv AS
WITH subquery AS (
SELECT
fem.http_response,
count(*) AS response_count
FROM fhir_endpoints_info fei
JOIN fhir_endpoints_metadata fem
ON fei.metadata_id = fem.id
WHERE fei.requested_fhir_version::text = 'None'::text
GROUP BY fem.http_response
)
SELECT
COALESCE(SUM(
CASE
WHEN subquery.http_response = 200 THEN subquery.response_count
ELSE 0::bigint
END), 0::numeric) AS http_200,
COALESCE(SUM(
CASE
WHEN subquery.http_response <> 200 THEN subquery.response_count
ELSE 0::bigint
END), 0::numeric) AS http_non200,
COALESCE(SUM(
CASE
WHEN subquery.http_response = 404 THEN subquery.response_count
ELSE 0::bigint
END), 0::numeric) AS http_404,
COALESCE(SUM(
CASE
WHEN subquery.http_response = 503 THEN subquery.response_count
ELSE 0::bigint
END), 0::numeric) AS http_503
FROM subquery;

COMMIT;
5 changes: 5 additions & 0 deletions db/migration/migrations/000036_mv_vendor_fhir_counts.down.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,5 @@
BEGIN;

DROP MATERIALIZED VIEW IF EXISTS mv_vendor_fhir_counts;

COMMIT;
50 changes: 50 additions & 0 deletions db/migration/migrations/000036_mv_vendor_fhir_counts.up.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,50 @@
BEGIN;

DROP MATERIALIZED VIEW IF EXISTS mv_vendor_fhir_counts;

CREATE MATERIALIZED VIEW mv_vendor_fhir_counts AS
WITH developer_counts AS (
SELECT
v_1.name AS vendor_name,
sum(count(e_1.url)) OVER (PARTITION BY v_1.name) AS developer_count
FROM endpoint_export e_1
LEFT JOIN vendors v_1
ON e_1.vendor_name::text = v_1.name::text
GROUP BY v_1.name
)
SELECT
COALESCE(v.name, 'Unknown'::character varying) AS vendor_name,
COALESCE(NULLIF(btrim(e.fhir_version::text), ''::text), 'Unknown'::text) AS fhir_version,
count(e.url)::integer AS n,
COALESCE(
CASE
WHEN v.name::text = 'Allscripts' THEN 'Allscripts'
WHEN v.name::text = 'CareEvolution, Inc.' THEN 'CareEvolution'
WHEN v.name::text = 'Cerner Corporation' THEN 'Cerner'
WHEN v.name::text = 'Epic Systems Corporation' THEN 'Epic'
WHEN v.name::text = 'Medical Information Technology, Inc. (MEDITECH)' THEN 'MEDITECH'
WHEN v.name::text = 'Microsoft Corporation' THEN 'Microsoft'
WHEN v.name::text = 'NA' THEN 'Unknown'
ELSE v.name
END, 'Unknown'::character varying
) AS short_name,
COALESCE(dc.developer_count, 0::numeric) AS developer_count,
COALESCE(
concat(
round(
COALESCE(count(e.url)::numeric / NULLIF(dc.developer_count, 0::numeric) * 100::numeric, 0::numeric),
0
), '%'
), '0%'::text
) AS percentage
FROM endpoint_export e
LEFT JOIN vendors v
ON e.vendor_name::text = v.name::text
LEFT JOIN developer_counts dc
ON v.name::text = dc.vendor_name::text
GROUP BY v.name, e.fhir_version, dc.developer_count
ORDER BY
COALESCE(v.name, 'Unknown'::character varying),
COALESCE(e.fhir_version, 'Unknown'::character varying);

COMMIT;
105 changes: 105 additions & 0 deletions db/sql/dbsetup.sql
Original file line number Diff line number Diff line change
Expand Up @@ -480,3 +480,108 @@ CREATE INDEX healthit_products_certification_status_idx ON healthit_products (ce
CREATE INDEX healthit_products_chpl_id_idx ON healthit_products (chpl_id);
CREATE INDEX fhir_endpoint_organizations_map_id_idx ON fhir_endpoint_organizations_map (id);
CREATE INDEX fhir_endpoint_organizations_map_org_database_id_idx ON fhir_endpoint_organizations_map (org_database_id);

DROP MATERIALIZED VIEW IF EXISTS mv_endpoint_totals;

CREATE MATERIALIZED VIEW mv_endpoint_totals AS
WITH latest_metadata AS (
SELECT max(fhir_endpoints_metadata.updated_at) AS last_updated
FROM fhir_endpoints_metadata
),
totals AS (
SELECT
(SELECT count(DISTINCT fhir_endpoints.url) FROM fhir_endpoints) AS all_endpoints,
(SELECT count(DISTINCT fhir_endpoints_info.url)
FROM fhir_endpoints_info
WHERE fhir_endpoints_info.requested_fhir_version = 'None') AS indexed_endpoints
)
SELECT
now() AS aggregation_date,
totals.all_endpoints,
totals.indexed_endpoints,
totals.all_endpoints - totals.indexed_endpoints AS nonindexed_endpoints,
(SELECT latest_metadata.last_updated FROM latest_metadata) AS last_updated
FROM totals;

DROP MATERIALIZED VIEW IF EXISTS response_tally_mv;

CREATE MATERIALIZED VIEW response_tally_mv AS
WITH subquery AS (
SELECT
fem.http_response,
count(*) AS response_count
FROM fhir_endpoints_info fei
JOIN fhir_endpoints_metadata fem
ON fei.metadata_id = fem.id
WHERE fei.requested_fhir_version::text = 'None'::text
GROUP BY fem.http_response
)
SELECT
COALESCE(SUM(
CASE
WHEN subquery.http_response = 200 THEN subquery.response_count
ELSE 0::bigint
END), 0::numeric) AS http_200,
COALESCE(SUM(
CASE
WHEN subquery.http_response <> 200 THEN subquery.response_count
ELSE 0::bigint
END), 0::numeric) AS http_non200,
COALESCE(SUM(
CASE
WHEN subquery.http_response = 404 THEN subquery.response_count
ELSE 0::bigint
END), 0::numeric) AS http_404,
COALESCE(SUM(
CASE
WHEN subquery.http_response = 503 THEN subquery.response_count
ELSE 0::bigint
END), 0::numeric) AS http_503
FROM subquery;

DROP MATERIALIZED VIEW IF EXISTS mv_vendor_fhir_counts;

CREATE MATERIALIZED VIEW mv_vendor_fhir_counts AS
WITH developer_counts AS (
SELECT
v_1.name AS vendor_name,
sum(count(e_1.url)) OVER (PARTITION BY v_1.name) AS developer_count
FROM endpoint_export e_1
LEFT JOIN vendors v_1
ON e_1.vendor_name::text = v_1.name::text
GROUP BY v_1.name
)
SELECT
COALESCE(v.name, 'Unknown'::character varying) AS vendor_name,
COALESCE(NULLIF(btrim(e.fhir_version::text), ''::text), 'Unknown'::text) AS fhir_version,
count(e.url)::integer AS n,
COALESCE(
CASE
WHEN v.name::text = 'Allscripts' THEN 'Allscripts'
WHEN v.name::text = 'CareEvolution, Inc.' THEN 'CareEvolution'
WHEN v.name::text = 'Cerner Corporation' THEN 'Cerner'
WHEN v.name::text = 'Epic Systems Corporation' THEN 'Epic'
WHEN v.name::text = 'Medical Information Technology, Inc. (MEDITECH)' THEN 'MEDITECH'
WHEN v.name::text = 'Microsoft Corporation' THEN 'Microsoft'
WHEN v.name::text = 'NA' THEN 'Unknown'
ELSE v.name
END, 'Unknown'::character varying
) AS short_name,
COALESCE(dc.developer_count, 0::numeric) AS developer_count,
COALESCE(
concat(
round(
COALESCE(count(e.url)::numeric / NULLIF(dc.developer_count, 0::numeric) * 100::numeric, 0::numeric),
0
), '%'
), '0%'::text
) AS percentage
FROM endpoint_export e
LEFT JOIN vendors v
ON e.vendor_name::text = v.name::text
LEFT JOIN developer_counts dc
ON v.name::text = dc.vendor_name::text
GROUP BY v.name, e.fhir_version, dc.developer_count
ORDER BY
COALESCE(v.name, 'Unknown'::character varying),
COALESCE(e.fhir_version, 'Unknown'::character varying);
5 changes: 4 additions & 1 deletion shinydashboard/lantern/functions/db_connection.R
Original file line number Diff line number Diff line change
Expand Up @@ -35,7 +35,10 @@ db_tables <- list(
npi_organizations = tbl(db_connection, "npi_organizations"),
endpoint_export = tbl(db_connection, "endpoint_export"),
organization_location = tbl(db_connection, "organization_location"),
vendors = tbl(db_connection, "vendors")
vendors = tbl(db_connection, "vendors"),
mv_endpoint_totals = tbl(db_connection, "mv_endpoint_totals"),
mv_vendor_fhir_counts = tbl(db_connection, "mv_vendor_fhir_counts"),
response_tally_mv = tbl(db_connection, "response_tally_mv")
)

valid_fhir_versions <- c("No Cap Stat", "0.4.0", "0.5.0", "1.0.0", "1.0.1", "1.0.2", "1.1.0", "1.2.0", "1.4.0", "1.6.0", "1.8.0", "3.0.0", "3.0.1", "3.0.2", "3.2.0", "3.3.0", "3.5.0", "3.5a.0", "4.0.0", "4.0.1")
41 changes: 20 additions & 21 deletions shinydashboard/lantern/functions/endpoints.R
Original file line number Diff line number Diff line change
Expand Up @@ -74,8 +74,16 @@ vendor_short_names <- data.frame(
# - indexed endpoints that have been queried
# - non-indexed endpoints yet to be queried
get_endpoint_totals_list <- function(db_tables) {
all <- db_tables$fhir_endpoints %>% distinct(url) %>% count() %>% pull(n)
indexed <- db_tables$fhir_endpoints_info %>% filter(requested_fhir_version == "None") %>% distinct(url) %>% count() %>% pull(n)
all <- db_tables$mv_endpoint_totals %>%
as.data.frame() %>%
slice(1) %>%
pull(all_endpoints)

indexed <- db_tables$mv_endpoint_totals %>%
as.data.frame() %>%
slice(1) %>%
pull(indexed_endpoints)

fhir_endpoint_totals <- list(
"all_endpoints" = all,
"indexed_endpoints" = indexed,
Expand All @@ -99,24 +107,10 @@ get_fhir_endpoints_tbl <- function() {
}

# get the endpoint tally by http_response received
get_response_tally_list <- function(db_tables) {
curr_tally <- db_tables$fhir_endpoints_info %>%
filter(requested_fhir_version == "None") %>%
select(metadata_id) %>%
left_join(db_tables$fhir_endpoints_metadata %>% select(http_response, id),
by = c("metadata_id" = "id")) %>%
select(http_response) %>%
group_by(http_response) %>%
tally()

# Get the list of most recent HTTP responses when requesting the capability statement from the
# fhir_endpoints
list(
"http_200" = max((curr_tally %>% filter(http_response == 200)) %>% pull(n), 0),
"http_non200" = max((curr_tally %>% filter(http_response != 200)) %>% pull(n), 0),
"http_404" = max((curr_tally %>% filter(http_response == 404)) %>% pull(n), 0),
"http_503" = max((curr_tally %>% filter(http_response == 503)) %>% pull(n), 0)
)
get_response_tally_list <- function(db_connection) {
response_tally <- db_connection$response_tally_mv %>%
as.data.frame() %>%
slice(1)
}

# get the date of the most recently updated fhir_endpoint
Expand All @@ -143,7 +137,12 @@ get_http_response_summary_tbl <- function(db_tables) {
tidyr::replace_na(list(vendor_name = "Unknown"))
}

# Get the count of endpoints by vendor
# Get the count of endpoints by vendors
prepare_vendor_data <- function(db_tables) {
fhir_data <- db_tables$mv_vendor_fhir_counts %>% collect()

return(fhir_data)
}
get_fhir_version_vendor_count <- function(endpoint_tbl) {
tbl <- endpoint_tbl %>%
distinct(vendor_name, url, fhir_version) %>%
Expand Down
Loading
Loading