Skip to content

Commit

Permalink
refactor(patients) remove subquery from search
Browse files Browse the repository at this point in the history
This commit updates the SQL used to search for patients, it also updates
the structure of the table to INDEX and FULLTEXT INDEX columns that are
frequently searched on. This update greatly reduces the number of rows
that must be accessed by the search query, reducing the time required
and working to improve the performance on lower end hardware.
  • Loading branch information
sfount authored and jniles committed Mar 25, 2017
1 parent 8b1a1b8 commit cf212d1
Show file tree
Hide file tree
Showing 2 changed files with 36 additions and 32 deletions.
57 changes: 26 additions & 31 deletions server/controllers/medical/patients/index.js
Original file line number Diff line number Diff line change
Expand Up @@ -374,9 +374,9 @@ function searchByName(req, res, next) {
*/
function find(options) {
// ensure epected options are parsed appropriately as binary
db.convert(options, ['patient_group_uuid']);
db.convert(options, ['patient_group_uuid', 'debtor_group_uuid']);

const filters = new FilterParser(options, { tableAlias: 'q' });
const filters = new FilterParser(options, { tableAlias: 'p' });
const sql = patientEntityQuery(options.detailed);

filters.fullText('display_name');
Expand All @@ -389,11 +389,16 @@ function find(options) {
filters.period('defaultPeriod', 'registration_date');

const patientGroupStatement =
'(SELECT COUNT(uuid) FROM assignation_patient where patient_uuid = q.uuid AND patient_group_uuid = ?) = 1';
'(SELECT COUNT(uuid) FROM assignation_patient where patient_uuid = p.uuid AND patient_group_uuid = ?) = 1';
filters.custom('patient_group_uuid', patientGroupStatement);
filters.equals('debtor_group_uuid', 'group_uuid', 'd');

const referenceStatement =
`CONCAT_WS('.', '${identifiers.PATIENT.key}', proj.abbr, p.reference) = ?`;
filters.custom('reference', referenceStatement);

// @TODO Support ordering query (reference support for limit)?
filters.setOrder('ORDER BY q.registration_date DESC');
filters.setOrder('ORDER BY p.registration_date DESC');

// applies filters and limits to defined sql, get parameters in correct order
const query = filters.applyQuery(sql);
Expand All @@ -407,40 +412,30 @@ function patientEntityQuery(detailed) {
// if the find should included detailed results
if (detailed) {
detailedColumns = `
, q.abbr, q.father_name, q.mother_name, q.profession, q.employer, q.hospital_no,
q.spouse, q.spouse_profession, q.spouse_employer, q.religion, q.marital_status,
q.phone, q.email, q.address_1, q.address_2, BUID(q.origin_location_id) as origin_location_id,
BUID(q.current_location_id) as current_location_id, q.registration_date, q.title, q.notes, q.text,
q.account_id, BUID(q.price_list_uuid) as price_list_uuid, q.is_convention, q.locked
, proj.abbr, p.father_name, p.mother_name, p.profession, p.employer,
p.spouse, p.spouse_profession, p.spouse_employer, p.religion, p.marital_status,
p.phone, p.email, p.address_1, p.address_2, BUID(p.origin_location_id) as origin_location_id,
BUID(p.current_location_id) as current_location_id, p.registration_date, p.title, p.notes, d.text,
dg.account_id, BUID(dg.price_list_uuid) as price_list_uuid, dg.is_convention, dg.locked
`;
}

// @TODO Investigate if this origin alias table as 'q' does JOINs on every single patient row
// _before_selecting.
// build the main part of the SQL query
const sql = `
SELECT BUID(q.uuid) AS uuid, q.project_id, q.reference, q.display_name, BUID(q.debtor_uuid) as debtor_uuid,
q.sex, q.dob, q.registration_date, BUID(q.debtor_group_uuid) as debtor_group_uuid, q.hospital_no,
q.last_visit, q.userName, q.originVillageName, q.originSectorName ${detailedColumns}
FROM (
SELECT p.uuid, p.project_id, CONCAT_WS('.', '${identifiers.PATIENT.key}', proj.abbr, p.reference) AS reference,
p.display_name, p.debtor_uuid AS debtor_uuid, p.sex, p.dob, p.father_name, p.mother_name, p.profession,
p.employer, p.spouse, p.spouse_profession, p.spouse_employer, p.religion, p.marital_status, p.phone,
p.email, p.address_1, p.address_2, p.origin_location_id, p.current_location_id,
p.registration_date, p.title, p.notes, p.hospital_no, p.user_id, d.text, proj.abbr, dg.account_id,
dg.price_list_uuid as price_list_uuid, dg.is_convention, dg.locked, MAX(pv.start_date) AS last_visit,
dg.uuid AS debtor_group_uuid, u.display_name AS userName, originVillage.name AS originVillageName,
originSector.name AS originSectorName
FROM patient AS p
JOIN project AS proj ON p.project_id = proj.id
JOIN debtor AS d ON p.debtor_uuid = d.uuid
JOIN debtor_group AS dg ON d.group_uuid = dg.uuid
JOIN village as originVillage ON originVillage.uuid = p.origin_location_id
JOIN sector AS originSector on originVillage.sector_uuid = originSector.uuid
JOIN user AS u ON p.user_id = u.id
LEFT JOIN patient_visit AS pv ON pv.patient_uuid = p.uuid
GROUP BY p.uuid
) AS q
SELECT BUID(p.uuid) AS uuid, p.project_id, CONCAT_WS('.', '${identifiers.PATIENT.key}', proj.abbr, p.reference) AS reference,
p.display_name, BUID(p.debtor_uuid) as debtor_uuid,
p.sex, p.dob, p.registration_date, BUID(d.group_uuid) as debtor_group_uuid, p.hospital_no,
u.display_name as userName, originVillage.name as originVillageName,
originSector.name as originSectorName ${detailedColumns}
FROM patient AS p
JOIN project AS proj ON p.project_id = proj.id
JOIN debtor AS d ON p.debtor_uuid = d.uuid
JOIN debtor_group AS dg ON d.group_uuid = dg.uuid
JOIN village as originVillage ON originVillage.uuid = p.origin_location_id
JOIN sector AS originSector on originVillage.sector_uuid = originSector.uuid
JOIN user AS u ON p.user_id = u.id
`;

return sql;
Expand Down
11 changes: 10 additions & 1 deletion server/models/schema.sql
Original file line number Diff line number Diff line change
Expand Up @@ -1096,7 +1096,7 @@ CREATE TABLE `patient` (
`debtor_uuid` BINARY(16) NOT NULL,
`display_name` VARCHAR(150) NOT NULL,
`dob` DATE NOT NULL,
`dob_unknown_date` BOOLEAN NOT NULL DEFAULT FALSE,
`dob_unknown_date` BOOLEAN NOT NULL DEFAULT FALSE,
`father_name` VARCHAR(150),
`mother_name` VARCHAR(150),
`profession` VARCHAR(150),
Expand Down Expand Up @@ -1128,6 +1128,15 @@ CREATE TABLE `patient` (
KEY `debtor_uuid` (`debtor_uuid`),
KEY `origin_location_id` (`origin_location_id`),
KEY `current_location_id` (`current_location_id`),

/* @TODO analyse performance implications of indexing frequently searched columns */
INDEX `registration_date` (`registration_date`),
INDEX `dob` (`dob`),
INDEX `sex` (`sex`),

/* @TODO fulltext index may degrade INSERT performance over time */
FULLTEXT `display_name` (`display_name`),

FOREIGN KEY (`project_id`) REFERENCES `project` (`id`),
FOREIGN KEY (`debtor_uuid`) REFERENCES `debtor` (`uuid`) ON DELETE CASCADE ON UPDATE CASCADE,
FOREIGN KEY (`current_location_id`) REFERENCES `village` (`uuid`) ON UPDATE CASCADE,
Expand Down

0 comments on commit cf212d1

Please sign in to comment.