├── .gitignore
├── .project
├── LICENSE.md
├── MSSQL
├── README.md
├── bcp.cmdline.formats.bat
├── create-database-mssql.sql
├── create_snomed_tables.sql
└── import.bat
├── MySQL
├── README.md
├── create-database-mysql.sql
├── environment-mysql-template.sql
├── environment-mysql.sql
├── load-mysql-full-only.sql
├── load-mysql.sql
├── load_release.sh
└── transitiveClosureRf2Snap_dbCompatible.pl
├── NEO4J
├── .gitignore
├── Readme.md
├── snomed_g_TC_tools.py
├── snomed_g_graphdb_build_tools.py
├── snomed_g_graphdb_cypher_add_assoc_refset.template
├── snomed_g_graphdb_cypher_create.template
├── snomed_g_graphdb_cypher_refset_assoc_create.template
├── snomed_g_graphdb_cypher_rmv_problem_edges.template
├── snomed_g_graphdb_cypher_update.template
├── snomed_g_graphdb_update_failure_check.cypher
├── snomed_g_graphdb_validate_tools.py
├── snomed_g_lib_neo4j.py
├── snomed_g_lib_rf2.py
├── snomed_g_neo4j_tools.py
├── snomed_g_rf2_tools.py
├── snomed_g_sqlite_tools.py
├── snomed_g_template_tools.py
├── snomed_g_version
├── snomed_lib.py
└── snomedct_constants.py
├── PostgreSQL
├── README.md
├── Verhoeff.sql
├── create-database-postgres.sql
├── environment-postgresql.sql
├── indexing-postgres.sql
├── load-postgresql.sql
└── load_release-postgresql.sh
├── README.md
├── mysql-loader-with-optimized-views
├── LICENSE.md
├── README.md
├── bash
│ ├── snomed_config_mysql
│ ├── snomed_load_mysql
│ └── snomed_run_mysql
├── cnf
│ ├── com.oracle.oss.mysql.mysqld.plist
│ ├── my_snomedimport_client.cnf
│ ├── my_snomedserver.cnf
│ └── ref_my_snomedserver.awk
├── lib
│ ├── test.pl
│ └── transitiveClosureRf2SnapMulti.pl
├── mysql_examples
│ ├── DeltaWithPreviousStateExample.sql
│ ├── SQL_Queries_Step_by_Step_Views
│ │ ├── Description_Composite_View_Step_by_Step
│ │ │ ├── 1b_Snapshot_and_Full_Synonyms.sql
│ │ │ ├── Description_Composite_View_Step_by_Step_00.sql
│ │ │ ├── Description_Composite_View_Step_by_Step_01.sql
│ │ │ ├── Description_Composite_View_Step_by_Step_02.sql
│ │ │ ├── Description_Composite_View_Step_by_Step_03.sql
│ │ │ ├── Description_Composite_View_Step_by_Step_04.sql
│ │ │ ├── Description_Composite_View_Step_by_Step_05.sql
│ │ │ ├── Description_Composite_View_Step_by_Step_06.sql
│ │ │ └── Description_Composite_View_Step_by_Step_07.sql
│ │ ├── README.md
│ │ └── Snapshot_View_Step_by_Step
│ │ │ ├── Snapshot_View_Step_by_Step_00.sql
│ │ │ ├── Snapshot_View_Step_by_Step_01.sql
│ │ │ ├── Snapshot_View_Step_by_Step_02.sql
│ │ │ ├── Snapshot_View_Step_by_Step_03.sql
│ │ │ ├── Snapshot_View_Step_by_Step_04.sql
│ │ │ ├── Snapshot_View_Step_by_Step_05.sql
│ │ │ ├── Snapshot_View_Step_by_Step_06.sql
│ │ │ └── Snapshot_View_Step_by_Step_07.sql
│ ├── SQL_Queries_for_Webinar
│ │ ├── 0_Imported_Table_and_View_Statistics.sql
│ │ ├── 1a_Preferred_Term_from_tables.sql
│ │ ├── 1b_Preferred_Term_from view.sql
│ │ ├── 2_ECL_Simple.sql
│ │ ├── 3_ECL_with_Refinement1.sql
│ │ ├── 4_ECL_with_Refinement2.sql
│ │ ├── 5_ECL_with_Refinement3.sql
│ │ ├── 6_ECL_with_Refinement3_using_EclQuery.sql
│ │ └── 7_Subtypes_of_two_concepts_using_intersection.sql
│ ├── SQL_Queries_for_eBook
│ │ ├── 01_Release_Types.sql
│ │ ├── 02_Descriptions.sql
│ │ ├── 03_Language_Preferences.sql
│ │ ├── 04_Relationships.sql
│ │ └── 05_Term_Searches.sql
│ ├── conceptInactivations.sql
│ ├── descriptionInactivations.sql
│ ├── ecl_example1.sql
│ ├── map_view.sql
│ ├── search_example1.sql
│ └── show_language_terms_for_concept.sql
├── mysql_load
│ ├── LOADER_README.md
│ ├── mysql_create
│ │ └── sct_mysql_load_create_Canadian_EditionRelease.sql
│ ├── mysql_extend
│ │ └── sct_mysql_load_extend_ICNPNursingPractice.sql
│ ├── mysql_index
│ │ ├── sct_mysql_load_index_Canadian_EditionRelease.sql
│ │ └── sct_mysql_load_index_ICNPNursingPractice.sql
│ ├── mysql_update
│ │ └── sct_mysql_load_update_Canadian_EditionRelease.sql
│ ├── sct_mysql_load_create_InternationalRF2.sql
│ ├── sct_mysql_load_index_InternationalRF2.sql
│ ├── sct_mysql_load_update_InternationalRF2.sql
│ └── sct_mysql_temp.sql
└── win
│ ├── my.ini
│ ├── mysqlPath.cfg
│ ├── perlPath.cfg
│ ├── snomed_wconfig_mysql.bat
│ ├── snomed_win_my.ini
│ ├── snomed_wload_mysql.bat
│ └── tabfile.tmp
├── python-dataframe
├── README.md
└── python-pandas.py
└── rf1
├── .gitignore
├── README.md
├── rf1_environment_mysql.sql
└── rf1_load_release.sh
/.gitignore:
--------------------------------------------------------------------------------
1 | tmp*
2 | .project
3 | *.pyc
4 | .idea/
5 | .DS_Store
6 | *.zip
7 | .vscode/settings.json
8 |
--------------------------------------------------------------------------------
/.project:
--------------------------------------------------------------------------------
1 |
2 |
3 | snomed-database-loader
4 |
5 |
6 |
7 |
8 |
9 |
10 |
11 |
12 |
--------------------------------------------------------------------------------
/LICENSE.md:
--------------------------------------------------------------------------------
1 | ```
2 | Apache License
3 | Version 2.0, January 2004
4 | http://www.apache.org/licenses/
5 | ```
6 |
7 | TERMS AND CONDITIONS FOR USE, REPRODUCTION, AND DISTRIBUTION
8 |
9 | 1. Definitions.
10 |
11 | "License" shall mean the terms and conditions for use, reproduction, and distribution as defined by Sections 1 through 9 of this document.
12 |
13 | "Licensor" shall mean the copyright owner or entity authorized by the copyright owner that is granting the License.
14 |
15 | "Legal Entity" shall mean the union of the acting entity and all other entities that control, are controlled by, or are under common control with that entity. For the purposes of this definition, "control" means (i) the power, direct or indirect, to cause the direction or management of such entity, whether by contract or otherwise, or (ii) ownership of fifty percent (50%) or more of the outstanding shares, or (iii) beneficial ownership of such entity.
16 |
17 | "You" (or "Your") shall mean an individual or Legal Entity exercising permissions granted by this License.
18 |
19 | "Source" form shall mean the preferred form for making modifications, including but not limited to software source code, documentation source, and configuration files.
20 |
21 | "Object" form shall mean any form resulting from mechanical transformation or translation of a Source form, including but not limited to compiled object code, generated documentation, and conversions to other media types.
22 |
23 | "Work" shall mean the work of authorship, whether in Source or Object form, made available under the License, as indicated by a copyright notice that is included in or attached to the work (an example is provided in the Appendix below).
24 |
25 | "Derivative Works" shall mean any work, whether in Source or Object form, that is based on (or derived from) the Work and for which the editorial revisions, annotations, elaborations, or other modifications represent, as a whole, an original work of authorship. For the purposes of this License, Derivative Works shall not include works that remain separable from, or merely link (or bind by name) to the interfaces of, the Work and Derivative Works thereof.
26 |
27 | "Contribution" shall mean any work of authorship, including the original version of the Work and any modifications or additions to that Work or Derivative Works thereof, that is intentionally submitted to Licensor for inclusion in the Work by the copyright owner or by an individual or Legal Entity authorized to submit on behalf of the copyright owner. For the purposes of this definition, "submitted" means any form of electronic, verbal, or written communication sent to the Licensor or its representatives, including but not limited to communication on electronic mailing lists, source code control systems, and issue tracking systems that are managed by, or on behalf of, the Licensor for the purpose of discussing and improving the Work, but excluding communication that is conspicuously marked or otherwise designated in writing by the copyright owner as "Not a Contribution."
28 |
29 | "Contributor" shall mean Licensor and any individual or Legal Entity on behalf of whom a Contribution has been received by Licensor and subsequently incorporated within the Work.
30 |
31 | 2. Grant of Copyright License. Subject to the terms and conditions of this License, each Contributor hereby grants to You a perpetual, worldwide, non-exclusive, no-charge, royalty-free, irrevocable copyright license to reproduce, prepare Derivative Works of, publicly display, publicly perform, sublicense, and distribute the Work and such Derivative Works in Source or Object form.
32 |
33 | 3. Grant of Patent License. Subject to the terms and conditions of this License, each Contributor hereby grants to You a perpetual, worldwide, non-exclusive, no-charge, royalty-free, irrevocable (except as stated in this section) patent license to make, have made, use, offer to sell, sell, import, and otherwise transfer the Work, where such license applies only to those patent claims licensable by such Contributor that are necessarily infringed by their Contribution(s) alone or by combination of their Contribution(s) with the Work to which such Contribution(s) was submitted. If You institute patent litigation against any entity (including a cross-claim or counterclaim in a lawsuit) alleging that the Work or a Contribution incorporated within the Work constitutes direct or contributory patent infringement, then any patent licenses granted to You under this License for that Work shall terminate as of the date such litigation is filed.
34 |
35 | 4. Redistribution. You may reproduce and distribute copies of the Work or Derivative Works thereof in any medium, with or without modifications, and in Source or Object form, provided that You meet the following conditions:
36 |
37 | (a) You must give any other recipients of the Work or
38 |
39 | ```
40 | Derivative Works a copy of this License; and
41 | ```
42 |
43 | (b) You must cause any modified files to carry prominent notices
44 |
45 | ```
46 | stating that You changed the files; and
47 | ```
48 |
49 | (c) You must retain, in the Source form of any Derivative Works
50 |
51 | ```
52 | that You distribute, all copyright, patent, trademark, and
53 | attribution notices from the Source form of the Work,
54 | excluding those notices that do not pertain to any part of
55 | the Derivative Works; and
56 | ```
57 |
58 | (d) If the Work includes a "NOTICE" text file as part of its
59 |
60 | ```
61 | distribution, then any Derivative Works that You distribute must
62 | include a readable copy of the attribution notices contained
63 | within such NOTICE file, excluding those notices that do not
64 | pertain to any part of the Derivative Works, in at least one
65 | of the following places: within a NOTICE text file distributed
66 | as part of the Derivative Works; within the Source form or
67 | documentation, if provided along with the Derivative Works; or,
68 | within a display generated by the Derivative Works, if and
69 | wherever such third-party notices normally appear. The contents
70 | of the NOTICE file are for informational purposes only and
71 | do not modify the License. You may add Your own attribution
72 | notices within Derivative Works that You distribute, alongside
73 | or as an addendum to the NOTICE text from the Work, provided
74 | that such additional attribution notices cannot be construed
75 | as modifying the License.
76 | ```
77 |
78 | You may add Your own copyright statement to Your modifications and may provide additional or different license terms and conditions for use, reproduction, or distribution of Your modifications, or for any such Derivative Works as a whole, provided Your use, reproduction, and distribution of the Work otherwise complies with the conditions stated in this License.
79 |
80 | 5. Submission of Contributions. Unless You explicitly state otherwise, any Contribution intentionally submitted for inclusion in the Work by You to the Licensor shall be under the terms and conditions of this License, without any additional terms or conditions. Notwithstanding the above, nothing herein shall supersede or modify the terms of any separate license agreement you may have executed with Licensor regarding such Contributions.
81 |
82 | 6. Trademarks. This License does not grant permission to use the trade names, trademarks, service marks, or product names of the Licensor, except as required for reasonable and customary use in describing the origin of the Work and reproducing the content of the NOTICE file.
83 |
84 | 7. Disclaimer of Warranty. Unless required by applicable law or agreed to in writing, Licensor provides the Work (and each Contributor provides its Contributions) on an "AS IS" BASIS, WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied, including, without limitation, any warranties or conditions of TITLE, NON-INFRINGEMENT, MERCHANTABILITY, or FITNESS FOR A PARTICULAR PURPOSE. You are solely responsible for determining the appropriateness of using or redistributing the Work and assume any risks associated with Your exercise of permissions under this License.
85 |
86 | 8. Limitation of Liability. In no event and under no legal theory, whether in tort (including negligence), contract, or otherwise, unless required by applicable law (such as deliberate and grossly negligent acts) or agreed to in writing, shall any Contributor be liable to You for damages, including any direct, indirect, special, incidental, or consequential damages of any character arising as a result of this License or out of the use or inability to use the Work (including but not limited to damages for loss of goodwill, work stoppage, computer failure or malfunction, or any and all other commercial damages or losses), even if such Contributor has been advised of the possibility of such damages.
87 |
88 | 9. Accepting Warranty or Additional Liability. While redistributing the Work or Derivative Works thereof, You may choose to offer, and charge a fee for, acceptance of support, warranty, indemnity, or other liability obligations and/or rights consistent with this License. However, in accepting such obligations, You may act only on Your own behalf and on Your sole responsibility, not on behalf of any other Contributor, and only if You agree to indemnify, defend, and hold each Contributor harmless for any liability incurred by, or claims asserted against, such Contributor by reason of your accepting any such warranty or additional liability.
89 |
90 | END OF TERMS AND CONDITIONS
91 |
92 | **Copyright (c) 2025, SNOMED International**
93 |
94 | Licensed under the Apache License, Version 2.0 (the "License"); you may not use this file except in compliance with the License. You may obtain a copy of the License at
95 |
96 |
97 |
98 | Unless required by applicable law or agreed to in writing, software distributed under the License is distributed on an "AS IS" BASIS, WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. See the License for the specific language governing permissions and limitations under the License.
99 |
--------------------------------------------------------------------------------
/MSSQL/README.md:
--------------------------------------------------------------------------------
1 | # SNOMED CT DATABASE
2 |
3 | MSSQL SQL Scripts to create and populate a MSSQL database with a SNOMED CT terminology release
4 |
5 | ## Minimum Specification
6 |
7 | - MSSQL 2008
8 |
9 | # Creating the SNOMED CT DB schema on MS SQL
10 |
11 | - Create an empty DB and execute manually script create-database-mssql.sql against it
12 |
13 | ## Diffences from the PostgreSQL version
14 |
15 | - TSQL check for table presentse
16 | - Changes `uniqueidentifier` for `uuid`
17 |
18 | ## Manual Installation
19 |
20 | - Unpack Full version of SNOMED CT files
21 | - Copy import.bat into root folder where Full SNOMED CR files were updacked (the root has "Documentation" and "Full" folders only)
22 | - execute import.bat
23 | - import.sql script will be generated. Execute it againt desired MS SQL DB
24 |
25 | You may use sqlcmd to execute import.sql
26 | sqlcmd -b -I -S [server IP/name, port] -d [DB name] -U [User] -P [Password] -i import.sql
27 |
28 | Note: If you recieve message that "... Operating system error code 5(Access is denied.)" - please follow https://stackoverflow.com/questions/14555262/cannot-bulk-load-operating-system-error-code-5-access-is-denied
29 |
--------------------------------------------------------------------------------
/MSSQL/bcp.cmdline.formats.bat:
--------------------------------------------------------------------------------
1 | @echo off
2 |
3 | REM Batch file to create tables and import to them from provided SNOMED
4 | REM Terminoology files
5 | REM Copyright Chris Tillman 2018, licensed under GPL any version
6 |
7 | REM Set the variables appropriately for your system
8 |
9 | REM Set the path where SQL and batch scripts live
10 | SET SCRIPT_PATH=E:\EncounterPro\SNOMED\MSSQL
11 |
12 | REM The server designation, this one is a local SQL SERVER Express I access through Windows user permisson
13 | SET MSSQLSERVER=DESKTOP-GU15HUD\ENCOUNTERPRO
14 |
15 | REM The path the import files were extracted into ... if you have spaces in the path, the script will fail
16 | SET IMPORT_FILE_PATH=E:\EncounterPro\SNOMED\SnomedCT_USEditionRF2_PRODUCTION_20180301T183000Z
17 |
18 | REM The YYYYMMDD which makes up part of the filename.
19 | SET YYYYMMDD=20180301
20 |
21 | REM The representation of the specialization of the data which makes up part of the filename
22 | REM (in this case it is the U.S. subset from UMLS)
23 | SET LOCAL_ID=US1000124
24 |
25 | REM Language (sometimes part of the filename)
26 | SET SNOMED_LANG=en
27 |
28 | REM The type of import, again part of the filename. Could be Snapshot, Full, or Delta
29 | SET IMPORT_TYPE=Snapshot
30 |
31 | REM In order to import UTF-8 files to SQL Server, you need a recent version of bcp. Microsoft didn't
32 | REM get around to providing for UTF-8 files until 2016. It works with earlier SQL server versions.
33 |
34 | REM Command Line Utilities 14.0 https://www.microsoft.com/en-us/download/details.aspx?id=53591
35 | REM ODBC Driver 13.1 https://www.microsoft.com/en-us/download/details.aspx?id=53339
36 | REM Windows Installer 14.5 https://www.microsoft.com/en-us/download/details.aspx?id=8483
37 |
38 | REM The installed path to UTF-8 compatible bcp. This is the 64-bit version.
39 | SET PATH_TO_BCP="C:\Program Files\Microsoft SQL Server\Client SDK\ODBC\130\Tools\Binn\bcp.exe"
40 |
41 | REM Execute the table setup script. You must not be connected to the snomedct database in another program.
42 | sqlcmd -i "%SCRIPT_PATH%\create_snomed_tables.sql" -S %MSSQLSERVER% -d master -E
43 |
44 | REM Import the data. -C 65001 chooses UTF8, -T is trusted connection, -c results in no format files being needed, -F 2 means skip the first line which has column names.
45 | %PATH_TO_BCP% sct2_concept in "%IMPORT_FILE_PATH%\%IMPORT_TYPE%\Terminology\sct2_Concept_%IMPORT_TYPE%_%LOCAL_ID%_%YYYYMMDD%.txt" -C 65001 -S %MSSQLSERVER% -d snomedct -T -c -F 2
46 | %PATH_TO_BCP% sct2_description in "%IMPORT_FILE_PATH%\%IMPORT_TYPE%\Terminology\sct2_Description_%IMPORT_TYPE%-%SNOMED_LANG%_%LOCAL_ID%_%YYYYMMDD%.txt" -C 65001 -S %MSSQLSERVER% -d snomedct -T -c -F 2
47 | %PATH_TO_BCP% sct2_identifier in "%IMPORT_FILE_PATH%\%IMPORT_TYPE%\Terminology\sct2_Identifier_%IMPORT_TYPE%_%LOCAL_ID%_%YYYYMMDD%.txt" -C 65001 -S %MSSQLSERVER% -d snomedct -T -c -F 2
48 | %PATH_TO_BCP% sct2_statedrelationship in "%IMPORT_FILE_PATH%\%IMPORT_TYPE%\Terminology\sct2_StatedRelationship_%IMPORT_TYPE%_%LOCAL_ID%_%YYYYMMDD%.txt" -C 65001 -S %MSSQLSERVER% -d snomedct -T -c -F 2
49 | %PATH_TO_BCP% sct2_textdefinition in "%IMPORT_FILE_PATH%\%IMPORT_TYPE%\Terminology\sct2_TextDefinition_%IMPORT_TYPE%-%SNOMED_LANG%_%LOCAL_ID%_%YYYYMMDD%.txt" -C 65001 -S %MSSQLSERVER% -d snomedct -T -c -F 2
50 | %PATH_TO_BCP% sct2_relationship in "%IMPORT_FILE_PATH%\%IMPORT_TYPE%\Terminology\sct2_Relationship_%IMPORT_TYPE%_%LOCAL_ID%_%YYYYMMDD%.txt" -C 65001 -S %MSSQLSERVER% -d snomedct -T -c -F 2
51 |
52 | REM I didn't do the refsets, the file names don't quite correspond to the table names from the original MYSQL script ...
53 | REM "%PATH_TO_BCP%" sct2_refset in "%IMPORT_FILE_PATH%\%IMPORT_TYPE%\Refset\sct2_refset_%IMPORT_TYPE%_%LOCAL_ID%_%YYYYMMDD%.txt" -C 65001 -S %MSSQLSERVER% -d snomedct -T -c -F 2
54 | REM "%PATH_TO_BCP%" sct2_refset_c in "%IMPORT_FILE_PATH%\%IMPORT_TYPE%\Refset\sct2_refset_c_%IMPORT_TYPE%_%LOCAL_ID%_%YYYYMMDD%.txt" -C 65001 -S %MSSQLSERVER% -d snomedct -T -c -F 2
55 | REM "%PATH_TO_BCP%" sct2_refset_cci in "%IMPORT_FILE_PATH%\%IMPORT_TYPE%\Refset\sct2_refset_cci_%IMPORT_TYPE%_%LOCAL_ID%_%YYYYMMDD%.txt" -C 65001 -S %MSSQLSERVER% -d snomedct -T -c -F 2
56 | REM "%PATH_TO_BCP%" sct2_refset_ci in "%IMPORT_FILE_PATH%\%IMPORT_TYPE%\Refset\sct2_refset_ci_%IMPORT_TYPE%_%LOCAL_ID%_%YYYYMMDD%.txt" -C 65001 -S %MSSQLSERVER% -d snomedct -T -c -F 2
57 | REM "%PATH_TO_BCP%" sct2_refset_iisssc in "%IMPORT_FILE_PATH%\%IMPORT_TYPE%\Refset\sct2_refset_iisssc_%IMPORT_TYPE%_%LOCAL_ID%_%YYYYMMDD%.txt" -C 65001 -S %MSSQLSERVER% -d snomedct -T -c -F 2
58 | REM "%PATH_TO_BCP%" sct2_refset_iissscc in "%IMPORT_FILE_PATH%\%IMPORT_TYPE%\Refset\sct2_refset_iissscc_%IMPORT_TYPE%_%LOCAL_ID%_%YYYYMMDD%.txt" -C 65001 -S %MSSQLSERVER% -d snomedct -T -c -F 2
59 | REM "%PATH_TO_BCP%" sct2_refset_s in "%IMPORT_FILE_PATH%\%IMPORT_TYPE%\Refset\sct2_refset_s_%IMPORT_TYPE%_%LOCAL_ID%_%YYYYMMDD%.txt" -C 65001 -S %MSSQLSERVER% -d snomedct -T -c -F 2
60 | REM "%PATH_TO_BCP%" sct2_refset_ss in "%IMPORT_FILE_PATH%\%IMPORT_TYPE%\Refset\sct2_refset_ss_%IMPORT_TYPE%_%LOCAL_ID%_%YYYYMMDD%.txt" -C 65001 -S %MSSQLSERVER% -d snomedct -T -c -F 2
61 |
62 | REM Reset the path variable for the ICD coding file
63 | SET IMPORT_TYPE=Documentation
64 |
65 | %PATH_TO_BCP% tls_Icd10cmHumanReadableMap in "%IMPORT_FILE_PATH%\%IMPORT_TYPE%\tls_Icd10cmHumanReadableMap_%LOCAL_ID%_%YYYYMMDD%.tsv" -C 65001 -S %MSSQLSERVER% -d snomedct -T -c -F 2
66 |
--------------------------------------------------------------------------------
/MSSQL/create-database-mssql.sql:
--------------------------------------------------------------------------------
1 | /* create the Full S-CT data tables */
2 |
3 |
4 | IF EXISTS(SELECT 1 FROM information_schema.tables WHERE table_name = 'curr_concept_f') DROP TABLE curr_concept_f;
5 | create table curr_concept_f(
6 | id varchar(18) not null,
7 | effectivetime char(8) not null,
8 | active char(1) not null,
9 | moduleid varchar(18) not null,
10 | definitionstatusid varchar(18) not null,
11 | PRIMARY KEY(id, effectivetime)
12 | );
13 |
14 | IF EXISTS(SELECT 1 FROM information_schema.tables WHERE table_name = 'curr_description_f') DROP TABLE curr_description_f;
15 | create table curr_description_f(
16 | id varchar(18) not null,
17 | effectivetime char(8) not null,
18 | active char(1) not null,
19 | moduleid varchar(18) not null,
20 | conceptid varchar(18) not null,
21 | languagecode varchar(2) not null,
22 | typeid varchar(18) not null,
23 | term text not null,
24 | casesignificanceid varchar(18) not null,
25 | PRIMARY KEY(id, effectivetime)
26 | );
27 |
28 | IF EXISTS(SELECT 1 FROM information_schema.tables WHERE table_name = 'curr_textdefinition_f') DROP TABLE curr_textdefinition_f;
29 | create table curr_textdefinition_f(
30 | id varchar(18) not null,
31 | effectivetime char(8) not null,
32 | active char(1) not null,
33 | moduleid varchar(18) not null,
34 | conceptid varchar(18) not null,
35 | languagecode varchar(2) not null,
36 | typeid varchar(18) not null,
37 | term text not null,
38 | casesignificanceid varchar(18) not null,
39 | PRIMARY KEY(id, effectivetime)
40 | );
41 |
42 | IF EXISTS(SELECT 1 FROM information_schema.tables WHERE table_name = 'curr_relationship_f') DROP TABLE curr_relationship_f;
43 | create table curr_relationship_f(
44 | id varchar(18) not null,
45 | effectivetime char(8) not null,
46 | active char(1) not null,
47 | moduleid varchar(18) not null,
48 | sourceid varchar(18) not null,
49 | destinationid varchar(18) not null,
50 | relationshipgroup varchar(18) not null,
51 | typeid varchar(18) not null,
52 | characteristictypeid varchar(18) not null,
53 | modifierid varchar(18) not null,
54 | PRIMARY KEY(id, effectivetime)
55 | );
56 |
57 | IF EXISTS(SELECT 1 FROM information_schema.tables WHERE table_name = 'curr_stated_relationship_f') DROP TABLE curr_stated_relationship_f;
58 | create table curr_stated_relationship_f(
59 | id varchar(18) not null,
60 | effectivetime char(8) not null,
61 | active char(1) not null,
62 | moduleid varchar(18) not null,
63 | sourceid varchar(18) not null,
64 | destinationid varchar(18) not null,
65 | relationshipgroup varchar(18) not null,
66 | typeid varchar(18) not null,
67 | characteristictypeid varchar(18) not null,
68 | modifierid varchar(18) not null,
69 | PRIMARY KEY(id, effectivetime)
70 | );
71 |
72 | IF EXISTS(SELECT 1 FROM information_schema.tables WHERE table_name = 'curr_langrefset_f') DROP TABLE curr_langrefset_f;
73 | create table curr_langrefset_f(
74 | id uniqueidentifier not null,
75 | effectivetime char(8) not null,
76 | active char(1) not null,
77 | moduleid varchar(18) not null,
78 | refsetid varchar(18) not null,
79 | referencedcomponentid varchar(18) not null,
80 | acceptabilityid varchar(18) not null,
81 | PRIMARY KEY(id, effectivetime)
82 | );
83 |
84 | IF EXISTS(SELECT 1 FROM information_schema.tables WHERE table_name = 'curr_associationrefset_f') DROP TABLE curr_associationrefset_f;
85 | create table curr_associationrefset_f(
86 | id uniqueidentifier not null,
87 | effectivetime char(8) not null,
88 | active char(1) not null,
89 | moduleid varchar(18) not null,
90 | refsetid varchar(18) not null,
91 | referencedcomponentid varchar(18) not null,
92 | targetcomponentid varchar(18) not null,
93 | PRIMARY KEY(id, effectivetime)
94 | );
95 |
96 | IF EXISTS(SELECT 1 FROM information_schema.tables WHERE table_name = 'curr_attributevaluerefset_f') DROP TABLE curr_attributevaluerefset_f;
97 | create table curr_attributevaluerefset_f(
98 | id uniqueidentifier not null,
99 | effectivetime char(8) not null,
100 | active char(1) not null,
101 | moduleid varchar(18) not null,
102 | refsetid varchar(18) not null,
103 | referencedcomponentid varchar(18) not null,
104 | valueid varchar(18) not null,
105 | PRIMARY KEY(id, effectivetime)
106 | );
107 |
108 | IF EXISTS(SELECT 1 FROM information_schema.tables WHERE table_name = 'curr_simplerefset_f') DROP TABLE curr_simplerefset_f;
109 | create table curr_simplerefset_f(
110 | id uniqueidentifier not null,
111 | effectivetime char(8) not null,
112 | active char(1) not null,
113 | moduleid varchar(18) not null,
114 | refsetid varchar(18) not null,
115 | referencedcomponentid varchar(18) not null,
116 | PRIMARY KEY(id, effectivetime)
117 | );
118 |
119 | IF EXISTS(SELECT 1 FROM information_schema.tables WHERE table_name = 'curr_simplemaprefset_f') DROP TABLE curr_simplemaprefset_f;
120 | create table curr_simplemaprefset_f(
121 | id uniqueidentifier not null,
122 | effectivetime char(8) not null,
123 | active char(1) not null,
124 | moduleid varchar(18) not null,
125 | refsetid varchar(18) not null,
126 | referencedcomponentid varchar(18) not null,
127 | maptarget text not null,
128 | PRIMARY KEY(id, effectivetime)
129 | );
130 |
131 | IF EXISTS(SELECT 1 FROM information_schema.tables WHERE table_name = 'curr_extendedmaprefset_f') DROP TABLE curr_extendedmaprefset_f;
132 | create table curr_extendedmaprefset_f(
133 | id uniqueidentifier not null,
134 | effectivetime char(8) not null,
135 | active char(1) not null,
136 | moduleid varchar(18) not null,
137 | refsetid varchar(18) not null,
138 | referencedcomponentid varchar(18) not null,
139 | mapGroup smallint not null,
140 | mapPriority smallint not null,
141 | mapRule text,
142 | mapAdvice text,
143 | mapTarget text,
144 | correlationId varchar(18),
145 | mapCategoryId varchar(18),
146 | PRIMARY KEY(id, effectivetime)
147 | )
--------------------------------------------------------------------------------
/MSSQL/import.bat:
--------------------------------------------------------------------------------
1 | @echo off
2 | @echo --Importing SNOMED CT into MS SQL DB> import.sql
3 | @echo TRUNCATE TABLE curr_extendedmaprefset_f;>> import.sql
4 | @echo TRUNCATE TABLE curr_simplemaprefset_f;>> import.sql
5 | @echo TRUNCATE TABLE curr_attributevaluerefset_f;>> import.sql
6 | @echo TRUNCATE TABLE curr_simplerefset_f;>> import.sql
7 | @echo TRUNCATE TABLE curr_associationrefset_f;>> import.sql
8 | @echo TRUNCATE TABLE curr_langrefset_f;>> import.sql
9 | @echo TRUNCATE TABLE curr_stated_relationship_f;>> import.sql
10 | @echo TRUNCATE TABLE curr_relationship_f;>> import.sql
11 | @echo TRUNCATE TABLE curr_description_f;>> import.sql
12 | @echo TRUNCATE TABLE curr_concept_f;>> import.sql
13 |
14 | IF NOT EXIST Full\Terminology\sct2_Concept_Full_INT_* (
15 | @echo Cannot find Full\Terminology\sct2_Concept_Full_INT_*
16 | EXIT /B 1
17 | )
18 | for /r %%i in (Full\Terminology\sct2_Concept_Full_INT_*) do (
19 | @echo BULK INSERT curr_concept_f FROM '%%i' WITH (FIRSTROW = 2, FIELDTERMINATOR = '\t', ROWTERMINATOR = '\n', TABLOCK^); >>import.sql
20 | )
21 |
22 | IF NOT EXIST Full\Terminology\sct2_Description_Full-en_INT_* (
23 | @echo Cannot find Full\Terminology\sct2_Description_Full-en_INT_
24 | EXIT /B 1
25 | )
26 | for /r %%i in (Full\Terminology\sct2_Description_Full-en_INT_*) do (
27 | @echo BULK INSERT curr_description_f FROM '%%i' WITH (FIRSTROW = 2, FIELDTERMINATOR = '\t', ROWTERMINATOR = '\n', TABLOCK^); >>import.sql
28 | )
29 |
30 | IF NOT EXIST Full\Terminology\sct2_TextDefinition_Full-en_INT_* (
31 | @echo Cannot find Full\Terminology\sct2_TextDefinition_Full-en_INT_*
32 | EXIT /B 1
33 | )
34 | for /r %%i in (Full\Terminology\sct2_TextDefinition_Full-en_INT_*) do (
35 | @echo BULK INSERT curr_textdefinition_f FROM '%%i' WITH (FIRSTROW = 2, FIELDTERMINATOR = '\t', ROWTERMINATOR = '\n', TABLOCK^); >>import.sql
36 | )
37 |
38 | IF NOT EXIST Full\Terminology\sct2_Relationship_Full_INT_* (
39 | @echo Cannot find Full\Terminology\sct2_Relationship_Full_INT_*
40 | EXIT /B 1
41 | )
42 | for /r %%i in (Full\Terminology\sct2_Relationship_Full_INT_*) do (
43 | @echo BULK INSERT curr_relationship_f FROM '%%i' WITH (FIRSTROW = 2, FIELDTERMINATOR = '\t', ROWTERMINATOR = '\n', TABLOCK^); >>import.sql
44 | )
45 |
46 | IF NOT EXIST Full\Terminology\sct2_StatedRelationship_Full_INT_* (
47 | @echo Cannot find Full\Terminology\sct2_StatedRelationship_Full_INT_*
48 | EXIT /B 1
49 | )
50 | for /r %%i in (Full\Terminology\sct2_StatedRelationship_Full_INT_*) do (
51 | @echo BULK INSERT curr_stated_relationship_f FROM '%%i' WITH (FIRSTROW = 2, FIELDTERMINATOR = '\t', ROWTERMINATOR = '\n', TABLOCK^); >>import.sql
52 | )
53 |
54 | IF NOT EXIST Full\Refset\Language\der2_cRefset_LanguageFull-en_INT_* (
55 | @echo Cannot find Full\Refset\Language\der2_cRefset_LanguageFull-en_INT_*
56 | EXIT /B 1
57 | )
58 | for /r %%i in (Full\Refset\Language\der2_cRefset_LanguageFull-en_INT_*) do (
59 | @echo BULK INSERT curr_langrefset_f FROM '%%i' WITH (FIRSTROW = 2, FIELDTERMINATOR = '\t', ROWTERMINATOR = '\n', TABLOCK^); >>import.sql
60 | )
61 |
62 | IF NOT EXIST Full\Refset\Content\der2_cRefset_AssociationReferenceFull_INT_* (
63 | @echo Cannot find Full\Refset\Content\der2_cRefset_AssociationReferenceFull_INT_*
64 | EXIT /B 1
65 | )
66 | for /r %%i in (Full\Refset\Content\der2_cRefset_AssociationReferenceFull_INT_*) do (
67 | @echo BULK INSERT curr_associationrefset_f FROM '%%i' WITH (FIRSTROW = 2, FIELDTERMINATOR = '\t', ROWTERMINATOR = '\n', TABLOCK^); >>import.sql
68 | )
69 |
70 | IF NOT EXIST Full\Refset\Content\der2_Refset_SimpleFull_INT_* (
71 | @echo Cannot find Full\Refset\Content\der2_Refset_SimpleFull_INT_*
72 | EXIT /B 1
73 | )
74 | for /r %%i in (Full\Refset\Content\der2_Refset_SimpleFull_INT_*) do (
75 | @echo BULK INSERT curr_simplerefset_f FROM '%%i' WITH (FIRSTROW = 2, FIELDTERMINATOR = '\t', ROWTERMINATOR = '\n', TABLOCK^); >>import.sql
76 | )
77 |
78 | IF NOT EXIST Full\Refset\Content\der2_cRefset_AttributeValueFull_INT_* (
79 | @echo Cannot find Full\Refset\Content\der2_cRefset_AttributeValueFull_INT_*
80 | EXIT /B 1
81 | )
82 | for /r %%i in (Full\Refset\Content\der2_cRefset_AttributeValueFull_INT_*) do (
83 | @echo BULK INSERT curr_attributevaluerefset_f FROM '%%i' WITH (FIRSTROW = 2, FIELDTERMINATOR = '\t', ROWTERMINATOR = '\n', TABLOCK^); >>import.sql
84 | )
85 |
86 | IF NOT EXIST Full\Refset\Map\der2_sRefset_SimpleMapFull_INT_* (
87 | @echo Cannot find Full\Refset\Map\der2_sRefset_SimpleMapFull_INT_*
88 | EXIT /B 1
89 | )
90 | for /r %%i in (Full\Refset\Map\der2_sRefset_SimpleMapFull_INT_*) do (
91 | @echo BULK INSERT curr_simplemaprefset_f FROM '%%i' WITH (FIRSTROW = 2, FIELDTERMINATOR = '\t', ROWTERMINATOR = '\n', TABLOCK^); >>import.sql
92 | )
93 |
94 | IF NOT EXIST Full\Refset\Map\der2_iisssccRefset_ExtendedMapFull_INT_* (
95 | @echo Cannot find Full\Refset\Map\der2_iisssccRefset_ExtendedMapFull_INT_*
96 | EXIT /B 1
97 | )
98 | for /r %%i in (Full\Refset\Map\der2_iisssccRefset_ExtendedMapFull_INT_*) do (
99 | @echo BULK INSERT curr_extendedmaprefset_f FROM '%%i' WITH (FIRSTROW = 2, FIELDTERMINATOR = '\t', ROWTERMINATOR = '\n', TABLOCK^); >>import.sql
100 | )
101 |
102 |
--------------------------------------------------------------------------------
/MySQL/README.md:
--------------------------------------------------------------------------------
1 | # SNOMED CT DATABASE
2 |
3 | MYSQL SQL Scripts to create and populate a MYSQL database with a SNOMED CT terminology release
4 |
5 | ## Minimum Specification
6 |
7 | - MYSQL v5.5.x
8 |
9 | ## Scripted Installation (Mac & Unix)
10 |
11 | run load_release.sh
12 |
13 |
14 |
15 |
16 |
17 |
18 |
19 |
20 | eg ./load_release.sh ~/Backup/SnomedCT_RF2Release_INT_20150731.zip SCT_20150731 SNAP
21 |
22 | Note that the scripted installation will now support loading other Editions. The script asks for a module identifier, which is INT by default, for the international edition. Loading the US Edition, for example, would work as follows: `Enter module string used in filenames [INT]: US1000124`
23 |
24 | ## Manual Installation
25 |
26 | 1. Download the SNOMED CT terminology release from the IHTSDO web site
27 | 2. Create the database using the db appropriate create-database.sql script or skip/perform this action manually if you'd like the data to be loaded into a existing/different database.
28 | 3. Create the tables using the db appropriate environment.sql script. The default file creates tables for full, snapshot and delta files and there's also a -full-only version.
29 | 4. Edit the db appropriate load.sql script with the correct location of the SNOMED CT release files An alternative under unix or mac would be to create a symlink to the appropriate directory eg `ln -s /your/snomed/directory RF2Release`
30 | 5. Load the database created using the edited load.sql script from the relevant command prompt, e.g. `mysql> source load.sql` or via the relevant management tool (tested in both phpmyadmin and mysqlworkbench).
31 |
32 | - again by default for full, snapshot and delta unless you only want the full version.
33 |
34 | NB If you're using mysql 5.5 or above then you'll need to start that with the following command in order to allow local files to be loaded: `mysql -u [your_user] -p --local-infile`
35 |
36 | ### Issues
37 |
38 | If you see the following error: ERROR 1148 (42000) at line 2 in file: 'tmp_rf1_loader.sql': The used command is not allowed with this MySQL version
39 |
40 | This is a security feature of MYSQL to prevent local files being loaded. The load script script includes an argument of "--local-infile" when starting the client application, but this must also be permitted in the server configuration (eg /usr/local/etc/my.cnf which you may need to create. Type mysql --help for a list of expected config locations). Add the following block to your mysql config file: `[mysql] local-infile=1`
41 |
42 | See
43 |
--------------------------------------------------------------------------------
/MySQL/create-database-mysql.sql:
--------------------------------------------------------------------------------
1 | /* create the database */
2 | drop database if exists snomedct;
3 | create database if not exists snomedct;
4 | use snomedct;
5 |
--------------------------------------------------------------------------------
/MySQL/environment-mysql-template.sql:
--------------------------------------------------------------------------------
1 | /* Template for creating the S-CT RF2 data tables - TYPE replaced with d, s and f at runtime*/
2 |
3 | /* Section for type : TYPE */
4 |
5 | drop table if exists concept_TYPE;
6 | create table concept_TYPE(
7 | id varchar(18) not null,
8 | effectivetime char(8) not null,
9 | active char(1) not null,
10 | moduleid varchar(18) not null,
11 | definitionstatusid varchar(18) not null,
12 | key idx_id(id),
13 | key idx_effectivetime(effectivetime),
14 | key idx_active(active),
15 | key idx_moduleid(moduleid),
16 | key idx_definitionstatusid(definitionstatusid)
17 | ) engine=myisam default charset=utf8;
18 |
19 |
20 | drop table if exists description_TYPE;
21 | create table description_TYPE(
22 | id varchar(18) not null,
23 | effectivetime char(8) not null,
24 | active char(1) not null,
25 | moduleid varchar(18) not null,
26 | conceptid varchar(18) not null,
27 | languagecode varchar(2) not null,
28 | typeid varchar(18) not null,
29 | term varchar(255) not null,
30 | casesignificanceid varchar(18) not null,
31 | key idx_id(id),
32 | key idx_effectivetime(effectivetime),
33 | key idx_active(active),
34 | key idx_moduleid(moduleid),
35 | key idx_conceptid(conceptid),
36 | key idx_languagecode(languagecode),
37 | key idx_typeid(typeid),
38 | key idx_casesignificanceid(casesignificanceid)
39 | ) engine=myisam default charset=utf8;
40 |
41 | drop table if exists textdefinition_TYPE;
42 | create table textdefinition_TYPE(
43 | id varchar(18) not null,
44 | effectivetime char(8) not null,
45 | active char(1) not null,
46 | moduleid varchar(18) not null,
47 | conceptid varchar(18) not null,
48 | languagecode varchar(2) not null,
49 | typeid varchar(18) not null,
50 | term varchar(4096) not null,
51 | casesignificanceid varchar(18) not null,
52 | key idx_id(id),
53 | key idx_effectivetime(effectivetime),
54 | key idx_active(active),
55 | key idx_moduleid(moduleid),
56 | key idx_conceptid(conceptid),
57 | key idx_languagecode(languagecode),
58 | key idx_typeid(typeid),
59 | key idx_casesignificanceid(casesignificanceid)
60 | ) engine=myisam default charset=utf8;
61 |
62 | drop table if exists relationship_TYPE;
63 | create table relationship_TYPE(
64 | id varchar(18) not null,
65 | effectivetime char(8) not null,
66 | active char(1) not null,
67 | moduleid varchar(18) not null,
68 | sourceid varchar(18) not null,
69 | destinationid varchar(18) not null,
70 | relationshipgroup varchar(18) not null,
71 | typeid varchar(18) not null,
72 | characteristictypeid varchar(18) not null,
73 | modifierid varchar(18) not null,
74 | key idx_id(id),
75 | key idx_effectivetime(effectivetime),
76 | key idx_active(active),
77 | key idx_moduleid(moduleid),
78 | key idx_sourceid(sourceid),
79 | key idx_destinationid(destinationid),
80 | key idx_relationshipgroup(relationshipgroup),
81 | key idx_typeid(typeid),
82 | key idx_characteristictypeid(characteristictypeid),
83 | key idx_modifierid(modifierid)
84 | ) engine=myisam default charset=utf8;
85 |
86 | drop table if exists relationship_concrete_TYPE;
87 | create table relationship_concrete_TYPE(
88 | id varchar(18) not null,
89 | effectivetime char(8) not null,
90 | active char(1) not null,
91 | moduleid varchar(18) not null,
92 | sourceid varchar(18) not null,
93 | `value` varchar(4096) not null,
94 | relationshipgroup varchar(18) not null,
95 | typeid varchar(18) not null,
96 | characteristictypeid varchar(18) not null,
97 | modifierid varchar(18) not null,
98 | key idx_id(id),
99 | key idx_effectivetime(effectivetime),
100 | key idx_active(active),
101 | key idx_moduleid(moduleid),
102 | key idx_sourceid(sourceid),
103 | key idx_relationshipgroup(relationshipgroup),
104 | key idx_typeid(typeid),
105 | key idx_characteristictypeid(characteristictypeid),
106 | key idx_modifierid(modifierid)
107 | ) engine=myisam default charset=utf8;
108 |
109 | drop table if exists stated_relationship_TYPE;
110 | create table stated_relationship_TYPE(
111 | id varchar(18) not null,
112 | effectivetime char(8) not null,
113 | active char(1) not null,
114 | moduleid varchar(18) not null,
115 | sourceid varchar(18) not null,
116 | destinationid varchar(18) not null,
117 | relationshipgroup varchar(18) not null,
118 | typeid varchar(18) not null,
119 | characteristictypeid varchar(18) not null,
120 | modifierid varchar(18) not null,
121 | key idx_id(id),
122 | key idx_effectivetime(effectivetime),
123 | key idx_active(active),
124 | key idx_moduleid(moduleid),
125 | key idx_sourceid(sourceid),
126 | key idx_destinationid(destinationid),
127 | key idx_relationshipgroup(relationshipgroup),
128 | key idx_typeid(typeid),
129 | key idx_characteristictypeid(characteristictypeid),
130 | key idx_modifierid(modifierid)
131 | ) engine=myisam default charset=utf8;
132 |
133 | drop table if exists langrefset_TYPE;
134 | create table langrefset_TYPE(
135 | id varchar(36) not null,
136 | effectivetime char(8) not null,
137 | active char(1) not null,
138 | moduleid varchar(18) not null,
139 | refsetid varchar(18) not null,
140 | referencedcomponentid varchar(18) not null,
141 | acceptabilityid varchar(18) not null,
142 | key idx_id(id),
143 | key idx_effectivetime(effectivetime),
144 | key idx_active(active),
145 | key idx_moduleid(moduleid),
146 | key idx_refsetid(refsetid),
147 | key idx_referencedcomponentid(referencedcomponentid),
148 | key idx_acceptabilityid(acceptabilityid)
149 | ) engine=myisam default charset=utf8;
150 |
151 | drop table if exists associationrefset_TYPE;
152 | create table associationrefset_TYPE(
153 | id varchar(36) not null,
154 | effectivetime char(8) not null,
155 | active char(1) not null,
156 | moduleid varchar(18) not null,
157 | refsetid varchar(18) not null,
158 | referencedcomponentid varchar(18) not null,
159 | targetcomponentid varchar(18) not null,
160 | key idx_id(id),
161 | key idx_effectivetime(effectivetime),
162 | key idx_active(active),
163 | key idx_moduleid(moduleid),
164 | key idx_refsetid(refsetid),
165 | key idx_referencedcomponentid(referencedcomponentid),
166 | key idx_targetcomponentid(targetcomponentid)
167 | ) engine=myisam default charset=utf8;
168 |
169 | drop table if exists attributevaluerefset_TYPE;
170 | create table attributevaluerefset_TYPE(
171 | id varchar(36) not null,
172 | effectivetime char(8) not null,
173 | active char(1) not null,
174 | moduleid varchar(18) not null,
175 | refsetid varchar(18) not null,
176 | referencedcomponentid varchar(18) not null,
177 | valueid varchar(18) not null,
178 | key idx_id(id),
179 | key idx_effectivetime(effectivetime),
180 | key idx_active(active),
181 | key idx_moduleid(moduleid),
182 | key idx_refsetid(refsetid),
183 | key idx_referencedcomponentid(referencedcomponentid),
184 | key idx_valueid(valueid)
185 | ) engine=myisam default charset=utf8;
186 |
187 | drop table if exists simplemaprefset_TYPE;
188 | create table simplemaprefset_TYPE(
189 | id varchar(36) not null,
190 | effectivetime char(8) not null,
191 | active char(1) not null,
192 | moduleid varchar(18) not null,
193 | refsetid varchar(18) not null,
194 | referencedcomponentid varchar(18) not null,
195 | maptarget varchar(32) not null,
196 | key idx_id(id),
197 | key idx_effectivetime(effectivetime),
198 | key idx_active(active),
199 | key idx_moduleid(moduleid),
200 | key idx_refsetid(refsetid),
201 | key idx_referencedcomponentid(referencedcomponentid),
202 | key idx_maptarget(maptarget)
203 | ) engine=myisam default charset=utf8;
204 |
205 | drop table if exists simplerefset_TYPE;
206 | create table simplerefset_TYPE(
207 | id varchar(36) not null,
208 | effectivetime char(8) not null,
209 | active char(1) not null,
210 | moduleid varchar(18) not null,
211 | refsetid varchar(18) not null,
212 | referencedcomponentid varchar(18) not null,
213 | key idx_id(id),
214 | key idx_effectivetime(effectivetime),
215 | key idx_active(active),
216 | key idx_moduleid(moduleid),
217 | key idx_refsetid(refsetid),
218 | key idx_referencedcomponentid(referencedcomponentid)
219 | ) engine=myisam default charset=utf8;
220 |
221 | drop table if exists complexmaprefset_TYPE;
222 | create table complexmaprefset_TYPE(
223 | id varchar(36) not null,
224 | effectivetime char(8) not null,
225 | active char(1) not null,
226 | moduleid varchar(18) not null,
227 | refsetid varchar(18) not null,
228 | referencedcomponentid varchar(18) not null,
229 | mapGroup smallint not null,
230 | mapPriority smallint not null,
231 | mapRule text,
232 | mapAdvice text,
233 | mapTarget varchar(18),
234 | correlationId varchar(18) not null,
235 | key idx_id(id),
236 | key idx_effectivetime(effectivetime),
237 | key idx_active(active),
238 | key idx_moduleid(moduleid),
239 | key idx_refsetid(refsetid),
240 | key idx_referencedcomponentid(referencedcomponentid),
241 | key idx_mapTarget(mapTarget)
242 | ) engine=myisam default charset=utf8;
243 |
244 | drop table if exists extendedmaprefset_TYPE;
245 | create table extendedmaprefset_TYPE(
246 | id varchar(36) not null,
247 | effectivetime char(8) not null,
248 | active char(1) not null,
249 | moduleid varchar(18) not null,
250 | refsetid varchar(18) not null,
251 | referencedcomponentid varchar(18) not null,
252 | mapGroup smallint not null,
253 | mapPriority smallint not null,
254 | mapRule text,
255 | mapAdvice text,
256 | mapTarget varchar(18),
257 | correlationId varchar(18) not null,
258 | mapCategoryId varchar(18),
259 | key idx_id(id),
260 | key idx_effectivetime(effectivetime),
261 | key idx_active(active),
262 | key idx_moduleid(moduleid),
263 | key idx_refsetid(refsetid),
264 | key idx_referencedcomponentid(referencedcomponentid),
265 | key idx_mapTarget(mapTarget)
266 | ) engine=myisam default charset=utf8;
267 |
268 | drop table if exists owlexpression_TYPE;
269 | create table owlexpression_TYPE(
270 | id varchar(36) not null,
271 | effectivetime char(8) not null,
272 | active char(1) not null,
273 | moduleid varchar(18) not null,
274 | refsetid varchar(18) not null,
275 | referencedcomponentid varchar(18) not null,
276 | owlExpression text not null,
277 | key idx_id(id),
278 | key idx_effectivetime(effectivetime),
279 | key idx_active(active),
280 | key idx_moduleid(moduleid),
281 | key idx_refsetid(refsetid),
282 | key idx_referencedcomponentid(referencedcomponentid)
283 | ) engine=myisam default charset=utf8;
284 |
285 |
286 |
--------------------------------------------------------------------------------
/MySQL/load-mysql-full-only.sql:
--------------------------------------------------------------------------------
1 | /* loads the SNOMED CT 'Full' release - replace filenames with relevant locations of base SNOMED CT release files*/
2 |
3 | /* Filenames may need to change depending on the release you wish to upload, currently set to January 2015 release */
4 |
5 | load data local
6 | infile 'RF2Release/Full/Terminology/sct2_Concept_Full_INT_20150131.txt'
7 | into table curr_concept_f
8 | columns terminated by '\t'
9 | lines terminated by '\r\n'
10 | ignore 1 lines;
11 |
12 | load data local
13 | infile 'RF2Release/Full/Terminology/sct2_Description_Full-en_INT_20150131.txt'
14 | into table curr_description_f
15 | columns terminated by '\t'
16 | lines terminated by '\r\n'
17 | ignore 1 lines;
18 |
19 | load data local
20 | infile 'RF2Release/Full/Terminology/sct2_TextDefinition_Full-en_INT_20150131.txt'
21 | into table curr_textdefinition_f
22 | columns terminated by '\t'
23 | lines terminated by '\r\n'
24 | ignore 1 lines;
25 |
26 | load data local
27 | infile 'RF2Release/Full/Terminology/sct2_Relationship_Full_INT_20150131.txt'
28 | into table curr_relationship_f
29 | columns terminated by '\t'
30 | lines terminated by '\r\n'
31 | ignore 1 lines;
32 |
33 | load data local
34 | infile 'RF2Release/Full/Terminology/sct2_StatedRelationship_Full_INT_20150131.txt'
35 | into table curr_stated_relationship_f
36 | columns terminated by '\t'
37 | lines terminated by '\r\n'
38 | ignore 1 lines;
39 |
40 | load data local
41 | infile 'RF2Release/Full/Refset/Language/der2_cRefset_LanguageFull-en_INT_20150131.txt'
42 | into table curr_langrefset_f
43 | columns terminated by '\t'
44 | lines terminated by '\r\n'
45 | ignore 1 lines;
46 |
47 | load data local
48 | infile 'RF2Release/Full/Refset/Content/der2_cRefset_AssociationReferenceFull_INT_20150131.txt'
49 | into table curr_associationrefset_f
50 | columns terminated by '\t'
51 | lines terminated by '\r\n'
52 | ignore 1 lines;
53 |
54 | load data local
55 | infile 'RF2Release/Full/Refset/Content/der2_cRefset_AttributeValueFull_INT_20150131.txt'
56 | into table curr_attributevaluerefset_f
57 | columns terminated by '\t'
58 | lines terminated by '\r\n'
59 | ignore 1 lines;
60 |
61 | load data local
62 | infile 'RF2Release/Full/Refset/Map/der2_sRefset_SimpleMapFull_INT_20150131.txt'
63 | into table curr_simplemaprefset_f
64 | columns terminated by '\t'
65 | lines terminated by '\r\n'
66 | ignore 1 lines;
67 |
68 | load data local
69 | infile 'RF2Release/Full/Refset/Content/der2_Refset_SimpleFull_INT_20150131.txt'
70 | into table curr_simplerefset_f
71 | columns terminated by '\t'
72 | lines terminated by '\r\n'
73 | ignore 1 lines;
74 |
75 | load data local
76 | infile 'RF2Release/Full/Refset/Map/der2_iissscRefset_ComplexMapFull_INT_20150131.txt'
77 | into table curr_complexmaprefset_f
78 | columns terminated by '\t'
79 | lines terminated by '\r\n'
80 | ignore 1 lines;
81 |
82 |
83 |
84 |
85 |
86 |
87 |
88 |
89 |
90 |
91 |
92 |
93 |
94 |
95 |
96 |
97 |
98 |
99 |
100 |
101 |
102 |
103 |
104 |
105 |
--------------------------------------------------------------------------------
/MySQL/load-mysql.sql:
--------------------------------------------------------------------------------
1 | /* loads the SNOMED CT 'Full', 'Snapshot' and 'Delta' release - replace filenames with relevant locations of base SNOMED CT release files*/
2 |
3 | /* Filenames may need to change depending on the release you wish to upload, currently set to July 2014 release */
4 |
5 | /* * * * * FULL * * * * */
6 | load data local
7 | infile 'RF2Release/Full/Terminology/sct2_Concept_Full_INT_20180131.txt'
8 | into table concept_f
9 | columns terminated by '\t'
10 | lines terminated by '\r\n'
11 | ignore 1 lines;
12 |
13 | load data local
14 | infile 'RF2Release/Full/Terminology/sct2_Description_Full-en_INT_20180131.txt'
15 | into table description_f
16 | columns terminated by '\t'
17 | lines terminated by '\r\n'
18 | ignore 1 lines;
19 |
20 | load data local
21 | infile 'RF2Release/Full/Terminology/sct2_TextDefinition_Full-en_INT_20180131.txt'
22 | into table textdefinition_f
23 | columns terminated by '\t'
24 | lines terminated by '\r\n'
25 | ignore 1 lines;
26 |
27 | load data local
28 | infile 'RF2Release/Full/Terminology/sct2_Relationship_Full_INT_20180131.txt'
29 | into table relationship_f
30 | columns terminated by '\t'
31 | lines terminated by '\r\n'
32 | ignore 1 lines;
33 |
34 | load data local
35 | infile 'RF2Release/Full/Terminology/sct2_StatedRelationship_Full_INT_20180131.txt'
36 | into table stated_relationship_f
37 | columns terminated by '\t'
38 | lines terminated by '\r\n'
39 | ignore 1 lines;
40 |
41 | load data local
42 | infile 'RF2Release/Full/Refset/Language/der2_cRefset_LanguageFull-en_INT_20180131.txt'
43 | into table langrefset_f
44 | columns terminated by '\t'
45 | lines terminated by '\r\n'
46 | ignore 1 lines;
47 |
48 | load data local
49 | infile 'RF2Release/Full/Refset/Content/der2_cRefset_AssociationFull_INT_20180131.txt'
50 | into table associationrefset_f
51 | columns terminated by '\t'
52 | lines terminated by '\r\n'
53 | ignore 1 lines;
54 |
55 | load data local
56 | infile 'RF2Release/Full/Refset/Content/der2_cRefset_AttributeValueFull_INT_20180131.txt'
57 | into table attributevaluerefset_f
58 | columns terminated by '\t'
59 | lines terminated by '\r\n'
60 | ignore 1 lines;
61 |
62 | load data local
63 | infile 'RF2Release/Full/Refset/Map/der2_sRefset_SimpleMapFull_INT_20180131.txt'
64 | into table simplemaprefset_f
65 | columns terminated by '\t'
66 | lines terminated by '\r\n'
67 | ignore 1 lines;
68 |
69 | load data local
70 | infile 'RF2Release/Full/Refset/Content/der2_Refset_SimpleFull_INT_20180131.txt'
71 | into table simplerefset_f
72 | columns terminated by '\t'
73 | lines terminated by '\r\n'
74 | ignore 1 lines;
75 |
76 | load data local
77 | infile 'RF2Release/Full/Refset/Map/der2_iissscRefset_ComplexMapFull_INT_20180131.txt'
78 | into table complexmaprefset_f
79 | columns terminated by '\t'
80 | lines terminated by '\r\n'
81 | ignore 1 lines;
82 |
83 | load data local
84 | infile 'RF2Release/Full/Refset/Map/der2_iisssccRefset_ExtendedMapFull_INT_20180131.txt'
85 | into table extendedmaprefset_f
86 | columns terminated by '\t'
87 | lines terminated by '\r\n'
88 | ignore 1 lines;
89 |
90 | /* * * * * Snapshot * * * * */
91 | load data local
92 | infile 'RF2Release/Snapshot/Terminology/sct2_Concept_Snapshot_INT_20180131.txt'
93 | into table concept_s
94 | columns terminated by '\t'
95 | lines terminated by '\r\n'
96 | ignore 1 lines;
97 |
98 | load data local
99 | infile 'RF2Release/Snapshot/Terminology/sct2_Description_Snapshot-en_INT_20180131.txt'
100 | into table description_s
101 | columns terminated by '\t'
102 | lines terminated by '\r\n'
103 | ignore 1 lines;
104 |
105 | load data local
106 | infile 'RF2Release/Snapshot/Terminology/sct2_TextDefinition_Snapshot-en_INT_20180131.txt'
107 | into table textdefinition_s
108 | columns terminated by '\t'
109 | lines terminated by '\r\n'
110 | ignore 1 lines;
111 |
112 | load data local
113 | infile 'RF2Release/Snapshot/Terminology/sct2_Relationship_Snapshot_INT_20180131.txt'
114 | into table relationship_s
115 | columns terminated by '\t'
116 | lines terminated by '\r\n'
117 | ignore 1 lines;
118 |
119 | load data local
120 | infile 'RF2Release/Snapshot/Terminology/sct2_StatedRelationship_Snapshot_INT_20180131.txt'
121 | into table stated_relationship_s
122 | columns terminated by '\t'
123 | lines terminated by '\r\n'
124 | ignore 1 lines;
125 |
126 | load data local
127 | infile 'RF2Release/Snapshot/Refset/Language/der2_cRefset_LanguageSnapshot-en_INT_20180131.txt'
128 | into table langrefset_s
129 | columns terminated by '\t'
130 | lines terminated by '\r\n'
131 | ignore 1 lines;
132 |
133 | load data local
134 | infile 'RF2Release/Snapshot/Refset/Content/der2_cRefset_AssociationSnapshot_INT_20180131.txt'
135 | into table associationrefset_s
136 | columns terminated by '\t'
137 | lines terminated by '\r\n'
138 | ignore 1 lines;
139 |
140 | load data local
141 | infile 'RF2Release/Snapshot/Refset/Content/der2_cRefset_AttributeValueSnapshot_INT_20180131.txt'
142 | into table attributevaluerefset_s
143 | columns terminated by '\t'
144 | lines terminated by '\r\n'
145 | ignore 1 lines;
146 |
147 | load data local
148 | infile 'RF2Release/Snapshot/Refset/Map/der2_sRefset_SimpleMapSnapshot_INT_20180131.txt'
149 | into table simplemaprefset_s
150 | columns terminated by '\t'
151 | lines terminated by '\r\n'
152 | ignore 1 lines;
153 |
154 | load data local
155 | infile 'RF2Release/Snapshot/Refset/Content/der2_Refset_SimpleSnapshot_INT_20180131.txt'
156 | into table simplerefset_s
157 | columns terminated by '\t'
158 | lines terminated by '\r\n'
159 | ignore 1 lines;
160 |
161 | load data local
162 | infile 'RF2Release/Snapshot/Refset/Map/der2_iissscRefset_ComplexMapSnapshot_INT_20180131.txt'
163 | into table complexmaprefset_s
164 | columns terminated by '\t'
165 | lines terminated by '\r\n'
166 | ignore 1 lines;
167 |
168 | load data local
169 | infile 'RF2Release/Snapshot/Refset/Map/der2_iisssccRefset_ExtendedMapSnapshot_INT_20180131.txt'
170 | into table extendedmaprefset_s
171 | columns terminated by '\t'
172 | lines terminated by '\r\n'
173 | ignore 1 lines;
174 |
175 | /* * * * * Delta * * * * */
176 | load data local
177 | infile 'RF2Release/Delta/Terminology/sct2_Concept_Delta_INT_20180131.txt'
178 | into table concept_d
179 | columns terminated by '\t'
180 | lines terminated by '\r\n'
181 | ignore 1 lines;
182 |
183 | load data local
184 | infile 'RF2Release/Delta/Terminology/sct2_Description_Delta-en_INT_20180131.txt'
185 | into table description_d
186 | columns terminated by '\t'
187 | lines terminated by '\r\n'
188 | ignore 1 lines;
189 |
190 | load data local
191 | infile 'RF2Release/Delta/Terminology/sct2_TextDefinition_Delta-en_INT_20180131.txt'
192 | into table textdefinition_d
193 | columns terminated by '\t'
194 | lines terminated by '\r\n'
195 | ignore 1 lines;
196 |
197 | load data local
198 | infile 'RF2Release/Delta/Terminology/sct2_Relationship_Delta_INT_20180131.txt'
199 | into table relationship_d
200 | columns terminated by '\t'
201 | lines terminated by '\r\n'
202 | ignore 1 lines;
203 |
204 | load data local
205 | infile 'RF2Release/Delta/Terminology/sct2_StatedRelationship_Delta_INT_20180131.txt'
206 | into table stated_relationship_d
207 | columns terminated by '\t'
208 | lines terminated by '\r\n'
209 | ignore 1 lines;
210 |
211 | load data local
212 | infile 'RF2Release/Delta/Refset/Language/der2_cRefset_LanguageDelta-en_INT_20180131.txt'
213 | into table langrefset_d
214 | columns terminated by '\t'
215 | lines terminated by '\r\n'
216 | ignore 1 lines;
217 |
218 | load data local
219 | infile 'RF2Release/Delta/Refset/Content/der2_cRefset_AssociationDelta_INT_20180131.txt'
220 | into table associationrefset_d
221 | columns terminated by '\t'
222 | lines terminated by '\r\n'
223 | ignore 1 lines;
224 |
225 | load data local
226 | infile 'RF2Release/Delta/Refset/Content/der2_cRefset_AttributeValueDelta_INT_20180131.txt'
227 | into table attributevaluerefset_d
228 | columns terminated by '\t'
229 | lines terminated by '\r\n'
230 | ignore 1 lines;
231 |
232 | load data local
233 | infile 'RF2Release/Delta/Refset/Map/der2_sRefset_SimpleMapDelta_INT_20180131.txt'
234 | into table simplemaprefset_d
235 | columns terminated by '\t'
236 | lines terminated by '\r\n'
237 | ignore 1 lines;
238 |
239 | load data local
240 | infile 'RF2Release/Delta/Refset/Content/der2_Refset_SimpleDelta_INT_20180131.txt'
241 | into table simplerefset_d
242 | columns terminated by '\t'
243 | lines terminated by '\r\n'
244 | ignore 1 lines;
245 |
246 | load data local
247 | infile 'RF2Release/Delta/Refset/Map/der2_iissscRefset_ComplexMapDelta_INT_20180131.txt'
248 | into table complexmaprefset_d
249 | columns terminated by '\t'
250 | lines terminated by '\r\n'
251 | ignore 1 lines;
252 |
253 | load data local
254 | infile 'RF2Release/Delta/Refset/Map/der2_iisssccRefset_ExtendedMapDelta_INT_20180131.txt'
255 | into table extendedmaprefset_d
256 | columns terminated by '\t'
257 | lines terminated by '\r\n'
258 | ignore 1 lines;
259 |
260 |
261 |
262 |
263 |
264 |
265 |
266 |
267 |
268 |
269 |
270 |
271 |
272 |
273 |
274 |
275 |
276 |
277 |
278 |
279 |
280 |
281 |
282 |
--------------------------------------------------------------------------------
/MySQL/load_release.sh:
--------------------------------------------------------------------------------
1 | #!/bin/bash
2 | set -e;
3 |
4 | releasePath=$1
5 | dbName=$2
6 | loadType=$3
7 |
8 | if [ -z ${loadType} ]
9 | then
10 | echo "Usage "
11 | exit -1
12 | fi
13 |
14 | moduleStr=INT
15 | echo "Enter module string used in filenames [$moduleStr]:"
16 | read newModuleStr
17 | if [ -n "$newModuleStr" ]
18 | then
19 | moduleStr=$newModuleStr
20 | fi
21 |
22 | ORIG_IFS=$IFS
23 | IFS=","
24 | langCodeArray=(en)
25 | echo "Enter the language code(s) string used in filenames. Comma separate if multiple [en]:"
26 | read newLangCode
27 | if [ -n "$newLangCode" ]
28 | then
29 | langCodeArray=($newLangCode)
30 | fi
31 | IFS=$ORIG_IFS
32 |
33 | for i in "${langCodeArray[@]}"; do
34 | echo "Language Code: $i"
35 | done
36 |
37 | dbUsername=root
38 | echo "Enter database username [$dbUsername]:"
39 | read newDbUsername
40 | if [ -n "$newDbUsername" ]
41 | then
42 | dbUsername=$newDbUsername
43 | fi
44 |
45 | dbUserPassword=""
46 | echo "Enter database password (or return for none):"
47 | read newDbPassword
48 | if [ -n "$newDbPassword" ]
49 | then
50 | dbUserPassword="-p${newDbPassword}"
51 | fi
52 |
53 | includeTransitiveClosure=false
54 | echo "Calculate and store inferred transitive closure? [Y/N]:"
55 | read tcResponse
56 | if [[ "${tcResponse}" == "Y" || "${tcResponse}" == "y" ]]
57 | then
58 | echo "Including transitive closure table - transclos"
59 | includeTransitiveClosure=true
60 | fi
61 |
62 | #Unzip the files here, junking the structure
63 | localExtract="tmp_extracted"
64 | generatedLoadScript="tmp_loader.sql"
65 | generatedEnvScript="tmp_environment-mysql.sql"
66 |
67 | #What types of files are we loading - delta, snapshot, full or all?
68 | case "${loadType}" in
69 | 'DELTA') fileTypes=(Delta)
70 | unzip -j ${releasePath} "*Delta*" -d ${localExtract}
71 | ;;
72 | 'SNAP') fileTypes=(Snapshot)
73 | unzip -j ${releasePath} "*Snapshot*" -d ${localExtract}
74 | ;;
75 | 'FULL') fileTypes=(Full)
76 | unzip -j ${releasePath} "*Full*" -d ${localExtract}
77 | ;;
78 | 'ALL') fileTypes=(Delta Snapshot Full)
79 | unzip -j ${releasePath} -d ${localExtract}
80 | ;;
81 | *) echo "File load type ${loadType} not recognised"
82 | exit -1;
83 | ;;
84 | esac
85 |
86 |
87 | #Determine the release date from the filenames
88 | releaseDate=`ls -1 ${localExtract}/*.txt | head -1 | egrep -o '[0-9]{8}'`
89 |
90 | #Generate the environment script by running through the template as
91 | #many times as required
92 | now=`date +"%Y%m%d_%H%M%S"`
93 | echo -e "\nGenerating Environment script for ${loadType} type(s)"
94 | echo "/* Script Generated Automatically by load_release.sh ${now} */" > ${generatedEnvScript}
95 | for fileType in ${fileTypes[@]}; do
96 | fileTypeLetter=`echo "${fileType}" | head -c 1 | tr '[:upper:]' '[:lower:]'`
97 | tail -n +2 environment-mysql-template.sql | while read thisLine
98 | do
99 | echo "${thisLine/TYPE/${fileTypeLetter}}" >> ${generatedEnvScript}
100 | done
101 | done
102 |
103 | function addLoadScript() {
104 | for fileType in ${fileTypes[@]}; do
105 | fileName=${1/TYPE/${fileType}}
106 | fileName=${fileName/DATE/${releaseDate}}
107 | fileName=${fileName/MOD/${moduleStr}}
108 | fileName=${fileName/LANG/${3}}
109 | parentPath="${localExtract}/"
110 | tableName=${2}_`echo $fileType | head -c 1 | tr '[:upper:]' '[:lower:]'`
111 | snapshotOnly=false
112 | #Check file exists - try beta version, or filepath directly if not
113 | if [ ! -f ${parentPath}${fileName} ]; then
114 | origFilename=${fileName}
115 | fileName="x${fileName}"
116 | if [ ! -f ${parentPath}${fileName} ]; then
117 | parentPath=""
118 | fileName=${origFilename}
119 | tableName=${2} #Files loaded outside of extract directory use own names for table
120 | snapshotOnly=true
121 | if [ ! -f ${parentPath}${fileName} ]; then
122 | echo "Unable to find ${origFilename} or beta version, skipping..."
123 | #SI are stopping producing Delta files, so don't worry about those missing
124 | if [ "$fileType" == "Delta" ]
125 | then
126 | echo "Checking next file type"
127 | continue
128 | else
129 | echo "Skipping"
130 | return
131 | fi
132 | fi
133 | fi
134 | fi
135 |
136 | if [[ $snapshotOnly = false || ($snapshotOnly = true && "$fileType" == "Snapshot") ]]
137 | then
138 | echo "alter table ${tableName} disable keys;" >> ${generatedLoadScript}
139 | echo "load data local" >> ${generatedLoadScript}
140 | echo -e "\tinfile '"${parentPath}${fileName}"'" >> ${generatedLoadScript}
141 | echo -e "\tinto table ${tableName}" >> ${generatedLoadScript}
142 | echo -e "\tcolumns terminated by '\\\t'" >> ${generatedLoadScript}
143 | echo -e "\tlines terminated by '\\\r\\\n'" >> ${generatedLoadScript}
144 | echo -e "\tignore 1 lines;" >> ${generatedLoadScript}
145 | echo -e "" >> ${generatedLoadScript}
146 | echo "alter table ${tableName} enable keys;" >> ${generatedLoadScript}
147 | echo -e "select 'Loaded ${fileName} into ${tableName}' as ' ';" >> ${generatedLoadScript}
148 | echo -e "" >> ${generatedLoadScript}
149 | fi
150 | done
151 | }
152 |
153 | echo -e "\nGenerating loading script for $releaseDate"
154 | echo "/* Generated Loader Script */" > ${generatedLoadScript}
155 | addLoadScript sct2_Concept_TYPE_MOD_DATE.txt concept
156 | for i in ${langCodeArray[@]}; do
157 | addLoadScript sct2_Description_TYPE-LANG_MOD_DATE.txt description $i
158 | addLoadScript sct2_TextDefinition_TYPE-LANG_MOD_DATE.txt textdefinition $i
159 | addLoadScript der2_cRefset_LanguageTYPE-LANG_MOD_DATE.txt langrefset $i
160 | done
161 | addLoadScript sct2_StatedRelationship_TYPE_MOD_DATE.txt stated_relationship
162 | addLoadScript sct2_Relationship_TYPE_MOD_DATE.txt relationship
163 | addLoadScript sct2_RelationshipConcreteValues_TYPE_MOD_DATE.txt relationship_concrete
164 | addLoadScript sct2_sRefset_OWLExpressionTYPE_MOD_DATE.txt owlexpression
165 | addLoadScript der2_cRefset_AttributeValueTYPE_MOD_DATE.txt attributevaluerefset
166 | addLoadScript der2_cRefset_AssociationTYPE_MOD_DATE.txt associationrefset
167 | addLoadScript der2_iissscRefset_ComplexMapTYPE_MOD_DATE.txt complexmaprefset
168 | addLoadScript der2_iisssccRefset_ExtendedMapTYPE_MOD_DATE.txt extendedmaprefset
169 |
170 | mysql -u ${dbUsername} ${dbUserPassword} --local-infile << EOF
171 | select 'Ensuring schema ${dbName} exists' as ' ';
172 | create database IF NOT EXISTS ${dbName};
173 | use ${dbName};
174 | select '(re)Creating Schema using ${generatedEnvScript}' as ' ';
175 | source ${generatedEnvScript};
176 | EOF
177 |
178 | if [ "${includeTransitiveClosure}" = true ]
179 | then
180 | echo "Generating Transitive Closure file..."
181 | tempFile=$(mktemp)
182 | infRelFile=${localExtract}/sct2_Relationship_Snapshot_${moduleStr}_${releaseDate}.txt
183 | if [ ! -f ${infRelFile} ]; then
184 | infRelFile=${localExtract}/xsct2_Relationship_Snapshot_${moduleStr}_${releaseDate}.txt
185 | fi
186 | perl ./transitiveClosureRf2Snap_dbCompatible.pl ${infRelFile} ${tempFile}
187 | mysql -u ${dbUsername} ${dbUserPassword} ${dbName} << EOF
188 | DROP TABLE IF EXISTS transclos;
189 | CREATE TABLE transclos (
190 | sourceid varchar(18) DEFAULT NULL,
191 | destinationid varchar(18) DEFAULT NULL,
192 | KEY idx_tc_source (sourceid),
193 | KEY idx_tc_destination (destinationid)
194 | ) ENGINE=InnoDB DEFAULT CHARSET=utf8;
195 | EOF
196 | addLoadScript ${tempFile} transclos
197 | fi
198 |
199 | mysql -u ${dbUsername} ${dbUserPassword} ${dbName} --local-infile << EOF
200 | select 'Loading RF2 Data using ${generatedLoadScript}' as ' ';
201 | source ${generatedLoadScript};
202 | EOF
203 |
204 | rm -rf $localExtract
205 | #We'll leave the generated environment & load scripts for inspection
206 |
207 |
--------------------------------------------------------------------------------
/MySQL/transitiveClosureRf2Snap_dbCompatible.pl:
--------------------------------------------------------------------------------
1 | #!/usr/bin/env perl -w
2 | use warnings;
3 |
4 | #-------------------------------------------------------------------------------
5 | # Copyright IHTSDO 2012
6 | # Licensed under the Apache License, Version 2.0 (the "License");
7 | # you may not use this file except in compliance with the License.
8 | # You may obtain a copy of the License at
9 | # http://www.apache.org/licenses/LICENSE-2.0
10 | # Unless required by applicable law or agreed to in writing, software
11 | # distributed under the License is distributed on an "AS IS" BASIS,
12 | # WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied.
13 | # See the License for the specific language governing permissions and
14 | # limitations under the License.
15 | #-------------------------------------------------------------------------------
16 | # This perl script carries no warranty of fitness for any purpose.
17 | # Use at your own risk.
18 | #-------------------------------------------------------------------------------
19 | # This perl script computes the transitive closure of a Directed Acyclic Graph
20 | # input in transitive reduction form.
21 | # Input is in the format of the SNOMED CT relationships table
22 | # Isa relationships are those elements in the table with relationshipID=116680003
23 | #-------------------------------------------------------------------------------
24 |
25 | # use this script as
26 | # perl transitiveClosure.pl
27 | # Input file contains the inferred child-parent pairs
28 | # as distributed in the relationships table, RF2 format SNAPSHOT
29 |
30 | # output is a tab-delimited file with two columns, child - parent.
31 |
32 | #-------------------------------------------------------------------------------
33 | # Start MAIN
34 | #-------------------------------------------------------------------------------
35 |
36 | %children = ();
37 | %visited = ();
38 | %descendants = ();
39 |
40 | &readrels(\%children,0);
41 |
42 | $counter=0;
43 | $root="138875005";
44 |
45 |
46 | transClos($root,\%children,\%descendants,\%visited);
47 |
48 | printRels(\%descendants,1);
49 |
50 |
51 | #-------------------------------------------------------------------------------
52 | # END MAIN
53 | #-------------------------------------------------------------------------------
54 |
55 | #-------------------------------------------------------------------------------
56 | # INPUT
57 | #-------------------------------------------------------------------------------
58 | # Takes as arguments: a hash table reference and an argument number $argn
59 | # Opens the relationships table in the file designated by the name in $ARGV[$argn]
60 | # Reads the isa-s and stores them in the hash
61 | #-------------------------------------------------------------------------------
62 | sub readrels {
63 | local($childhashref,$argn) = @_;
64 | my ($firstline,@values);
65 | open(ISAS,$ARGV[$argn]) || die "can't open $ARGV[$argn]";
66 | # read first input row
67 | chop($firstline = );
68 | # throw away first row, it contains the column names
69 |
70 | # read remaining input rows
71 | while () {
72 | chop;
73 | @values=split('\t',$_);
74 | if (($values[7] eq "116680003") && ($values[2] eq "1")) { # rel.Type is "is-a"
75 | $$childhashref{$values[5]}{$values[4]} = 1; # a hash of hashes, where parent is 1st arg and child is 2nd.
76 | }
77 | }
78 | close(ISAS);
79 | }
80 |
81 |
82 | #-------------------------------------------------------------------------------
83 | # transClos
84 | #-------------------------------------------------------------------------------
85 | # This subroutine is based on a method described in "Transitive Closure Algorithms
86 | # Based on Graph Traversal" by Yannis Ioannidis, Raghu Ramakrishnan, and Linda Winger,
87 | # ACM Transactions on Database Systems, Vol. 18, No. 3, September 1993,
88 | # Pages: 512 - 576.
89 | # It uses a simplified version of their "DAG_DFTC" algorithm.
90 | #-------------------------------------------------------------------------------
91 | #
92 | sub transClos { # recursively depth-first traverse the graph.
93 | local($startnode,$children,$descendants,$visited) = @_;
94 | my($descendant, $childnode);
95 | $counter++;
96 | # if (($counter % 1000) eq 0) { print "Visit ", $startnode, " ", $counter, "\n"; }
97 | for $childnode (keys %{ $$children{$startnode} }) { # for all the children of the startnode
98 | unless ($$visited{$childnode}) { # unless it has already been traversed
99 | &transClos($childnode,$children,$descendants,$visited); # recursively visit the childnode
100 | $$visited{$childnode}="T"; # and when the recursive visit completes, mark as visited
101 | } # end unless
102 | for $descendant (keys %{ $$descendants{$childnode} }) { # for each descendant of childnode
103 | $$descendants{$startnode}{$descendant} = 1; # mark as a descendant of startnode
104 | }
105 | $$descendants{$startnode}{$childnode} = 1; # mark the immediate childnode as a descendant of startnode
106 | } # end for
107 | } # end sub transClos
108 |
109 |
110 | #-------------------------------------------------------------------------------
111 | # OUTPUT
112 | #-------------------------------------------------------------------------------
113 |
114 | sub printRels {
115 | local($descendants,$argn)=@_;
116 | open(OUTF,">$ARGV[$argn]") || die "can't open $ARGV[$argn]";
117 | printf OUTF "sourceid\tdestinationid\r\n";
118 | for $startnode (keys %$descendants) {
119 | for $endnode ( keys %{ $$descendants{$startnode} }) {
120 | print OUTF "$endnode\t$startnode\r\n";
121 | }
122 | }
123 | }
124 |
125 |
126 | #-------------------------------------------------------------------------------
127 | # END
128 | #-------------------------------------------------------------------------------
129 |
130 |
131 |
--------------------------------------------------------------------------------
/NEO4J/.gitignore:
--------------------------------------------------------------------------------
1 | *.pyc
2 | *.txt
3 |
--------------------------------------------------------------------------------
/NEO4J/snomed_g_graphdb_cypher_add_assoc_refset.template:
--------------------------------------------------------------------------------
1 | // -----------------------------------------------------------------------------------------
2 | // Module: snomed_g_graphdb_add_assoc_refset.cypher
3 | // Author: Jay Pedersen, University of Nebraska, September 2016
4 | // Concept: Update a SNOMED_G Graph Database from input CSV files which describe the
5 | // Association Refset. Creation of the following edges.
6 | // (ObjectConcept)-[:WASA]->(ObjectConcept)
7 | // (ObjectConcept)-[:POSSIBLY_REPLACED_BY]->(ObjectConcept)
8 | // Input Files:
9 | // assoc_refset_new.csv
10 |
11 | // Create edges for association refset
12 | RETURN 'Creating ASSOCIATION REFSET edges between ObjectConcept nodes';
13 | LOAD csv with headers from "<<>><<>>assoc_refset_new.csv" as line
14 | CALL {
15 | with line
16 | MATCH (s:ObjectConcept { sctid: line.referencedComponentId }), (d:ObjectConcept { sctid: line.targetComponentId })
17 | WITH s,d,line
18 | CREATE UNIQUE (s)-[:HAS_ASSOCIATION {association: line.association, refsetId: line.refsetId, active: line.active, effectiveTime: line.effectiveTime, referencedComponentId: line.referencedComponentId, targetComponentId: line.targetComponentId, moduleId: line.moduleId, id: line.id } ]->(d)
19 | } IN TRANSACTIONS OF 200 ROWS;
20 |
21 |
--------------------------------------------------------------------------------
/NEO4J/snomed_g_graphdb_cypher_create.template:
--------------------------------------------------------------------------------
1 | // -----------------------------------------------------------------------------------------
2 | // Module: snomed_g_graphdb_create.cypher
3 | // Author: Jay Pedersen, University of Nebraska, August 2015
4 | // Concept: Update a SNOMED_G Graph Database from input CSV files which describe the changes
5 | // to concepts, descriptions, ISA relationships and defining relationships.
6 | // Input Files:
7 | // concept_new.csv
8 | // descrip_new.csv
9 | // isa_rel_new.csv
10 | // defining_rel_new.csv
11 |
12 | // NEXT STEP -- create INDEXES
13 |
14 | CREATE CONSTRAINT FOR (c:ObjectConcept) REQUIRE c.id IS UNIQUE;
15 | CREATE CONSTRAINT FOR (c:ObjectConcept) REQUIRE c.sctid IS UNIQUE;
16 | // id,sctid index created, requiring uniqueness
17 | // Note: Can't have "FSN is UNIQUE"" constraint, can have dups (inactive concepts)
18 | // for example -- "retired procedure" is FSN of multiple inactive concepts
19 | CREATE CONSTRAINT FOR (c:Description) REQUIRE c.id IS UNIQUE;
20 | CREATE INDEX FOR (x:Description) ON (x.sctid);
21 | // need index so setting HAS_DESCRIPTION edges doesn't stall
22 | // there can be more than one description for the same sctid, sctid not unique, but id is unique
23 |
24 | // ROLE_GROUP nodes. Index needed for defining relationship assignment.
25 | CREATE INDEX FOR (x:RoleGroup) ON (x.sctid);
26 |
27 | // NEXT STEP -- create CONCEPT nodes
28 |
29 | RETURN 'Creating NEW ObjectConcept nodes';
30 | LOAD csv with headers from "<<>><<>>concept_new.csv" as line
31 | CALL {
32 | with line
33 | CREATE (n:ObjectConcept
34 | { nodetype: 'concept',
35 | id: line.id,
36 | sctid: line.id,
37 | active: line.active,
38 | effectiveTime: line.effectiveTime,
39 | moduleId: line.moduleId,
40 | definitionStatusId: line.definitionStatusId,
41 | FSN: line.FSN,
42 | history: line.history} )
43 |
44 | } IN TRANSACTIONS OF 200 ROWS;
45 |
46 | // NEXT STEP -- create DESCRIPTION nodes (info from Language+Description file)
47 | RETURN 'Creating NEW Description nodes';
48 |
49 | LOAD csv with headers from "<<>><<>>descrip_new.csv" as line
50 | CALL {
51 | with line
52 | CREATE (n:Description
53 | { nodetype:'description',
54 | id: line.id,
55 | sctid: line.sctid,
56 | active: line.active,
57 | typeId: line.typeId,
58 | moduleId: line.moduleId,
59 | descriptionType: line.descriptionType,
60 | id128bit: line.id128bit,
61 | term: line.term,
62 | effectiveTime: line.effectiveTime,
63 | acceptabilityId: line.acceptabilityId,
64 | refsetId: line.refsetId,
65 | caseSignificanceId: line.caseSignificanceId,
66 | languageCode: line.languageCode,
67 | history: line.history} )
68 |
69 | } IN TRANSACTIONS OF 200 ROWS;
70 |
71 | // NEXT STEP - create DESCRIPTION edges
72 | RETURN 'Creating HAS_DESCRIPTION edges for new Description nodes related to ObjectConcept nodes';
73 |
74 | LOAD csv with headers from "<<>><<>>descrip_new.csv" as line
75 | CALL {
76 | with line
77 | MATCH (c:ObjectConcept { sctid: line.sctid }), (f:Description { id: line.id })
78 | MERGE (c)-[:HAS_DESCRIPTION]->(f)
79 | } IN TRANSACTIONS OF 200 ROWS;
80 |
81 | // --------------------------------------------------------------------------------------
82 | // NEXT STEP -- create ISA relationships
83 | // --------------------------------------------------------------------------------------
84 |
85 | RETURN 'Creating NEW ISA edges';
86 |
87 | LOAD csv with headers from "<<>><<>>isa_rel_new.csv" as line
88 | CALL {
89 | with line
90 | MATCH (c1:ObjectConcept { id: line.sourceId }), (c2:ObjectConcept { id: line.destinationId })
91 | MERGE (c1)-[:ISA { id: line.id,
92 | active: line.active,
93 | effectiveTime: line.effectiveTime,
94 | moduleId: line.moduleId,
95 | relationshipGroup: line.relationshipGroup,
96 | typeId: line.typeId,
97 | characteristicTypeId: line.characteristicTypeId,
98 | sourceId: line.sourceId,
99 | destinationId: line.destinationId,
100 | history: line.history }]->(c2)
101 | } IN TRANSACTIONS OF 200 ROWS;
102 |
103 | // --------------------------------------------------------------------------------------
104 | // NEXT STEP -- create RoleGroup nodes
105 | // --------------------------------------------------------------------------------------
106 | RETURN 'Creating RoleGroup nodes';
107 | LOAD csv with headers from "<<>><<>>rolegroups.csv" as line
108 | CALL {
109 | with line
110 | MERGE (rg:RoleGroup
111 | { nodetype:'rolegroup',
112 | sctid: line.sctid,
113 | rolegroup: line.rolegroup})
114 | } IN TRANSACTIONS OF 500 ROWS;
115 |
116 | // Add edge in 2nd step, Java memory issue
117 | RETURN 'Creating HAS_ROLE_GROUP edges';
118 | LOAD csv with headers from "<<>><<>>rolegroups.csv" as line
119 | CALL {
120 | with line
121 | MATCH (c:ObjectConcept { sctid: line.sctid }), (rg:RoleGroup { sctid: line.sctid, rolegroup: line.rolegroup })
122 | MERGE (c)-[:HAS_ROLE_GROUP]->(rg)
123 | } IN TRANSACTIONS OF 500 ROWS;
124 |
125 |
126 | // --------------------------------------------------------------------------------------
127 | // NEXT STEP -- create Defining relationships
128 | // --------------------------------------------------------------------------------------
129 |
130 |
--------------------------------------------------------------------------------
/NEO4J/snomed_g_graphdb_cypher_refset_assoc_create.template:
--------------------------------------------------------------------------------
1 | // -----------------------------------------------------------------------------------------
2 | // Module: snomed_g_graphdb_cypher_refset_assoc_create.cypher
3 | // Author: Jay Pedersen, University of Nebraska, September 2016
4 | // Concept: Update a SNOMED_G Graph Database from input CSV files which describe the
5 | // Association Refset. Creation of the following edges.
6 | // (ObjectConcept)-[:WASA]->(ObjectConcept)
7 | // (ObjectConcept)-[:POSSIBLY_REPLACED_BY]->(ObjectConcept)
8 | // Input Files:
9 | // assoc_refset_new.csv
10 |
11 | // Create edges for association refset
12 | RETURN 'Creating ASSOCIATION REFSET edges between ObjectConcept nodes';
13 | LOAD csv with headers from "<<>><<>>assoc_refset_new.csv" as line
14 | CALL {
15 | with line
16 | MATCH (s:ObjectConcept { sctid: line.referencedComponentId }), (d:ObjectConcept { sctid: line.targetComponentId })
17 | WITH s,d,line
18 | MERGE (s)-[:HAS_ASSOCIATION {id: line.id,
19 | association: line.association,
20 | refsetId: line.refsetId,
21 | active: line.active,
22 | effectiveTime: line.effectiveTime,
23 | referencedComponentId: line.referencedComponentId,
24 | targetComponentId: line.targetComponentId,
25 | moduleId: line.moduleId,
26 | history: line.history } ]->(d)
27 | } IN TRANSACTIONS OF 200 ROWS;
28 |
29 |
--------------------------------------------------------------------------------
/NEO4J/snomed_g_graphdb_cypher_rmv_problem_edges.template:
--------------------------------------------------------------------------------
1 | // --------------------------------------------------------------------
2 | // Module: snomed_g_graphdb_cypher_rmv_problem_edges.cypher
3 | // Author: Jay Pedersen, University of Nebraska, August 2015
4 | // Concept: Remove ISA and defining-relationship edges which were not
5 | // appropriately updated after an update.
6 | // The issue is caused by MATCH failure due to the source or
7 | // destination of the edge changing.
8 | // The idea is that removal of these problem edges, will allow
9 | // the next update attempt to work.
10 | // Input Files:
11 | // concept_chg.csv
12 | // defining_rel_chg.csv
13 | // --------------------------------------------------------------------
14 |
15 | RETURN 'Removing defining-relationships (DRs) that changed source/destination';'
16 | LOAD csv with headers from "<<>><<>>defining_rel_chg.csv" as line
17 | CALL {
18 | MATCH (rg:RoleGroup)-[r {id: line.id}]->(c:ObjectConcept)
19 | DELETE r;
20 | } IN TRANSACTIONS OF 200 ROWS
21 |
22 |
23 | RETURN 'Removing ISA relationships that changed the source or destination.';
24 | LOAD csv with headers from "<<>><<>>defining_rel_chg.csv" as line
25 | CALL {
26 | MATCH (b:ObjectConcept)-[r {id: line.id}]->(c:ObjectConcept)
27 | DELETE r
28 | } IN TRANSACTIONS OF 200 ROWS;
29 |
30 |
--------------------------------------------------------------------------------
/NEO4J/snomed_g_graphdb_update_failure_check.cypher:
--------------------------------------------------------------------------------
1 | return 'CHECKING FOR SNOMED_G_UPDATE_FAILURE NODE WHICH INDICATES FAILURE';
2 |
3 | match (a:SNOMED_G_UPDATE_FAILURE)
4 | LOAD CSV with headers from "UPDATE FAILURE DETECTED" as line create (b:UPDATE_FAILED)
5 | return 'SNOMED_G GRAPH UPDATE SUCCEEDED';
6 |
--------------------------------------------------------------------------------
/NEO4J/snomed_g_lib_neo4j.py:
--------------------------------------------------------------------------------
1 | '''
2 | Module: snomed_g_lib_neo4j.py
3 | Author: Jay Pedersen, July 2016
4 | Purpose: Define utility classes for accessing NEO4J databases containing SNOMED_G data.
5 | '''
6 |
7 | import py2neo, sys
8 |
9 | def db_data_prep(v):
10 | return v if isinstance(v,unicode) else unicode( (str(v) if isinstance(v, int) else v) , "utf8")
11 |
12 | class Neo4j_Access:
13 | def __init__(self, base64pw):
14 | # NEO4J init
15 | self.graph_db = py2neo.Graph("bolt://localhost:7687", auth=("neo4j", base64pw)) # 'http://localhost:7474/db/data/transaction/commit'
16 |
17 | def lookup_elements_by_id(self,query_template,query_target_variable,id_field_name,id_list,chunk_size):
18 | matches = {}
19 | n = chunk_size
20 | for chunk in [id_list[idx:idx+n] for idx in range (0, len(id_list), n)]:
21 | cypher_str = query_template % (str(chunk),query_target_variable) # eg: 'match ... where a.sctid in %s return %s'
22 | cursor = None
23 | try:
24 | cursor = self.graph_db.run(cypher_str)
25 | except:
26 | print('DB Failure for [%s]' % cypher_str)
27 | raise
28 | sys.exit(1)
29 | else:
30 | pass # succeeded
31 | # end of exception processing
32 | # List result
33 | idx = 0
34 | while cursor.forward():
35 | idx += 1
36 | r = cursor.current()[query_target_variable] # variable in CYPHER query
37 | matches[r[id_field_name]] = { a : r[a] for a in r.keys() } # copy.deepcopy(r) # copy dictionary
38 | # end of processing result from this chunk
39 | # end of chunk processing
40 | return matches
41 |
42 | def make_attribute_map_by_id(self,query_template,query_target_variable,id_field_name,id_list,chunk_size,target_attribute,allow_dup_prefer_active=False):
43 | matches = {}
44 | n = chunk_size
45 | for chunk in [id_list[idx:idx+n] for idx in range (0, len(id_list), n)]:
46 | cypher_str = query_template % (str(chunk),query_target_variable) # eg: 'match ... where a.sctid in %s return %s'
47 | cursor = None
48 | try:
49 | cursor = self.graph_db.run(cypher_str)
50 | except:
51 | print('DB Failure for [%s]' % cypher_str)
52 | raise
53 | sys.exit(1)
54 | else:
55 | pass # succeeded
56 | # end of exception processing
57 | # List result
58 | idx = 0
59 | while cursor.forward():
60 | idx += 1
61 | r = cursor.current()[query_target_variable] # variable in CYPHER query
62 | keyvalue = db_data_prep(r[id_field_name])
63 | if not allow_dup_prefer_active:
64 | matches[keyvalue] = db_data_prep(r[target_attribute])
65 | else:
66 | if keyvalue not in matches: # Prefer active='1'
67 | matches[keyvalue] = db_data_prep(r[target_attribute])
68 | elif db_data_prep(r['active'])=='1':
69 | matches[keyvalue] = db_data_prep(r[target_attribute])
70 | # end of processing result from this chunk
71 | # end of chunk processing
72 | return matches
73 |
74 | def lookup_concepts_for_ids(self, id_list):
75 | return self.lookup_elements_by_id('match (a:ObjectConcept) where a.sctid in %s return %s',
76 | 'a','sctid',id_list,200)
77 | def lookup_Fsns_for_ids(self, id_list):
78 | # TODO: cant there be more than one FSN for a particular concept?, where one or more is not active??
79 | # ==> assume no more than one FSN with active='1' for a particular concept
80 | # GOAL: "prefer" active, but "inactive" presumably is not always wrong -- inactivated concept with inactivated FSN may exist??
81 | return self.make_attribute_map_by_id('''match (a:ObjectConcept) where a.sctid in %s return %s''',
82 | 'a', 'id', id_list, 200, 'FSN', True)
83 | def lookup_descriptions_for_ids(self, id_list): # Description id, NOT sctid
84 | return self.lookup_elements_by_id('match (a:Description) where a.id in %s return %s',
85 | 'a','id',id_list,100)
86 | def lookup_descriptions_for_sctid(self, sctid): # all descriptions for specific concept
87 | return self.lookup_elements_by_id('match (o:ObjectConcept)-[r:HAS_DESCRIPTION]->(a:Description) where o.id in %s return %s',
88 | 'a','id',[sctid],100)
89 |
90 | def extract_property_names(self, cursor, vbl_name):
91 | # NOTE: ONE result only, guaranteed by LIMIT 1
92 | property_names = []
93 | idx = 0
94 | while cursor.forward():
95 | idx += 1
96 | property_names = cursor.current()[vbl_name]
97 | # eg: [u'typeId', u'effectiveTime', u'active', ..., u'history']
98 | print('%d. %s' % (idx, str(property_names)))
99 | return property_names
100 | print('*** extract_property_names FAILED -- no result'); sys.exit(1)
101 | return []
102 |
103 | def execute_cypher(self, cypher_string):
104 | command_list = [ x.rstrip('\n').rstrip('\r') for x in cypher_string.split('\n') if len(x) > 0]
105 | succeeded, failed = 0, 0
106 | for idx,cmd in enumerate(command_list):
107 | cursor = None
108 | try:
109 | cursor = self.graph_db.run(cmd)
110 | except:
111 | print('DB Failure for [%s]' % cmd)
112 | failed += 1
113 | else:
114 | succeeded += 1
115 | # Report statistics
116 | print('%d commands succeeded' % succeeded)
117 | if failed>0: print('*** %d commands FAILED ***' % failed); sys.exit(1)
118 | return cursor
119 |
120 | def lookup_all_concepts(self): # Why?? 7 minutes to read concepts by id values -- 37 seconds to read ALL (with around 426K ids)
121 | cypher_q = '''MATCH (a:ObjectConcept)'''
122 | # Query #1 -- determine keys(r)
123 | vbl_name = 'keys(a)'
124 | cypher_str = cypher_q + ' return %s LIMIT 1' % vbl_name
125 | neo4j_cursor = self.execute_cypher(cypher_str)
126 | field_names = self.extract_property_names(neo4j_cursor,vbl_name)
127 | # Query #2, return all properties for every matching object
128 | cypher_str = cypher_q + ' return ' + ','.join('a.%s' % x for x in field_names)
129 | neo4j_cursor = self.execute_cypher(cypher_str)
130 | result = {}
131 | while neo4j_cursor.forward():
132 | result[neo4j_cursor.current()['a.id']] = { nm: neo4j_cursor.current()['a.%s' % nm] for nm in field_names }
133 | return result
134 |
135 | def lookup_all_descriptions(self): # Why? Can be over 1.2 million descriptions for FULL/SNAPSHOT, dont look individually
136 | cypher_q = '''MATCH (a:Description)'''
137 | # Query #1 -- determine keys(r)
138 | vbl_name = 'keys(a)'
139 | cypher_str = cypher_q + ' return %s LIMIT 1' % vbl_name
140 | neo4j_cursor = self.execute_cypher(cypher_str)
141 | field_names = self.extract_property_names(neo4j_cursor,vbl_name)
142 | # Query #2, return all properties for every matching object
143 | cypher_str = cypher_q + ' return ' + ','.join('a.%s' % x for x in field_names)
144 | neo4j_cursor = self.execute_cypher(cypher_str)
145 | result = {}
146 | while neo4j_cursor.forward():
147 | result[neo4j_cursor.current()['a.id']] = { nm: neo4j_cursor.current()['a.%s' % nm] for nm in field_names }
148 | return result
149 |
150 | def lookup_all_isa_rels(self): # Why? No indexes on edges, if large lookup, this is fastest way to get all info
151 | cypher_q = '''MATCH (a:ObjectConcept)-[r:ISA]->(b:ObjectConcept)'''
152 | # Query #1 -- determine keys(r)
153 | vbl_name = 'keys(r)'
154 | cypher_str = cypher_q + ' return %s LIMIT 1' % vbl_name
155 | neo4j_cursor = self.execute_cypher(cypher_str)
156 | field_names = self.extract_property_names(neo4j_cursor,vbl_name)
157 | # Query #2, return all properties for every matching object
158 | cypher_str = cypher_q + ' return ' + ','.join('r.%s' % x for x in field_names)
159 | neo4j_cursor = self.execute_cypher(cypher_str)
160 | result = {}
161 | while neo4j_cursor.forward():
162 | result[neo4j_cursor.current()['r.id']] = { nm: neo4j_cursor.current()['r.%s' % nm] for nm in field_names }
163 | return result
164 |
165 | def lookup_all_defining_rels(self): # Why? No indexes on edges, if large lookup, this is fastest way to get all info
166 | cypher_q = '''MATCH (a:RoleGroup)-[r]->(b:ObjectConcept)'''
167 | # Query #1 -- determine keys(r)
168 | vbl_name = 'keys(r)'
169 | cypher_str = cypher_q + ' return %s LIMIT 1' % vbl_name
170 | neo4j_cursor = self.execute_cypher(cypher_str)
171 | field_names = self.extract_property_names(neo4j_cursor,vbl_name) # wont include destinationId
172 | # Query #2, return all properties for every matching object
173 | cypher_str = cypher_q + ' return ' + ','.join('r.%s' % x for x in field_names) + ',endNode(r).id as destinationId'
174 | neo4j_cursor = self.execute_cypher(cypher_str)
175 | result = {}
176 | while neo4j_cursor.forward():
177 | result[neo4j_cursor.current()['r.id']] = { nm: neo4j_cursor.current()['r.%s' % nm] for nm in field_names }
178 | result[neo4j_cursor.current()['r.id']]['destinationId'] = neo4j_cursor.current()['destinationId']
179 | return result
180 |
181 | def lookup_isa_rels_for_ids(self, id_list): # SLOOOOOOOOOOOOOOOOOOOOOOOOOOOOW
182 | return self.lookup_elements_by_id('match (a:ObjectConcept)-[r:ISA]->(b:ObjectConcept) where r.id in %s return %s',
183 | 'r','id',id_list,100)
184 | def lookup_defining_rels_for_ids(self, id_list): # SLOOOOOOOOOOOOOOOOOOOOOOOOOOOOW
185 | return self.lookup_elements_by_id('match (a:RoleGroup)-[r]->(b:ObjectConcept) where r.id in %s return %s',
186 | 'r','id',id_list,100)
187 | def lookup_rolegroups_for_sctid(self, sctid):
188 | return self.lookup_elements_by_id('match (o:ObjectConcept)-[r]->(a:RoleGroup) where a.sctid in %s return %s',
189 | 'a','rolegroup',[sctid],100)
190 |
--------------------------------------------------------------------------------
/NEO4J/snomed_g_neo4j_tools.py:
--------------------------------------------------------------------------------
1 | #!/usr/bin/python
2 | from __future__ import print_function
3 | import py2neo, sys, base64, optparse, datetime
4 |
5 | '''
6 | Module: snomed_g_neo4j_tools.py
7 | Author: Jay Pedersen, July 2016
8 | Purpose: NEO4J utility commands -- eg 'run_cypher'.
9 | Syntax and Semantics:
10 | python run_cypher --neopw
11 | '''
12 |
13 | def run_cypher(arglist):
14 |
15 | def parse_command(arglist):
16 | # Parse command line
17 | opt = optparse.OptionParser()
18 | opt.add_option('--verbose',action='store_true')
19 | opt.add_option('--neopw64', action='store')
20 | opt.add_option('--neopw', action='store')
21 | opt.add_option('--cypher', action='store')
22 | opts, args = opt.parse_args(arglist)
23 | if len(args)==0 and not opts.cypher:
24 | print('''Usage: must specify CYPHER file or --cypher ''.''')
25 | sys.exit(1)
26 | if not (opts.neopw or opts.neopw64):
27 | print('''Usage: must specify --neopw '' or --neopw64 ''.''')
28 | sys.exit(1)
29 | if not ((opts.neopw or opts.neopw64) and
30 | ((len(args)==1 and not opts.cypher) or
31 | (len(args)==0 and opts.cypher))):
32 | print('''Usage: command [] --neopw [--cypher '']'''); sys.exit(1)
33 | if opts.neopw and opts.neopw64:
34 | print('Usage: only one of --neopw and --neopw64 may be specified')
35 | sys.exit(1)
36 | if opts.neopw64: # snomed_g v1.2, convert neopw64 to neopw
37 | opts.neopw = str(base64.b64decode(opts.neopw64),'utf-8') if sys.version_info[0]==3 else base64.decodestring(opts.neopw64) # py2
38 | return opts, args
39 | # end parse_command
40 |
41 | opts, args = parse_command(arglist)
42 | n4jpw = opts.neopw
43 | try:
44 | graph_db = py2neo.Graph("bolt://localhost:7687", auth=("neo4j", n4jpw)) # 'http://localhost:7474/db/data/transaction/commit')
45 | except Exception as e:
46 | print('*** Failed to make connection to NEO4J database ***')
47 | print('Exception: %s' % type(e).__name__)
48 | print('Exception arguments: %s' % e.args)
49 | sys.exit(1)
50 | if py2neo.__version__[0]=='3': # e.g. '3.1.2' instead of '4.1.0'
51 | # want LONG TIMEOUT for CSV loading, supported in py2neo 3.1.2, but not 4.1.0
52 | from py2neo.packages.httpstream import http
53 | http.socket_timeout = 1200 # JGP default was 30 on July 2016, this is 20 min I believe
54 | # end if py2neo version 3
55 | # Execute the CYPHER commands in the file
56 | if opts.cypher:
57 | command_lines = [ opts.cypher ]
58 | else:
59 | cypher_fn = args[0]
60 | command_lines = [ x.rstrip('\n').rstrip('\r').strip() for x in open(cypher_fn) ]
61 | succeeded, failed = 0, 0
62 | next_cmd = ''
63 | for idx,cmd in enumerate(command_lines):
64 | if opts.verbose: print('%d. %s' % (idx+1,cmd))
65 | if len(cmd)==0 or cmd.startswith('//'): continue # empty or comment
66 | next_cmd += (cmd if len(next_cmd)==0 else (' '+cmd))
67 | if next_cmd.rstrip()[-1] != ';': continue # dont sent until semicolon ends sequence of commands
68 | # dont' send if a RETURN '';, just check for RETURN ' for now -- works with our scripts
69 | if next_cmd.startswith("""RETURN '"""): next_cmd = ''; continue
70 | if opts.verbose: print('Sending CYPHER:[%s]' % next_cmd)
71 | command_start = datetime.datetime.now()
72 | try:
73 | temp_cursor = graph_db.run(next_cmd) # returns Cursor, empirical evidence (not in py2neo doc)
74 | # e.g. from doc -- graph.run("MATCH (a:Person) RETURN a.name, a.born LIMIT 4").to_data_frame()
75 | if py2neo.__version__[0] == '3': # e.g. '3.1.2' instead of '4.1.0'
76 | temp_cursor.dump() # v3 method
77 | else:
78 | print(str(temp_cursor.data())) # v4 method, list of dictionaries
79 | # end if py2neo v3 versus v4
80 | except Exception as e:
81 | failed += 1
82 | print('*** DB failure: command %d [%s] : [%s,%s]' % (idx+1,next_cmd,type(e),str(e)))
83 | pass
84 | else:
85 | succeeded += 1
86 | if opts.verbose: command_end = datetime.datetime.now(); print('CYPHER execution time: %s' % (str(command_end-command_start),))
87 | next_cmd = ''
88 | print('SUCCESS (%d commands)' % succeeded if failed==0 else 'FAILED (%d commands failed, %d commands succeeded)' % (failed,succeeded) )
89 | if len(next_cmd) > 0:
90 | print('*** Did NOT the trailing command that is missing a semicolon ***')
91 | print('[%s]' % next_cmd)
92 | sys.exit(failed) # CONVENTION -- exit program -- exit status is number of failures, zero if no failures
93 | # END run_cypher
94 |
95 | #----------------------------------------------------------------------------|
96 | # MAIN |
97 | #----------------------------------------------------------------------------|
98 |
99 | def parse_and_interpret(arglist):
100 | command_interpreters = [('run_cypher',run_cypher)]
101 | command_names = [x[0] for x in command_interpreters]
102 | if len(arglist) < 1: print('Usage: python %s ...' % '[one of %s]' % ','.join(command_names)); sys.exit(1)
103 | # DEMAND that arglist[0] be one of the sub-commands
104 | command_name = arglist[0]
105 | try: command_index = command_names.index(command_name)
106 | except: print('Usage : python %s ...' % '[one of %s]' % ','.join(command_names)); sys.exit(1)
107 | command_interpreters[command_index][1](arglist[1:]) # call appropriate interpreter
108 |
109 | # MAIN
110 | parse_and_interpret(sys.argv[1:]) # causes sub-command processing to occur as well
111 | sys.exit(0)
112 |
--------------------------------------------------------------------------------
/NEO4J/snomed_g_template_tools.py:
--------------------------------------------------------------------------------
1 | #!/usr/bin/python
2 | from __future__ import print_function
3 | import sys, os, re, optparse
4 | import snomed_g_lib_rf2
5 |
6 | '''
7 | Module: snomed_g_template_tools.py
8 | Concept: translate template file using configuration file information
9 | eg: replace <<>> by 20140731, depending on config.
10 | Supported tags:
11 | <<>>, where X is one of the keys in the config file,
12 | such as <<>> since "release_date" is configured.
13 | Syntax: cmd
14 | Version 1.1 Jay Pedersen, July 2016. Version created to match rf2_tools.
15 | Author: Jay Pedersen, University of Nebraska, Jan 8, 2015
16 | '''
17 |
18 | if sys.platform not in ['cygwin']: # Ubuntu/Mac
19 | def get_path(relpath, os_pathsep):
20 | return os.path.abspath(os.path.expanduser(relpath)).rstrip(os_pathsep)+os_pathsep
21 | else: # cygwin
22 | def get_path(relpath, os_pathsep): # Need t:/neo/data/sc_20140731/snomed_g_rconcept_... from '/cygdrive/t/neo/data/...
23 | s1 = os.path.realpath(os.path.expanduser(relpath)) # was abspath, realpath expands symlink
24 | m = re.match(r'/cygdrive/(.)/(.*)', s1)
25 | if m: # cygwin full path
26 | s = '%s:/%s' % (m.group(1),m.group(2))
27 | if s[-1] != os_pathsep: s += os_pathsep
28 | else:
29 | print('*** unable to translate path <%s> ***', relpath); sys.exit(1)
30 | return s
31 |
32 | def instantiate(arglist):
33 | # instantiate:
34 | # PARSE COMMAND
35 | # syntax: instantiate
36 | opt = optparse.OptionParser()
37 | opt.add_option('--rf2',action='store',dest='rf2')
38 | opt.add_option('--release_type', action='store', dest='release_type', choices=['delta','snapshot','full'])
39 | opt.add_option('--verbose',action='store_true',dest='verbose')
40 | opt.add_option('--action', action='store', dest='action', default='create', choices=['create','update'])
41 | opts, args = opt.parse_args(arglist)
42 | if not (len(args)==2 and opts.rf2 and opts.release_type):
43 | print('Usage: intantiate --rf2 --release_type {Full,Snapshot,Delta}'); sys.exit(1)
44 | template_file, output_file = args
45 | # Connect to RF2 files
46 | rf2_folders = snomed_g_lib_rf2.Rf2_Folders(opts.rf2, opts.release_type)
47 | # Information for creating the CSV files
48 | attributes_by_file = snomed_g_lib_rf2.Rf2_Attributes_per_File()
49 | # CONFIGURATION
50 | config = {}
51 | config['terminology_dir'] = rf2_folders.get_terminology_dir()
52 | config['release_date'] = rf2_folders.get_release_date()
53 | config['release_center'] = rf2_folders.get_release_center()
54 | config['output_dir'] = './'
55 |
56 | # Process template file
57 | fout = open(output_file, 'w')
58 | release_date = config['release_date'].strip()
59 | release_center = config.get('release_center', 'INT')
60 | os_pathsep = config.get('os_pathsep', '/') # JGP 2015/10/07, no default previously
61 | output_dir = get_path(config['output_dir'], os_pathsep)
62 | if sys.platform=='win32': output_dir = output_dir.replace('\\','/') # JGP 2016/07/30 -- issue "c:\sno\build\us20160301/defining_rel_edge_rem.csv"
63 | terminology_dir = get_path(config['terminology_dir'], os_pathsep)
64 | config_file_suffix = '%s_%s' % (release_center, release_date)
65 | file_protocol = 'file:///' if sys.platform in ['cygwin','win32','darwin'] else 'file:' # ubuntu is else case
66 | # NOTE: can result in 'file:////Users/' on Mac, replace by 'file:///Users/'
67 | # INSTANTIATION PT1 -- PROCESS FILES IN TEMPLATE, REPLACING TEMPLATES WITH INSTANTIATED VALUES
68 | for line in [x.rstrip('\n').rstrip('\r') for x in open(template_file)]:
69 | line = line.replace('<<>>', release_date) \
70 | .replace('<<>>', output_dir) \
71 | .replace('<<>>', terminology_dir) \
72 | .replace('<<>>', config_file_suffix) \
73 | .replace('<<>>', file_protocol) \
74 | .replace('file:////','file:///')
75 | print(line, file=fout)
76 |
77 | # INSTANTIATION PT2 -- DEFINING RELATIONSHIPS PROCESSING
78 |
79 | # Handle NEW defining relationships
80 | # Data source (for new defining relationships):
81 | # /defining_rels_new_sorted.csv file
82 | # id,active,sctid,rolegroup,typeId,rolename,destinationId,effectiveTime,
83 | # moduleId,characteristicTypeId,modifierId,history
84 | # 4661958023,1,471280008,1,FINDING_SITE,589001,20140731,
85 | # 900000000000207008,900000000000011006,900000000000451002,
86 | # Algorithm:
87 | # NOTE: already sorted by rolename, so all FINDING_SITE elements together, etc
88 | # ./snomed_sort_csv.py --fields 'rolename' --string
89 | # defining_rels_new.csv defining_rels_new_sorted.csv
90 | # ==> create separate files for each defining-relationship type that
91 | # is found, eg: DR__new.csv
92 | # ==> add CYPHER code to process the created files and add the
93 | # defining relationships.
94 |
95 | with open(output_dir+'used_roles.csv') as f:
96 | for idx,line in enumerate(x.rstrip('\n').rstrip('\r') for x in f):
97 | if idx==0: continue # typeId,rolename
98 | typeId, rolename = line.split(',')
99 | # create CYPHER to load the file and add the relationships to ROLE_GROUP nodes
100 | # JGP 2017-10-31. Use a 2-step procedure for creating the defining relationships,
101 | # to support systems with smaller amounts of memory (use smaller transactions).
102 | # The first step creates any necessary role groups, and the second step creates
103 | # the defining relationship edges from role groups to the specified target concepts.
104 | print('// %s defining relationships' % rolename,file=fout)
105 | print('''RETURN 'NEW Defining relationships of type %s';''' % rolename,file=fout)
106 | print(file=fout)
107 | load_csv_line = ('LOAD CSV with headers from "%s%sDR_%s_new.csv" as line' % (('file:///' if sys.platform in ['cygwin','win32','darwin'] else 'file:'),output_dir,typeId)).replace('file:////','file:///')
108 | print(load_csv_line,file=fout)
109 | print('CALL {',file=fout)
110 | print(' with line ',file=fout)
111 | print(' MERGE (rg:RoleGroup { sctid: line.sctid, rolegroup: line.rolegroup })',file=fout)
112 | print(' } IN TRANSACTIONS OF 200 ROWS;',file=fout)
113 | print(file=fout)
114 | print('// Add defining relationship edge in 2nd step, Java memory issue',file=fout)
115 | load_csv_line = ('LOAD CSV with headers from "%s%sDR_%s_new.csv" as line' % (('file:///' if sys.platform in ['cygwin','win32','darwin'] else 'file:'),output_dir,typeId)).replace('file:////','file:///')
116 | print(load_csv_line,file=fout)
117 | print('CALL {',file=fout)
118 | print(' with line ',file=fout)
119 | print(' MATCH (rg:RoleGroup { sctid: line.sctid, rolegroup: line.rolegroup })',file=fout)
120 | print( 'WITH line,rg ',file=fout)
121 | print(' MATCH (c:ObjectConcept { sctid: line.destinationId })',file=fout)
122 | print(' MERGE (rg)-[:%s { id: line.id, active: line.active, sctid: line.sctid,' % rolename,file=fout)
123 | print(' typeId: line.typeId,',file=fout)
124 | print(' rolegroup: line.rolegroup, effectiveTime: line.effectiveTime,',file=fout)
125 | print(' moduleId: line.moduleId, characteristicTypeId: line.characteristicTypeId,',file=fout)
126 | print(' modifierId: line.modifierId,',file=fout)
127 | print(' history: line.history }]->(c)',file=fout)
128 | print(' } IN TRANSACTIONS OF 200 ROWS;',file=fout)
129 | # close CSV, wrap up
130 | print('// Finito',file=fout)
131 | fout.close()
132 | return
133 |
134 | def parse_and_interpret(arglist):
135 | command_interpreters = [('instantiate',instantiate)]
136 | command_names = [x[0] for x in command_interpreters]
137 | if len(arglist) < 1: print('Usage: python %s ...' % '[one of %s]' % ','.join(command_names)); sys.exit(1)
138 | # DEMAND that arglist[0] be one of the sub-commands
139 | command_name = arglist[0]
140 | try: command_index = command_names.index(command_name)
141 | except: print('Usage : python %s ...' % '[one of %s]' % ','.join(command_names)); sys.exit(1)
142 | command_interpreters[command_index][1](arglist[1:]) # call appropriate interpreter
143 |
144 | # MAIN
145 | parse_and_interpret(sys.argv[1:]) # causes sub-command processing to occur as well
146 | sys.exit(0)
147 |
--------------------------------------------------------------------------------
/NEO4J/snomed_g_version:
--------------------------------------------------------------------------------
1 | 1.05
2 |
3 | 2017/05/10 Added compare_concept_sets and extract_concept_sets to the rf2_tools.
4 | Added CompareRF2s and WalkRF2 classes to lib_rf2.
5 |
6 | 1.04
7 |
8 | 2017/05/05 Improved reporting in Transitive Closure file comparison, with the --verbose option.
9 |
10 | 1.03
11 |
12 | 2017/04/30 1.03: #1. Added CHECK_RESULT step to Graph Database update.
13 | #2. Handle case where source and destination nodes for an edge
14 | differs between the Graph and the update RF2. Remove
15 | such edges and fail the update -- requiring a 2nd pass which adds them
16 | with the new source and destination and completes the update.
17 |
18 | NOTE: it is not possible to repoint the source or destination of
19 | an edge in NEO4J 3.0. Removal and re-addition of the edge is required.
20 |
21 | The plan is to later detect this in the graph vs RF2
22 | comparison and perform the same edge removal and re-add,
23 | but in a single pass instead of 2 passes.
24 |
--------------------------------------------------------------------------------
/NEO4J/snomedct_constants.py:
--------------------------------------------------------------------------------
1 | #!/usr/bin/python
2 | SNOMEDCT_TYPEID_ISA = '116680003'
3 | SNOMEDCT_TYPEID_FSN = '900000000000003001'
4 |
5 | SNOMEDCT_ROOT_CONCEPT_ID = '138875005'
6 |
7 | SNOMEDCT_REFSETID_USA = '900000000000509007'
8 |
9 |
--------------------------------------------------------------------------------
/PostgreSQL/README.md:
--------------------------------------------------------------------------------
1 | # SNOMED CT DATABASE
2 |
3 | PostgreSQL SQL Scripts to create and populate a PostgreSQL database with a SNOMED CT terminology release.
4 |
5 | **NOTE:** This script is not directly supported by SNOMED International and has not been fully tested by the SNOMED International team. It has been kindly donated by others in the SNOMED CT community.
6 |
7 | ## Minimum Specification
8 |
9 | - PostgreSQL v.9
10 |
11 | # Creating the SNOMED CT schema on PostgreSQL
12 |
13 | PostgreSQL is an [`ORDBMS`](http://en.wikipedia.org/wiki/ORDBMS) therefore every Database is self-contained object. A _"database"_ contains logins, one or more schemas, groups, etc. and every conection is related to a sigle database.
14 |
15 | ## Diffences from the MySQL version
16 |
17 | - PostgreSQL does not need `engine=myisam` which by itself is a bit strange as `myisam` does not support foreign keys.
18 | - Changes `database` for `schema`
19 | - using the `unique` constraint instead of `key`
20 |
21 | ## Scripted Installation (Mac & Unix)
22 |
23 | run load_release-postgresql.sh
24 |
25 |
26 |
27 |
28 |
29 |
30 |
31 |
32 | eg ./load_release-postgresql.sh ~/Backup/SnomedCT_RF2Release_INT_20180131.zip SCT_20180131 SNAP
33 |
34 | Note that the scripted installation will now support loading other Editions. The script asks for a module identifier, which is INT by default, for the international edition. Loading the US Edition, for example, would work as follows: `Enter module string used in filenames [INT]: US1000124`
35 |
36 | ## Manual Installation
37 |
38 | 1. Download the SNOMED CT terminology release from the IHTSDO web site
39 | 2. Create the database using the db create-database-postgres.sql script or skip/perform this action manually if you'd like the data to be loaded into a existing/different database.
40 | 3. Create the tables using the db appropriate environment.sql script. The default file creates tables for full, snapshot and delta files and there's also a -full-only version.
41 | 4. Edit the db appropriate load.sql script with the correct location of the SNOMED CT release files An alternative under unix or mac would be to create a symlink to the appropriate directory eg `ln -s /your/snomed/directory RF2Release`
42 | 5. Load the database created using the edited load.sql script from the relevant command prompt, again by default for full, snapshot and delta unless you only want the full version.
43 |
--------------------------------------------------------------------------------
/PostgreSQL/Verhoeff.sql:
--------------------------------------------------------------------------------
1 | /* Create functions to calculate Verhoeff check sum */
2 |
3 | CREATE OR REPLACE FUNCTION snomedct.reverse (
4 | input text
5 | )
6 | RETURNS text AS $$
7 | DECLARE
8 | RESULT text = '';
9 | i INT;
10 | BEGIN
11 | FOR i IN 1..LENGTH(INPUT) BY 2 LOOP
12 | RESULT = substr(INPUT,i+1,1) || substr(INPUT,i,1) || RESULT;
13 | END LOOP;
14 | RETURN RESULT;
15 | END; $$
16 | LANGUAGE 'plpgsql'
17 | IMMUTABLE
18 | RETURNS NULL ON NULL INPUT;
19 |
20 | CREATE OR REPLACE FUNCTION snomedct.generateverhoeff (
21 | input numeric = NULL::numeric
22 | )
23 | RETURNS smallint AS $$
24 | DECLARE
25 | _c SMALLINT := 0;
26 | _m SMALLINT;
27 | _i SMALLINT := 0;
28 | _n VARCHAR(255);
29 | -- Delcare array
30 | _d CHAR(100) := '0123456789123406789523401789563401289567401239567859876043216598710432765982104387659321049876543210';
31 | _p CHAR(80) := '01234567891576283094580379614289160435279453126870428657390127938064157046913258';
32 | _v CHAR(10) := '0432156789';
33 | BEGIN
34 | _n := REVERSE(input::TEXT);
35 | WHILE _i "
13 | exit -1
14 | fi
15 |
16 | dbUsername=postgres
17 | echo "Enter postgres username [$dbUsername]:"
18 | read newDbUsername
19 | if [ -n "$newDbUsername" ]
20 | then
21 | dbUsername=$newDbUsername
22 | fi
23 |
24 | dbPortNumber=5432
25 | echo "Enter postgres port number [$dbPortNumber|:"
26 | read newDbPortNumber
27 | if [ -n "$newDbPortNumber" ]
28 | then
29 | dbPortNumber=$newDbPortNumber
30 | fi
31 |
32 | #Unzip the files here, junking the structure
33 | localExtract="tmp_extracted"
34 | generatedLoadScript="tmp_loader.sql"
35 | generatedEnvScript="tmp_environment-postgresql.sql"
36 |
37 | #What types of files are we loading - delta, snapshot, full or all?
38 | case "${loadType}" in
39 | 'DELTA') fileTypes=(Delta)
40 | unzip -j ${releasePath} "*Delta*" -d ${localExtract}
41 | ;;
42 | 'SNAP') fileTypes=(Snapshot)
43 | unzip -j ${releasePath} "*Snapshot*" -d ${localExtract}
44 | ;;
45 | 'FULL') fileTypes=(Full)
46 | unzip -j ${releasePath} "*Full*" -d ${localExtract}
47 | ;;
48 | 'ALL') fileTypes=(Delta Snapshot Full)
49 | unzip -j ${releasePath} -d ${localExtract}
50 | ;;
51 | *) echo "File load type ${loadType} not recognised"
52 | exit -1;
53 | ;;
54 | esac
55 |
56 |
57 | #Determine the release date from the filenames
58 | releaseDate=`ls -1 ${localExtract}/*.txt | head -1 | egrep -o '[0-9]{8}'`
59 |
60 | #Generate the environemnt script by running through the template as
61 | #many times as required
62 | #now=`date +"%Y%m%d_%H%M%S"`
63 | #echo -e "\nGenerating Environment script for ${loadType} type(s)"
64 | #echo "/* Script Generated Automatically by load_release.sh ${now} */" > ${generatedEnvScript}
65 | #for fileType in ${fileTypes[@]}; do
66 | # fileTypeLetter=`echo "${fileType}" | head -c 1 | tr '[:upper:]' '[:lower:]'`
67 | # tail -n +2 environment-postgresql-mysql.sql | while read thisLine
68 | # do
69 | # echo "${thisLine/TYPE/${fileTypeLetter}}" >> ${generatedEnvScript}
70 | # done
71 | #done
72 |
73 | function addLoadScript() {
74 | for fileType in ${fileTypes[@]}; do
75 | fileName=${1/TYPE/${fileType}}
76 | fileName=${fileName/DATE/${releaseDate}}
77 |
78 | #Check file exists - try beta version if not
79 | if [ ! -f ${localExtract}/${fileName} ]; then
80 | origFilename=${fileName}
81 | fileName="x${fileName}"
82 | if [ ! -f ${localExtract}/${fileName} ]; then
83 | echo "Unable to find ${origFilename} or beta version"
84 | exit -1
85 | fi
86 | fi
87 |
88 | tableName=${2}_`echo $fileType | head -c 1 | tr '[:upper:]' '[:lower:]'`
89 |
90 | echo -e "COPY ${tableName}" >> ${generatedLoadScript}
91 | echo -e "FROM '"${basedir}/${localExtract}/${fileName}"'" >> ${generatedLoadScript}
92 | echo -e "WITH (FORMAT csv, HEADER true, ENCODING 'UTF8', DELIMITER E' ', QUOTE E'\b');" >> ${generatedLoadScript}
93 | echo -e "" >> ${generatedLoadScript}
94 | done
95 | }
96 |
97 | echo -e "\nGenerating loading script for $releaseDate"
98 | echo "/* Generated Loader Script */" > ${generatedLoadScript}
99 | echo "" >> ${generatedLoadScript}
100 | echo "set schema 'snomedct';" >> ${generatedLoadScript}
101 | echo "" >> ${generatedLoadScript}
102 | addLoadScript sct2_Concept_TYPE_INT_DATE.txt concept
103 | addLoadScript sct2_Description_TYPE-en_INT_DATE.txt description
104 | addLoadScript sct2_StatedRelationship_TYPE_INT_DATE.txt stated_relationship
105 | addLoadScript sct2_Relationship_TYPE_INT_DATE.txt relationship
106 | addLoadScript sct2_TextDefinition_TYPE-en_INT_DATE.txt textdefinition
107 | addLoadScript der2_cRefset_AttributeValueTYPE_INT_DATE.txt attributevaluerefset
108 | addLoadScript der2_cRefset_LanguageTYPE-en_INT_DATE.txt langrefset
109 | addLoadScript der2_cRefset_AssociationTYPE_INT_DATE.txt associationrefset
110 |
111 | psql -U ${dbUsername} -p ${dbPortNumber} -d ${dbName} << EOF
112 | \ir create-database-postgres.sql;
113 | \ir environment-postgresql.sql;
114 | \ir ${generatedLoadScript};
115 | EOF
116 |
117 | rm -rf $localExtract
118 | #We'll leave the generated environment & load scripts for inspection
119 |
--------------------------------------------------------------------------------
/README.md:
--------------------------------------------------------------------------------
1 | # SNOMED CT Database Scripts
2 |
3 | The scripts in this repository can be used to create and populate a MYSQL, PostgreSQL, MSSQL or NEO4J database with a SNOMED CT terminology release distributed in the **RF2 distribution format**.
4 |
5 | Please see the relevant sub-directories for each of the different database load scripts:
6 |
7 | - [MYSQL](MySQL/)
8 | - [MYSQL with optimizedviews](mysql-loader-with-optimized-views/)
9 | - [NEO4J](NEO4J/)
10 | - [PostgreSQL](PostgreSQL/)
11 | - [MSSQL](MSSQL/)
12 | - [Python DataFrame](python-dataframe/)
13 |
14 | If you have any scripts for other databases, please fork this repository and create the pull request to submit any contributions.
15 |
--------------------------------------------------------------------------------
/mysql-loader-with-optimized-views/README.md:
--------------------------------------------------------------------------------
1 | # SNOMED CT MySQL Release Files Loader with Optimized Views
2 | ## SnomedRfsMySql 2022-01-26
3 |
4 | ## INSTRUCTION ON USE
5 |
6 | See http://snomed.org/snomedmysql for detailed instruction on use of this package.
7 |
8 | ## IMPORTANT NOTES
9 |
10 | This loader has been tested to work with MySQL 8.x and with the earlier version 5.7.
11 |
12 | Use with MySQL version 8.x requires the server to reference a copy of the file *cnf/my_snomedserver.cnf* as an additional configuration file.
13 |
14 | # Support for Use on Mac Systems
15 |
16 | The package includes two bash scripts for use on a Mac.
17 |
18 | ## bash/snomed_config_mysql
19 |
20 | * Applies the required MySQL configuration settings in *cnf/my_snomedserver.cnf* to the server.
21 |
22 | ## bash/snomed_load_mysql
23 |
24 | 1. Collects user input to configure the following settings:
25 | - Name of the SQL import script to be used (default: create_latest)
26 | - Note VP_latest refers to the file *mysql_load/sct_mysql_load_create_latest.sql*
27 | - Path to SNOMED CT release file package
28 | - Name of the database schema to be created (default: snomedct)
29 | - MySQL database username for running the SNOMED CT import script (default: root)
30 | 2. Configures the import script to use the chosen settings
31 | 3. Builds a Transitive Closure snapshot file (from the relationships release file)
32 | 4. Prompts for the MySQL password
33 | 5. Runs the SNOMED CT MySQL import script
34 |
35 | # Other Operating System Environments
36 |
37 | In other environments the following steps may need to be carried out manually.
38 | * MySQL configuration changes
39 | * Running the Perl script to generate the Transitive Closure snapshot file.
40 | * Modifying and running the SNOMED CT MySQL import script *mysql_load/sct_mysql_load_create_latest.sql*.
41 |
42 | The notes below outline the extent to which the scripts may be useful in other environments and outline steps required to run the processes manually.
43 |
44 | ## Other Unix Based Systems
45 |
46 | ### Configuration Settings on Other Unix Based Systems
47 |
48 | As written the script *bash/snomed_mysql_config* is unlikely to work on other Unix based systems. This is because it assumes the default location for configuration files on the Mac.
49 | Therefore, you will need to manually adjust the settings to include the settings in the *cnf/my_snomedserver.cnf* file in one of the configuration file read when the MySQL server is started.
50 |
51 | ### Loading the SNOMED CT Release Package on Other Unix Based Systems
52 |
53 | This script *bash/snomed_mysql_load* should work in most Unix based environments. It uses the bash shell and general purpose unix utilities. However, it has not been tested except on the Mac, so some changes might be necessary.
54 |
55 | If it does not work please refer to the notes on use on Widnows systems below for a description of the required manual steps.
56 |
57 | ## Support for Use on Windows
58 |
59 | ## win/snomed_wconfig_mysql.bat
60 |
61 | * Applies the required MySQL configuration settings in *win/snomed_win_my.cnf* to the server.
62 |
63 | ## win/snomed_wload_mysql.bat
64 |
65 | 1. Collects user input to configure the following settings:
66 | - Name of the SQL import script to be used (default: create_latest)
67 | - Note VP_latest refers to the file *mysql_load/sct_mysql_load_create_latest.sql*
68 | - Path to SNOMED CT release file package
69 | - Name of the database schema to be created (default: snomedct)
70 | - MySQL database username for running the SNOMED CT import script (default: root)
71 | 2. Configures the import script to use the chosen settings
72 | 3. Builds a Transitive Closure snapshot file (from the relationships release file)
73 | 4. Prompts for the MySQL password
74 | 5. Runs the SNOMED CT MySQL import script
75 |
76 | ### Configuration Settings on Windows Systems
77 |
78 | Manually adjust the settings to include the settings in the *cnf/my_snomedserver.cnf* file in one of the configuration file read when the MySQL server is started.
79 |
80 | ### Loading the SNOMED CT Release Package on Other Unix Based Systems
81 |
82 | 1. Create a copy of the file *mysql_load/sct_mysql_load_VP_latest.sql*
83 | - Name the new file: *mysql_load_local.sql*
84 | 2. Open the file *mysql_load_local.sql* in text editor.
85 | 3. Use the text editor to replace all instances of the following three placeholders:
86 | - $RELPATH with the full path to the folder containing the SNOMED CT release package you want to import.
87 | - $RELDATE with the YYYYDDMM representation of the release date (e.g. 20190731)
88 | - $DBNAME with the name of the database schema you want to create (e.g. snomedct).
89 | 4. Save the file *mysql_load_local.sql*.
90 | 5. Run the following command line:
91 |
92 | mysql --defaults-extra-file="*my_snomedimport_client.cnf*" --protocol=tcp --host=localhost --default-character-set=utf8mb4 --comments --user *mysql_username* --password < "*mysql_load_local.sql*"
93 |
94 | ### NOTES
95 | - The full path names of the following files should be included on the command line enclosed in quotation marks.
96 | - "*my_snomedimport_client.cnf*"
97 | - "*mysql_load_local.sql*"
98 | - The *mysql_username* must either be **root** or another account with rights to drop and create database schemas. You will be required to enter the password for this account when running the command.
99 | - There are spaces before each of the double dashes in the command line.
100 |
--------------------------------------------------------------------------------
/mysql-loader-with-optimized-views/bash/snomed_config_mysql:
--------------------------------------------------------------------------------
1 | #!/bin/bash
2 | if ! [[ $USER =~ ^(root|su)$ ]] ; then
3 | printf "Must be run as superuser (su or root)\n"
4 | exit
5 | fi
6 | # Cannot use the $EPSDRIVE variable as not accessible as SUDO
7 | if [[ $EPSDRIVE == '' ]] ; then
8 | cnffolder="/Volumes/GoogleDrive/Shared drives/EPS_Team/SnomedRfs/SnomedRfsMySql/cnf"
9 | else
10 | cnffolder="$EPSDRIVE/Shared drives/EPS_Team/SnomedRfs/SnomedRfsMySql/cnf"
11 | fi
12 | # Default port
13 | port='0'
14 |
15 | if [[ $# >1 ]] ; then
16 | if [[ $1 =~ '-p' ]] ; then
17 | shift
18 | port=$1
19 | shift
20 | fi
21 | if [[ $1 =~ '^-[cd]' ]] ; then
22 | shift
23 | cnffolder=$1
24 | shift
25 | fi
26 | fi
27 | if ! [ -d "$cnffolder" ] ; then
28 | cd `dirname "$0"`
29 | bashfolder="$PWD"
30 | echo "$bashfolder"
31 | rfsfolder=`dirname "$bashfolder"`
32 | echo "$rfsfolder"
33 | cnffolder="$rfsfolder/cnf"
34 | echo "$cnffolder"
35 | if ! [ -d "$cnffolder" ] ; then
36 | printf "Error! No CNF Folder: $cnffolder\n"
37 | exit
38 | fi
39 | fi
40 | printf "\nSNOMED MySQL Configuration folder: $cnffolder\n"
41 | cd "$cnffolder"
42 |
43 | # If a port is specified apply this to the config files
44 | if [[ $port =~ ^[0-9]{3,5}$ ]] ; then
45 | printf "Setting Port to: $port\n"
46 | mv -f "my_snomedimport_client.cnf" "my_snomedimport_client.cnf.bak"
47 | mv -f "my_snomedserver.cnf" "my_snomedserver.cnf.bak"
48 | sed "s/^port=.\{0,10\}$/port=$port/" "my_snomedimport_client.cnf.bak" >"my_snomedimport_client.cnf"
49 | sed "s/^port=.\{0,10\}$/port=$port/" "my_snomedserver.cnf.bak" >"my_snomedserver.cnf"
50 | fi
51 |
52 |
53 | # Copy the my_snomedserver.cnf file to the MySQL support-files folder
54 | supportfolder="/usr/local/mysql/support-files"
55 | cp "my_snomedserver.cnf" "$supportfolder/my_snomedserver.cnf"
56 |
57 | # Set the ownerships and permission of the my_snomedserver.cnf in the MySQL support-files folder
58 | chown root:wheel $supportfolder/my_snomedserver.cnf
59 | chmod a+r $supportfolder/my_snomedserver.cnf
60 |
61 | # ls -l $folder/my.cnf
62 |
63 | # Update the MySQL lunch demon to reference the my_snomedserver.cnf file
64 | mysql_launch="com.oracle.oss.mysql.mysqld.plist"
65 | rm -f "$mysql_launch"
66 | ldfolder="/Library/LaunchDaemons"
67 | ldtarget="$ldfolder/$mysql_launch"
68 | mv "$ldtarget" "$mysql_launch"
69 | awk -f "ref_my_snomedserver.awk" "$mysql_launch" >"$ldtarget"
70 | chown root:wheel "$ldtarget"
71 | chmod a+r "$ldtarget"
72 | chmod a-x "$ldtarget"
73 |
74 | # Add /usr/local/mysql/bin to the PATH environment variable
75 | # Required to ensure that the mysql command can be run.
76 | tmp_profile=`cat $HOME/.bash_profile`
77 | if ! [[ "$PATH" =~ mysql/bin || "$tmp_profile" =~ mysql/bin ]] ; then
78 | printf 'Added "/usr/local/mysql/bin" to $PATH\n\n'
79 | echo "export PATH=${PATH}:/usr/local/mysql/bin" >>$HOME/.bash_profile
80 | fi
81 | printf "** Configuration settings update completed ** \n\n"
82 |
--------------------------------------------------------------------------------
/mysql-loader-with-optimized-views/bash/snomed_run_mysql:
--------------------------------------------------------------------------------
1 | #!/bin/bash
2 |
3 | self=$0
4 | prog=`basename "$self"`
5 | mysqlrun='mysql'
6 | mysqlload='mysql_load'
7 | mode="standard"
8 |
9 | help="\n----------------------------------\nHELP FOR SCRIPT: $prog\n----------------------------------\nRuns MySQL Command Line.\n\nRequires:tA SnomedRfsMySql folder containing relevant support folders and files\n\t(e.g. previous release of same package)\n\nCommand line parameters (all optional). Script uses default values and prompts for required parameters.\n\t-help (or -h): Displays this message.\n\t-d dbname: Specifies dbname (the name of the database to be created).\n\t-b loaderFolder: Specifies loaderFolder (the folder containing required support folders and files).\n\t-c cnfname: Specifies the {cnfname} in the MySQL configuration file name {cnfname}.cnf (default: $cnfname).\n\t-u mysqluser: Specifies the username for an administrator account on the MySQL Server (default $USER).\n\t-p portnumber: Specifies the MySQL port number (by default read from the file {cnfname}.cnf.\n\n"
10 |
11 | # Get command line parameters
12 | # -h Help
13 | # -d dbname (New target database name)
14 | # -f loaderFolder (Folder )
15 | # -c cnfname (MySQL configuration file name : default my_snomedimport_client)
16 | # -p portnumber (MySQL portnumber : default from cnfname file)
17 | # -u MySQL username
18 |
19 | while [[ $#>0 ]]
20 | do
21 | echo $1
22 | if [[ $1 =~ ^-h.* ]] ; then
23 | printf "$help"
24 | exit
25 | fi
26 | if [[ $1 == '-d' ]] ; then
27 | # Specify a the database name
28 | # Not needed as script prompts if not supplied here and defaults to snomedct.
29 | shift
30 | dbname="$1"
31 | if ! [[ $dbname =~ ^s[-a-zA-Z_0-9]{1,9}$ ]] ; then
32 | printf "Invalid database name: $dbname\n\tMust start with 's' and be no longer than 10 characters\n"
33 | printf "$help"
34 | exit
35 | fi
36 | fi
37 | if [[ $1 == '-f' ]] ; then
38 | # Specify a loader folder in which required load subfolders will be found
39 | # Not needed as this can be located if not specified (either local to script or in EPSDRIVE)
40 | shift
41 | loaderFolder="$1"
42 | if ! [ -d "$loaderFolder/$mysqlload" ] ; then
43 | printf "Invalid loader folder: $loaderFolder\n\tError! Missing folder: $loaderFolder/$mysqlload\n"
44 | printf "$help"
45 | exit
46 | fi
47 | fi
48 | if [[ $1 == '-c' ]] ; then
49 | # Specify the mysql Config filename stem
50 | shift
51 | cnfname="$1"
52 | fi
53 | if [[ $1 == '-p' ]] ; then
54 | # Specify the mysql Port Number
55 | # Optional as can be read from mysql config file.
56 | shift
57 | portnumber="$1"
58 | fi
59 |
60 | if [[ $1 == '-u' ]] ; then
61 | # Specify My SQL username
62 | # Optional as prompts for this if not provided and defaults to logged in user
63 | shift
64 | mysqluser="$1"
65 | fi
66 | shift
67 | done
68 |
69 | # If loaderFolder not set by command line set it here
70 | # Other scripts are relative to the defined base folder
71 |
72 | if [[ "$loaderFolder" == "" ]] ; then
73 | # First check folder containing the script
74 | loaderFolder=`dirname "$self"`
75 | cd $loaderFolder
76 | # The folder from $0 may be relative so change to the folder
77 | # Then get the absolute folder path
78 | loaderFolder=$PWD
79 | if ! [ -d "$loaderFolder/$mysqlload" ] ; then
80 | # Failing that check parent script
81 | loaderFolder=`dirname "$loaderFolder"`
82 | fi
83 | if ! [ -d "$loaderFolder/$mysqlload" ] ; then
84 | # Finally look in the place it will be on EPS team systems
85 | loaderFolder="$EPSDRIVE/SnomedRfs/SnomedRfsMySql"
86 | fi
87 | if ! [ -d "$loaderFolder/$mysqlload" ] ; then
88 | printf "ERROR INVALID Loader Folder: $loaderFolder.\nDoes not contain required subfolder: $mysqlload\n\n"
89 | printf "$help"
90 | exit
91 | fi
92 | fi
93 |
94 |
95 | # By default uses the create_latest.sql script
96 | # (Based on the Variable Path version substitution made later in the script)
97 | loadkey=''
98 | loadkey_default='create_latest'
99 |
100 | Q='"'
101 |
102 | log_file="${loaderFolder}/cnf/${USER}_load_log.txt"
103 | user_prefs="${loaderFolder}/cnf/${USER}_prefs.txt"
104 | tmp_prefs="${loaderFolder}/cnf/${USER}_tmp.txt"
105 |
106 | function addLog()
107 | {
108 | printf "`date +'%Y-%m-%d %T'` $1\n" >>"$log_file"
109 | }
110 | printf ''> "$log_file"
111 | addLog "Started snomed_load_mysql"
112 |
113 | if ! [ -f "$user_prefs" ] ; then
114 | echo "" >"$user_prefs"
115 | fi
116 |
117 | function setCfgValue()
118 | {
119 | local cfgName="$1"
120 | local cfgValue="$2"
121 | if ! [ -f "$user_prefs" ] ; then
122 | echo "${cfgName}=${cfgValue}" >"$user_prefs"
123 | else
124 | sed '/'$cfgName'=/d' "$user_prefs" >"$tmp_prefs"
125 | echo "${cfgName}=${cfgValue}" >>"$tmp_prefs"
126 | mv -f "$tmp_prefs" "$user_prefs"
127 | fi
128 | }
129 | function getCfgValue()
130 | {
131 | local cfgName="$1"
132 | local defaultValue="$2" #set default value
133 | if ! [ -f "$user_prefs" ] ; then
134 | echo "" "$user_prefs"
135 | fi
136 | cfgValue=`sed '/^[^=]*$/d;s/'$cfgName'=\(.*\)/\1/;/.*=.*/d' "$user_prefs"`
137 | if [[ $cfgValue == '' ]] ; then
138 | cfgValue="$defaultValue"
139 | fi
140 | }
141 |
142 | if ! [ -f "$user_prefs" ] ; then
143 | echo "" > "$user_prefs"
144 | fi
145 |
146 | # releasePath set here is container for all release files
147 | # prevRel set here is previous release folder name
148 | getCfgValue 'relpath' "$HOME/SnomedCT_ReleaseFiles"
149 | releasePath=$cfgValue
150 | getCfgValue 'prevrel'
151 | prevRelease=$cfgValue
152 | getCfgValue 'mysqluser' 'root'
153 | prevUser=$cfgValue
154 |
155 | cnfname="my_snomedimport_client"
156 | cnf_file="${loaderFolder}/cnf/${cnfname}.cnf"
157 | portnumber=`sed -n 's/port=//p;' "$cnf_file"`
158 | if [[ $portnumber == '' ]] ; then
159 | read -p "MySQL port number: " portnumber
160 | fi
161 | read -p "MySQL username (default: $prevUser): " mysqluser
162 | if [[ "$mysqluser" == '' ]] ; then
163 | mysqluser=$prevUser
164 | else
165 | setCfgValue 'mysqluser' "$mysqluser"
166 | fi
167 |
168 | # Get Database Name
169 |
170 | read -p "Database name (default: snomedct): " dbname
171 | if [[ "$dbname" == '' ]] ; then
172 | dbname='snomedct'
173 | fi
174 |
175 |
176 | ${mysqlrun} --defaults-extra-file="${cnf_file}" --protocol=tcp --host=localhost --port=${portnumber} --default-character-set=utf8mb4 --database ${dbname} --comments --user $mysqluser --password
177 |
178 |
--------------------------------------------------------------------------------
/mysql-loader-with-optimized-views/cnf/com.oracle.oss.mysql.mysqld.plist:
--------------------------------------------------------------------------------
1 |
2 |
3 |
4 |
5 | Disabled
6 |
7 | EnvironmentVariables
8 |
9 | MYSQLD_PARENT_PID
10 | 1
11 |
12 | ExitTimeOut
13 | 600
14 | GroupName
15 | _mysql
16 | KeepAlive
17 |
18 | AfterInitialDemand
19 |
20 | SuccessfulExit
21 |
22 |
23 | Label
24 | com.oracle.oss.mysql.mysqld
25 | LaunchOnlyOnce
26 |
27 | ProcessType
28 | Interactive
29 | Program
30 | /usr/local/mysql/bin/mysqld
31 | ProgramArguments
32 |
33 | /usr/local/mysql/bin/mysqld
34 | --user=_mysql
35 | --basedir=/usr/local/mysql
36 | --datadir=/usr/local/mysql/data
37 | --plugin-dir=/usr/local/mysql/lib/plugin
38 | --log-error=/usr/local/mysql/data/mysqld.local.err
39 | --pid-file=/usr/local/mysql/data/mysqld.local.pid
40 | --keyring-file-data=/usr/local/mysql/keyring/keyring
41 | --early-plugin-load=keyring_file=keyring_file.so
42 | --default_authentication_plugin=mysql_native_password
43 |
44 | RunAtLoad
45 |
46 | SessionCreate
47 |
48 | UserName
49 | _mysql
50 | WorkingDirectory
51 | /usr/local/mysql
52 |
53 |
54 |
--------------------------------------------------------------------------------
/mysql-loader-with-optimized-views/cnf/my_snomedimport_client.cnf:
--------------------------------------------------------------------------------
1 | [mysql]
2 | local-infile=1
3 | [client]
4 | local-infile=1
5 | protocol=tcp
6 | host=localhost
7 | port=3306
8 |
9 |
--------------------------------------------------------------------------------
/mysql-loader-with-optimized-views/cnf/my_snomedserver.cnf:
--------------------------------------------------------------------------------
1 | [mysqld]
2 | local-infile=1
3 | ft_stopword_file = ''
4 | ft_min_word_len = 2
5 | disable-log-bin
6 | skip-log-bin
7 | default-authentication-plugin=mysql_native_password
8 | [mysql]
9 | local-infile=1
10 | [client]
11 | local-infile=1
12 | protocol=tcp
13 | host=localhost
14 | port=3306
15 |
16 |
--------------------------------------------------------------------------------
/mysql-loader-with-optimized-views/cnf/ref_my_snomedserver.awk:
--------------------------------------------------------------------------------
1 | # Adds or replaces the defaults-file reference in the MySQL file
2 | # /Library/LaunchDaemons/com.oracle.oss.mysql.mysqld.plist
3 | # So that this references the file /usr/local/mysql/support-files/my_snomedserver.cnf
4 | !/--defaults-file=.*<.string>/ {print $0 }
5 | /<.?array>/ {counter=counter+1 }
6 | /.usr.local.mysql.bin.mysqld<.string>/ {if (counter == 1) { print " --defaults-file=/usr/local/mysql/support-files/my_snomedserver.cnf" }}
7 |
--------------------------------------------------------------------------------
/mysql-loader-with-optimized-views/lib/test.pl:
--------------------------------------------------------------------------------
1 | #!/usr/bin/perl
2 | use strict;
3 | use warnings;
4 | print "Perl is correctly installed\n";
--------------------------------------------------------------------------------
/mysql-loader-with-optimized-views/lib/transitiveClosureRf2SnapMulti.pl:
--------------------------------------------------------------------------------
1 | #!/usr/local/bin/perl
2 | #-------------------------------------------------------------------------------
3 | # Copyright IHTSDO 2012
4 | # Licensed under the Apache License, Version 2.0 (the "License");
5 | # you may not use this file except in compliance with the License.
6 | # You may obtain a copy of the License at
7 | # http://www.apache.org/licenses/LICENSE-2.0
8 | # Unless required by applicable law or agreed to in writing, software
9 | # distributed under the License is distributed on an "AS IS" BASIS,
10 | # WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied.
11 | # See the License for the specific language governing permissions and
12 | # limitations under the License.
13 | #-------------------------------------------------------------------------------
14 | # This perl script carries no warranty of fitness for any purpose.
15 | # Use at your own risk.
16 | #-------------------------------------------------------------------------------
17 | # This perl script computes the transitive closure of a Directed Acyclic Graph
18 | # input in transitive reduction form.
19 | # Input is in the format of the SNOMED CT relationships table
20 | # Isa relationships are those elements in the table with relationshipID=116680003
21 | #-------------------------------------------------------------------------------
22 |
23 | # use this script as
24 | # perl transitiveClosure.pl [ ...]
25 | # Input files (and optionally ...) contain the inferred child-parent pairs
26 | # as distributed in the relationships table, RF2 format SNAPSHOT
27 | # Use multiple input files when combining Extension files with the International Edition
28 |
29 | # output is a tab-delimited file with two columns, child - parent.
30 |
31 | #-------------------------------------------------------------------------------
32 | # Start MAIN
33 | #-------------------------------------------------------------------------------
34 |
35 | %children = ();
36 | %visited = ();
37 | %descendants = ();
38 |
39 | for (my $infile=0; $infile < $#ARGV; $infile++) {
40 | &readrels(\%children,$infile);
41 | }
42 |
43 |
44 |
45 |
46 | $counter=0;
47 | $root="138875005";
48 |
49 |
50 | transClos($root,\%children,\%descendants,\%visited);
51 |
52 | printRels(\%descendants,$#ARGV);
53 |
54 |
55 | #-------------------------------------------------------------------------------
56 | # END MAIN
57 | #-------------------------------------------------------------------------------
58 |
59 | #-------------------------------------------------------------------------------
60 | # INPUT
61 | #-------------------------------------------------------------------------------
62 | # Takes as arguments: a hash table reference and an argument number $argn
63 | # Opens the relationships table in the file designated by the name in $ARGV[$argn]
64 | # Reads the isa-s and stores them in the hash
65 | #-------------------------------------------------------------------------------
66 | sub readrels {
67 | local($childhashref,$argn) = @_;
68 | my ($firstline,@values);
69 | open(ISAS,$ARGV[$argn]) || die "can't open $ARGV[$argn]";
70 | # read first input row
71 | chop($firstline = );
72 | # throw away first row, it contains the column names
73 |
74 | # read remaining input rows
75 | while () {
76 | chop;
77 | @values=split('\t',$_);
78 | if (($values[7] eq "116680003") && ($values[2] eq "1")) { # rel.Type is "is-a"
79 | $$childhashref{$values[5]}{$values[4]} = 1; # a hash of hashes, where parent is 1st arg and child is 2nd.
80 | }
81 | }
82 | close(ISAS);
83 | }
84 |
85 |
86 | #-------------------------------------------------------------------------------
87 | # transClos
88 | #-------------------------------------------------------------------------------
89 | # This subroutine is based on a method described in "Transitive Closure Algorithms
90 | # Based on Graph Traversal" by Yannis Ioannidis, Raghu Ramakrishnan, and Linda Winger,
91 | # ACM Transactions on Database Systems, Vol. 18, No. 3, September 1993,
92 | # Pages: 512 - 576.
93 | # It uses a simplified version of their "DAG_DFTC" algorithm.
94 | #-------------------------------------------------------------------------------
95 | #
96 | sub transClos { # recursively depth-first traverse the graph.
97 | local($startnode,$children,$descendants,$visited) = @_;
98 | my($descendant, $childnode);
99 | $counter++;
100 | # if (($counter % 1000) eq 0) { print "Visit ", $startnode, " ", $counter, "\n"; }
101 | for $childnode (keys %{ $$children{$startnode} }) { # for all the children of the startnode
102 | unless ($$visited{$childnode}) { # unless it has already been traversed
103 | &transClos($childnode,$children,$descendants,$visited); # recursively visit the childnode
104 | $$visited{$childnode}="T"; # and when the recursive visit completes, mark as visited
105 | } # end unless
106 | for $descendant (keys %{ $$descendants{$childnode} }) { # for each descendant of childnode
107 | $$descendants{$startnode}{$descendant} = 1; # mark as a descendant of startnode
108 | }
109 | $$descendants{$startnode}{$childnode} = 1; # mark the immediate childnode as a descendant of startnode
110 | } # end for
111 | } # end sub transClos
112 |
113 |
114 | #-------------------------------------------------------------------------------
115 | # OUTPUT
116 | #-------------------------------------------------------------------------------
117 |
118 | sub printRels {
119 | local($descendants,$argn)=@_;
120 | open(OUTF,">$ARGV[$argn]") || die "can't open $ARGV[$argn]";
121 | for $startnode (keys %$descendants) {
122 | for $endnode ( keys %{ $$descendants{$startnode} }) {
123 | print OUTF "$endnode\t$startnode\n";
124 | }
125 | # print OUTF "\n";
126 | }
127 | }
128 |
129 |
130 | #-------------------------------------------------------------------------------
131 | # END
132 | #-------------------------------------------------------------------------------
133 |
134 |
135 |
--------------------------------------------------------------------------------
/mysql-loader-with-optimized-views/mysql_examples/DeltaWithPreviousStateExample.sql:
--------------------------------------------------------------------------------
1 | select * from full_concept tbl
2 | where tbl.effectiveTime > '20190131' and tbl.effectiveTime <= '20190731'
3 | union
4 | select * from full_concept tbl
5 | where tbl.effectiveTime = (select max(sub.effectiveTime) from full_concept sub
6 | where sub.id = tbl.id and sub.effectiveTime<='20190131')
7 | and tbl.id IN (select id from full_concept
8 | where effectiveTime > '20190131' and effectiveTime <= '20190731')
9 | order by id;
--------------------------------------------------------------------------------
/mysql-loader-with-optimized-views/mysql_examples/SQL_Queries_Step_by_Step_Views/Description_Composite_View_Step_by_Step/1b_Snapshot_and_Full_Synonyms.sql:
--------------------------------------------------------------------------------
1 | -- All versions of all synonyms for concept 80146002
2 | SELECT
3 | *
4 | FROM
5 | full_description
6 | WHERE
7 | conceptId = 80146002 and typeId = 900000000000013009;
8 |
9 | -- All versions of synonym with descriptionId 132967011
10 | SELECT
11 | *
12 | FROM
13 | full_description tbl
14 | WHERE
15 | conceptId = 80146002 and typeId = 900000000000013009
16 | and id=132967011;
17 |
18 | -- Most recent effectiveTime for synonym with descriptionId 33388017
19 | SELECT
20 | MAX(sub.effectiveTime)
21 | FROM
22 | full_description sub
23 | WHERE
24 | sub.id = 33388017;
25 |
26 | -- Row with most recent effectiveTime for synonym with descriptionId 33388017
27 | SELECT
28 | *
29 | FROM
30 | full_description tbl
31 | WHERE
32 | conceptId = 80146002 and typeId = 900000000000013009
33 | and id=132967011 and effectiveTime = 20170731;
34 |
35 | -- Nested identification of most recent row for every synonym of concept 80146002
36 | SELECT
37 | *
38 | FROM
39 | full_description tbl
40 | WHERE
41 | conceptId = 80146002 and typeId = 900000000000013009
42 | AND effectiveTime =
43 | (SELECT
44 | MAX(sub.effectiveTime)
45 | FROM
46 | full_description sub
47 | WHERE
48 | sub.id = tbl.id);
49 |
50 |
51 | -- SNAPSHOT of active synonyms for concept 80146002
52 | SELECT
53 | *
54 | FROM
55 | snap_description d
56 | WHERE
57 | d.conceptId = 80146002 AND d.typeId = 900000000000013009
58 | AND d.active = 1;
59 |
60 | -- Preferred synonym for concept 80146002
61 | SELECT
62 | *
63 | FROM
64 | snap_description d
65 | JOIN
66 | snap_refset_language rs ON d.id = rs.referencedComponentId
67 | WHERE
68 | d.conceptId = 80146002
69 | AND d.active = 1
70 | AND d.typeId = 900000000000013009 -- Synonym
71 | AND rs.refsetId = 900000000000509007 -- US Language Refset
72 | -- AND rs.refsetId = 900000000000508004 -- GB Language Refset
73 | AND rs.active = 1
74 | AND rs.acceptabilityId = 900000000000548007; -- Preferred Acceptability
--------------------------------------------------------------------------------
/mysql-loader-with-optimized-views/mysql_examples/SQL_Queries_Step_by_Step_Views/Description_Composite_View_Step_by_Step/Description_Composite_View_Step_by_Step_00.sql:
--------------------------------------------------------------------------------
1 | -- Step By Step Development of Description Composite Views - Introduction
2 |
3 | -- This folder contains a series of queries that illustrate the steps in developing
4 | -- useful composite views of descriptions from existing snapshot views of concepts,
5 | -- descriptions and language reference sets.
6 | --
7 | -- Each step explained and illustrated in a separate SQL script file containing
8 | -- notes accompanied by an SQL query that can be run in the SNOMED CT Example Database.
9 | --
10 | -- All the scripts have the same name followed by a number indicating the order of the steps.
11 | --
12 | -- The idea of these files is to illustrate each of the key points in this logical process.
13 | -- If you are only interested in using the database for access to the terminology this
14 | -- is not for you. However, if you are interested in understanding how composite views can be
15 | -- derived from a snapshot release tables you may find this helpful.
16 | --
17 |
18 | -- All versions of all synonyms for concept 80146002
19 | SELECT
20 | *
21 | FROM
22 | full_description
23 | WHERE
24 | conceptId = 80146002 and typeId = 900000000000013009;
25 |
26 | -- All versions of synonym with descriptionId 132967011
27 | SELECT
28 | *
29 | FROM
30 | full_description tbl
31 | WHERE
32 | conceptId = 80146002 and typeId = 900000000000013009
33 | and id=132967011;
34 |
35 | -- Most recent effectiveTime for synonym with descriptionId 132967011
36 | SELECT
37 | MAX(sub.effectiveTime)
38 | FROM
39 | full_description sub
40 | WHERE
41 | sub.id = 132967011;
42 |
43 | -- Row with most recent effectiveTime for synonym with descriptionId 33388017
44 | SELECT
45 | *
46 | FROM
47 | full_description tbl
48 | WHERE
49 | conceptId = 80146002 and typeId = 900000000000013009
50 | and id=132967011 and effectiveTime = 20170731;
51 |
52 | -- Nested identification of most recent row for every synonym of concept 80146002
53 | SELECT
54 | *
55 | FROM
56 | full_description tbl
57 | WHERE
58 | conceptId = 80146002 and typeId = 900000000000013009
59 | AND effectiveTime =
60 | (SELECT
61 | MAX(sub.effectiveTime)
62 | FROM
63 | full_description sub
64 | WHERE
65 | sub.id = tbl.id);
66 |
67 |
68 | -- SNAPSHOT of active synonyms for concept 80146002
69 | SELECT
70 | *
71 | FROM
72 | snap_description d
73 | WHERE
74 | d.conceptId = 80146002 AND d.typeId = 900000000000013009
75 | AND d.active = 1;
76 |
77 | -- Preferred synonym for concept 80146002
78 | SELECT
79 | *
80 | FROM
81 | snap_description d
82 | JOIN
83 | snap_refset_language rs ON d.id = rs.referencedComponentId
84 | WHERE
85 | d.conceptId = 80146002
86 | AND d.active = 1
87 | AND d.typeId = 900000000000013009 -- Synonym
88 | -- AND rs.refsetId = 900000000000509007 -- US Language Refset
89 | AND rs.refsetId = 900000000000508004 -- GB Language Refset
90 | AND rs.active = 1
91 | AND rs.acceptabilityId = 900000000000548007; -- Preferred Acceptability
--------------------------------------------------------------------------------
/mysql-loader-with-optimized-views/mysql_examples/SQL_Queries_Step_by_Step_Views/Description_Composite_View_Step_by_Step/Description_Composite_View_Step_by_Step_01.sql:
--------------------------------------------------------------------------------
1 | -- Step By Step Development of Description Composite Views from Concepts, Descriptions and Language refsets
2 |
3 | -- STEP 1: Show all description for a concept.
4 |
5 | -- In this series of steps we look at descriptions of the concept 80146002 before applying the
6 | -- resulting views more generally.
7 | -- You can repeat the same queries with other concepts but some concepts will not illustrate all the points
8 | -- in these examples.
9 |
10 | SELECT * FROM snap_description
11 | WHERE conceptId = 80146002
12 |
13 | -- Run this query.
14 | -- Note that:
15 | -- 1. The result contains some rows that have a 0 (zero) in the active column.
16 | -- - Those descriptions are inactive and in the next step we will filter them out.
17 | -- 2. The typeId values vary
18 | -- - Some rows have the typeId 900000000000013009 (Synonym)
19 | -- - Other rows have the typeId 900000000000003001 (Fully specified name)
--------------------------------------------------------------------------------
/mysql-loader-with-optimized-views/mysql_examples/SQL_Queries_Step_by_Step_Views/Description_Composite_View_Step_by_Step/Description_Composite_View_Step_by_Step_02.sql:
--------------------------------------------------------------------------------
1 | -- Step By Step Development of Description Composite Views from Concepts, Descriptions and Language refsets
2 |
3 | -- STEP 2: Show all ACTIVE descriptions for a concept.
4 |
5 | SELECT * FROM snap_description
6 | WHERE conceptId = 80146002 AND active=1;
7 |
8 | -- Run this query.
9 | -- Note that:
10 | -- 1. The inactive description shown in the previous step are no longer shown.
11 | -- 2. The typeId values vary
12 | -- - Most rows have the typeId 900000000000013009 (Synonym)
13 | -- - One row has the typeId 900000000000003001 (Fully specified name)
14 | -- 3. The synonyms include both "Appendectomy" and "Appendicectomy"
15 | --
--------------------------------------------------------------------------------
/mysql-loader-with-optimized-views/mysql_examples/SQL_Queries_Step_by_Step_Views/Description_Composite_View_Step_by_Step/Description_Composite_View_Step_by_Step_03.sql:
--------------------------------------------------------------------------------
1 | -- Step By Step Development of Description Composite Views from Concepts, Descriptions and Language refsets
2 |
3 | -- STEP 3: Show all active synonyms for a concept.
4 |
5 | SELECT * FROM snap_description
6 | WHERE conceptId = 80146002 AND active=1
7 | AND typeId=900000000000013009;
8 |
9 | -- Run this query.
10 | -- Note that:
11 | -- 1. Only active synonyms are now shown.
12 | -- - typeId 900000000000013009 (Synonym)
13 | -- 2. The synonyms include both "Appendectomy" and "Appendicectomy"
14 | -- - One of these is valid in US English and the other is valid in GB English
15 | -- The next step uses the language reference sets to identify the appropriate term to display.
16 | --
17 | -- You can modify this query to see fully specified name description(s):
18 | -- - replace typeId=900000000000013009
19 | -- - with typeId=900000000000003001
20 | --
21 |
--------------------------------------------------------------------------------
/mysql-loader-with-optimized-views/mysql_examples/SQL_Queries_Step_by_Step_Views/Description_Composite_View_Step_by_Step/Description_Composite_View_Step_by_Step_04.sql:
--------------------------------------------------------------------------------
1 | -- Step By Step Development of Description Composite Views from Concepts, Descriptions and Language refsets
2 |
3 | -- STEP 4: Show all active synonyms that are acceptable or preferred in the US.
4 |
5 | SELECT d.* FROM snap_description d
6 | JOIN snap_refset_language rs ON d.id = rs.referencedComponentId
7 | WHERE d.conceptId = 80146002 AND d.active=1
8 | AND d.typeId=900000000000013009
9 | AND rs.refsetId = 900000000000509007 -- US Language Refset -- (for GB Language Refset replace with: 900000000000508004 )
10 | AND rs.active = 1
11 |
12 | -- Run this query.
13 | -- - Note that the synonym "Appendectomy" is shown but NOT "Appendicectomy"
14 | -- Change rs.refsetId = 900000000000509007 to rs.refsetId = 900000000000508004
15 | -- Run the revised query to see the en-GB terms
16 | -- - Note that now the synonym "Appendicectomy" is shown but NOT "Appendectomy"
17 |
18 | -- NOTE
19 | -- - This query only includes synonyms that are referenced by an active row in the US Language Refset.
20 | -- - It does not distinguish between the preferred term and other acceptable synonyms.
--------------------------------------------------------------------------------
/mysql-loader-with-optimized-views/mysql_examples/SQL_Queries_Step_by_Step_Views/Description_Composite_View_Step_by_Step/Description_Composite_View_Step_by_Step_05.sql:
--------------------------------------------------------------------------------
1 | -- Step By Step Development of Description Composite Views from Concepts, Descriptions and Language refsets
2 |
3 | -- STEP 5: Show the preferred term in US English
4 |
5 | SELECT d.* FROM snap_description d
6 | JOIN snap_refset_language rs ON d.id = rs.referencedComponentId
7 | WHERE d.conceptId = 80146002 AND d.active=1
8 | AND d.typeId=900000000000013009
9 | AND rs.refsetId = 900000000000509007 -- US Language Refset -- (for GB Language Refset replace with: 900000000000508004 )
10 | AND rs.active = 1
11 | AND rs.acceptabilityId = 900000000000548007; -- Preferred Acceptability
12 |
13 | -- Run this query.
14 | -- - Note that the US preferred term "Appendectomy" is shown
15 | -- Change rs.refsetId = 900000000000509007 to rs.refsetId = 900000000000508004
16 | -- Run the revised query to see the en-GB terms
17 | -- - Note that now the GB preferred term "Appendicectomy" is shown
18 | -- You can also change this query show it shows only synonyms that are acceptable (excluding the preferred term)
19 | -- - Change rs.acceptabilityId = 900000000000548007 to rs.acceptabilityId = 900000000000549004
--------------------------------------------------------------------------------
/mysql-loader-with-optimized-views/mysql_examples/SQL_Queries_Step_by_Step_Views/Description_Composite_View_Step_by_Step/Description_Composite_View_Step_by_Step_06.sql:
--------------------------------------------------------------------------------
1 | -- Step By Step Development of Description Composite Views from Concepts, Descriptions and Language refsets
2 |
3 | -- STEP 6: Create a View that displays synonymous terms for a concept
4 |
5 | DROP VIEW IF EXISTS myview_synonyms;
6 | CREATE VIEW myview_synonyms AS
7 | SELECT d.* FROM snap_description d
8 | JOIN snap_refset_language rs ON d.id = rs.referencedComponentId
9 | WHERE d.active=1
10 | AND d.typeId=900000000000013009
11 | AND rs.refsetId = 900000000000509007 -- US Language Refset -- (for GB Language Refset replace with: 900000000000508004 )
12 | AND rs.active = 1;
13 |
14 | -- When this view has been created as simple query like the one shown below
15 | -- can be used to show the preferred and acceptable synonyms for any concept.
16 |
17 | SELECT term FROM myview_synonyms
18 | WHERE conceptId=80146002;
19 |
20 | -- Modifications to the view to allow the language reference set identifier to be read from a configuration table can allow the
21 | -- same view to be used show synonyms in different languages. This feature is supported by the snap_syn view in the SNOMED Example Database.
22 |
--------------------------------------------------------------------------------
/mysql-loader-with-optimized-views/mysql_examples/SQL_Queries_Step_by_Step_Views/Description_Composite_View_Step_by_Step/Description_Composite_View_Step_by_Step_07.sql:
--------------------------------------------------------------------------------
1 | -- Step By Step Development of Description Composite Views from Concepts, Descriptions and Language refsets
2 |
3 | -- STEP 7: Using a View for searches
4 |
5 | -- While the view in STEP 6 can be searched, it is worth noting that it includes active terms associated with inactive concepts
6 | -- the terms are important for displaying the a human-readable term for concepts that have been inactivated since they were used.
7 | -- However, in most cases, searches for concepts should only return active concepts. Therefore the view can be adjusted to
8 | -- ensure it can be searched without finding terms associated with inactive concepts.
9 |
10 | -- One way to do this is to use the view created in STEP 6 in the following query
11 |
12 | SELECT term, conceptId
13 | FROM myview_synonyms d
14 | JOIN snap_concept c ON c.id=d.conceptId
15 | WHERE c.active=1
16 | AND MATCH (term) AGAINST ('+pneumonia +bacterial' IN BOOLEAN MODE) ;
17 |
18 | -- Alternatively a modified view can be created as shown below including the condition requiring the associated concept to be active.
19 |
20 | DROP VIEW IF EXISTS myview_search;
21 | CREATE VIEW myview_search AS
22 | SELECT d.* FROM snap_description d
23 | JOIN snap_concept c ON c.id=d.conceptId
24 | JOIN snap_refset_language rs ON d.id = rs.referencedComponentId
25 | WHERE d.active=1
26 | AND d.typeId=900000000000013009
27 | AND rs.refsetId = 900000000000509007 -- US Language Refset -- (for GB Language Refset replace with: 900000000000508004 )
28 | AND rs.active = 1
29 | AND c.active = 1;
30 |
31 | -- When this view has been created the search query is simplified
32 | -- can be used to show the preferred and acceptable synonyms for any concept.
33 |
34 | SELECT term, conceptId FROM myview_search
35 | WHERE MATCH (term) AGAINST ('+pneumonia +bacterial' IN BOOLEAN MODE) ;
36 |
37 |
--------------------------------------------------------------------------------
/mysql-loader-with-optimized-views/mysql_examples/SQL_Queries_Step_by_Step_Views/README.md:
--------------------------------------------------------------------------------
1 | # SNOMED CT MySQL Worked Examples
2 | ## Folder: SQL_Queries_Step_by_Step_Views
3 |
4 | ## WORK-IN-PROGRESS - Additional content for this folder is being developed.
5 | ## Please check for future updates.
6 |
7 | The subfolders of this folder contain worked examples building step by step to explain how some useful views of SNOMED CT can be developed. Views that serve these purposes are already created when you install this database so these queries are not essential. They are intended aid understanding of how views that simplify access to SNOMED CT can be designed by combining simple queries.
8 |
9 | The sets of queries in this version of the folder are noted below.
10 |
11 | ## Snapshot_View_Step_by_Step ##
12 |
13 | How to create current and retrospective views from any FULL release database table. Starting from simple queries and building up to creating reusable views.
14 |
15 |
16 | ## Description_Composite_View_Step_by_Step ##
17 |
18 | How to create views of the descriptions of a concept that take account of the description type and acceptability in a given language and the active status of the description and its associated concept.
19 |
20 |
21 |
22 |
--------------------------------------------------------------------------------
/mysql-loader-with-optimized-views/mysql_examples/SQL_Queries_Step_by_Step_Views/Snapshot_View_Step_by_Step/Snapshot_View_Step_by_Step_00.sql:
--------------------------------------------------------------------------------
1 | -- Step By Step Development of a Snapshot Views from the Full Table - Introduction
2 |
3 | -- This folder contains a series of queries that illustrate the steps in going from
4 | -- a FULL release file to to a SNAPSHOT view of one or more concepts.
5 | --
6 | -- Each step is explained and illustrated in a separate SQL script file containing
7 | -- notes accompanied by an SQL query that can be run in the SNOMED CT Example Database.
8 | --
9 | -- All the scripts have the same name followed by a number indicating the order of the steps.
10 | --
11 | -- The idea of these files is to illustrate each of the key points in this logical process.
12 | -- If you are only interested in using the database for access to the terminology this
13 | -- is not for you. However, if you are interested in understanding how snapshot views can be
14 | -- derived from a full release tables you may find this helpful.
15 | --
--------------------------------------------------------------------------------
/mysql-loader-with-optimized-views/mysql_examples/SQL_Queries_Step_by_Step_Views/Snapshot_View_Step_by_Step/Snapshot_View_Step_by_Step_01.sql:
--------------------------------------------------------------------------------
1 | -- Step By Step Development of a Snapshot Views from the Full Table
2 |
3 | -- STEP 1: Get all versions of concepts with specified id values.
4 | --
5 | -- In the example we look at three concepts with the following id values 172001,157000,80146002
6 | -- Because we are looking for all versions the query looks at the full_concept table
7 |
8 | SELECT * FROM full_concept
9 | WHERE id IN (157000,172001,80146002)
10 | ORDER BY id,effectiveTime;
11 |
12 | -- Run this query and note that the following points:
13 | -- 1) Five rows are returned although only three distict id values were specified
14 | -- 2) Two of the concept id values are present in two rows with different effectiveTime values
15 | -- 3) All of the concepts were initially added with an effectiveTime of 2002-01-31 (the first SNOMED CT release)
16 | -- 4) Two of the concepts were subsequently updated with later effectiveTime values
17 | -- - One update changed the active value (inactivating the concept)
18 | -- - The other update changed the definitionStatusId (the concept became "define" rather than "primitive")
19 | --
20 | -- You can also adapt this query by changing the concept id values selected to look at other concepts.
21 | -- However, to provide simple example the following steps all use the three concept ids shown here.
22 |
--------------------------------------------------------------------------------
/mysql-loader-with-optimized-views/mysql_examples/SQL_Queries_Step_by_Step_Views/Snapshot_View_Step_by_Step/Snapshot_View_Step_by_Step_02.sql:
--------------------------------------------------------------------------------
1 | -- Step By Step Development of a Snapshot Views from the Full Table
2 |
3 | -- STEP 2: Get the most recent effectiveTime for a concept with a specified id value.
4 | SELECT MAX(effectiveTime) FROM full_concept
5 | WHERE id = 157000;
6 |
7 | -- This provides the most recent effectiveTime for concept 157000
8 | -- You can also rerun the query for the concepts with id 172001,80146002 noting that each of these gives a different result.
9 |
10 | -- Make a note of the most recent effectiveTime for each of the identifiers.
--------------------------------------------------------------------------------
/mysql-loader-with-optimized-views/mysql_examples/SQL_Queries_Step_by_Step_Views/Snapshot_View_Step_by_Step/Snapshot_View_Step_by_Step_03.sql:
--------------------------------------------------------------------------------
1 | -- Step By Step Development of a Snapshot Views from the Full Table
2 |
3 | -- STEP 3: Get the most recent row for a concept with a specified id value.
4 | -- Using the effectiveTimes reported by step 2 in the query allows us to
5 | -- select only the most recent row.
6 |
7 | SELECT * FROM full_concept
8 | WHERE id = 157000
9 | AND effectiveTime = '2006-07-31';
10 |
11 | -- Run this query and note that it returns the most recent row for the concept 157000
12 |
13 | -- Since the most recent effectiveTime is different for each of the three example
14 | -- concepts, repeating this for each of the concepts involves changing both the id
15 | -- and the effectiveTime! Obviously this manual approach of specifying the
16 | -- effectiveTime for each concept is NOT a practical solution!
17 | --
18 | -- The next step illustrates how steps 2 and 3 can be built into a single query.
--------------------------------------------------------------------------------
/mysql-loader-with-optimized-views/mysql_examples/SQL_Queries_Step_by_Step_Views/Snapshot_View_Step_by_Step/Snapshot_View_Step_by_Step_04.sql:
--------------------------------------------------------------------------------
1 | -- Step By Step Development of a Snapshot Views from the Full Table
2 |
3 | -- STEP 4: Combine steps 2 and 3 in a single query.
4 | --
5 | SELECT * FROM full_concept
6 | WHERE id = 157000
7 | AND effectiveTime = (SELECT MAX(effectiveTime)
8 | FROM full_concept
9 | WHERE id = 157000);
10 |
11 | -- Run this query and note that it returns the most recent row for the concept 157000
12 | --
13 | -- This query is still NOT generalizable to provide a snapshot view of all concepts.
14 | -- It requires the same id to be specified in the main query and the nested query.
15 | --
16 | -- The next step revises this query to provide a generalizable solution.
17 |
--------------------------------------------------------------------------------
/mysql-loader-with-optimized-views/mysql_examples/SQL_Queries_Step_by_Step_Views/Snapshot_View_Step_by_Step/Snapshot_View_Step_by_Step_05.sql:
--------------------------------------------------------------------------------
1 | -- Step By Step Development of a Snapshot Views from the Full Table
2 |
3 | -- STEP 5: Generalizable version of the query in step 4.
4 | --
5 | -- To make the query generalizable, two changes need to be made
6 | -- a) The two references to the full_concept table must be given distinct aliases
7 | -- to allow them to be separately referenced. In this example:
8 | -- - the outer reference has the alias: tbl
9 | -- - the nested reference has the alias: sub
10 | -- b) The WHERE clause in the nested query must now test for
11 | -- the id of the concept in the main and nested queries being
12 | -- equal (rather than referring to a specific value)
13 | --
14 | -- Because the query is now generalizable we can also change the
15 | -- main WHERE clause to refer to any concepts. In this example
16 | -- we return specify the same three concept id values using in
17 | -- step 1.
18 | --
19 | SELECT tbl.* FROM full_concept tbl
20 | WHERE tbl.id IN (157000,172001,80146002)
21 | AND tbl.effectiveTime = (SELECT MAX(sub.effectiveTime)
22 | FROM full_concept sub
23 | WHERE sub.id = tbl.id);
24 |
25 | -- Run this query and note that it returns the most recent rows for
26 | -- the three concepts specified.
27 | --
28 | -- In the next step this query will be turned into a view that
29 | -- can be reused without requiring repetition of the code shown above
30 | -- each time a snapshot is required.
31 |
--------------------------------------------------------------------------------
/mysql-loader-with-optimized-views/mysql_examples/SQL_Queries_Step_by_Step_Views/Snapshot_View_Step_by_Step/Snapshot_View_Step_by_Step_06.sql:
--------------------------------------------------------------------------------
1 | -- Step By Step Development of a Snapshot Views from the Full Table
2 |
3 | -- STEP 6: Create a Reusable Snapshot View Using the Query from Step 5
4 | --
5 |
6 | -- First just in case the view is already there DROP it.
7 | DROP VIEW IF EXISTS mysnap_concept;
8 | -- Then create the view called mysnap_concept
9 | -- - The view is defined based on the query from step 5
10 | -- - The id condition in the main query has been removed so the view includes all concepts
11 | CREATE VIEW mysnap_concept AS
12 | SELECT tbl.* FROM full_concept tbl
13 | WHERE tbl.effectiveTime = (SELECT MAX(sub.effectiveTime)
14 | FROM full_concept sub
15 | WHERE sub.id = tbl.id);
16 |
17 | -- After the view has been created the following simple query demonstrates that this view
18 | -- returns only the most recent rows for the selected concepts.
19 | SELECT * FROM mysnap_concept WHERE id IN (157000,172001,80146002);
20 |
21 | -- Run this query and note that it returns the most recent rows for
22 | -- the three concepts specified.
23 |
24 | -- NOTE: Snapshot views can be created for all full tables in the release by
25 | -- following exactly the same pattern.
26 | -- Simply replace the occurences of '_concept' with '_[table-name]'
27 | -- (where [table-name] is the name of the specific table)
28 |
29 | -- In the next step we consider how to create a similar view for retrospective snapshots
30 | -- that is snapshot views as they were at a specified past date.
31 |
--------------------------------------------------------------------------------
/mysql-loader-with-optimized-views/mysql_examples/SQL_Queries_Step_by_Step_Views/Snapshot_View_Step_by_Step/Snapshot_View_Step_by_Step_07.sql:
--------------------------------------------------------------------------------
1 | -- Step By Step Development of a Snapshot Views from the Full Table
2 |
3 | -- STEP 7: Create a Reusable Retrospective Snapshot View
4 | -- The only different between a current (most recent) snapshot and a retrospective
5 | -- snapshot is that the nested query for a retrospective snapshot must specify
6 | -- a maximum effectiveTime.
7 | --
8 | -- In this example the maximum effective time is specified as 2019-01-31
9 |
10 | -- First just in case the view is already there DROP it.
11 | DROP VIEW IF EXISTS myretrosnap_concept;
12 | -- Then create the view called mysnap_concept
13 | -- - The view is defined based on the query from step 5
14 | -- - The id condition in the main query has been removed so the view includes all concepts
15 | CREATE VIEW myretrosnap_concept AS
16 | SELECT tbl.* FROM full_concept tbl
17 | WHERE tbl.effectiveTime = (SELECT MAX(sub.effectiveTime)
18 | FROM full_concept sub
19 | WHERE sub.id = tbl.id
20 | AND sub.effectiveTime<='2009-01-31');
21 |
22 | -- After the view has been created the following simple query demonstrates that this view
23 | -- returns only the most recent rows for the selected concepts.
24 | SELECT * FROM myretrosnap_concept WHERE id IN (157000,172001,80146002);
25 |
26 | -- Run this query and note that it returns the most recent rows PRIOR TO the specified date
27 | -- for the three concepts specified. In particular note that for the concept 172001 the
28 | -- row returned has the date 2002-01-31 because, although the full table contains a more
29 | -- recent row, that row was added in 2009-07-31, which was after the specified snapshot date.
30 |
31 | -- NOTE 1: Retrospective snapshot views can be created for all full tables in the release by
32 | -- following exactly the same pattern.
33 | -- Simply replace the occurences of '_concept' with '_[table-name]'
34 | -- (where [table-name] is the name of the specific table)
35 |
36 | -- NOTE 2: If the maximum value for the condition sub.effectiveTime is specified as
37 | -- a reference to a configurable value (e.g. in a configuration table) it
38 | -- is possible to vary the retrospective snapshot date. Resulting in a more
39 | -- flexible solution. This is the approach implemented in the snap1_ and snap2_
40 | -- views created by the example database.
--------------------------------------------------------------------------------
/mysql-loader-with-optimized-views/mysql_examples/SQL_Queries_for_Webinar/0_Imported_Table_and_View_Statistics.sql:
--------------------------------------------------------------------------------
1 | CREATE TABLE IF NOT EXISTS `snap_transclose` (
2 | `subtypeId` bigint(20) NOT NULL DEFAULT '0',
3 | `supertypeId` bigint(20) NOT NULL DEFAULT '0',
4 | PRIMARY KEY (`subtypeId`,`supertypeId`),
5 | KEY `supertypeId` (`supertypeId`,`subtypeId`)
6 | ) ENGINE=MyISAM DEFAULT CHARSET=utf8;
7 |
8 | SELECT 'Concept Full View Rows' as 'View',COUNT(id) as 'Count' FROM full_concept
9 | UNION
10 | SELECT 'Concept Snapshot Rows',COUNT(id) FROM snap_concept
11 | UNION
12 | SELECT 'Concept Snapshot Active Rows',COUNT(id) FROM snap_concept WHERE active=1
13 | UNION
14 | SELECT 'Description Full View Rows',COUNT(id) FROM full_description
15 | UNION
16 | SELECT 'Description Snapshot Rows',COUNT(id) FROM snap_description
17 | UNION
18 | SELECT 'Description Snapshot Active Rows',COUNT(id) FROM snap_description WHERE active=1
19 | UNION
20 | SELECT 'Relationship Full View Rows',COUNT(id) FROM full_relationship
21 | UNION
22 | SELECT 'Relationship Snapshot Rows',COUNT(id) FROM snap_relationship
23 | UNION
24 | SELECT 'Relationship Snapshot Active Rows',COUNT(id) FROM snap_relationship WHERE active=1
25 | UNION
26 | SELECT 'IS A Relationship Snapshot Active Rows',COUNT(id) FROM snap_relationship WHERE active=1 and typeId=116680003
27 | UNION
28 | SELECT 'Transitive Closure Snapshot Active Rows',COUNT(subTypeId) FROM snap_transclose
29 | UNION
30 | SELECT 'Simple Refset Full View Rows' as 'View',COUNT(id) as 'Count' FROM full_refset_Simple
31 | UNION
32 | SELECT 'Simple Refset Snapshot Rows',COUNT(id) FROM snap_refset_Simple
33 | UNION
34 | SELECT 'Simple Refset Snapshot Active Rows',COUNT(id) FROM snap_refset_Simple WHERE active=1;
35 |
36 | SELECT 'Language Refset Full View Rows' as 'View',refsetId, COUNT(id) as 'Count' FROM full_refset_Language GROUP BY refsetId
37 | UNION
38 | SELECT 'Language Refset Snapshot Rows', refsetId, COUNT(id) FROM snap_refset_Language GROUP BY refsetId
39 | UNION
40 | SELECT 'Language Refset Snapshot Active Rows',refsetId, COUNT(id) FROM snap_refset_Language WHERE active=1 GROUP BY refsetId
--------------------------------------------------------------------------------
/mysql-loader-with-optimized-views/mysql_examples/SQL_Queries_for_Webinar/1a_Preferred_Term_from_tables.sql:
--------------------------------------------------------------------------------
1 | -- Preferred synonym for concept 80146002
2 | SELECT d.* FROM
3 | snap_description d
4 | JOIN
5 | snap_refset_language rs ON d.id = rs.referencedComponentId
6 | WHERE d.conceptId = 80146002
7 | AND d.active = 1 AND rs.active = 1
8 | AND d.typeId = 900000000000013009 -- Synonym
9 | -- AND rs.refsetId = 900000000000509007 -- US Language Refset
10 | AND rs.refsetId = 900000000000508004 -- GB Language Refset
11 | AND rs.acceptabilityId = 900000000000548007; -- Preferred Acceptability
--------------------------------------------------------------------------------
/mysql-loader-with-optimized-views/mysql_examples/SQL_Queries_for_Webinar/1b_Preferred_Term_from view.sql:
--------------------------------------------------------------------------------
1 | --
2 | -- Find the Preferred Term of subtypes of the concept with id “80146002”
3 | -- Uses SNAPSHOT view of preferred synonyms
4 | --
5 | SELECT conceptId, term
6 | FROM snap_pref
7 | WHERE conceptId = 80146002;
--------------------------------------------------------------------------------
/mysql-loader-with-optimized-views/mysql_examples/SQL_Queries_for_Webinar/2_ECL_Simple.sql:
--------------------------------------------------------------------------------
1 | --
2 | -- Find the lung disorders
3 | -- Expression Constraint: < 19829001 |disorder of lung|
4 | --
5 | SELECT tc.subtypeId, pt.term -- select these columns
6 | FROM snap_transclose as tc, snap_pref as pt -- from snapshot transitive closure table and snapshot of preferred terms
7 | WHERE tc.supertypeId = 19829001 -- where the value in the transitive closure supertype column is equal to this SCTID
8 | AND pt.conceptId = tc.subtypeId -- and the value in preferred term conceptId column is equal to the value in the trasitive closure subtypeId column
9 | ORDER BY pt.term -- sort alphabetically by preferred term
--------------------------------------------------------------------------------
/mysql-loader-with-optimized-views/mysql_examples/SQL_Queries_for_Webinar/3_ECL_with_Refinement1.sql:
--------------------------------------------------------------------------------
1 | --
2 | -- Find the lung disorders with an associated morphology equal to edema
3 | -- Expression Constraint: < 19829001 |disorder of lung|: 116676008 |associated morphology| = 79654002 |edema|
4 | --
5 | SELECT tc.subtypeId, pt.term
6 | FROM snap_transclose as tc,
7 | snap_pref as pt
8 | WHERE tc.supertypeId = 19829001
9 | AND pt.conceptId = tc.subtypeId
10 | AND tc.subtypeId IN
11 | (SELECT sourceId FROM snap_relationship as r
12 | WHERE r.active = 1 AND r.typeId = 116676008 -- |associated morphology|
13 | AND r.destinationId = 79654002) -- |edema|
14 | ORDER BY pt.term
--------------------------------------------------------------------------------
/mysql-loader-with-optimized-views/mysql_examples/SQL_Queries_for_Webinar/4_ECL_with_Refinement2.sql:
--------------------------------------------------------------------------------
1 | --
2 | -- Find the lung disorders with an associated morphology of edema (or subtype)
3 | -- Expression Constraint: < 19829001 |disorder of lung|:
4 | -- 116676008 |associated morphology| = << 79654002 |edema|
5 | --
6 | SELECT tc.subtypeId, pt.term
7 | FROM snap_transclose as tc, snap_pref as pt
8 | WHERE tc.supertypeId = 19829001
9 | AND pt.conceptId = tc.subtypeId
10 | AND tc.subtypeId IN
11 | (SELECT sourceId FROM snap_relationship as r
12 | WHERE r.active = 1 AND r.typeId = 116676008
13 | AND (r.destinationId = 79654002
14 | OR r.destinationId IN -- or any descendants of edema
15 | (SELECT tc1.subtypeID
16 | FROM snap_transclose as tc1
17 | WHERE tc1.supertypeId = 79654002)))
18 | ORDER BY pt.term
19 |
20 |
21 |
22 |
23 |
24 |
--------------------------------------------------------------------------------
/mysql-loader-with-optimized-views/mysql_examples/SQL_Queries_for_Webinar/5_ECL_with_Refinement3.sql:
--------------------------------------------------------------------------------
1 | --
2 | -- Find the clinical findings with a finding site of pulmonary valve (or subtype) and an
3 | -- associated morphology of stenosis (or subtype)
4 | -- Expression Constraint: < 404684003 |clinical finding|:
5 | -- 363698007 |finding site| = << 39057004 |pulmonary valve|,
6 | -- 116676008 |associated morphology| = << 415582006 |stenosis|
7 | --
8 | SELECT tc.subtypeId, pt.term
9 | FROM snap_transclose as tc, snap_pref as pt
10 | WHERE tc.supertypeId = 404684003 AND pt.conceptId = tc.subtypeId
11 |
12 | AND tc.subtypeId IN (SELECT sourceId FROM snap_relationship as r
13 | WHERE r.active = 1 AND r.typeId = 363698007
14 | AND (r.destinationId = 39057004 OR r.destinationId IN
15 | (SELECT tc1.subtypeID FROM snap_transclose as tc1
16 | WHERE tc1.supertypeId = 39057004 )))
17 |
18 | AND tc.subtypeId IN (SELECT sourceId FROM snap_relationship as r
19 | WHERE r.active = 1 AND r.typeId = 116676008
20 | AND (r.destinationId = 415582006 OR r.destinationId IN
21 | (SELECT tc2.subtypeID FROM snap_transclose as tc2
22 | WHERE tc2.supertypeId = 415582006 )))
23 | ORDER BY pt.term
--------------------------------------------------------------------------------
/mysql-loader-with-optimized-views/mysql_examples/SQL_Queries_for_Webinar/6_ECL_with_Refinement3_using_EclQuery.sql:
--------------------------------------------------------------------------------
1 | CALL `eclQuery`('<404684003:363698007=<<39057004,116676008=<<415582006');
2 |
--------------------------------------------------------------------------------
/mysql-loader-with-optimized-views/mysql_examples/SQL_Queries_for_Webinar/7_Subtypes_of_two_concepts_using_intersection.sql:
--------------------------------------------------------------------------------
1 | -- Expression Constraint
2 | -- < 107907001 | Operative procedure on digestive system |
3 | -- AND < 363687006 | Endoscopic procedure |
4 |
5 | -- Show preferred term for 107907001
6 | SELECT conceptId, term
7 | FROM snap_pref
8 | WHERE conceptId = 107907001;
9 |
10 | -- Show preferred term for 363687006
11 | SELECT conceptId, term
12 | FROM snap_pref
13 | WHERE conceptId = 363687006;
14 |
15 | -- Show subtypes of both concepts
16 | SELECT tc.subtypeId, pt.term
17 | FROM snap_transclose as tc,snap_transclose as tc2, snap_pref as pt
18 | WHERE tc.supertypeId = 107907001 -- | Operative procedure on digestive system |
19 | AND pt.conceptId = tc.subtypeId
20 | AND tc2.supertypeId = 363687006 -- | Endoscopic procedure |
21 | AND pt.conceptId = tc2.subtypeId
22 | ORDER BY pt.term;
23 |
24 |
--------------------------------------------------------------------------------
/mysql-loader-with-optimized-views/mysql_examples/SQL_Queries_for_eBook/01_Release_Types.sql:
--------------------------------------------------------------------------------
1 | SELECT * FROM full_concept -- show all rows from snapshot concept table
2 | where id=1427008; -- provide concept SCTID
3 |
4 | SELECT * FROM snap_concept -- show all rows from snapshot concept table
5 | where id=1427008; -- provide concept SCTID
--------------------------------------------------------------------------------
/mysql-loader-with-optimized-views/mysql_examples/SQL_Queries_for_eBook/02_Descriptions.sql:
--------------------------------------------------------------------------------
1 | select * from snap_description -- only interested in descriptions from the current release (snapshot)
2 | where conceptId=80146002 -- provide concept SCTID
3 | and active=1; -- only looking for active descriptions
--------------------------------------------------------------------------------
/mysql-loader-with-optimized-views/mysql_examples/SQL_Queries_for_eBook/03_Language_Preferences.sql:
--------------------------------------------------------------------------------
1 | SELECT d.* -- select all columns
2 | FROM (snap_description d -- from the snapshot description table
3 | JOIN snap_refset_Language lr ON d.id = lr.referencedComponentId) -- join the snapshot description table (id column) with the snapshot language reference set (referencedComponentId column)
4 | WHERE d.active = 1 AND lr.active = 1 -- only interested in active rows from these tables
5 | AND d.conceptId = 80146002 -- provide concept SCTID
6 | AND d.typeId = 900000000000013009 -- description type is synonym (as opposed to FSN)
7 | AND lr.refSetId = 900000000000509007 -- specify langauge refset 900000000000509007 (US) or 900000000000508004 (GB)
8 | AND lr.acceptabilityId = 900000000000548007; -- specify that we are looking for the preferred synonym
9 |
10 | SELECT d.* -- select all columns
11 | FROM (snap_description d -- from the snapshot description table
12 | JOIN snap_refset_Language lr ON d.id = lr.referencedComponentId) -- join the snapshot description table (id column) with the snapshot language reference set (referencedComponentId column)
13 | WHERE d.active = 1 AND lr.active = 1 -- only interested in active rows from these tables
14 | AND d.conceptId = 80146002 -- provide concept SCTID
15 | AND d.typeId = 900000000000013009 -- description type is synonym (as opposed to FSN)
16 | AND lr.refSetId = 900000000000508004 -- specify langauge refset 900000000000509007 (US) or 900000000000508004 (GB)
17 | AND lr.acceptabilityId = 900000000000548007; -- specify that we are looking for the preferred synonym
--------------------------------------------------------------------------------
/mysql-loader-with-optimized-views/mysql_examples/SQL_Queries_for_eBook/04_Relationships.sql:
--------------------------------------------------------------------------------
1 | select * from snap_rel_pref -- snap_rel_pref is a view which conatins a snapshot view of all active relationships with their preferred terms
2 | where src_id=80146002; -- provide concept SCTID
--------------------------------------------------------------------------------
/mysql-loader-with-optimized-views/mysql_examples/SQL_Queries_for_eBook/05_Term_Searches.sql:
--------------------------------------------------------------------------------
1 | --
2 | -- Find the active concepts with an 'acceptable' or 'preferred' synonym
3 | -- containing the words “disorder” and “lung”
4 | --
5 | SELECT conceptId, term -- select specific columns
6 | FROM snap_synall -- from view snap_synall which is a snapshot of all active synonyms
7 | WHERE MATCH (term) AGAINST -- look in the term column
8 | ('+disorder +lung' IN BOOLEAN MODE) -- must include both term1 and term2
9 | AND conceptId IN (SELECT id -- conceptId
10 | FROM snap_concept -- from snapshot concept table
11 | WHERE active = 1) -- only interested active concepts
12 | ORDER BY length (term) -- order the results such that shortest appear first
--------------------------------------------------------------------------------
/mysql-loader-with-optimized-views/mysql_examples/conceptInactivations.sql:
--------------------------------------------------------------------------------
1 | -- The following three queries return information about concept inactivations in last three releases
2 | SELECT * FROM delta_inactive_concepts;
3 | SELECT * FROM delta1_inactive_concepts;
4 | SELECT * FROM delta2_inactive_concepts;
5 | -- The following query return historical information about all inactive concepts in the current snapshot
6 | SELECT * FROM delta2_inactive_concepts;
--------------------------------------------------------------------------------
/mysql-loader-with-optimized-views/mysql_examples/descriptionInactivations.sql:
--------------------------------------------------------------------------------
1 | -- The following three queries return information about description inactivations in last three releases
2 | SELECT * FROM delta_inactive_descriptions;
3 | SELECT * FROM delta1_inactive_descriptions;
4 | SELECT * FROM delta2_inactive_descriptions;
5 | -- The following query return historical information about all inactive descriptions in the current snapshot
6 | SELECT * FROM snap_inactive_descriptions;
--------------------------------------------------------------------------------
/mysql-loader-with-optimized-views/mysql_examples/ecl_example1.sql:
--------------------------------------------------------------------------------
1 | I have looked at your questions, and I hope that the following will clarify your questions:
2 |
3 |
4 | 1) It is uncommon that you specify the |is a| attribute for the purpose of creating a postcoordinated expression. You would specify the supertypes of a concept when you author a new concept, for example, if you were creating an extension concept. In your situation, where you want to represent the left and right tendon of forearm and hand respectively, I suggest that you simply do it as follows:
5 |
6 | 360496004 |Structure of tendon of forearm and/or hand (body structure)|: 272741003 |Laterality (attribute)|= 24028007 |Right (qualifier value)|
7 | 360496004 |Structure of tendon of forearm and/or hand (body structure)|: 272741003 |Laterality (attribute)|= 24028007 |Right (qualifier value)|
8 | Note:
9 | It is not correct to state that 360496004 |Structure of tendon of forearm and/or hand (body structure)|: 116680003 |Is a (attribute)|= 71685008 |Structure of common tendon (body structure)|, because when you look in the browser the concept 360496004 |Structure of tendon of forearm and/or hand| is NOT subsumed by |Structure of common tendon|
10 | You can confirm this using the following expression constraint: < 71685008 AND 360496004 - this query will return no results because there is no conjunction between < 71685008 and 360496004. Had 360496004 been a subtype of 71685008, then the concept 360496004 would have been returned. This is an easy way for you to check the subsumption relationship between two concepts using ECL.
11 | Remember that when adding laterality to a body structure, you should confirm that the concept is a member of the 723264001 |Lateralizable body structure reference set (foundation metadata concept)| as this refset includes all concepts where you can apply a laterality
12 | You can confirm that the concept in focus is included in the refset using this expression constraint: ^ 723264001 |Lateralizable body structure reference set| AND 360496004 - as you can see it is okay to apply laterality to this concept.
13 | 2 and 3) I am afraid I need some more detail to answer. First, can you explain to me what meaning you are trying to represent through this expression? I can't figure out what term or concept you would map to that expression... If you send me some detail, I will forward that to our Anatomy expert to have him help with the correct expression for that meaning.
14 |
15 | Furthermore, the expression you ask about is syntactically okay (you can test that here: apg.ihtsdotools.org). I.e. the syntax supports nested expressions like the expression you use for the attribute value (see the last example on this page: https://confluence.ihtsdotools.org/display/DOCECL/6.7+Nested+Expression+Constraints). When you look in the Editorial Guide or the MRCM refsets, you find that the range for the |Systemic part of| attribute is << 123037004 |Body structure (body structure)|, and the reason why the self-built parser fails, is probably that the target, in this case, is not a precoordinated concept which is a subtype of |Body structure|, but the expression (71685008 |Structure of common tendon (body structure)|:272741003 |Laterality (attribute)|=7771000 |Left (qualifier value)|). This expression represents a body structure, and you can therefore argue that the expression conform to the concept model as well. However, as the concept model for anatomy is not yet applied to International content, I would recommend that you don't use the |Systemic part of| attribute for postcoordination - at least until we start to release content with these attributes, and the concept model for this hierarchy is more stable. It is perfectly fine to create expressions for lateralized body structures - but for more advanced body structures, you should rather request for content to be added as pre-coordinated concepts in the International Edition than creating the meanings yourself.
16 |
17 | 4) Wrt. parsers, and here I assume that you are looking for a parser, which also validates whether the expression conforms to the concept model - and not only the syntax... Then, I am afraid I am not aware of systems that allow you to construct and validate postcoordinated expressions. I agree, it would be a very useful system to have for implementers that support postcoordination.
18 |
19 | 5) With respect to the difference between stated and inferred view, you are correct:
20 | Stated view:
21 | This view shows the supertypes and defining relationships that are manually assigned by the author.
22 | Inferred view:
23 | The inferred view shows the classified definition of a concept, including the inferred supertypes and additional defining properties.
24 | Different types of inferred views exist, which can be used for different purposes, and these different types of inferred views differ in terms of the amount of redundancy.
25 | In the SNOMED International Browser, the Inferred view includes redundant defining properties, but it does not include redundant |is a| relationships.
26 |
27 |
--------------------------------------------------------------------------------
/mysql-loader-with-optimized-views/mysql_examples/map_view.sql:
--------------------------------------------------------------------------------
1 | -- CREATE ICD-10 MAP VIEW
2 | DROP VIEW IF EXISTS snap_extendedMapView;
3 | CREATE VIEW snap_extendedMapView AS
4 | SELECT id, effectiveTime, active, moduleId, refsetId,
5 | referencedComponentId, (SELECT term FROM snap_pref WHERE conceptId=m.referencedComponentId) Term,
6 | mapGroup, mapPriority, mapRule, mapAdvice, mapTarget,
7 | correlationId, (SELECT term FROM snap_pref WHERE conceptId=m.correlationId) correlationTerm,
8 | mapCategoryId, (SELECT term FROM snap_pref WHERE conceptId=m.mapCategoryId) mapCategoryTerm
9 | FROM snap_refset_extendedmap m
10 | WHERE refsetId=447562003 -- MODIFY THIS CODE FOR OTHER MAPS USING SAME REFSET TYPE (e.g. ICD-10-CM 6011000124106, ICPC 450993002)
11 | AND active=1
12 | ORDER BY referencedComponentId,mapGroup,mapPriority;
13 |
14 | -- ICD-10 MAP EXAMPLE 1: SIMPLE
15 | -- 74400008|Appendicitis|
16 | SELECT * FROM snap_extendedMapView WHERE referencedComponentId=74400008;
17 |
18 | -- ICD-10 MAP EXAMPLE 2: TWO MAP GROUPS
19 | -- 196607008|Esophageal ulcer due to aspirin|
20 | SELECT * FROM snap_extendedMapView WHERE referencedComponentId=196607008;
21 |
22 | -- ICD-10 MAP EXAMPLE 3: AGE BASED RULE
23 | -- 32398004|Bronchitis|
24 | SELECT * FROM snap_extendedMapView WHERE referencedComponentId=32398004;
25 |
26 | -- ICD-10 MAP EXAMPLE 4: GENDER BASED RULE
27 | -- 8619003|Infertility|
28 | SELECT * FROM snap_extendedMapView WHERE referencedComponentId=8619003;
29 |
30 | -- ICD-10 MAP EXAMPLE 5: EXTERNAL CAUSES
31 | -- 111613008|Closed skull fracture with intracranial injury|
32 | SELECT * FROM snap_extendedMapView WHERE referencedComponentId=111613008;
33 |
--------------------------------------------------------------------------------
/mysql-loader-with-optimized-views/mysql_examples/search_example1.sql:
--------------------------------------------------------------------------------
1 | CALL snap_SearchPlus('+mitral +valve','<404684003');
2 | CALL snap_SearchPlus('+mitral +valve',' `
8 |
9 | eg `./rf1_load_release.sh ~/Backup/SnomedCT_RF1Release_INT_20150731.zip rf1_20150731`
10 |
11 | ## Issues
12 |
13 | If you see the following error: ERROR 1148 (42000) at line 2 in file: 'tmp_rf1_loader.sql': The used command is not allowed with this MySQL version
14 |
15 | This is a security feature of MYSQL to prevent local files being loaded. The script includes an argument of "--local-infile" when starting the client application, but this must also be permitted in the server configuration (eg /usr/local/etc/my.cnf which you may need to create. Type mysql --help for a list of expected config locations). Add the following block to your mysql config file: `[mysql] local-infile=1`
16 |
17 | See
18 |
19 | ## Notes
20 |
21 | - The script will add the tables to an existing schema, replacing any RF1 tables already present.
22 |
23 | ## Example output
24 |
25 | `...`
26 |
27 | ` ``` ...
28 |
29 | inflating: tmp_rf1_extracted/res1_WordKeyIndex_Concepts-en-US_INT_20150731.txt
30 |
31 | inflating: tmp_rf1_extracted/res1_WordKeyIndex_Descriptions-en-US_INT_20150731.txt
32 |
33 | Generating RF1 loading script for 20150731
34 |
35 | Passing tmp_rf1_loader.sql to MYSQL
36 |
37 | Loaded sct1_Concepts_Core_INT_20150731.txt into rf1_concept
38 |
39 | Loaded sct1_Descriptions_en_INT_20150731.txt into rf1_description
40 |
41 | Loaded sct1_References_Core_INT_20150731.txt into rf1_reference
42 |
43 | Loaded sct1_Relationships_Core_INT_20150731.txt into rf1_relationship
44 |
45 | Loaded sct1_TextDefinitions_en-US_INT_20150731.txt into rf1_textdefinition
46 |
47 | Loaded der1_CrossMapSets_ICDO_INT_20150731.txt into rf1_xmapset
48 |
49 | Loaded der1_CrossMapTargets_ICDO_INT_20150731.txt into rf1_xmaptarget
50 |
51 | Loaded der1_CrossMaps_ICDO_INT_20150731.txt into rf1_xmap
52 |
53 | Loaded der1_CrossMapSets_ICD9_INT_20150731.txt into rf1_xmapset
54 |
55 | Loaded der1_CrossMapTargets_ICD9_INT_20150731.txt into rf1_xmaptarget
56 |
57 | Loaded der1_CrossMaps_ICD9_INT_20150731.txt into rf1_xmap
58 |
59 | Loaded der1_Subsets_en-GB_INT_20150731.txt into rf1_subset
60 |
61 | Loaded der1_Subsets_en-US_INT_20150731.txt into rf1_subset
62 |
63 | Loaded der1_SubsetMembers_en-GB_INT_20150731.txt into rf1_subsetmember
64 |
65 | Loaded der1_SubsetMembers_en-US_INT_20150731.txt into rf1_subsetmember
66 |
67 | Loaded res1_StatedRelationships_Core_INT_20150731.txt into rf1_stated_relationship
68 |
69 | Loaded sct1_ComponentHistory_Core_INT_20150731.txt into rf1_componenthistory ` `` `
70 |
71 | ``
72 |
--------------------------------------------------------------------------------
/rf1/rf1_environment_mysql.sql:
--------------------------------------------------------------------------------
1 | /* create the RF1 data tables */
2 |
3 | drop table if exists rf1_concept;
4 | create table rf1_concept(
5 | CONCEPTID VARCHAR (18) NOT NULL,
6 | CONCEPTSTATUS TINYINT (2) UNSIGNED NOT NULL,
7 | FULLYSPECIFIEDNAME VARCHAR (255) CHARACTER SET utf8 COLLATE utf8_bin NOT NULL,
8 | CTV3ID BINARY (5) NOT NULL,
9 | SNOMEDID VARBINARY (8) NOT NULL,
10 | ISPRIMITIVE TINYINT (1) UNSIGNED NOT NULL,
11 | SOURCE BINARY (4) NOT NULL,
12 | key idx_id(CONCEPTID)
13 | ) engine=myisam default charset=utf8;
14 |
15 |
16 | drop table if exists rf1_description;
17 | create table rf1_description(
18 | DESCRIPTIONID VARCHAR (18) NOT NULL,
19 | DESCRIPTIONSTATUS TINYINT (2) UNSIGNED NOT NULL,
20 | CONCEPTID VARCHAR (18) NOT NULL,
21 | TERM VARCHAR (255) CHARACTER SET utf8 COLLATE utf8_bin NOT NULL,
22 | INITIALCAPITALSTATUS TINYINT (1) UNSIGNED NOT NULL,
23 | DESCRIPTIONTYPE TINYINT (1) UNSIGNED NOT NULL,
24 | DEFAULTDESCTYPE TINYINT (1) UNSIGNED NOT NULL,
25 | LANGUAGECODE VARBINARY (8) NOT NULL,
26 | SOURCE BINARY(4) NOT NULL,
27 | key idx_id(DESCRIPTIONID),
28 | key idx_status(DESCRIPTIONSTATUS)
29 | ) engine=myisam default charset=utf8;
30 |
31 | drop table if exists rf1_textdefinition;
32 | create table rf1_textdefinition(
33 | CONCEPTID VARCHAR (18) NOT NULL,
34 | SNOMEDID VARBINARY (8) NOT NULL,
35 | FULLYSPECIFIEDNAME VARCHAR (255) CHARACTER SET utf8 COLLATE utf8_bin NOT NULL,
36 | DEFINITION VARCHAR (450) CHARACTER SET utf8 COLLATE utf8_bin NOT NULL,
37 | key idx_id(SNOMEDID)
38 | ) engine=myisam default charset=utf8;
39 |
40 | drop table if exists rf1_relationship;
41 | create table rf1_relationship(
42 | RELATIONSHIPID VARCHAR (18) NOT NULL,
43 | CONCEPTID1 VARCHAR (18) NOT NULL,
44 | RELATIONSHIPTYPE VARCHAR (18) NOT NULL,
45 | CONCEPTID2 VARCHAR (18) NOT NULL,
46 | CHARACTERISTICTYPE TINYINT (1) UNSIGNED NOT NULL,
47 | REFINABILITY TINYINT (1) UNSIGNED NOT NULL,
48 | RELATIONSHIPGROUP TINYINT (2) UNSIGNED NOT NULL,
49 | SOURCE BINARY (4) NOT NULL,
50 | key idx_id(RELATIONSHIPID)
51 | ) engine=myisam default charset=utf8;
52 |
53 | drop table if exists rf1_stated_relationship;
54 | create table rf1_stated_relationship(
55 | RELATIONSHIPID VARCHAR (18) NOT NULL,
56 | CONCEPTID1 VARCHAR (18) NOT NULL,
57 | RELATIONSHIPTYPE VARCHAR (18) NOT NULL,
58 | CONCEPTID2 VARCHAR (18) NOT NULL,
59 | CHARACTERISTICTYPE TINYINT (1) UNSIGNED NOT NULL,
60 | REFINABILITY TINYINT (1) UNSIGNED NOT NULL,
61 | RELATIONSHIPGROUP TINYINT (2) UNSIGNED NOT NULL,
62 | SOURCE BINARY (4) NOT NULL,
63 | key idx_id(RELATIONSHIPID)
64 | ) engine=myisam default charset=utf8;
65 |
66 | DROP TABLE IF EXISTS rf1_subset;
67 | CREATE TABLE rf1_subset (
68 | SubsetId VARCHAR (18) NOT NULL,
69 | SubsetOriginalID VARCHAR (18) NOT NULL,
70 | SubsetVersion VARBINARY(4) NOT NULL,
71 | SubsetName VARCHAR(255) CHARACTER SET utf8 COLLATE utf8_bin NOT NULL,
72 | SubsetType TINYINT (1) UNSIGNED NOT NULL,
73 | LanguageCode VARBINARY(5),
74 | SubsetRealmID VARBINARY (10) NOT NULL,
75 | ContextID TINYINT (1) UNSIGNED NOT NULL
76 | );
77 |
78 | DROP TABLE IF EXISTS rf1_subsetmember;
79 | CREATE TABLE rf1_subsetmember (
80 | SubsetId VARCHAR (18) NOT NULL,
81 | MemberID VARCHAR (18) NOT NULL,
82 | MemberStatus TINYINT (1) UNSIGNED NOT NULL,
83 | LinkedID VARCHAR(18) CHARACTER SET latin1 COLLATE latin1_general_ci
84 | );
85 |
86 | DROP TABLE IF EXISTS rf1_reference;
87 | CREATE TABLE rf1_reference(
88 | COMPONENTID VARCHAR (18) NOT NULL,
89 | REFERENCETYPE TINYINT (1) NOT NULL,
90 | REFERENCEDID VARCHAR (18) NOT NULL,
91 | SOURCE BINARY (4) NOT NULL
92 | );
93 |
94 | DROP TABLE IF EXISTS rf1_componenthistory;
95 | CREATE TABLE rf1_componenthistory(
96 | COMPONENTID VARCHAR (18) NOT NULL,
97 | RELEASEVERSION BINARY (8) NOT NULL,
98 | CHANGETYPE TINYINT (1) NOT NULL,
99 | STAT TINYINT (1) NOT NULL,
100 | REASON VARCHAR(255) CHARACTER SET latin1 COLLATE latin1_general_ci NOT NULL,
101 | SOURCE BINARY(4) NOT NULL
102 | );
103 |
--------------------------------------------------------------------------------
/rf1/rf1_load_release.sh:
--------------------------------------------------------------------------------
1 | #!/bin/bash
2 | set -e;
3 |
4 | releasePath=$1
5 | dbName=$2
6 |
7 | if [ -z ${dbName} ]
8 | then
9 | echo "Usage "
10 | exit -1
11 | fi
12 |
13 | dbUsername=root
14 | echo "Enter database username [$dbUsername]:"
15 | read newDbUsername
16 | if [ -n "$newDbUsername" ]
17 | then
18 | dbUsername=$newDbUsername
19 | fi
20 |
21 | dbUserPassword=""
22 | echo "Enter database password (or return for none):"
23 | read newDbPassword
24 | if [ -n "$newDbPassword" ]
25 | then
26 | dbUserPassword="-p${newDbPassword}"
27 | fi
28 |
29 | #Unzip the files here, junking the structure
30 | localExtract="tmp_rf1_extracted"
31 | rm -rf $localExtract
32 | generatedScript="tmp_rf1_loader.sql"
33 | unzip -j ${releasePath} -d ${localExtract} || true
34 |
35 | #Determine the release date from the filenames
36 | releaseDate=`ls -1 ${localExtract}/*.txt | head -1 | egrep -o '[0-9]{8}'`
37 |
38 | function addLoadScript() {
39 | fileName=${1/DATE/${releaseDate}}
40 | tableName=${2}
41 |
42 | #Check file exists - try beta version if not
43 | if [ ! -f ${localExtract}/${fileName} ]; then
44 | origFilename=${fileName}
45 | fileName="x${fileName}"
46 | if [ ! -f ${localExtract}/${fileName} ]; then
47 | echo "Unable to find ${origFilename} or beta version - skipping load"
48 | return
49 | fi
50 | fi
51 |
52 | echo "load data local" >> ${generatedScript}
53 | echo -e "\tinfile '"${localExtract}/${fileName}"'" >> ${generatedScript}
54 | echo -e "\tinto table ${tableName}" >> ${generatedScript}
55 | echo -e "\tcolumns terminated by '\\\t'" >> ${generatedScript}
56 | echo -e "\tlines terminated by '\\\r\\\n'" >> ${generatedScript}
57 | echo -e "\tignore 1 lines;" >> ${generatedScript}
58 | echo "" >> ${generatedScript}
59 | echo -e "select 'Loaded ${fileName} into ${tableName}' as ' ';" >> ${generatedScript}
60 | echo "" >> ${generatedScript}
61 | }
62 |
63 | echo "Generating RF1 loading script for $releaseDate"
64 | echo "/* Generated Loader Script */" > ${generatedScript}
65 | addLoadScript sct1_Concepts_Core_INT_DATE.txt rf1_concept
66 | addLoadScript sct1_Descriptions_en_INT_DATE.txt rf1_description
67 | addLoadScript sct1_References_Core_INT_DATE.txt rf1_reference
68 | addLoadScript sct1_Relationships_Core_INT_DATE.txt rf1_relationship
69 | addLoadScript sct1_TextDefinitions_en-US_INT_DATE.txt rf1_textdefinition
70 |
71 | addLoadScript der1_Subsets_en-GB_INT_DATE.txt rf1_subset
72 | addLoadScript der1_Subsets_en-US_INT_DATE.txt rf1_subset
73 | addLoadScript der1_SubsetMembers_en-GB_INT_DATE.txt rf1_subsetmember
74 | addLoadScript der1_SubsetMembers_en-US_INT_DATE.txt rf1_subsetmember
75 |
76 | addLoadScript res1_StatedRelationships_Core_INT_DATE.txt rf1_stated_relationship
77 | addLoadScript sct1_ComponentHistory_Core_INT_DATE.txt rf1_componenthistory
78 |
79 |
80 | echo "Passing $generatedScript to MYSQL"
81 |
82 | #Unlike the RF2 script, we will not wipe the database by default
83 | mysql -u ${dbUsername} ${dbUserPassword} ${dbName} --local-infile << EOF
84 | create database IF NOT EXISTS ${dbName};
85 | source rf1_environment_mysql.sql;
86 | source ${generatedScript};
87 | EOF
88 |
89 | rm -rf ${localExtract}
90 |
--------------------------------------------------------------------------------