forked from ehb54/us3_sql
-
Notifications
You must be signed in to change notification settings - Fork 0
/
us3_spectrum_procs.sql
228 lines (175 loc) · 6.9 KB
/
us3_spectrum_procs.sql
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
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
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
--
-- us3_spectrum_procs.sql
--
-- Script to set up the MySQL stored procedures for the US3 system
-- These are related to the spectrum table
-- Run as us3admin
--
DELIMITER $$
-- Verifies that the specified component ID (bufferID, analyteID) exists
DROP FUNCTION IF EXISTS verify_componentID$$
CREATE FUNCTION verify_componentID( p_personGUID CHAR(36),
p_password VARCHAR(80),
p_componentID INT,
p_componentType enum( 'Buffer', 'Analyte' ) )
RETURNS INT
READS SQL DATA
BEGIN
DECLARE count_componentID INT;
CALL config();
SET count_componentID = 0;
SET @US3_LAST_ERRNO = @OK;
SET @US3_LAST_ERROR = '';
IF ( verify_user( p_personGUID, p_password ) = @OK ) THEN
IF ( p_componentType = 'Buffer' ) THEN
SELECT COUNT(*)
INTO count_componentID
FROM buffer
WHERE bufferID = p_componentID;
IF ( count_componentID < 1 ) THEN
SET @US3_LAST_ERRNO = @NO_BUFFER;
SET @US3_LAST_ERROR = CONCAT('MySQL: No buffer with ID ',
p_componentID,
' exists' );
END IF;
ELSE -- p_componentType = 'Analyte'
SELECT COUNT(*)
INTO count_componentID
FROM analyte
WHERE analyteID = p_componentID;
IF ( count_componentID < 1 ) THEN
SET @US3_LAST_ERRNO = @NO_ANALYTE;
SET @US3_LAST_ERROR = CONCAT('MySQL: No analyte with ID ',
p_componentID,
' exists' );
END IF;
END IF;
END IF;
RETURN( @US3_LAST_ERRNO );
END$$
-- Returns the row count of spectrum info associated with p_componentID
DROP FUNCTION IF EXISTS count_spectrum$$
CREATE FUNCTION count_spectrum( p_personGUID CHAR(36),
p_password VARCHAR(80),
p_componentID INT,
p_componentType enum( 'Buffer', 'Analyte' ),
p_opticsType enum( 'Extinction', 'Refraction', 'Fluorescence' ) )
RETURNS INT
READS SQL DATA
BEGIN
DECLARE count_component INT;
CALL config();
SET count_component = 0;
IF ( verify_user( p_personGUID, p_password ) = @OK ) THEN
SELECT COUNT(*)
INTO count_component
FROM spectrum
WHERE componentID = p_componentID
AND componentType = p_componentType
AND opticsType = p_opticsType;
END IF;
RETURN( count_component );
END$$
-- INSERTs a new spectrum value with the specified information
DROP PROCEDURE IF EXISTS new_spectrum$$
CREATE PROCEDURE new_spectrum( p_personGUID CHAR(36),
p_password VARCHAR(80),
p_componentID INT,
p_componentType enum( 'Buffer', 'Analyte' ),
p_opticsType enum( 'Extinction', 'Refraction', 'Fluorescence' ),
p_lambda FLOAT,
p_molarCoefficient FLOAT )
MODIFIES SQL DATA
BEGIN
DECLARE l_componentID INT;
CALL config();
SET @US3_LAST_ERRNO = @OK;
SET @US3_LAST_ERROR = '';
SET @LAST_INSERT_ID = 0;
IF ( verify_componentID( p_personGUID, p_password, p_componentID, p_componentType ) = @OK ) THEN
INSERT INTO spectrum SET
componentID = p_componentID,
componentType = p_componentType,
opticsType = p_opticsType,
lambda = p_lambda,
molarCoefficient = p_molarCoefficient;
SET @LAST_INSERT_ID = LAST_INSERT_ID();
END IF;
SELECT @US3_LAST_ERRNO AS status;
END$$
-- UPDATEs an existing spectrum value with the specified information
DROP PROCEDURE IF EXISTS update_spectrum$$
CREATE PROCEDURE update_spectrum( p_personGUID CHAR(36),
p_password VARCHAR(80),
p_spectrumID INT,
p_componentID INT,
p_componentType enum( 'Buffer', 'Analyte' ),
p_opticsType enum( 'Extinction', 'Refraction', 'Fluorescence' ),
p_lambda FLOAT,
p_molarCoefficient FLOAT )
MODIFIES SQL DATA
BEGIN
DECLARE l_componentID INT;
CALL config();
SET @US3_LAST_ERRNO = @OK;
SET @US3_LAST_ERROR = '';
IF ( verify_componentID( p_personGUID, p_password, p_componentID, p_componentType ) = @OK ) THEN
UPDATE spectrum SET
componentID = p_componentID,
componentType = p_componentType,
opticsType = p_opticsType,
lambda = p_lambda,
molarCoefficient = p_molarCoefficient
WHERE spectrumID = p_spectrumID;
END IF;
SELECT @US3_LAST_ERRNO AS status;
END$$
-- Returns all spectrum info associated with p_componentID
DROP PROCEDURE IF EXISTS get_spectrum$$
CREATE PROCEDURE get_spectrum( p_personGUID CHAR(36),
p_password VARCHAR(80),
p_componentID INT,
p_componentType enum( 'Buffer', 'Analyte' ),
p_opticsType enum( 'Extinction', 'Refraction', 'Fluorescence' ) )
READS SQL DATA
BEGIN
CALL config();
SET @US3_LAST_ERRNO = @OK;
SET @US3_LAST_ERROR = '';
IF ( verify_componentID( p_personGUID, p_password, p_componentID, p_componentType ) != @OK ) THEN
SELECT @US3_LAST_ERRNO AS status;
ELSEIF ( count_spectrum( p_personGUID, p_password, p_componentID, p_componentType, p_opticsType ) < 1 ) THEN
SET @US3_LAST_ERRNO = @NOROWS;
SET @US3_LAST_ERROR = 'MySQL: no rows returned';
SELECT @US3_LAST_ERRNO AS status;
ELSE
-- Ok, we found some spectrum info
SELECT @OK AS status;
SELECT spectrumID, lambda, molarCoefficient
FROM spectrum
WHERE componentID = p_componentID
AND componentType = p_componentType
AND opticsType = p_opticsType
ORDER BY lambda;
END IF;
END$$
-- DELETEs all extinction information associated with a spectrumID
DROP PROCEDURE IF EXISTS delete_spectrum$$
CREATE PROCEDURE delete_spectrum( p_personGUID CHAR(36),
p_password VARCHAR(80),
p_componentID INT,
p_componentType enum( 'Buffer', 'Analyte' ),
p_opticsType enum( 'Extinction', 'Refraction', 'Fluorescence' ) )
MODIFIES SQL DATA
BEGIN
CALL config();
SET @US3_LAST_ERRNO = @OK;
SET @US3_LAST_ERROR = '';
IF ( verify_user( p_personGUID, p_password ) = @OK ) THEN
DELETE FROM spectrum
WHERE componentID = p_componentID
AND componentType = p_componentType
AND opticsType = p_opticsType;
END IF;
SELECT @US3_LAST_ERRNO AS status;
END$$