Skip to content

Commit

Permalink
added location table export script
Browse files Browse the repository at this point in the history
  • Loading branch information
Mikhail-iontsev committed Jun 28, 2024
1 parent b6ff655 commit d2e0bfd
Show file tree
Hide file tree
Showing 6 changed files with 101 additions and 55 deletions.
18 changes: 17 additions & 1 deletion R/exportToAres.R
Original file line number Diff line number Diff line change
Expand Up @@ -1915,6 +1915,18 @@ generateDataDensityTotal <- function(connection, resultsDatabaseSchema) {
return(data)
}

generateLocationData <- function(connection, resultsDatabaseSchema) {
renderedSql <- SqlRender::loadRenderTranslateSql(
sqlFilename = "export/location/sqlLocationTable.sql",
packageName = "Achilles",
dbms = connection@dbms,
results_database_schema = resultsDatabaseSchema
)

locationData <- DatabaseConnector::querySql(connection, renderedSql)
return(locationData)
}

generateDataDensityRecordsPerPerson <- function(connection, resultsDatabaseSchema) {
renderedSql <- SqlRender::loadRenderTranslateSql(
sqlFilename = "export/datadensity/recordsperperson.sql",
Expand Down Expand Up @@ -2292,6 +2304,10 @@ exportToAres <- function(
filename <- file.path(sourceOutputPath, "death.json")
write(jsonlite::toJSON(currentTable), filename)

writeLines("Generating location report")
currentTable <- generateLocationData(conn, resultsDatabaseSchema)
filename <- file.path(sourceOutputPath, "location.csv")
data.table::fwrite(currentTable, file = filename)
writeLines("Generating domain summary reports")

# domain summary - conditions
Expand Down Expand Up @@ -2636,4 +2652,4 @@ exportToAres <- function(
jsonOutput = jsonlite::toJSON(currentTable)
write(jsonOutput, file = paste0(sourceOutputPath, "/person.json"))
}
}
}
33 changes: 17 additions & 16 deletions inst/sql/sql_server/analyses/1100.sql
Original file line number Diff line number Diff line change
Expand Up @@ -2,23 +2,24 @@

--HINT DISTRIBUTE_ON_KEY(stratum_1)
WITH rawData AS (
select
left(l1.zip,3) as stratum_1,
COUNT_BIG(distinct person_id) as count_value
from @cdmDatabaseSchema.person p1
inner join @cdmDatabaseSchema.location l1
on p1.location_id = l1.location_id
where p1.location_id is not null
and l1.zip is not null
group by left(l1.zip,3)
SELECT
LEFT(l1.zip, 3) AS stratum_1,
l1.location_id AS stratum_2,
COUNT_BIG(DISTINCT p1.person_id) AS count_value
FROM @cdmDatabaseSchema.person p1
INNER JOIN @cdmDatabaseSchema.location l1
ON p1.location_id = l1.location_id
WHERE p1.location_id IS NOT NULL
AND l1.zip IS NOT NULL
GROUP BY LEFT(l1.zip, 3), l1.location_id
)
SELECT
1100 as analysis_id,
CAST(stratum_1 AS VARCHAR(255)) as stratum_1,
cast(null as varchar(255)) as stratum_2,
cast(null as varchar(255)) as stratum_3,
cast(null as varchar(255)) as stratum_4,
cast(null as varchar(255)) as stratum_5,
1100 AS analysis_id,
CAST(stratum_1 AS VARCHAR(255)) AS stratum_1,
CAST(stratum_2 AS VARCHAR(255)) AS stratum_2,
CAST(NULL AS VARCHAR(255)) AS stratum_3,
CAST(NULL AS VARCHAR(255)) AS stratum_4,
CAST(NULL AS VARCHAR(255)) AS stratum_5,
count_value
into @scratchDatabaseSchema@schemaDelim@tempAchillesPrefix_1100
INTO @scratchDatabaseSchema@schemaDelim@tempAchillesPrefix_1100
FROM rawData;
26 changes: 15 additions & 11 deletions inst/sql/sql_server/analyses/1101.sql
Original file line number Diff line number Diff line change
@@ -1,14 +1,18 @@
-- 1101 Number of persons by location state

--HINT DISTRIBUTE_ON_KEY(stratum_1)
select 1101 as analysis_id,
CAST(l1.state AS VARCHAR(255)) as stratum_1,
cast(null as varchar(255)) as stratum_2, cast(null as varchar(255)) as stratum_3, cast(null as varchar(255)) as stratum_4, cast(null as varchar(255)) as stratum_5,
COUNT_BIG(distinct person_id) as count_value
into @scratchDatabaseSchema@schemaDelim@tempAchillesPrefix_1101
from @cdmDatabaseSchema.person p1
inner join @cdmDatabaseSchema.location l1
on p1.location_id = l1.location_id
where p1.location_id is not null
and l1.state is not null
group by l1.state;
SELECT
1101 AS analysis_id,
CAST(l1.state AS VARCHAR(255)) AS stratum_1,
CAST(l1.location_id AS VARCHAR(255)) AS stratum_2,
CAST(NULL AS VARCHAR(255)) AS stratum_3,
CAST(NULL AS VARCHAR(255)) AS stratum_4,
CAST(NULL AS VARCHAR(255)) AS stratum_5,
COUNT_BIG(DISTINCT p1.person_id) AS count_value
INTO @scratchDatabaseSchema@schemaDelim@tempAchillesPrefix_1101
FROM @cdmDatabaseSchema.person p1
INNER JOIN @cdmDatabaseSchema.location l1
ON p1.location_id = l1.location_id
WHERE p1.location_id IS NOT NULL
AND l1.state IS NOT NULL
GROUP BY l1.state, l1.location_id;
34 changes: 18 additions & 16 deletions inst/sql/sql_server/analyses/1102.sql
Original file line number Diff line number Diff line change
Expand Up @@ -2,23 +2,25 @@

--HINT DISTRIBUTE_ON_KEY(stratum_1)
WITH rawData AS (
select
left(l1.zip,3) as stratum_1,
COUNT_BIG(distinct care_site_id) as count_value
from @cdmDatabaseSchema.care_site cs1
inner join @cdmDatabaseSchema.location l1
on cs1.location_id = l1.location_id
where cs1.location_id is not null
and l1.zip is not null
group by left(l1.zip,3)
SELECT
LEFT(l1.zip, 3) AS stratum_1,
cs1.location_id AS stratum_2,
COUNT_BIG(DISTINCT cs1.care_site_id) AS count_value
FROM @cdmDatabaseSchema.care_site cs1
INNER JOIN @cdmDatabaseSchema.location l1
ON cs1.location_id = l1.location_id
WHERE cs1.location_id IS NOT NULL
AND l1.zip IS NOT NULL
GROUP BY LEFT(l1.zip, 3), cs1.location_id
)
SELECT
1102 as analysis_id,
CAST(stratum_1 AS VARCHAR(255)) as stratum_1,
cast(null as varchar(255)) as stratum_2,
cast(null as varchar(255)) as stratum_3,
cast(null as varchar(255)) as stratum_4,
cast(null as varchar(255)) as stratum_5,
1102 AS analysis_id,
CAST(stratum_1 AS VARCHAR(255)) AS stratum_1,
CAST(stratum_2 AS VARCHAR(255)) AS stratum_2,
CAST(NULL AS VARCHAR(255)) AS stratum_3,
CAST(NULL AS VARCHAR(255)) AS stratum_4,
CAST(NULL AS VARCHAR(255)) AS stratum_5,
count_value
into @scratchDatabaseSchema@schemaDelim@tempAchillesPrefix_1102
INTO @scratchDatabaseSchema@schemaDelim@tempAchillesPrefix_1102
FROM rawData;

26 changes: 15 additions & 11 deletions inst/sql/sql_server/analyses/1103.sql
Original file line number Diff line number Diff line change
@@ -1,14 +1,18 @@
-- 1103 Number of care sites by location state

--HINT DISTRIBUTE_ON_KEY(stratum_1)
select 1103 as analysis_id,
CAST(l1.state AS VARCHAR(255)) as stratum_1,
cast(null as varchar(255)) as stratum_2, cast(null as varchar(255)) as stratum_3, cast(null as varchar(255)) as stratum_4, cast(null as varchar(255)) as stratum_5,
COUNT_BIG(distinct care_site_id) as count_value
into @scratchDatabaseSchema@schemaDelim@tempAchillesPrefix_1103
from @cdmDatabaseSchema.care_site cs1
inner join @cdmDatabaseSchema.location l1
on cs1.location_id = l1.location_id
where cs1.location_id is not null
and l1.state is not null
group by l1.state;
SELECT
1103 AS analysis_id,
CAST(l1.state AS VARCHAR(255)) AS stratum_1,
CAST(cs1.location_id AS VARCHAR(255)) AS stratum_2,
CAST(NULL AS VARCHAR(255)) AS stratum_3,
CAST(NULL AS VARCHAR(255)) AS stratum_4,
CAST(NULL AS VARCHAR(255)) AS stratum_5,
COUNT_BIG(DISTINCT cs1.care_site_id) AS count_value
INTO @scratchDatabaseSchema@schemaDelim@tempAchillesPrefix_1103
FROM @cdmDatabaseSchema.care_site cs1
INNER JOIN @cdmDatabaseSchema.location l1
ON cs1.location_id = l1.location_id
WHERE cs1.location_id IS NOT NULL
AND l1.state IS NOT NULL
GROUP BY l1.state, cs1.location_id;
19 changes: 19 additions & 0 deletions inst/sql/sql_server/export/location/sqlLocationTable.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,19 @@
WITH denom AS (
SELECT
count_value
FROM
@results_database_schema.achilles_results
WHERE
analysis_id = 1
)
SELECT
c.analysis_id AS analysis_id,
c.stratum_1 AS location_name,
c.stratum_2 AS location_id,
c.count_value AS count_persons,
1.0 * c.count_value / denom.count_value AS percent_persons
FROM
@results_database_schema.achilles_results c,
denom
WHERE
c.analysis_id BETWEEN 1100 AND 1103;

0 comments on commit d2e0bfd

Please sign in to comment.