diff --git a/datasources/lowerNenoOpenmrs.yml b/datasources/lowerNenoOpenmrs.yml new file mode 100644 index 0000000..c2c8d0f --- /dev/null +++ b/datasources/lowerNenoOpenmrs.yml @@ -0,0 +1,7 @@ +databaseType: "mysql" +host: ${lowerNenoOpenmrs.host} +port: ${lowerNenoOpenmrs.port} +databaseName: ${lowerNenoOpenmrs.databaseName} +user: ${lowerNenoOpenmrs.user} +password: ${lowerNenoOpenmrs.password} +options: ${lowerNenoOpenmrs.options} \ No newline at end of file diff --git a/datasources/upperNenoOpenmrs.yml b/datasources/upperNenoOpenmrs.yml new file mode 100644 index 0000000..1f439b3 --- /dev/null +++ b/datasources/upperNenoOpenmrs.yml @@ -0,0 +1,7 @@ +databaseType: "mysql" +host: ${upperNenoOpenmrs.host} +port: ${upperNenoOpenmrs.port} +databaseName: ${upperNenoOpenmrs.databaseName} +user: ${upperNenoOpenmrs.user} +password: ${upperNenoOpenmrs.password} +options: ${upperNenoOpenmrs.options} \ No newline at end of file diff --git a/jobs/create-source-views-and-functions.yml b/jobs/create-source-views-and-functions.yml new file mode 100644 index 0000000..886b954 --- /dev/null +++ b/jobs/create-source-views-and-functions.yml @@ -0,0 +1,17 @@ +type: "job-pipeline" +description: "Load from SQL from ${sourceDatasource}" +configuration: + jobs: + - type: "sql-execution" + description: "Create functions for ${sourceDatasource}" + configuration: + datasource: "${sourceDatasource}.yml" + delimiter: "#" + scripts: + - "sql/functions/person_address_city_village.sql" + - "sql/functions/person_address_county_district.sql" + - "sql/functions/person_address_state_province.sql" + - "sql/functions/person_family_name.sql" + - "sql/functions/person_given_name.sql" + - "sql/functions/person_name.sql" + - "sql/functions/person_phone_number.sql" diff --git a/jobs/sql-extract-and-transfer-to-table.yml b/jobs/sql-extract-and-transfer-to-table.yml new file mode 100644 index 0000000..5e715de --- /dev/null +++ b/jobs/sql-extract-and-transfer-to-table.yml @@ -0,0 +1,16 @@ +# Template that takes in the following parameters +# ${tableName} +# ${sourceDatasource} +# ${targetDatasource} +type: "sql-transfer" +description: "Extracting from ${sourceDatasource} to ${tableName} in ${targetDatasource}" +configuration: + extract: + datasource: "${sourceDatasource}.yml" + query: "sql/extractions/${tableName}.sql" + load: + datasource: "${targetDatasource}.yml" + table: "${tableName}" + schema: "sql/schemas/${tableName}.sql" + bulkCopy: + batchSize: 400 diff --git a/jobs/sql/extractions/mw_patient_2.sql b/jobs/sql/extractions/mw_patient_2.sql new file mode 100644 index 0000000..b22c673 --- /dev/null +++ b/jobs/sql/extractions/mw_patient_2.sql @@ -0,0 +1,70 @@ +drop temporary table if exists temp_patient; +create temporary table temp_patient ( + patient_id INT NOT NULL PRIMARY KEY, + patient_uuid CHAR(38), + first_name VARCHAR(50), + last_name VARCHAR(50), + gender CHAR(1), + birthdate DATE, + birthdate_estimated BOOLEAN, + phone_number VARCHAR(50), + district VARCHAR(255), + traditional_authority VARCHAR(255), + village VARCHAR(255), + chw_person_id INT, + chw VARCHAR(100), + dead BOOLEAN, + death_date DATE +); + +insert into temp_patient (patient_id, patient_uuid, gender, birthdate, birthdate_estimated, dead, death_date) +select n.person_id as patient_id, + n.uuid as patient_uuid, + n.gender, + n.birthdate, + n.birthdate_estimated, + n.dead, + n.death_date +from patient p +inner join person n on p.patient_id = n.person_id +where p.voided = 0 + and n.voided = 0 +; + +update temp_patient set first_name = person_given_name(patient_id); +update temp_patient set last_name = person_family_name(patient_id); +update temp_patient set phone_number = phone_number(patient_id); +update temp_patient set district = person_address_state_province(patient_id); +update temp_patient set traditional_authority = person_address_county_district(patient_id); +update temp_patient set village = person_address_city_village(patient_id); + +select relationship_type_id into @chwRelationshipType from relationship_type where a_is_to_b = 'Community Health Worker'; + +update temp_patient p set chw_person_id = ( + select r.person_a + from relationship r + where r.person_b = p.patient_id + and r.voided = 0 + and r.relationship = @chwRelationshipType + order by if(r.end_date is null, 1, 0) desc, if(r.start_date is null, 0, 1) desc, r.date_created desc + limit 1 +); + +update temp_patient set chw = person_name(chw_person_id); + +select + patient_id, + patient_uuid, + first_name, + last_name, + gender, + birthdate, + birthdate_estimated, + phone_number, + district, + traditional_authority, + village, + chw, + dead, + death_date +from temp_patient; \ No newline at end of file diff --git a/jobs/sql/functions/person_address_city_village.sql b/jobs/sql/functions/person_address_city_village.sql new file mode 100644 index 0000000..c04f47a --- /dev/null +++ b/jobs/sql/functions/person_address_city_village.sql @@ -0,0 +1,19 @@ +# +DROP FUNCTION IF EXISTS person_address_city_village; +# +CREATE FUNCTION person_address_city_village( + _person_id int +) + RETURNS TEXT + DETERMINISTIC + +BEGIN + DECLARE patientAddressCityVillage TEXT; + + select city_village into patientAddressCityVillage + from person_address where voided = 0 and person_id = _person_id order by preferred desc, date_created desc limit 1; + + RETURN patientAddressCityVillage; + +END +# \ No newline at end of file diff --git a/jobs/sql/functions/person_address_county_district.sql b/jobs/sql/functions/person_address_county_district.sql new file mode 100644 index 0000000..0960c9a --- /dev/null +++ b/jobs/sql/functions/person_address_county_district.sql @@ -0,0 +1,19 @@ +# +DROP FUNCTION IF EXISTS person_address_county_district; +# +CREATE FUNCTION person_address_county_district( + _person_id int +) + RETURNS TEXT + DETERMINISTIC + +BEGIN + DECLARE personAddressCountyDistrict TEXT; + + select county_district into personAddressCountyDistrict + from person_address where voided = 0 and person_id = _person_id order by preferred desc, date_created desc limit 1; + + RETURN personAddressCountyDistrict; + +END +# \ No newline at end of file diff --git a/jobs/sql/functions/person_address_state_province.sql b/jobs/sql/functions/person_address_state_province.sql new file mode 100644 index 0000000..854f59c --- /dev/null +++ b/jobs/sql/functions/person_address_state_province.sql @@ -0,0 +1,19 @@ +# +DROP FUNCTION IF EXISTS person_address_state_province; +# +CREATE FUNCTION person_address_state_province( + _person_id int +) + RETURNS TEXT + DETERMINISTIC + +BEGIN + DECLARE patientAddressStateProvince TEXT; + + select state_province into patientAddressStateProvince + from person_address where voided = 0 and person_id = _person_id order by preferred desc, date_created desc limit 1; + + RETURN patientAddressStateProvince; + +END +# \ No newline at end of file diff --git a/jobs/sql/functions/person_family_name.sql b/jobs/sql/functions/person_family_name.sql new file mode 100644 index 0000000..6486975 --- /dev/null +++ b/jobs/sql/functions/person_family_name.sql @@ -0,0 +1,23 @@ +# +DROP FUNCTION IF EXISTS person_family_name; +# +CREATE FUNCTION person_family_name( + _person_id int +) + RETURNS TEXT + DETERMINISTIC + +BEGIN + DECLARE personFamilyName TEXT; + + select family_name into personFamilyName + from person_name + where voided = 0 + and person_id = _person_id + order by preferred desc, date_created desc + limit 1; + + RETURN personFamilyName; + +END +# \ No newline at end of file diff --git a/jobs/sql/functions/person_given_name.sql b/jobs/sql/functions/person_given_name.sql new file mode 100644 index 0000000..99e9e54 --- /dev/null +++ b/jobs/sql/functions/person_given_name.sql @@ -0,0 +1,23 @@ +# +DROP FUNCTION IF EXISTS person_given_name; +# +CREATE FUNCTION person_given_name( + _person_id int +) + RETURNS TEXT + DETERMINISTIC + +BEGIN + DECLARE personGivenName TEXT; + + select given_name into personGivenName + from person_name + where voided = 0 + and person_id = _person_id + order by preferred desc, date_created desc + limit 1; + + RETURN personGivenName; + +END +# \ No newline at end of file diff --git a/jobs/sql/functions/person_name.sql b/jobs/sql/functions/person_name.sql new file mode 100644 index 0000000..ffd9152 --- /dev/null +++ b/jobs/sql/functions/person_name.sql @@ -0,0 +1,23 @@ +# +DROP FUNCTION IF EXISTS person_name; +# +CREATE FUNCTION person_name( + _person_id int +) + RETURNS TEXT + DETERMINISTIC + +BEGIN + DECLARE personName TEXT; + + select concat(given_name, ' ', family_name) into personName + from person_name + where voided = 0 + and person_id = _person_id + order by preferred desc, date_created desc + limit 1; + + RETURN personName; + +END +# \ No newline at end of file diff --git a/jobs/sql/functions/person_phone_number.sql b/jobs/sql/functions/person_phone_number.sql new file mode 100644 index 0000000..e6f1f56 --- /dev/null +++ b/jobs/sql/functions/person_phone_number.sql @@ -0,0 +1,25 @@ +# +DROP FUNCTION IF EXISTS phone_number; +# +CREATE FUNCTION phone_number( + _person_id int) + + RETURNS VARCHAR(50) + DETERMINISTIC + +BEGIN + DECLARE attVal VARCHAR(50); + + select a.value into attVal + from person_attribute a + inner join person_attribute_type t on a.person_attribute_type_id = t.person_attribute_type_id + where t.name = 'Cell Phone Number' + and a.voided = 0 + and a.person_id = _person_id + order by a.date_created desc + limit 1; + + RETURN attVal; + +END +# \ No newline at end of file diff --git a/jobs/sql/schemas/mw_patient_2.sql b/jobs/sql/schemas/mw_patient_2.sql new file mode 100644 index 0000000..feee1f7 --- /dev/null +++ b/jobs/sql/schemas/mw_patient_2.sql @@ -0,0 +1,16 @@ +CREATE TABLE mw_patient_2 ( + patient_id INT NOT NULL PRIMARY KEY, + patient_uuid CHAR(38), + first_name VARCHAR(50), + last_name VARCHAR(50), + gender CHAR(1), + birthdate DATE, + birthdate_estimated BOOLEAN, + phone_number VARCHAR(50), + district VARCHAR(255), + traditional_authority VARCHAR(255), + village VARCHAR(255), + chw VARCHAR(100), + dead BOOLEAN, + death_date DATE +); \ No newline at end of file diff --git a/jobs/test.yml b/jobs/test.yml new file mode 100644 index 0000000..a4e3b9b --- /dev/null +++ b/jobs/test.yml @@ -0,0 +1,16 @@ +type: "job-pipeline" +description: "Refreshing Upper Neno data" +parameters: + sourceDatasource: "upperNenoOpenmrs" + targetDatasource: "upperNenoReporting" +configuration: + jobs: + - path: "create-source-views-and-functions.yml" + - type: "iterating-job" + description: "Extracting from ${sourceDatasource} to ${tableName} in ${targetDatasource}" + configuration: + maxConcurrentJobs: 1 + jobTemplate: + path: "sql-extract-and-transfer-to-table.yml" + iterations: + - tableName: "mw_patient_2"