-
Notifications
You must be signed in to change notification settings - Fork 2
RWA-778 ensure-orders-have-encounters #6
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
base: master
Are you sure you want to change the base?
Changes from 1 commit
File filter
Filter by extension
Conversations
Jump to
Diff view
Diff view
There are no files selected for viewing
| Original file line number | Diff line number | Diff line change |
|---|---|---|
|
|
@@ -17,28 +17,43 @@ | |
| then create the encounters for orders that don’t have encounters | ||
| --> | ||
| <sql> | ||
| There are over 300,000 orders on both Rwink and Butaro with no linked encounter | ||
| select count(*) from orders where encounter_id is null | ||
|
|
||
| Of these, there are still between 100k and 150k on each server with no encounters on the same day | ||
| SET @EncTUUID := "a9ef19d1-8875-11ea-8c74-7a7919290ad6"; | ||
|
|
||
| select count(*) | ||
| from orders o | ||
| left join encounter e on o.patient_id = e.patient_id and date(o.start_date) = date(e.encounter_datetime) | ||
| where e.encounter_id is null; | ||
|
|
||
| So we need to figure out a strategy for this. | ||
| /* Create EncounterType */ | ||
| INSERT INTO `encounter_type` | ||
| (`name`,`description`,`creator`,`date_created`,`uuid`) | ||
| VALUES | ||
| ( | ||
| "Drug Order Encounter","for orders without encounters",1,now(),@EncTUUID); | ||
|
|
||
| Safest thing for now might be to create new encounters for all of these. Later on, if we want to merge | ||
| some of these into other existing enocunters for the same patient on the same day, we can do so, | ||
| but that isn't needed for migration and might not be 100% accurate. | ||
| /* Get encounterType id */ | ||
| select @encTId:=encounter_type_id from encounter_type where uuid=@EncTUUID; | ||
|
|
||
|
|
||
| /* Create encounters */ | ||
| INSERT INTO `encounter`(`encounter_type`,`patient_id`,`encounter_datetime`,`creator`,`date_created`,`voided`,`voided_by`,`date_voided`,`void_reason`,`uuid`) | ||
| SELECT @encTId,patient_id,start_date,creator,date_created,voided,voided_by,date_voided,void_reason,UUID() FROM orders WHERE encounter_id is null; | ||
|
|
||
| /* Update orders*/ | ||
| UPDATE orders O | ||
| LEFT JOIN encounter ENC ON O.patient_id = ENC.patient_id AND O.start_date=ENC.encounter_datetime AND O.creator=ENC.creator AND O.date_created=ENC.date_created | ||
| SET O.encounter_id=ENC.encounter_id | ||
| WHERE O.encounter_id is null AND ENC.encounter_type=@encTId; | ||
|
|
||
|
|
||
| /* select the unknown provider */ | ||
|
|
||
| SELECT @UnknownProvider := provider_id FROM provider WHERE uuid="6a7d7d04-f523-11e5-9ce9-5e5517507c66"; | ||
|
||
| /* Create encounter providers*/ | ||
|
|
||
| INSERT INTO `encounter_provider`(`encounter_id`,`provider_id`,`encounter_role_id`,`creator`,`date_created`,`changed_by`, | ||
| `date_changed`,`voided`,`date_voided`,`voided_by`,`void_reason`,`uuid`) | ||
| SELECT encounter_id,@UnknownProvider,1,creator,date_created,changed_by,date_changed,voided,date_voided,voided_by,void_reason,UUID() | ||
| FROM encounter WHERE encounter_type = @encTId; | ||
|
|
||
| This could be something like a SQL script that runs the following statements: | ||
|
|
||
| 1. Create new encounter type if not exists with known, fixed uuid (eg. with name "Drug Order Encounter") | ||
| 2. Get this encounter_type_id as @encId | ||
| 3. Add new encounter for each patient/order.start_date combination | ||
| 4. Update all orders with null encounter by setting them to the encounter for matching patient/date with the created encounter_type | ||
|
|
||
| </sql> | ||
| </changeSet> | ||
|
|
||
Uh oh!
There was an error while loading. Please reload this page.
There was a problem hiding this comment.
Choose a reason for hiding this comment
The reason will be displayed to describe this comment to others. Learn more.
Are we sure that this is what we want to name this encounter type? And can the description be capitalized?