Mercurial > hg > orthanc
annotate OrthancServer/Sources/Database/PrepareDatabase.sql @ 4832:2e71a08eea15 openssl-3.x
integration mainline->openssl-3.x
author | Sebastien Jodogne <s.jodogne@gmail.com> |
---|---|
date | Thu, 25 Nov 2021 19:02:38 +0100 |
parents | f0038043fb97 7053502fbf97 |
children | 6eff25f70121 |
rev | line source |
---|---|
4124
28944db5318b
adding missing license headers
Sebastien Jodogne <s.jodogne@gmail.com>
parents:
4044
diff
changeset
|
1 -- Orthanc - A Lightweight, RESTful DICOM Store |
28944db5318b
adding missing license headers
Sebastien Jodogne <s.jodogne@gmail.com>
parents:
4044
diff
changeset
|
2 -- Copyright (C) 2012-2016 Sebastien Jodogne, Medical Physics |
28944db5318b
adding missing license headers
Sebastien Jodogne <s.jodogne@gmail.com>
parents:
4044
diff
changeset
|
3 -- Department, University Hospital of Liege, Belgium |
4437
d9473bd5ed43
upgrade to year 2021
Sebastien Jodogne <s.jodogne@gmail.com>
parents:
4124
diff
changeset
|
4 -- Copyright (C) 2017-2021 Osimis S.A., Belgium |
4831
7053502fbf97
added copyright UCLouvain
Sebastien Jodogne <s.jodogne@gmail.com>
parents:
4437
diff
changeset
|
5 -- Copyright (C) 2021-2021 Sebastien Jodogne, ICTEAM UCLouvain, Belgium |
4124
28944db5318b
adding missing license headers
Sebastien Jodogne <s.jodogne@gmail.com>
parents:
4044
diff
changeset
|
6 -- |
28944db5318b
adding missing license headers
Sebastien Jodogne <s.jodogne@gmail.com>
parents:
4044
diff
changeset
|
7 -- This program is free software: you can redistribute it and/or |
28944db5318b
adding missing license headers
Sebastien Jodogne <s.jodogne@gmail.com>
parents:
4044
diff
changeset
|
8 -- modify it under the terms of the GNU General Public License as |
28944db5318b
adding missing license headers
Sebastien Jodogne <s.jodogne@gmail.com>
parents:
4044
diff
changeset
|
9 -- published by the Free Software Foundation, either version 3 of the |
28944db5318b
adding missing license headers
Sebastien Jodogne <s.jodogne@gmail.com>
parents:
4044
diff
changeset
|
10 -- License, or (at your option) any later version. |
28944db5318b
adding missing license headers
Sebastien Jodogne <s.jodogne@gmail.com>
parents:
4044
diff
changeset
|
11 -- |
28944db5318b
adding missing license headers
Sebastien Jodogne <s.jodogne@gmail.com>
parents:
4044
diff
changeset
|
12 -- This program is distributed in the hope that it will be useful, but |
28944db5318b
adding missing license headers
Sebastien Jodogne <s.jodogne@gmail.com>
parents:
4044
diff
changeset
|
13 -- WITHOUT ANY WARRANTY; without even the implied warranty of |
28944db5318b
adding missing license headers
Sebastien Jodogne <s.jodogne@gmail.com>
parents:
4044
diff
changeset
|
14 -- MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the GNU |
28944db5318b
adding missing license headers
Sebastien Jodogne <s.jodogne@gmail.com>
parents:
4044
diff
changeset
|
15 -- General Public License for more details. |
28944db5318b
adding missing license headers
Sebastien Jodogne <s.jodogne@gmail.com>
parents:
4044
diff
changeset
|
16 -- |
28944db5318b
adding missing license headers
Sebastien Jodogne <s.jodogne@gmail.com>
parents:
4044
diff
changeset
|
17 -- You should have received a copy of the GNU General Public License |
28944db5318b
adding missing license headers
Sebastien Jodogne <s.jodogne@gmail.com>
parents:
4044
diff
changeset
|
18 -- along with this program. If not, see <http://www.gnu.org/licenses/>. |
28944db5318b
adding missing license headers
Sebastien Jodogne <s.jodogne@gmail.com>
parents:
4044
diff
changeset
|
19 |
28944db5318b
adding missing license headers
Sebastien Jodogne <s.jodogne@gmail.com>
parents:
4044
diff
changeset
|
20 |
181 | 21 CREATE TABLE GlobalProperties( |
206
4453a010d0db
flush to disk thread
Sebastien Jodogne <s.jodogne@gmail.com>
parents:
203
diff
changeset
|
22 property INTEGER PRIMARY KEY, |
181 | 23 value TEXT |
24 ); | |
25 | |
26 CREATE TABLE Resources( | |
27 internalId INTEGER PRIMARY KEY AUTOINCREMENT, | |
28 resourceType INTEGER, | |
29 publicId TEXT, | |
30 parentId INTEGER REFERENCES Resources(internalId) ON DELETE CASCADE | |
31 ); | |
32 | |
1159
8f9d49192815
speeding up db schema
Sebastien Jodogne <s.jodogne@gmail.com>
parents:
1158
diff
changeset
|
33 CREATE TABLE MainDicomTags( |
1158 | 34 id INTEGER REFERENCES Resources(internalId) ON DELETE CASCADE, |
35 tagGroup INTEGER, | |
36 tagElement INTEGER, | |
37 value TEXT, | |
38 PRIMARY KEY(id, tagGroup, tagElement) | |
39 ); | |
40 | |
1176 | 41 -- The following table was added in Orthanc 0.8.5 (database v5) |
1159
8f9d49192815
speeding up db schema
Sebastien Jodogne <s.jodogne@gmail.com>
parents:
1158
diff
changeset
|
42 CREATE TABLE DicomIdentifiers( |
181 | 43 id INTEGER REFERENCES Resources(internalId) ON DELETE CASCADE, |
44 tagGroup INTEGER, | |
45 tagElement INTEGER, | |
46 value TEXT, | |
47 PRIMARY KEY(id, tagGroup, tagElement) | |
48 ); | |
49 | |
50 CREATE TABLE Metadata( | |
51 id INTEGER REFERENCES Resources(internalId) ON DELETE CASCADE, | |
52 type INTEGER, | |
53 value TEXT, | |
54 PRIMARY KEY(id, type) | |
55 ); | |
56 | |
57 CREATE TABLE AttachedFiles( | |
58 id INTEGER REFERENCES Resources(internalId) ON DELETE CASCADE, | |
197
530a25320461
removal of text as ids in sqlite db
Sebastien Jodogne <s.jodogne@gmail.com>
parents:
192
diff
changeset
|
59 fileType INTEGER, |
181 | 60 uuid TEXT, |
183 | 61 compressedSize INTEGER, |
181 | 62 uncompressedSize INTEGER, |
63 compressionType INTEGER, | |
693
01d8611c4a60
md5 for attached files
Sebastien Jodogne <s.jodogne@gmail.com>
parents:
616
diff
changeset
|
64 uncompressedMD5 TEXT, -- New in Orthanc 0.7.3 (database v4) |
01d8611c4a60
md5 for attached files
Sebastien Jodogne <s.jodogne@gmail.com>
parents:
616
diff
changeset
|
65 compressedMD5 TEXT, -- New in Orthanc 0.7.3 (database v4) |
197
530a25320461
removal of text as ids in sqlite db
Sebastien Jodogne <s.jodogne@gmail.com>
parents:
192
diff
changeset
|
66 PRIMARY KEY(id, fileType) |
181 | 67 ); |
68 | |
183 | 69 CREATE TABLE Changes( |
70 seq INTEGER PRIMARY KEY AUTOINCREMENT, | |
71 changeType INTEGER, | |
189
ccbc2cf64a0d
record main dicom tags and changes
Sebastien Jodogne <s.jodogne@gmail.com>
parents:
183
diff
changeset
|
72 internalId INTEGER REFERENCES Resources(internalId) ON DELETE CASCADE, |
183 | 73 resourceType INTEGER, |
74 date TEXT | |
75 ); | |
76 | |
231 | 77 CREATE TABLE ExportedResources( |
183 | 78 seq INTEGER PRIMARY KEY AUTOINCREMENT, |
231 | 79 resourceType INTEGER, |
80 publicId TEXT, | |
183 | 81 remoteModality TEXT, |
82 patientId TEXT, | |
83 studyInstanceUid TEXT, | |
84 seriesInstanceUid TEXT, | |
85 sopInstanceUid TEXT, | |
86 date TEXT | |
87 ); | |
88 | |
262
2354560daf2f
primitives for recycling patients
Sebastien Jodogne <s.jodogne@gmail.com>
parents:
252
diff
changeset
|
89 CREATE TABLE PatientRecyclingOrder( |
2354560daf2f
primitives for recycling patients
Sebastien Jodogne <s.jodogne@gmail.com>
parents:
252
diff
changeset
|
90 seq INTEGER PRIMARY KEY AUTOINCREMENT, |
2354560daf2f
primitives for recycling patients
Sebastien Jodogne <s.jodogne@gmail.com>
parents:
252
diff
changeset
|
91 patientId INTEGER REFERENCES Resources(internalId) ON DELETE CASCADE |
2354560daf2f
primitives for recycling patients
Sebastien Jodogne <s.jodogne@gmail.com>
parents:
252
diff
changeset
|
92 ); |
2354560daf2f
primitives for recycling patients
Sebastien Jodogne <s.jodogne@gmail.com>
parents:
252
diff
changeset
|
93 |
181 | 94 CREATE INDEX ChildrenIndex ON Resources(parentId); |
95 CREATE INDEX PublicIndex ON Resources(publicId); | |
190 | 96 CREATE INDEX ResourceTypeIndex ON Resources(resourceType); |
262
2354560daf2f
primitives for recycling patients
Sebastien Jodogne <s.jodogne@gmail.com>
parents:
252
diff
changeset
|
97 CREATE INDEX PatientRecyclingIndex ON PatientRecyclingOrder(patientId); |
181 | 98 |
1159
8f9d49192815
speeding up db schema
Sebastien Jodogne <s.jodogne@gmail.com>
parents:
1158
diff
changeset
|
99 CREATE INDEX MainDicomTagsIndex1 ON MainDicomTags(id); |
1176 | 100 -- The 2 following indexes were removed in Orthanc 0.8.5 (database v5), to speed up |
1159
8f9d49192815
speeding up db schema
Sebastien Jodogne <s.jodogne@gmail.com>
parents:
1158
diff
changeset
|
101 -- CREATE INDEX MainDicomTagsIndex2 ON MainDicomTags(tagGroup, tagElement); |
8f9d49192815
speeding up db schema
Sebastien Jodogne <s.jodogne@gmail.com>
parents:
1158
diff
changeset
|
102 -- CREATE INDEX MainDicomTagsIndexValues ON MainDicomTags(value COLLATE BINARY); |
8f9d49192815
speeding up db schema
Sebastien Jodogne <s.jodogne@gmail.com>
parents:
1158
diff
changeset
|
103 |
1176 | 104 -- The 3 following indexes were added in Orthanc 0.8.5 (database v5) |
1159
8f9d49192815
speeding up db schema
Sebastien Jodogne <s.jodogne@gmail.com>
parents:
1158
diff
changeset
|
105 CREATE INDEX DicomIdentifiersIndex1 ON DicomIdentifiers(id); |
8f9d49192815
speeding up db schema
Sebastien Jodogne <s.jodogne@gmail.com>
parents:
1158
diff
changeset
|
106 CREATE INDEX DicomIdentifiersIndex2 ON DicomIdentifiers(tagGroup, tagElement); |
8f9d49192815
speeding up db schema
Sebastien Jodogne <s.jodogne@gmail.com>
parents:
1158
diff
changeset
|
107 CREATE INDEX DicomIdentifiersIndexValues ON DicomIdentifiers(value COLLATE BINARY); |
183 | 108 |
189
ccbc2cf64a0d
record main dicom tags and changes
Sebastien Jodogne <s.jodogne@gmail.com>
parents:
183
diff
changeset
|
109 CREATE INDEX ChangesIndex ON Changes(internalId); |
181 | 110 |
111 CREATE TRIGGER AttachedFileDeleted | |
112 AFTER DELETE ON AttachedFiles | |
113 BEGIN | |
273
d384af918264
more detailed signal about deleted file
Sebastien Jodogne <s.jodogne@gmail.com>
parents:
262
diff
changeset
|
114 SELECT SignalFileDeleted(old.uuid, old.fileType, old.uncompressedSize, |
693
01d8611c4a60
md5 for attached files
Sebastien Jodogne <s.jodogne@gmail.com>
parents:
616
diff
changeset
|
115 old.compressionType, old.compressedSize, |
694
72dc919a028c
upgrade database from v3 to v4
Sebastien Jodogne <s.jodogne@gmail.com>
parents:
693
diff
changeset
|
116 -- These 2 arguments are new in Orthanc 0.7.3 (database v4) |
693
01d8611c4a60
md5 for attached files
Sebastien Jodogne <s.jodogne@gmail.com>
parents:
616
diff
changeset
|
117 old.uncompressedMD5, old.compressedMD5); |
181 | 118 END; |
119 | |
120 CREATE TRIGGER ResourceDeleted | |
121 AFTER DELETE ON Resources | |
122 BEGIN | |
1176 | 123 SELECT SignalResourceDeleted(old.publicId, old.resourceType); -- New in Orthanc 0.8.5 (db v5) |
183 | 124 SELECT SignalRemainingAncestor(parent.publicId, parent.resourceType) |
125 FROM Resources AS parent WHERE internalId = old.parentId; | |
181 | 126 END; |
127 | |
183 | 128 -- Delete a parent resource when its unique child is deleted |
129 CREATE TRIGGER ResourceDeletedParentCleaning | |
130 AFTER DELETE ON Resources | |
131 FOR EACH ROW WHEN (SELECT COUNT(*) FROM Resources WHERE parentId = old.parentId) = 0 | |
132 BEGIN | |
133 DELETE FROM Resources WHERE internalId = old.parentId; | |
134 END; | |
252 | 135 |
262
2354560daf2f
primitives for recycling patients
Sebastien Jodogne <s.jodogne@gmail.com>
parents:
252
diff
changeset
|
136 CREATE TRIGGER PatientAdded |
2354560daf2f
primitives for recycling patients
Sebastien Jodogne <s.jodogne@gmail.com>
parents:
252
diff
changeset
|
137 AFTER INSERT ON Resources |
2354560daf2f
primitives for recycling patients
Sebastien Jodogne <s.jodogne@gmail.com>
parents:
252
diff
changeset
|
138 FOR EACH ROW WHEN new.resourceType = 1 -- "1" corresponds to "ResourceType_Patient" in C++ |
2354560daf2f
primitives for recycling patients
Sebastien Jodogne <s.jodogne@gmail.com>
parents:
252
diff
changeset
|
139 BEGIN |
2354560daf2f
primitives for recycling patients
Sebastien Jodogne <s.jodogne@gmail.com>
parents:
252
diff
changeset
|
140 INSERT INTO PatientRecyclingOrder VALUES (NULL, new.internalId); |
2354560daf2f
primitives for recycling patients
Sebastien Jodogne <s.jodogne@gmail.com>
parents:
252
diff
changeset
|
141 END; |
2354560daf2f
primitives for recycling patients
Sebastien Jodogne <s.jodogne@gmail.com>
parents:
252
diff
changeset
|
142 |
2354560daf2f
primitives for recycling patients
Sebastien Jodogne <s.jodogne@gmail.com>
parents:
252
diff
changeset
|
143 |
252 | 144 -- Set the version of the database schema |
145 -- The "1" corresponds to the "GlobalProperty_DatabaseSchemaVersion" enumeration | |
1668
de1413733c97
reconstructing main dicom tags
Sebastien Jodogne <s.jodogne@gmail.com>
parents:
1176
diff
changeset
|
146 INSERT INTO GlobalProperties VALUES (1, "6"); |