Skip to content
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

AMTv4 sample scripts - changes to align with TIG updates #6

Open
wants to merge 7 commits into
base: master
Choose a base branch
from
24 changes: 14 additions & 10 deletions AMTv4-sample-scripts/schema/2_populateTables.sql
Original file line number Diff line number Diff line change
Expand Up @@ -12,56 +12,60 @@ USE `sctau`;
-- RF2_CONCEPTS_SNAPSHOT
TRUNCATE TABLE concepts_snapshot;

LOAD DATA LOCAL INFILE 'C://Releases/SnomedCT_AMT_Experiment_20231130/Snapshot/Terminology/xsct2_Concept_Snapshot_AU1000036_20231130.txt' INTO TABLE concepts_snapshot CHARACTER SET 'utf8' LINES TERMINATED BY '\r\n' IGNORE 1 LINES
LOAD DATA LOCAL INFILE '<release-files>/Snapshot/Terminology/xsct2_Concept_Snapshot_AU1000036_20231130.txt' INTO TABLE concepts_snapshot CHARACTER SET 'utf8' LINES TERMINATED BY '\r\n' IGNORE 1 LINES
(id, @effectivetime, active, moduleid, definitionstatusid)
set effectivetime = str_to_date(@effectivetime, '%Y%m%d');


-- RF2_DESCRIPTIONS_SNAPSHOT
TRUNCATE TABLE descriptions_snapshot;

LOAD DATA LOCAL INFILE 'C://Releases/SnomedCT_AMT_Experiment_20231130/Snapshot/Terminology/xsct2_Description_Snapshot-en-AU_AU1000036_20231130.txt' INTO TABLE descriptions_snapshot CHARACTER SET 'utf8' LINES TERMINATED BY '\r\n' IGNORE 1 LINES
LOAD DATA LOCAL INFILE '<release-files>/Snapshot/Terminology/xsct2_Description_Snapshot-en-AU_AU1000036_20231130.txt' INTO TABLE descriptions_snapshot CHARACTER SET 'utf8' LINES TERMINATED BY '\r\n' IGNORE 1 LINES
(id, @effectivetime, active, moduleid, conceptid, languagecode, typeid, term, casesignificanceid)
set effectivetime = str_to_date(@effectivetime, '%Y%m%d');


-- RF2_RELATIONSHIPS_SNAPSHOT
TRUNCATE TABLE relationships_snapshot;

LOAD DATA LOCAL INFILE 'C://Releases/SnomedCT_AMT_Experiment_20231130/Snapshot/Terminology/xsct2_Relationship_Snapshot_AU1000036_20231130.txt' INTO TABLE relationships_snapshot CHARACTER SET 'utf8' LINES TERMINATED BY '\r\n' IGNORE 1 LINES
LOAD DATA LOCAL INFILE '<release-files>/Snapshot/Terminology/xsct2_Relationship_Snapshot_AU1000036_20231130.txt' INTO TABLE relationships_snapshot CHARACTER SET 'utf8' LINES TERMINATED BY '\r\n' IGNORE 1 LINES
(id, @effectivetime, active, moduleid, sourceid, destinationid, relationshipgroup, typeid, characteristictypeid, modifierid)
set effectivetime = str_to_date(@effectivetime, '%Y%m%d');

-- RF2_RELATIONSHIPS_CONCRETE_VALUES_SNAPSHOT
TRUNCATE TABLE relationships_concrete_values_snapshot;

LOAD DATA LOCAL INFILE 'C://Releases/SnomedCT_AMT_Experiment_20231130/Snapshot/Terminology/xsct2_RelationshipConcreteValues_Snapshot_AU1000036_20231130.txt' INTO TABLE relationships_concrete_values_snapshot CHARACTER SET 'utf8' LINES TERMINATED BY '\r\n' IGNORE 1 LINES
LOAD DATA LOCAL INFILE '<release-files>/Snapshot/Terminology/xsct2_RelationshipConcreteValues_Snapshot_AU1000036_20231130.txt' INTO TABLE relationships_concrete_values_snapshot CHARACTER SET 'utf8' LINES TERMINATED BY '\r\n' IGNORE 1 LINES
(id, @effectivetime, active, moduleid, sourceid, value, relationshipgroup, typeid, characteristictypeid, modifierid)
set effectivetime = str_to_date(@effectivetime, '%Y%m%d');

-- Remove the # character from the value field (Description logic artefact)
UPDATE relationships_concrete_values_snapshot
SET value = REPLACE(value, '#', '');

-- RF2_LANGUAGE_REFSET_SNAPSHOT
TRUNCATE TABLE language_refset_snapshot;

LOAD DATA LOCAL INFILE 'C://Releases/SnomedCT_AMT_Experiment_20231130/Snapshot/Refset/Language/xder2_cRefset_LanguageSnapshot-en-AU_AU1000036_20231130.txt' INTO TABLE language_refset_snapshot CHARACTER SET 'utf8' LINES TERMINATED BY '\r\n' IGNORE 1 LINES
LOAD DATA LOCAL INFILE '<release-files>/Snapshot/Refset/Language/xder2_cRefset_LanguageSnapshot-en-AU_AU1000036_20231130.txt' INTO TABLE language_refset_snapshot CHARACTER SET 'utf8' LINES TERMINATED BY '\r\n' IGNORE 1 LINES
(id, @effectivetime, active, moduleid, refsetid, referencedcomponentid, acceptabilityid)
set effectivetime = str_to_date(@effectivetime, '%Y%m%d');


-- RF2_REFSET_SNAPSHOT
-- AMTv4, only a single import is required. All simple refsets exist in the same file.
LOAD DATA LOCAL INFILE 'C://Releases/SnomedCT_AMT_Experiment_20231130/Snapshot/Refset/Content/xder2_Refset_SimpleSnapshot_AU1000036_20231130.txt' INTO TABLE refset_snapshot CHARACTER SET 'utf8' LINES TERMINATED BY '\r\n' IGNORE 1 LINES
LOAD DATA LOCAL INFILE '<release-files>/Snapshot/Refset/Content/xder2_Refset_SimpleSnapshot_AU1000036_20231130.txt' INTO TABLE refset_snapshot CHARACTER SET 'utf8' LINES TERMINATED BY '\r\n' IGNORE 1 LINES
(id, @effectivetime, active, moduleid, refsetid, referencedcomponentid)
set effectivetime = str_to_date(@effectivetime, '%Y%m%d');

-- RF2_CREFSET_SNAPSHOT
-- Import historical association reference sets
TRUNCATE TABLE crefset_snapshot;

LOAD DATA LOCAL INFILE 'C://Releases/SnomedCT_AMT_Experiment_20231130/Snapshot/Refset/Content/xder2_cRefset_AssociationSnapshot_AU1000036_20231130.txt' INTO TABLE crefset_snapshot CHARACTER SET 'utf8' LINES TERMINATED BY '\r\n' IGNORE 1 LINES
LOAD DATA LOCAL INFILE '<release-files>/Snapshot/Refset/Content/xder2_cRefset_AssociationSnapshot_AU1000036_20231130.txt' INTO TABLE crefset_snapshot CHARACTER SET 'utf8' LINES TERMINATED BY '\r\n' IGNORE 1 LINES
(id, @effectivetime, active, moduleid, refsetid, referencedcomponentid, targetComponentid)
set effectivetime = str_to_date(@effectivetime, '%Y%m%d');

LOAD DATA LOCAL INFILE 'C://Releases/SnomedCT_AMT_Experiment_20231130/Snapshot/Refset/Content/xder2_cRefset_AttributeValueSnapshot_AU1000036_20231130.txt' INTO TABLE crefset_snapshot CHARACTER SET 'utf8' LINES TERMINATED BY '\r\n' IGNORE 1 LINES
LOAD DATA LOCAL INFILE '<release-files>/Snapshot/Refset/Content/xder2_cRefset_AttributeValueSnapshot_AU1000036_20231130.txt' INTO TABLE crefset_snapshot CHARACTER SET 'utf8' LINES TERMINATED BY '\r\n' IGNORE 1 LINES
(id, @effectivetime, active, moduleid, refsetid, referencedcomponentid, targetComponentid)
set effectivetime = str_to_date(@effectivetime, '%Y%m%d');

Expand All @@ -70,7 +74,7 @@ set effectivetime = str_to_date(@effectivetime, '%Y%m%d');
-- Import extended association schema refset. Currently only one exists - Route and form extended association
TRUNCATE TABLE ccrefset_snapshot;

LOAD DATA LOCAL INFILE 'C://Releases/SnomedCT_AMT_Experiment_20231130/Snapshot/Refset/Content/xder2_ccRefset_ExtendedAssociationSnapshot_AU1000036_20231130.txt' INTO TABLE ccrefset_snapshot CHARACTER SET 'utf8' LINES TERMINATED BY '\r\n' IGNORE 1 LINES
LOAD DATA LOCAL INFILE '<release-files>/Snapshot/Refset/Content/xder2_ccRefset_ExtendedAssociationSnapshot_AU1000036_20231130.txt' INTO TABLE ccrefset_snapshot CHARACTER SET 'utf8' LINES TERMINATED BY '\r\n' IGNORE 1 LINES
(id, @effectivetime, active, moduleid, refsetid, referencedcomponentid,value1,value2)
set effectivetime = str_to_date(@effectivetime, '%Y%m%d');

Expand All @@ -79,6 +83,6 @@ set effectivetime = str_to_date(@effectivetime, '%Y%m%d');
-- Import the 11000168105 ARTG Id reference set
TRUNCATE TABLE irefset_snapshot;

LOAD DATA LOCAL INFILE 'C://Releases/SnomedCT_AMT_Experiment_20231130/Snapshot/Refset/Map/xder2_iRefset_SimpleMapSnapshot_AU1000036_20231130.txt' INTO TABLE irefset_snapshot CHARACTER SET 'utf8' LINES TERMINATED BY '\r\n' IGNORE 1 LINES
LOAD DATA LOCAL INFILE '<release-files>/Snapshot/Refset/Map/xder2_iRefset_SimpleMapSnapshot_AU1000036_20231130.txt' INTO TABLE irefset_snapshot CHARACTER SET 'utf8' LINES TERMINATED BY '\r\n' IGNORE 1 LINES
(id, @effectivetime, active, moduleid, refsetid, referencedcomponentid, schemeValue)
set effectivetime = str_to_date(@effectivetime, '%Y%m%d');
4 changes: 0 additions & 4 deletions AMTv4-sample-scripts/schema/6_createAMTv4Objects.sql
Original file line number Diff line number Diff line change
Expand Up @@ -147,10 +147,6 @@ FROM v4_MPPhasMPUU MPPhasMPUU
AND ConcentrationUnit.typeid = 999000031000168102 -- Has concentration strength unit (attribute)
AND ConcentrationUnit.active = 1;

-- Clean up the numeric columns by removing the # character
UPDATE v4_ingredient_strength SET ConcentrationValue = REPLACE(ConcentrationValue, '#', '');
UPDATE v4_ingredient_strength SET TotalQuantity = REPLACE(TotalQuantity, '#', '');


-- Create Indexes for v4_ingredient_strength table
CREATE INDEX v4_ingredient_strength ON v4_ingredient_strength(mppid);
Expand Down
17 changes: 13 additions & 4 deletions AMTv4-sample-scripts/sql/sample_queries.sql
Original file line number Diff line number Diff line change
Expand Up @@ -22,14 +22,18 @@ FROM
refset_snapshot AS rs,
descriptions_snapshot AS d,
language_refset_snapshot AS adrs

WHERE c.id=rs.referencedComponentId
AND c.id=d.conceptid
AND d.id=adrs.referencedComponentId
AND adrs.acceptabilityid=900000000000548007 -- ID of Preferred Term
AND rs.refsetid= 11000036103 -- ID of Adverse reaction type refset
AND d.typeid = 900000000000013009 -- Synonym
AND adrs.refsetid = 32570271000036106 -- ADRS
AND adrs.acceptabilityid=900000000000548007 -- ID of Preferred Term
AND c.active=1
AND d.active=1
AND rs.active=1
AND ADRS.active = 1
ORDER BY preferred_term;

-- 4. List of Australian reference sets & member count
Expand All @@ -42,7 +46,8 @@ FROM
(SELECT
term,id,conceptid
FROM descriptions_snapshot AS ds
WHERE active=1) AS desc_active,
WHERE active=1 AND typeid = 900000000000013009 -- Synonym
) AS desc_active,

(SELECT
referencedComponentId
Expand Down Expand Up @@ -75,9 +80,9 @@ JOIN (SELECT sourceId
) AS ffd
ON c.id=ffd.sourceid
JOIN descriptions_snapshot AS d
ON c.id=d.conceptid
ON c.id=d.conceptid AND d.typeid = 900000000000013009 -- Synonym
JOIN language_refset_snapshot AS adrs
ON d.id=adrs.referencedComponentId
ON d.id=adrs.referencedComponentId AND adrs.refsetId = 32570271000036106 -- Australian dialect refset
WHERE adrs.acceptabilityid = 900000000000548007 -- ID of Preferred Term
AND c.active=1
AND d.active=1
Expand Down Expand Up @@ -106,6 +111,8 @@ language_refset_snapshot AS adrs
WHERE c.id=ffd.sourceid
AND c.id=d.conceptid
AND d.id=adrs.referencedComponentId
AND d.typeid = 900000000000013009 -- Synonym
AND adrs.refsetId = 32570271000036106 -- Australian dialect refset
AND adrs.acceptabilityid=900000000000548007 -- ID of Preferred Term
AND c.active=1
AND d.active=1
Expand All @@ -130,6 +137,8 @@ WHERE
c.id=pd.sourceid
AND c.id=d.conceptid
AND d.id=adrs.referencedComponentId
AND d.typeid = 900000000000013009 -- Synonym
AND adrs.refsetId = 32570271000036106 -- Australian dialect refset
AND adrs.acceptabilityid=900000000000548007 -- ID of Preferred Term
AND c.active=1
AND d.active=1
Expand Down