From f5540e5cb7769e09c4b23ee0ae0ea2fceac30f25 Mon Sep 17 00:00:00 2001 From: jamesfeshner Date: Thu, 1 Dec 2022 14:37:49 -0500 Subject: [PATCH 1/2] Last update --- drug_lookup_isanteplus.sql | 2 +- indicators_report.sql | 72 ++++++++++++++++++++++++++++++++-- insertion_obs_by_day.sql | 14 ++++--- isanteplusreportsddlscript.sql | 23 +++++++++-- isanteplusreportsdmlscript.sql | 68 ++++++++++++++++++++++++++------ patient_status_arv_dml.sql | 2 +- psychoSocialResume.sql | 28 +++++++++++++ 7 files changed, 184 insertions(+), 25 deletions(-) create mode 100644 psychoSocialResume.sql diff --git a/drug_lookup_isanteplus.sql b/drug_lookup_isanteplus.sql index 63641b9..12b0709 100644 --- a/drug_lookup_isanteplus.sql +++ b/drug_lookup_isanteplus.sql @@ -54,7 +54,7 @@ LOCK TABLES `druglookup` WRITE; INSERT INTO `druglookup` VALUES (1,1,70056,NULL,'abacavir','Abacavir (ABC)','NRTIs','300mg BID','ABC','Abacavir (ABC)','Abacavir (ABC)','300mg caplet','20mg/ml liquid','300mg comprimé','20mg/ml sirop','qd'), (2,2,70245,NULL,'acyclovir','Acyclovir','Other Treatments',NULL,'','Acyclovir','Acyclovir',NULL,NULL,NULL,NULL,NULL), -(3,3,NULL, NULL,'amprenavir','Amprenavir (AMP)','Pls','1200mg BID','AMP','Amprenavir (AMP)','Amprenavir (AMP)',NULL,NULL,NULL,NULL,NULL), +(3,3,71193, NULL,'amprenavir','Amprenavir (AMP)','Pls','1200mg BID','AMP','Amprenavir (AMP)','Amprenavir (AMP)',NULL,NULL,NULL,NULL,NULL), (4,4,NULL,NULL,'amprenavirPlusBostRtv','Amprenavir+BostRTV','Pls','1200mg/200mg qd','AMP+BostRTV','Amprenavir+BostRTV','Amprenavir+BostRTV',NULL,NULL,NULL,NULL,NULL), (5,5,71647,NUll,'atazanavir','Atazanavir (ATZN)','Pls','400mg qd','ATZN','Atazanavir (ATZN)','Atazanavir (ATZN)','150 mg qd',NULL,'150 mg qd',NULL,NULL), (6,6,159809,NULL,'atazanavirPlusBostRtv','Atazanavir+BostRTV','Pls','300mg/100mg qd','ATZN+BostRTV','Atazanavir+BostRTV','Atazanavir+BostRTV',NULL,NULL,NULL,NULL,NULL), diff --git a/indicators_report.sql b/indicators_report.sql index 6f9e2c7..0394a4f 100644 --- a/indicators_report.sql +++ b/indicators_report.sql @@ -214,6 +214,23 @@ DROP TABLE IF EXISTS isanteplus.report_type; INSERT INTO isanteplus.indicator_type (indicator_type_id,report_type_id,indicator_name_fr, indicator_name_en,indicator_type_description,date_created) VALUES(37,1,'Violences (physique, sexuelle)','Violence (physical, sexual) ','Violences (physique, sexuelle)', now()); + + /*Covid suspect 155762*/ + INSERT INTO isanteplus.indicator_type (indicator_type_id,report_type_id,indicator_name_fr, + indicator_name_en,indicator_type_description,date_created) + VALUES(38,1,'Covid suspect','Covid suspect','Covid suspect', now()); + + /*Covid confirmé*/ + INSERT INTO isanteplus.indicator_type (indicator_type_id,report_type_id,indicator_name_fr, + indicator_name_en,indicator_type_description,date_created) + VALUES(39,1,'Covid confirmé','Covid confirmé','Confirm Covid', now()); + + /*Cancer du Col*/ + + INSERT INTO isanteplus.indicator_type (indicator_type_id,report_type_id,indicator_name_fr, + indicator_name_en,indicator_type_description,date_created) + VALUES(40,1,'Cancer du Col','Cancer du Col','Cancer of Col', now()); + DELIMITER $$ DROP PROCEDURE IF EXISTS patient_diagnosis$$ @@ -273,8 +290,9 @@ INSERT into patient_diagnosis /*Update encounter date for patient_diagnosis*/ update patient_diagnosis pdiag, openmrs.encounter enc SET pdiag.encounter_date = DATE(enc.encounter_datetime) - WHERE pdiag.location_id = enc.location_id - AND pdiag.encounter_id = enc.encounter_id + WHERE /*pdiag.location_id = enc.location_id + AND*/ pdiag.encounter_id = enc.encounter_id + AND enc.encounter_datetime IS NOT NULL AND enc.voided = 0; /*Ending patient_diagnosis*/ END$$ @@ -294,6 +312,7 @@ DELIMITER ; AND pdiag.answer_concept_id = 160146 AND pdiag.suspected_confirmed = 159393 AND pdiag.voided <> 1 + AND pdiag.encounter_date IS NOT NULL ON DUPLICATE KEY UPDATE last_updated_date = NOW(), voided = pdiag.voided; @@ -398,7 +417,7 @@ DELIMITER ; voided = pdiag.voided; /*9 : Paludisme confirme*/ - INSERT INTO isanteplus.indicators (indicator_id,indicator_type_id,patient_id,location_id,encounter_id, + /*INSERT INTO isanteplus.indicators (indicator_id,indicator_type_id,patient_id,location_id,encounter_id, indicator_date,voided,created_date,last_updated_date) SELECT 9,9,pdiag.patient_id, pdiag.location_id, pdiag.encounter_id, pdiag.encounter_date, pdiag.voided, now(), now() FROM isanteplus.patient p, isanteplus.patient_diagnosis pdiag @@ -409,7 +428,7 @@ DELIMITER ; AND pdiag.voided <> 1 ON DUPLICATE KEY UPDATE last_updated_date = NOW(), - voided = pdiag.voided; + voided = pdiag.voided;*/ /*10 : Paralysie flasque aigue(pfa)*/ @@ -784,6 +803,51 @@ DELIMITER ; ON DUPLICATE KEY UPDATE last_updated_date = NOW(), voided = pdiag.voided; + + /* 38: Covid Suspect - 155762 */ + + INSERT INTO isanteplus.indicators (indicator_id,indicator_type_id,patient_id,location_id,encounter_id, + indicator_date,voided,created_date,last_updated_date) + SELECT 38,38,pdiag.patient_id, pdiag.location_id, pdiag.encounter_id, pdiag.encounter_date, + pdiag.voided, now(), now() FROM isanteplus.patient p, isanteplus.patient_diagnosis pdiag + WHERE p.patient_id = pdiag.patient_id + AND pdiag.concept_id = 1284 + AND pdiag.answer_concept_id = 155762 + AND pdiag.suspected_confirmed = 159393 + AND pdiag.voided <> 1 + ON DUPLICATE KEY UPDATE + last_updated_date = NOW(), + voided = pdiag.voided; + + /* 39: Covid Confirme - 155762 */ + + INSERT INTO isanteplus.indicators (indicator_id,indicator_type_id,patient_id,location_id,encounter_id, + indicator_date,voided,created_date,last_updated_date) + SELECT 39,39,pdiag.patient_id, pdiag.location_id, pdiag.encounter_id, pdiag.encounter_date, + pdiag.voided, now(), now() FROM isanteplus.patient p, isanteplus.patient_diagnosis pdiag + WHERE p.patient_id = pdiag.patient_id + AND pdiag.concept_id = 1284 + AND pdiag.answer_concept_id = 155762 + AND pdiag.suspected_confirmed = 159392 + AND pdiag.voided <> 1 + ON DUPLICATE KEY UPDATE + last_updated_date = NOW(), + voided = pdiag.voided; + + /*CANCER DU COL*/ + + INSERT INTO isanteplus.indicators (indicator_id,indicator_type_id,patient_id,location_id,encounter_id, + indicator_date,voided,created_date,last_updated_date) + SELECT 40,40,pdiag.patient_id, pdiag.location_id, pdiag.encounter_id, pdiag.encounter_date, + pdiag.voided, now(), now() FROM isanteplus.patient p, isanteplus.patient_diagnosis pdiag + WHERE p.patient_id = pdiag.patient_id + AND pdiag.concept_id = 1284 + AND pdiag.answer_concept_id = 116023 + AND pdiag.voided <> 1 + ON DUPLICATE KEY UPDATE + last_updated_date = NOW(), + voided = pdiag.voided; + END$$ DELIMITER ; diff --git a/insertion_obs_by_day.sql b/insertion_obs_by_day.sql index d60d893..5dafeae 100644 --- a/insertion_obs_by_day.sql +++ b/insertion_obs_by_day.sql @@ -406,17 +406,21 @@ CREATE TABLE IF NOT EXISTS patient_prescription_day ( AND en.visit_id=vi.visit_id AND vi.voided = 0; /*update test_done,date_test_done,comment_test_done for patient_laboratory*/ - update patient_laboratory plab,isanteplus.obs_by_day ob - SET plab.test_done=1,plab.test_result=CASE WHEN ob.value_coded<>'' + UPDATE patient_laboratory plab,openmrs.obs ob + SET plab.test_done=1, + plab.test_result=CASE WHEN ob.value_coded IS NOT NULL THEN ob.value_coded - WHEN ob.value_numeric<>'' THEN ob.value_numeric - WHEN ob.value_text<>'' THEN ob.value_text + WHEN ob.value_numeric IS NOT NULL + THEN ob.value_numeric + WHEN ob.value_text IS NOT NULL THEN ob.value_text END, plab.date_test_done=ob.obs_datetime, plab.comment_test_done=ob.comments WHERE plab.test_id=ob.concept_id AND plab.encounter_id=ob.encounter_id - AND ob.voided = 0; + AND ob.voided = 0 + AND (ob.value_coded IS NOT NULL OR ob.value_numeric IS NOT NULL + OR ob.value_text IS NOT NULL); /*End of patient_laboratory*/ END$$ diff --git a/isanteplusreportsddlscript.sql b/isanteplusreportsddlscript.sql index dfff749..4cc53ab 100644 --- a/isanteplusreportsddlscript.sql +++ b/isanteplusreportsddlscript.sql @@ -837,10 +837,10 @@ ALTER TABLE isanteplus.patient_prescription ADD COLUMN dispensation_date DATE AFTER drug_id; ALTER TABLE isanteplus.patient_prescription -ADD COLUMN number_day_dispense INT(11) AFTER number_day; +ADD COLUMN number_day_dispense DOUBLE AFTER number_day; ALTER TABLE isanteplus.patient_prescription -ADD COLUMN pills_amount_dispense INT(11) AFTER number_day_dispense; +ADD COLUMN pills_amount_dispense DOUBLE AFTER number_day_dispense; ALTER TABLE isanteplus.patient ADD COLUMN isante_id varchar(50) AFTER national_id; @@ -1217,4 +1217,21 @@ CREATE TABLE if not exists immunization_dose ( ) ENGINE=InnoDB DEFAULT CHARSET=utf8; ALTER TABLE isanteplus.patient_prescription -MODIFY COLUMN number_day double; \ No newline at end of file +MODIFY COLUMN number_day double; + +ALTER TABLE isanteplus.patient +ADD COLUMN date_transferred_in DATETIME AFTER transferred_in; + +ALTER TABLE isanteplus.patient +ADD COLUMN date_started_arv_other_site DATETIME +AFTER date_transferred_in; +/*Field modify on 17_12_2021*/ +ALTER TABLE isanteplus.patient_on_art +MODIFY COLUMN cervical_cancer_treatment TEXT; +/*Field added on 19 janv 2022*/ +ALTER TABLE isanteplus.patient_dispensing +ADD COLUMN ddp int(11) default 0 AFTER dispensation_location; + +ALTER TABLE patient_dispensing +MODIFY COLUMN dose_day double; + diff --git a/isanteplusreportsdmlscript.sql b/isanteplusreportsdmlscript.sql index dec00f6..ac8b1a8 100644 --- a/isanteplusreportsdmlscript.sql +++ b/isanteplusreportsdmlscript.sql @@ -76,26 +76,30 @@ DELIMITER $$ openmrs.patient_identifier_type pit set p.st_id=pi.identifier where p.patient_id=pi.patient_id AND pi.identifier_type=pit.patient_identifier_type_id - and pit.uuid="d059f6d0-9e42-4760-8de1-8316b48bc5f1"; + and pit.uuid="d059f6d0-9e42-4760-8de1-8316b48bc5f1" + AND pi.voided <> 1; /*National ID*/ update patient p,openmrs.patient_identifier pi, openmrs.patient_identifier_type pit set p.national_id=pi.identifier where p.patient_id=pi.patient_id AND pi.identifier_type=pit.patient_identifier_type_id - and pit.uuid="9fb4533d-4fd5-4276-875b-2ab41597f5dd"; + and pit.uuid="9fb4533d-4fd5-4276-875b-2ab41597f5dd" + AND pi.voided <> 1; /*iSantePlus_ID*/ update patient p,openmrs.patient_identifier pi, openmrs.patient_identifier_type pit set p.identifier=pi.identifier where p.patient_id=pi.patient_id AND pi.identifier_type=pit.patient_identifier_type_id - and pit.uuid="05a29f94-c0ed-11e2-94be-8c13b969e334"; + and pit.uuid="05a29f94-c0ed-11e2-94be-8c13b969e334" + AND pi.voided <> 1; /*isante_id*/ update patient p,openmrs.patient_identifier pi, openmrs.patient_identifier_type pit set p.isante_id = pi.identifier where p.patient_id=pi.patient_id AND pi.identifier_type=pit.patient_identifier_type_id - and pit.uuid="0e0c7cc2-3491-4675-b705-746e372ff346"; + and pit.uuid="0e0c7cc2-3491-4675-b705-746e372ff346" + AND pi.voided <> 1; /* update location_id for patients*/ update patient p, @@ -121,7 +125,9 @@ DELIMITER $$ FROM openmrs.location l, openmrs.location_attribute la, openmrs.location_attribute_type lat WHERE l.location_id = la.location_id AND la.attribute_type_id = lat.location_attribute_type_id - AND lat.uuid = "0e52924e-4ebb-40ba-9b83-b198b532653b"; + AND lat.uuid = "0e52924e-4ebb-40ba-9b83-b198b532653b" + ON DUPLICATE KEY UPDATE + name=l.name; update isanteplus.patient p, isanteplus.location l SET site_code = l.isante_location_id WHERE p.location_id = l.location_id; @@ -190,7 +196,7 @@ DELIMITER $$ AND ob.concept_id = 165210 AND (o.value_text is not null AND o.value_text <> ''); - /* update patient with vih status */ + /* update patient with vih_status when patient has a HIV form*/ UPDATE patient p, openmrs.encounter en, openmrs.encounter_type ent SET p.vih_status=1 @@ -200,6 +206,18 @@ DELIMITER $$ OR ent.uuid='349ae0b4-65c1-4122-aa06-480f186c8350' OR ent.uuid='33491314-c352-42d0-bd5d-a9d0bffc9bf1') AND en.voided = 0; + /*Update vih_status WHEN patient has a laboratory form WITH + HIV test positive*/ + UPDATE patient p, openmrs.encounter en, openmrs.encounter_type ent, openmrs.obs o + SET p.vih_status=1 + WHERE p.patient_id = en.patient_id AND en.encounter_type = ent.encounter_type_id + AND en.encounter_id = o.encounter_id + AND en.patient_id = o.person_id + AND ent.uuid = 'f037e97b-471e-4898-a07c-b8e169e0ddc4' + AND o.concept_id IN (1040,1042) + AND o.value_coded = 703 + AND en.voided <> 1 + ANd o.voided <> 1; /*Update for vih_status = 1 where the patient has a labs test hiv positive*/ /*UPDATE patient p, openmrs.encounter en, openmrs.obs ob SET p.vih_status=1 @@ -272,6 +290,21 @@ DELIMITER $$ AND o.concept_id = 159936 AND o.value_coded = 5622; + /*Date des premiers soins dans cet établissement*/ + update patient p, openmrs.obs o, openmrs.concept c + SET p.date_transferred_in = o.value_datetime + WHERE p.patient_id = o.person_id + AND o.concept_id = c.concept_id + AND c.uuid = 'd9885523-a923-474b-88df-f3294d422c3c' + AND o.value_datetime IS NOT NULL; + + /*Date début des ARV dans l’établissement de référence*/ + update patient p, openmrs.obs o + SET p.date_started_arv_other_site = o.value_datetime + WHERE p.patient_id = o.person_id + AND o.concept_id = 159599 + AND o.value_datetime IS NOT NULL; + /*End of DML queries*/ END$$ DELIMITER ; @@ -395,7 +428,16 @@ DELIMITER $$ WHERE patdisp.encounter_id=ob.encounter_id AND ob.concept_id=1755 AND ob.value_coded=1065 - AND ob.voided = 0; + AND ob.voided = 0; + /*UPDATE ddp field for patient on DDP, ddp=1065 for patient on DDP + and ddp = 0 for patient not on DDP*/ + UPDATE patient_dispensing patdisp, openmrs.obs ob, openmrs.concept c + SET patdisp.ddp = 1065 + WHERE patdisp.encounter_id = ob.encounter_id + AND ob.concept_id = c.concept_id + AND c.uuid = 'c2aacdc8-156e-4527-8934-a8fb94162419' + AND ob.value_coded = 1065 + AND ob.voided = 0; /* Update on patient_dispensing where the drug is a ARV drug */ UPDATE patient_dispensing pdis, (SELECT ad.drug_id FROM arv_drugs ad) B SET pdis.arv_drug = 1065 @@ -851,16 +893,20 @@ DELIMITER $$ AND vi.voided = 0; /*update test_done,date_test_done,comment_test_done for patient_laboratory*/ UPDATE patient_laboratory plab,openmrs.obs ob - SET plab.test_done=1,plab.test_result=CASE WHEN ob.value_coded IS NULL + SET plab.test_done=1, + plab.test_result=CASE WHEN ob.value_coded IS NOT NULL THEN ob.value_coded - WHEN ob.value_numeric<>'' THEN ob.value_numeric - WHEN ob.value_text<>'' THEN ob.value_text + WHEN ob.value_numeric IS NOT NULL + THEN ob.value_numeric + WHEN ob.value_text IS NOT NULL THEN ob.value_text END, plab.date_test_done=ob.obs_datetime, plab.comment_test_done=ob.comments WHERE plab.test_id=ob.concept_id AND plab.encounter_id=ob.encounter_id - AND ob.voided = 0; + AND ob.voided = 0 + AND (ob.value_coded IS NOT NULL OR ob.value_numeric IS NOT NULL + OR ob.value_text IS NOT NULL); /*update order_destination for patient_laboratory*/ UPDATE patient_laboratory plab,openmrs.obs ob diff --git a/patient_status_arv_dml.sql b/patient_status_arv_dml.sql index 0e5acec..6e10622 100644 --- a/patient_status_arv_dml.sql +++ b/patient_status_arv_dml.sql @@ -1287,8 +1287,8 @@ AND CONVERT(pati.dose, SIGNED INTEGER) = 8 AND voided <> 1; DROP PROCEDURE IF EXISTS calling_patient_alert$$ CREATE PROCEDURE calling_patient_alert() BEGIN - call isanteplus_patient_alert(); call alert_viral_load(); + call isanteplus_patient_alert(); call isanteplus_patient_immunization(); END$$ DELIMITER ; diff --git a/psychoSocialResume.sql b/psychoSocialResume.sql new file mode 100644 index 0000000..0c40406 --- /dev/null +++ b/psychoSocialResume.sql @@ -0,0 +1,28 @@ + /*Resume iSante PsychoSocial forms*/ + USE isanteplus; + DROP TABLE IF EXISTS comprehension; + CREATE TABLE IF NOT EXISTS comprehension( + comprehension_id INT(11) AUTO_INCREMENT, + patient_id INT(11), + isante_id VARCHAR(11), + visitDate VARCHAR(10), + visit_date DATE, + compRemarks LONGTEXT, + obstaclesRemarks LONGTEXT, + barriersToApptsText VARCHAR(255), + barriersToHomeVisitsText VARCHAR(255), + CONSTRAINT pk_comprehension_isanteplus PRIMARY KEY (comprehension_id) + )ENGINE=InnoDB DEFAULT CHARSET=utf8; + + INSERT INTO comprehension(patient_id,isante_id,visitDate,compRemarks, + obstaclesRemarks,barriersToApptsText,barriersToHomeVisitsText) + SELECT p.patient_id, c.patientID, + concat(c.visitDateDd,'-',c.visitDateMm,'-',c.visitDateYy),c.compRemarks, + c.obstaclesRemarks,c.barriersToApptsText, c.barriersToHomeVisitsText + FROM isanteplus.patient p, itech.comprehension c + WHERE p.isante_id = c.patientID + AND ((c.compRemarks IS NOT NULL OR c.compRemarks <> '') + OR (c.obstaclesRemarks IS NOT NULL OR c.obstaclesRemarks <> '') + OR (c.barriersToApptsText IS NOT NULL OR c.barriersToApptsText <> '') + OR (c.barriersToHomeVisitsText IS NOT NULL OR c.barriersToHomeVisitsText <> '') + ) \ No newline at end of file From b1d4eaced17428f63df66c1e6c9f5567a91cc89f Mon Sep 17 00:00:00 2001 From: jamesfeshner Date: Thu, 1 Dec 2022 14:50:48 -0500 Subject: [PATCH 2/2] Adding psychoSocialResume SQL file --- load.sh | 3 ++- psychoSocialResume.sql => sql_files/psychoSocialResume.sql | 0 2 files changed, 2 insertions(+), 1 deletion(-) rename psychoSocialResume.sql => sql_files/psychoSocialResume.sql (100%) diff --git a/load.sh b/load.sh index 2fc65b9..343ae4b 100755 --- a/load.sh +++ b/load.sh @@ -9,4 +9,5 @@ mysql --protocol=tcp -h ${host} -P ${port} -u ${user} -p${pass} < ./sql_files/dr mysql --protocol=tcp -h ${host} -P ${port} -u ${user} -p${pass} < ./sql_files/run_isante_patient_status.sql mysql --protocol=tcp -h ${host} -P ${port} -u ${user} -p${pass} < ./sql_files/insertion_obs_by_day.sql mysql --protocol=tcp -h ${host} -P ${port} -u ${user} -p${pass} < ./sql_files/patient_status_arv_dml.sql -mysql --protocol=tcp -h ${host} -P ${port} -u ${user} -p${pass} < ./sql_files/indicators_report.sql \ No newline at end of file +mysql --protocol=tcp -h ${host} -P ${port} -u ${user} -p${pass} < ./sql_files/indicators_report.sql +mysql --protocol=tcp -h ${host} -P ${port} -u ${user} -p${pass} < ./sql_files/psychoSocialResume.sql \ No newline at end of file diff --git a/psychoSocialResume.sql b/sql_files/psychoSocialResume.sql similarity index 100% rename from psychoSocialResume.sql rename to sql_files/psychoSocialResume.sql