Skip to content

Commit

Permalink
[SQL] Refactor FK CandID int(6) to CandidateID int(10) (candidate.ID …
Browse files Browse the repository at this point in the history
…PK) (#9556)

This refactors the DB schema to rename every table except
`candidate`'s `CandID` field to `CandidateID`. This field now instead
references `candidate`.`ID`, which is now the PK of the table and a
`int(10)` instead of `int(6)` previously. `candidate`'s `CandID` field
has also been upgraded to an `unsigned int(10)`.

There is a patch that sets all the values of `CandidateID` of all tables
to instead become the corresponding `candidate`.`ID`.

The back-end of most modules that used a table with a `CandID` were
refactored to use `candidate`.`CandID` and to instead `JOIN ON
candidate.ID = table_with_CandID_previously.CandidateID`.

The result is that CandIDs have 1 canonical source now, and changes
(such as increasing its length) do not need to be made to every foreign
key.

Fixes #8827
  • Loading branch information
jeffersoncasimir authored Feb 12, 2025
1 parent 5e37d6a commit af6b5e0
Show file tree
Hide file tree
Showing 117 changed files with 22,672 additions and 22,453 deletions.
103 changes: 54 additions & 49 deletions SQL/0000-00-00-schema.sql

Large diffs are not rendered by default.

88 changes: 88 additions & 0 deletions SQL/New_patches/2025_02_05_change_candid_fk_to_id.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,88 @@
-- Change FKs from CandID to CandidateID which is now candidate.ID
ALTER TABLE CNV DROP constraint CNV_ibfk_3;
UPDATE CNV SET CandID=(SELECT ID from candidate c WHERE c.CandID=CNV.CandID);
ALTER TABLE CNV CHANGE CandID CandidateID int(10) unsigned;
ALTER TABLE CNV ADD CONSTRAINT CNV_ibfk_3 FOREIGN KEY (CandidateID) REFERENCES candidate(ID);

ALTER TABLE candidate_consent_rel DROP CONSTRAINT `FK_candidate_consent_rel_CandidateID`;
UPDATE candidate_consent_rel SET CandidateID=(SELECT ID from candidate c WHERE c.CandID=candidate_consent_rel.CandidateID);
ALTER TABLE candidate_consent_rel CHANGE CandidateID CandidateID int(10) unsigned;
ALTER TABLE candidate_consent_rel ADD CONSTRAINT FK_candidate_consent_rel_CandidateID FOREIGN KEY (CandidateID) REFERENCES candidate(ID) ON DELETE RESTRICT ON UPDATE RESTRICT;

ALTER TABLE participant_status DROP CONSTRAINT `fk_participant_status_3`;
UPDATE participant_status SET CandID=(SELECT ID from candidate c WHERE c.CandID=participant_status.CandID);
ALTER TABLE participant_status CHANGE CandID CandidateID int(10) unsigned;
ALTER TABLE participant_status ADD CONSTRAINT FK_participant_status_3 FOREIGN KEY (CandidateID) REFERENCES candidate(ID) ON DELETE CASCADE ON UPDATE CASCADE;

ALTER TABLE dataquery_run_results DROP CONSTRAINT `dataquery_run_results_ibfk_1`;
UPDATE dataquery_run_results SET CandID=(SELECT ID from candidate c WHERE c.CandID=dataquery_run_results.CandID);
ALTER TABLE dataquery_run_results CHANGE CandID CandidateID int(10) unsigned;
ALTER TABLE dataquery_run_results ADD CONSTRAINT dataquery_run_results_ibfk_1 FOREIGN KEY (CandidateID) REFERENCES candidate(ID);

ALTER TABLE issues DROP CONSTRAINT `fk_issues_3`;
UPDATE issues SET CandID=(SELECT ID from candidate c WHERE c.CandID=issues.CandID);
ALTER TABLE issues CHANGE CandID CandidateID int(10) unsigned;
ALTER TABLE issues ADD CONSTRAINT fk_issues_3 FOREIGN KEY (CandidateID) REFERENCES candidate(ID);

ALTER TABLE session DROP CONSTRAINT `fk_session_1`;
UPDATE session SET CandID=(SELECT ID from candidate c WHERE c.CandID=session.CandID);
ALTER TABLE session CHANGE CandID CandidateID int(10) unsigned;
ALTER TABLE session ADD CONSTRAINT fk_session_1 FOREIGN KEY (CandidateID) REFERENCES candidate(ID);

ALTER TABLE genomic_candidate_files_rel DROP CONSTRAINT `genomic_candidate_files_rel_ibfk_1`;
UPDATE genomic_candidate_files_rel SET CandID=(SELECT ID from candidate c WHERE c.CandID=genomic_candidate_files_rel.CandID);
ALTER TABLE genomic_candidate_files_rel CHANGE CandID CandidateID int(10) unsigned;
ALTER TABLE genomic_candidate_files_rel ADD CONSTRAINT genomic_candidate_files_rel_ibfk_1 FOREIGN KEY (CandidateID) REFERENCES candidate(ID);

ALTER TABLE mri_scanner DROP CONSTRAINT `FK_mri_scanner_1`;
UPDATE mri_scanner SET CandID=(SELECT ID from candidate c WHERE c.CandID=mri_scanner.CandID);
ALTER TABLE mri_scanner CHANGE CandID CandidateID int(10) unsigned;
ALTER TABLE mri_scanner ADD CONSTRAINT FK_mri_scanner_1 FOREIGN KEY (CandidateID) REFERENCES candidate(ID);

ALTER TABLE genomic_sample_candidate_rel DROP CONSTRAINT `genomic_sample_candidate_rel_ibfk_1`;
UPDATE genomic_sample_candidate_rel SET CandID=(SELECT ID from candidate c WHERE c.CandID=genomic_sample_candidate_rel.CandID);
ALTER TABLE genomic_sample_candidate_rel CHANGE CandID CandidateID int(10) unsigned;
ALTER TABLE genomic_sample_candidate_rel ADD CONSTRAINT `genomic_sample_candidate_rel_ibfk_1` FOREIGN KEY (CandidateID) REFERENCES `candidate`(`ID`);

ALTER TABLE SNP_candidate_rel DROP CONSTRAINT `fk_SNP_candidate_rel_2`;
UPDATE SNP_candidate_rel SET CandID=(SELECT ID from candidate c WHERE c.CandID=SNP_candidate_rel.CandID);
ALTER TABLE SNP_candidate_rel CHANGE CandID CandidateID int(10) unsigned;
ALTER TABLE SNP_candidate_rel ADD CONSTRAINT `fk_SNP_candidate_rel_2` FOREIGN KEY (CandidateID) REFERENCES candidate(ID) ON DELETE NO ACTION ON UPDATE NO ACTION;

ALTER TABLE parameter_candidate DROP CONSTRAINT `FK_parameter_candidate_2`;
UPDATE parameter_candidate SET CandID=(SELECT ID from candidate c WHERE c.CandID=parameter_candidate.CandID);
ALTER TABLE parameter_candidate CHANGE CandID CandidateID int(10) unsigned;
ALTER TABLE parameter_candidate ADD CONSTRAINT FK_parameter_candidate_2 FOREIGN KEY (CandidateID) REFERENCES candidate(ID);

ALTER TABLE candidate_diagnosis_evolution_rel DROP CONSTRAINT `PK_candidate_diagnosis_evolution_rel`;
ALTER TABLE candidate_diagnosis_evolution_rel DROP CONSTRAINT `FK_candidate_diagnosis_evolution_rel_CandID`;
UPDATE candidate_diagnosis_evolution_rel SET CandID=(SELECT ID from candidate c WHERE c.CandID=candidate_diagnosis_evolution_rel.CandID);
ALTER TABLE candidate_diagnosis_evolution_rel CHANGE CandID CandidateID int(10) unsigned;
ALTER TABLE candidate_diagnosis_evolution_rel ADD CONSTRAINT PK_candidate_diagnosis_evolution_rel PRIMARY KEY (CandidateID, DxEvolutionID);
ALTER TABLE candidate_diagnosis_evolution_rel ADD CONSTRAINT FK_candidate_diagnosis_evolution_rel_CandID FOREIGN KEY (CandidateID) REFERENCES candidate(ID) ON DELETE RESTRICT ON UPDATE RESTRICT;


-- Changes references to candidate.CandID that were NOT FK. Add FK
UPDATE feedback_bvl_thread SET CandID=(SELECT ID from candidate c WHERE c.CandID=feedback_bvl_thread.CandID);
ALTER TABLE feedback_bvl_thread CHANGE CandID CandidateID int(10) unsigned;
ALTER TABLE feedback_bvl_thread ADD CONSTRAINT FK_feedback_bvl_thread_candidate_1 FOREIGN KEY (CandidateID) REFERENCES candidate(ID);

UPDATE mri_violations_log SET CandID=(SELECT ID from candidate c WHERE c.CandID=mri_violations_log.CandID);
ALTER TABLE mri_violations_log CHANGE CandID CandidateID int(10) unsigned;
ALTER TABLE mri_violations_log ADD CONSTRAINT FK_mri_violations_log_candidate_1 FOREIGN KEY (CandidateID) REFERENCES candidate(ID);

UPDATE mri_protocol_violated_scans SET CandID=(SELECT ID from candidate c WHERE c.CandID=mri_protocol_violated_scans.CandID);
ALTER TABLE mri_protocol_violated_scans CHANGE CandID CandidateID int(10) unsigned;
ALTER TABLE mri_protocol_violated_scans ADD CONSTRAINT FK_mri_protocol_violated_scans_candidate_1 FOREIGN KEY (CandidateID) REFERENCES candidate(ID);

UPDATE participant_status_history SET CandID=(SELECT ID from candidate c WHERE c.CandID=participant_status_history.CandID);
ALTER TABLE participant_status_history CHANGE CandID CandidateID int(10) unsigned;
ALTER TABLE participant_status_history ADD CONSTRAINT FK_participant_status_history_candidate_1 FOREIGN KEY (CandidateID) REFERENCES candidate(ID);

UPDATE family SET CandID=(SELECT ID from candidate c WHERE c.CandID=family.CandID);
ALTER TABLE family CHANGE CandID CandidateID int(10) unsigned;
ALTER TABLE family ADD CONSTRAINT FK_family_candidate_1 FOREIGN KEY (CandidateID) REFERENCES candidate(ID);


-- Change candidate's PK to ID
ALTER TABLE candidate DROP PRIMARY KEY, ADD PRIMARY KEY(ID);
3 changes: 2 additions & 1 deletion modules/api/php/provisioners/candidatesprovisioner.class.inc
Original file line number Diff line number Diff line change
Expand Up @@ -44,7 +44,7 @@ class CandidatesProvisioner extends DBRowProvisioner
parent::__construct(
$this->loris,
'
SELECT
SELECT
c.CandID as CandID,
p.Name as ProjectName,
c.RegistrationProjectID as ProjectID,
Expand All @@ -61,6 +61,7 @@ class CandidatesProvisioner extends DBRowProvisioner
LEFT JOIN Project p
ON (c.RegistrationProjectID = p.ProjectID)
WHERE c.Active=\'Y\'
ORDER BY c.CandID
',
[]
);
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -50,7 +50,7 @@ class ProjectImagesRowProvisioner extends DBRowProvisioner
$this->loris,
'
SELECT
s.CandID as Candidate,
c.CandID as Candidate,
c.PSCID as PSCID,
c.Entity_type as Entity_type,
s.Visit_label as Visit,
Expand All @@ -69,7 +69,7 @@ class ProjectImagesRowProvisioner extends DBRowProvisioner
LEFT JOIN session s
ON (f.SessionID = s.ID)
LEFT JOIN candidate c
ON (s.CandID = c.CandID)
ON (s.CandidateID = c.ID)
LEFT JOIN psc p
ON (s.CenterID = p.CenterID)
LEFT JOIN files_qcstatus qc
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -53,9 +53,9 @@ class ProjectRecordingsRowProvisioner extends DBRowProvisioner
$this->loris,
'
SELECT
s.CandID as Candidate,
c.CandID as Candidate,
c.PSCID as PSCID,
c.Entity_type as Entity_type,
c.Entity_type as Entity_type,
s.Visit_label as Visit,
s.Date_visit as Visit_date,
s.CenterID as CenterID,
Expand All @@ -68,7 +68,7 @@ class ProjectRecordingsRowProvisioner extends DBRowProvisioner
LEFT JOIN session s
ON (f.SessionID = s.ID)
LEFT JOIN candidate c
ON (s.CandID = c.CandID)
ON (s.CandidateID = c.ID)
LEFT JOIN psc p
ON (s.CenterID = p.CenterID)
LEFT JOIN Project project
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -51,8 +51,8 @@ class VisitDicomsRowProvisioner extends DBRowProvisioner
JOIN session s
ON (s.ID=t.SessionID)
JOIN candidate c
ON (s.CandID=c.CandID)
WHERE
ON (s.CandidateID=c.ID)
WHERE
c.Active=\'Y\' AND
s.Active=\'Y\' AND
s.ID = :v_sessionid
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -26,7 +26,7 @@ class BehaviouralProvisioner extends \LORIS\Data\Provisioners\DBObjectProvisione
"
SELECT
tn.Full_name AS _instrument,
fb.CandID AS _candID,
ca.CandID AS _candID,
ca.PSCID AS _pscID,
s.Visit_label AS _visit,
COALESCE(s.ProjectID, ca.RegistrationProjectID) AS _project,
Expand All @@ -41,7 +41,7 @@ class BehaviouralProvisioner extends \LORIS\Data\Provisioners\DBObjectProvisione
fb.Status as _feedback_status
FROM
feedback_bvl_thread AS fb
JOIN candidate ca ON (ca.CandID = fb.CandID)
JOIN candidate ca ON (ca.ID = fb.CandidateID)
LEFT JOIN session s ON (s.ID = fb.SessionID)
LEFT JOIN psc ON (s.CenterID = psc.CenterID)
LEFT JOIN psc psc2 ON (ca.RegistrationCenterID=psc2.CenterID)
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -25,7 +25,7 @@ class ConflictsProvisioner extends \LORIS\Data\Provisioners\DBObjectProvisioner
parent::__construct(
"
SELECT DISTINCT
s.CandID AS _candID,
ca.CandID AS _candID,
ca.PSCID AS _pscID,
c.FieldName AS _fieldName,
c.TestName AS _testName,
Expand All @@ -41,7 +41,7 @@ class ConflictsProvisioner extends \LORIS\Data\Provisioners\DBObjectProvisioner
conflicts_unresolved c
LEFT JOIN flag f ON (c.CommentId1 = f.CommentID)
LEFT JOIN session s ON (f.SessionID = s.ID)
LEFT JOIN candidate ca ON (ca.CandID = s.CandID)
LEFT JOIN candidate ca ON (ca.ID = s.CandidateID)
JOIN test_names t ON (t.ID = f.TestID)
JOIN psc ON (s.CenterID = psc.CenterID)
WHERE
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -26,7 +26,7 @@ class IncompleteProvisioner extends \LORIS\Data\Provisioners\DBObjectProvisioner
"
SELECT DISTINCT
t.Full_name AS _instrument,
s.candid AS _candID,
c.CandID AS _candID,
c.PSCID AS _pscID,
s.visit_label AS _visit,
s.ProjectID AS _project,
Expand All @@ -40,7 +40,7 @@ class IncompleteProvisioner extends \LORIS\Data\Provisioners\DBObjectProvisioner
FROM
session s
JOIN flag f ON (f.sessionid = s.id)
JOIN candidate c ON (c.candid = s.candid)
JOIN candidate c ON (c.ID = s.CandidateID)
JOIN test_names t ON (t.ID = f.TestID)
JOIN psc ON (s.CenterID = psc.CenterID)
JOIN test_battery ON (
Expand Down
2 changes: 1 addition & 1 deletion modules/brainbrowser/php/imageinfo.class.inc
Original file line number Diff line number Diff line change
Expand Up @@ -198,7 +198,7 @@ class ImageInfo extends \NDB_Page
f.FileID as FileID
FROM files f
JOIN session s ON (f.SessionID=s.ID)
JOIN candidate c ON (s.CandID=c.CandID)
JOIN candidate c ON (s.CandidateID=c.ID)
WHERE FileID IN (" . join(",", $params) . ")";
break;
case 'ProtocolViolation':
Expand Down
5 changes: 3 additions & 2 deletions modules/bvl_feedback/php/module.class.inc
Original file line number Diff line number Diff line change
Expand Up @@ -71,11 +71,12 @@ class Module extends \Module

// Base query
$query = "SELECT fbt.Name, fbe.Testdate, fbe.Comment, fbth.FieldName,
fbth.CommentID, fbth.SessionID, fbth.CandID, fbth.Feedback_level
fbth.CommentID, fbth.SessionID, c.CandID, fbth.Feedback_level
FROM feedback_bvl_entry fbe
JOIN feedback_bvl_thread fbth USING (FeedbackID)
JOIN feedback_bvl_type fbt USING (Feedback_type)
JOIN session s ON s.ID=fbth.SessionID
JOIN candidate c ON s.CandidateID=c.ID
WHERE fbth.Status='opened' AND fbth.Active='Y'";

// Add centerID restriction if needed
Expand All @@ -86,7 +87,7 @@ class Module extends \Module

// Add project restriction & order BY
$project_arr = implode(",", $user->getProjectIDs());
$query .= " AND s.ProjectID IN ({$project_arr})
$query .= " AND s.ProjectID IN ({$project_arr})
ORDER BY Testdate DESC LIMIT 4";

$bvl_feedback = $DB->pselect(
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -73,10 +73,10 @@ class CandidateListRowProvisioner extends \LORIS\Data\Provisioners\DBRowProvisio
$maybeEDC
FROM candidate c
LEFT JOIN psc ON (c.RegistrationCenterID=psc.CenterID)
LEFT JOIN session s ON (c.CandID = s.CandID AND s.Active = 'Y')
LEFT JOIN session s ON (c.ID=s.CandidateID AND s.Active = 'Y')
LEFT JOIN feedback_bvl_thread
ON (c.CandID=feedback_bvl_thread.CandID)
LEFT JOIN participant_status ps ON (ps.CandID=c.CandID)
ON (c.ID=feedback_bvl_thread.CandidateID)
LEFT JOIN participant_status ps ON (ps.CandidateID=c.ID)
LEFT JOIN participant_status_options pso
ON (ps.participant_status=pso.ID)
LEFT JOIN Project p ON (c.RegistrationProjectID=p.ProjectID)
Expand Down
Loading

0 comments on commit af6b5e0

Please sign in to comment.