本文為英文版的機器翻譯版本,如內容有任何歧義或不一致之處,概以英文版為準。
具有複雜篩選的範例 SQL 查詢
下列範例示範如何使用具有複雜篩選的 Amazon Athena SQL 查詢,從 HealthLake 資料存放區尋找 FHIR 資料。
範例 根據人口統計資料建立篩選條件
建立病患群組時,識別正確的病患人口統計特性非常重要。此範例查詢示範如何使用 Trino 點表示法和 json_extract來篩選 HealthLake 資料存放區中的資料。
SELECT id , CONCAT(name[1].family, ' ', name[1].given[1]) as name , (year(current_date) - year(date(birthdate))) as age , gender as gender , json_extract(extension[1], '$.valueString') as MothersMaidenName , json_extract(extension[2], '$.valueAddress.city') as birthPlace , maritalstatus.coding[1].display as maritalstatus , address[1].line[1] as addressline , address[1].city as city , address[1].district as district , address[1].state as state , address[1].postalcode as postalcode , address[1].country as country , json_extract(address[1].extension[1], '$.extension[0].valueDecimal') as latitude , json_extract(address[1].extension[1], '$.extension[1].valueDecimal') as longitude , telecom[1].value as telNumber , deceasedboolean as deceasedIndicator , deceaseddatetime FROMdatabase.patient;
您可以使用 Athena 主控台進一步排序和下載結果。
範例 為病患及其相關條件建立篩選條件
下列範例查詢示範如何尋找和排序 HealthLake 資料存放區中找到之病患的所有相關條件。
SELECT patient.id as patientId , condition.id as conditionId , CONCAT(name[1].family, ' ', name[1].given[1]) as name , condition.meta.tag[1].display , json_extract(condition.modifierextension[1], '$.valueDecimal') AS confidenceScore , category[1].coding[1].code as categoryCode , category[1].coding[1].display as categoryDescription , code.coding[1].code as diagnosisCode , code.coding[1].display as diagnosisDescription , onsetdatetime , severity.coding[1].code as severityCode , severity.coding[1].display as severityDescription , verificationstatus.coding[1].display as verificationStatus , clinicalstatus.coding[1].display as clinicalStatus , encounter.reference as encounterId , encounter.type as encountertype FROMdatabase.patient, condition WHERE CONCAT('Patient/', patient.id) = condition.subject.reference ORDER BY name;
您可以使用 Athena 主控台進一步排序結果,或下載結果以進行進一步分析。
範例 為患者及其相關觀察建立篩選條件
下列範例查詢示範如何尋找和排序 HealthLake 資料存放區中找到之病患的所有相關觀察。
SELECT patient.id as patientId , observation.id as observationId , CONCAT(name[1].family, ' ', name[1].given[1]) as name , meta.tag[1].display , json_extract(modifierextension[1], '$.valueDecimal') AS confidenceScore , status , category[1].coding[1].code as categoryCode , category[1].coding[1].display as categoryDescription , code.coding[1].code as observationCode , code.coding[1].display as observationDescription , effectivedatetime , CASE WHEN valuequantity.value IS NOT NULL THEN CONCAT(CAST(valuequantity.value AS VARCHAR),' ',valuequantity.unit) WHEN valueCodeableConcept.coding [ 1 ].code IS NOT NULL THEN CAST(valueCodeableConcept.coding [ 1 ].code AS VARCHAR) WHEN valuestring IS NOT NULL THEN CAST(valuestring AS VARCHAR) WHEN valueboolean IS NOT NULL THEN CAST(valueboolean AS VARCHAR) WHEN valueinteger IS NOT NULL THEN CAST(valueinteger AS VARCHAR) WHEN valueratio IS NOT NULL THEN CONCAT(CAST(valueratio.numerator.value AS VARCHAR),'/',CAST(valueratio.denominator.value AS VARCHAR)) WHEN valuerange IS NOT NULL THEN CONCAT(CAST(valuerange.low.value AS VARCHAR),'-',CAST(valuerange.high.value AS VARCHAR)) WHEN valueSampledData IS NOT NULL THEN CAST(valueSampledData.data AS VARCHAR) WHEN valueTime IS NOT NULL THEN CAST(valueTime AS VARCHAR) WHEN valueDateTime IS NOT NULL THEN CAST(valueDateTime AS VARCHAR) WHEN valuePeriod IS NOT NULL THEN valuePeriod.start WHEN component[1] IS NOT NULL THEN CONCAT(CAST(component[2].valuequantity.value AS VARCHAR),' ',CAST(component[2].valuequantity.unit AS VARCHAR), '/', CAST(component[1].valuequantity.value AS VARCHAR),' ',CAST(component[1].valuequantity.unit AS VARCHAR)) END AS observationvalue , encounter.reference as encounterId , encounter.type as encountertype FROMdatabase.patient, observation WHERE CONCAT('Patient/', patient.id) = observation.subject.reference ORDER BY name;
範例 為病患及其相關程序建立篩選條件
將程序連接到病患是醫療保健的重要層面。下列 SQL 範例查詢示範如何使用 FHIR Procedure Patient和資源類型來完成此操作。下列 SQL 查詢將傳回 HealthLake 資料存放區中找到的所有患者及其相關程序。
SELECT patient.id as patientId , PROCEDURE.id as procedureId , CONCAT(name[1].family, ' ', name[1].given[1]) as name , status , category.coding[1].code as categoryCode , category.coding[1].display as categoryDescription , code.coding[1].code as procedureCode , code.coding[1].display as procedureDescription , performeddatetime , performer[1] , encounter.reference as encounterId , encounter.type as encountertype FROMdatabase.patient, procedure WHERE CONCAT('Patient/', patient.id) = procedure.subject.reference ORDER BY name;
您可以使用 Athena 主控台下載結果以進行進一步分析,或對其進行排序,以進一步了解結果。
範例 為病患及其相關處方建立篩選條件
查看病患目前正在使用之藥物的目前清單非常重要。您可以使用 Athena 撰寫 SQL 查詢,該查詢同時使用 HealthLake 資料存放區中找到的 MedicationRequest Patient和資源類型。
下列 SQL 查詢會聯結匯入 Athena 的 Patient和 MedicationRequest資料表。它也會使用點表示法,將處方組織到其個別項目中。
SELECT patient.id as patientId , medicationrequest.id as medicationrequestid , CONCAT(name[1].family, ' ', name[1].given[1]) as name , status , statusreason.coding[1].code as categoryCode , statusreason.coding[1].display as categoryDescription , category[1].coding[1].code as categoryCode , category[1].coding[1].display as categoryDescription , priority , donotperform , encounter.reference as encounterId , encounter.type as encountertype , medicationcodeableconcept.coding[1].code as medicationCode , medicationcodeableconcept.coding[1].display as medicationDescription , dosageinstruction[1].text as dosage FROMdatabase.patient, medicationrequest WHERE CONCAT('Patient/', patient.id ) = medicationrequest.subject.reference ORDER BY name
您可以使用 Athena 主控台來排序結果,或下載結果以進行進一步分析。
範例 查看MedicationStatement資源類型中找到的藥品
下列範例查詢說明如何使用 SQL 組織匯入 Athena 的巢狀 JSON。查詢使用 FHIR meta元素來指出 HealthLake 整合自然語言處理 (NLP) 新增藥物的時間。它也會使用 json_extract 來搜尋 JSON 字串陣列內的資料。如需詳細資訊,請參閱自然語言處理。
SELECT medicationcodeableconcept.coding[1].code as medicationCode , medicationcodeableconcept.coding[1].display as medicationDescription , meta.tag[1].display , json_extract(modifierextension[1], '$.valueDecimal') AS confidenceScore FROM medicationstatement;
您可以使用 Athena 主控台下載或排序這些結果。
範例 針對特定疾病類型進行篩選
此範例示範如何找到一組 18 到 75 歲、已診斷出糖尿病的患者。
SELECT patient.id as patientId, condition.id as conditionId, CONCAT(name [ 1 ].family, ' ', name [ 1 ].given [ 1 ]) as name, (year(current_date) - year(date(birthdate))) AS age, CASE WHEN condition.encounter.reference IS NOT NULL THEN condition.encounter.reference WHEN observation.encounter.reference IS NOT NULL THEN observation.encounter.reference END as encounterId, CASE WHEN condition.encounter.type IS NOT NULL THEN observation.encounter.type WHEN observation.encounter.type IS NOT NULL THEN observation.encounter.type END AS encountertype, condition.code.coding [ 1 ].code as diagnosisCode, condition.code.coding [ 1 ].display as diagnosisDescription, observation.category [ 1 ].coding [ 1 ].code as categoryCode, observation.category [ 1 ].coding [ 1 ].display as categoryDescription, observation.code.coding [ 1 ].code as observationCode, observation.code.coding [ 1 ].display as observationDescription, effectivedatetime AS observationDateTime, CASE WHEN valuequantity.value IS NOT NULL THEN CONCAT(CAST(valuequantity.value AS VARCHAR),' ',valuequantity.unit) WHEN valueCodeableConcept.coding [ 1 ].code IS NOT NULL THEN CAST(valueCodeableConcept.coding [ 1 ].code AS VARCHAR) WHEN valuestring IS NOT NULL THEN CAST(valuestring AS VARCHAR) WHEN valueboolean IS NOT NULL THEN CAST(valueboolean AS VARCHAR) WHEN valueinteger IS NOT NULL THEN CAST(valueinteger AS VARCHAR) WHEN valueratio IS NOT NULL THEN CONCAT(CAST(valueratio.numerator.value AS VARCHAR),'/',CAST(valueratio.denominator.value AS VARCHAR)) WHEN valuerange IS NOT NULL THEN CONCAT(CAST(valuerange.low.value AS VARCHAR),'-',CAST(valuerange.high.value AS VARCHAR)) WHEN valueSampledData IS NOT NULL THEN CAST(valueSampledData.data AS VARCHAR) WHEN valueTime IS NOT NULL THEN CAST(valueTime AS VARCHAR) WHEN valueDateTime IS NOT NULL THEN CAST(valueDateTime AS VARCHAR) WHEN valuePeriod IS NOT NULL THEN valuePeriod.start WHEN component[1] IS NOT NULL THEN CONCAT(CAST(component[2].valuequantity.value AS VARCHAR),' ',CAST(component[2].valuequantity.unit AS VARCHAR), '/', CAST(component[1].valuequantity.value AS VARCHAR),' ',CAST(component[1].valuequantity.unit AS VARCHAR)) END AS observationvalue, CASE WHEN condition.meta.tag [ 1 ].display = 'SYSTEM GENERATED' THEN 'YES' WHEN condition.meta.tag [ 1 ].display IS NULL THEN 'NO' WHEN observation.meta.tag [ 1 ].display = 'SYSTEM GENERATED' THEN 'YES' WHEN observation.meta.tag [ 1 ].display IS NULL THEN 'NO' END AS IsSystemGenerated, CAST( json_extract( condition.modifierextension [ 1 ], '$.valueDecimal' ) AS int ) AS confidenceScore FROMdatabase.patient,database.condition,database.observation WHERE CONCAT('Patient/', patient.id) = condition.subject.reference AND CONCAT('Patient/', patient.id) = observation.subject.reference AND (year(current_date) - year(date(birthdate))) >= 18 AND (year(current_date) - year(date(birthdate))) <= 75 AND condition.code.coding [ 1 ].display like ('%diabetes%');
現在您可以使用 Athena 主控台來排序結果,或下載結果以進行進一步分析。