summaryrefslogtreecommitdiffstats
path: root/extra/sql/bulkload/clds-stored-procedures.sql
blob: 112cb2b55e5af9a4c58a9b2ef76c156995742e6c (plain)
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
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
260
261
262
263
264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
285
286
287
288
289
290
291
292
293
294
295
296
297
298
299
300
301
302
303
304
305
306
307
308
309
310
311
312
313
314
315
316
317
318
319
320
321
322
323
324
325
326
327
328
329
330
331
332
333
334
335
336
337
338
339
340
341
342
343
344
345
346
347
348
349
350
351
352
353
354
355
356
357
358
359
360
361
362
363
364
365
366
367
368
369
370
371
372
373
374
375
376
377
378
379
380
381
382
383
384
385
386
387
388
389
390
391
392
393
394
395
396
397
398
399
400
401
402
403
404
405
406
407
408
409
410
411
412
413
414
415
416
417
418
419
420
421
422
423
424
425
426
427
428
429
430
431
432
433
434
435
436
437
438
439
440
441
442
443
444
445
446
447
448
449
#
# CLDS stored procedures
#

USE cldsdb4;

DROP PROCEDURE IF EXISTS upd_event;
DROP PROCEDURE IF EXISTS ins_event;
DROP PROCEDURE IF EXISTS del_all_model_instances;
DROP PROCEDURE IF EXISTS del_model_instance;
DROP PROCEDURE IF EXISTS ins_model_instance;
DROP PROCEDURE IF EXISTS set_model;
DROP PROCEDURE IF EXISTS get_model;
DROP PROCEDURE IF EXISTS get_model_template;
DROP PROCEDURE IF EXISTS set_template;
DROP PROCEDURE IF EXISTS get_template;
DELIMITER //
CREATE PROCEDURE get_template
  (IN v_template_name VARCHAR(80),
   OUT v_template_id VARCHAR(36),
   OUT v_template_bpmn_id VARCHAR(36),
   OUT v_template_bpmn_user_id VARCHAR(80),
   OUT v_template_bpmn_text MEDIUMTEXT,
   OUT v_template_image_id VARCHAR(36),
   OUT v_template_image_user_id VARCHAR(80),
   OUT v_template_image_text MEDIUMTEXT,
   OUT v_template_doc_id VARCHAR(36),
   OUT v_template_doc_user_id VARCHAR(80),
   OUT v_template_doc_text MEDIUMTEXT)
BEGIN
  SELECT t.template_id,
		 tb.template_bpmn_id,
		 tb.user_id,
		 tb.template_bpmn_text,
		 ti.template_image_id,
		 ti.user_id,
		 ti.template_image_text,
		 td.template_doc_id,
		 td.user_id,
		 td.template_doc_text
    INTO v_template_id,
         v_template_bpmn_id,
         v_template_bpmn_user_id,
         v_template_bpmn_text,
         v_template_image_id,
         v_template_image_user_id,
         v_template_image_text,
         v_template_doc_id,
         v_template_doc_user_id,
         v_template_doc_text
    FROM template t,
         template_bpmn tb,
		 template_image ti,
		 template_doc td
    WHERE t.template_bpmn_id = tb.template_bpmn_id
	  AND t.template_image_id = ti.template_image_id
	  AND t.template_doc_id = td.template_doc_id
      AND t.template_name = v_template_name;
END;
CREATE PROCEDURE set_template
  (IN v_template_name VARCHAR(80),
   IN v_user_id VARCHAR(80),
   IN v_template_bpmn_text MEDIUMTEXT,
   IN v_template_image_text MEDIUMTEXT,
   IN v_template_doc_text MEDIUMTEXT,
   OUT v_template_id VARCHAR(36),
   OUT v_template_bpmn_id VARCHAR(36),
   OUT v_template_bpmn_user_id VARCHAR(80),
   OUT v_template_image_id VARCHAR(36),
   OUT v_template_image_user_id VARCHAR(80),
   OUT v_template_doc_id VARCHAR(36),
   OUT v_template_doc_user_id VARCHAR(80))
BEGIN
  DECLARE v_old_template_bpmn_text MEDIUMTEXT;
  DECLARE v_old_template_image_text MEDIUMTEXT;
  DECLARE v_old_template_doc_text MEDIUMTEXT;
  SET v_template_id = NULL;
  CALL get_template(
    v_template_name,
    v_template_id,
    v_template_bpmn_id,
    v_template_bpmn_user_id,
    v_old_template_bpmn_text,
    v_template_image_id,
    v_template_image_user_id,
    v_old_template_image_text,
    v_template_doc_id,
    v_template_doc_user_id,
    v_old_template_doc_text);
  IF v_template_id IS NULL THEN
    BEGIN
	  SET v_template_id = UUID();
      INSERT INTO template
	    (template_id, template_name)
	    VALUES (v_template_id, v_template_name);
	END;
  END IF;
  IF v_template_bpmn_id IS NULL OR v_template_bpmn_text <> v_old_template_bpmn_text THEN
	SET v_template_bpmn_id = UUID();
    INSERT INTO template_bpmn
	  (template_bpmn_id, template_id, template_bpmn_text, user_id)
	  VALUES (v_template_bpmn_id, v_template_id, v_template_bpmn_text, v_user_id);
	SET v_template_bpmn_user_id = v_user_id;
  END IF;
  IF v_template_image_id IS NULL OR v_template_image_text <> v_old_template_image_text THEN
	SET v_template_image_id = UUID();
    INSERT INTO template_image
	  (template_image_id, template_id, template_image_text, user_id)
	  VALUES (v_template_image_id, v_template_id, v_template_image_text, v_user_id);
	SET v_template_image_user_id = v_user_id;
  END IF;
  IF v_template_doc_id IS NULL OR v_template_doc_text <> v_old_template_doc_text THEN
	SET v_template_doc_id = UUID();
    INSERT INTO template_doc
	  (template_doc_id, template_id, template_doc_text, user_id)
	  VALUES (v_template_doc_id, v_template_id, v_template_doc_text, v_user_id);
	SET v_template_doc_user_id = v_user_id;
  END IF;
  UPDATE template
    SET template_bpmn_id = v_template_bpmn_id,
	    template_image_id = v_template_image_id,
	    template_doc_id = v_template_doc_id
    WHERE template_id = v_template_id;
END;
CREATE PROCEDURE get_model
  (IN v_model_name VARCHAR(80),
   OUT v_control_name_prefix VARCHAR(80),
   INOUT v_control_name_uuid VARCHAR(36),
   OUT v_model_id VARCHAR(36),
   OUT v_service_type_id VARCHAR(80),
   OUT v_deployment_id VARCHAR(80),
   OUT v_template_name VARCHAR(80),
   OUT v_template_id VARCHAR(36),
   OUT v_model_prop_id VARCHAR(36),
   OUT v_model_prop_user_id VARCHAR(80),
   OUT v_model_prop_text MEDIUMTEXT,
   OUT v_model_blueprint_id VARCHAR(36),
   OUT v_model_blueprint_user_id VARCHAR(80),
   OUT v_model_blueprint_text MEDIUMTEXT,
   OUT v_event_id VARCHAR(36),
   OUT v_action_cd VARCHAR(80),
   OUT v_action_state_cd VARCHAR(80),
   OUT v_event_process_instance_id VARCHAR(80),
   OUT v_event_user_id VARCHAR(80))
BEGIN
  SELECT m.control_name_prefix,
		 m.control_name_uuid,
		 m.model_id,
		 m.service_type_id,
		 m.deployment_id,
		 t.template_name,
		 m.template_id,
		 mp.model_prop_id,
		 mp.user_id,
		 mp.model_prop_text,
		 mb.model_blueprint_id,
		 mb.user_id,
		 mb.model_blueprint_text,
		 e.event_id,
		 e.action_cd,
		 e.action_state_cd,
		 e.process_instance_id,
		 e.user_id
    INTO v_control_name_prefix,
         v_control_name_uuid,
		 v_model_id,
		 v_service_type_id,
		 v_deployment_id,
		 v_template_name,
         v_template_id,
         v_model_prop_id,
         v_model_prop_user_id,
         v_model_prop_text,
         v_model_blueprint_id,
         v_model_blueprint_user_id,
         v_model_blueprint_text,
         v_event_id,
         v_action_cd,
		 v_action_state_cd,
         v_event_process_instance_id,
         v_event_user_id
    FROM model m,
		 template t,
		 model_properties mp,
		 model_blueprint mb,
		 event e
    WHERE m.template_id = t.template_id
	  AND m.model_prop_id = mp.model_prop_id
	  AND m.model_blueprint_id = mb.model_blueprint_id
	  AND m.event_id = e.event_id
      AND (m.model_name = v_model_name
      OR  m.control_name_uuid = v_control_name_uuid);
    SELECT model_instance_id,
           vm_name,
           location,
           timestamp
    FROM model_instance
    WHERE model_id = v_model_id
    ORDER BY 2;
END;
CREATE PROCEDURE get_model_template
  (IN v_model_name VARCHAR(80),
   OUT v_control_name_prefix VARCHAR(80),
   INOUT v_control_name_uuid VARCHAR(36),
   OUT v_model_id VARCHAR(36),
   OUT v_service_type_id VARCHAR(80),
   OUT v_deployment_id VARCHAR(80),
   OUT v_template_name VARCHAR(80),
   OUT v_template_id VARCHAR(36),
   OUT v_model_prop_id VARCHAR(36),
   OUT v_model_prop_user_id VARCHAR(80),
   OUT v_model_prop_text MEDIUMTEXT,
   OUT v_model_blueprint_id VARCHAR(36),
   OUT v_model_blueprint_user_id VARCHAR(80),
   OUT v_model_blueprint_text MEDIUMTEXT,
   OUT v_template_bpmn_id VARCHAR(36),
   OUT v_template_bpmn_user_id VARCHAR(80),
   OUT v_template_bpmn_text MEDIUMTEXT,
   OUT v_template_image_id VARCHAR(36),
   OUT v_template_image_user_id VARCHAR(80),
   OUT v_template_image_text MEDIUMTEXT,
   OUT v_template_doc_id VARCHAR(36),
   OUT v_template_doc_user_id VARCHAR(80),
   OUT v_template_doc_text MEDIUMTEXT,
   OUT v_event_id VARCHAR(36),
   OUT v_action_cd VARCHAR(80),
   OUT v_action_state_cd VARCHAR(80),
   OUT v_event_process_instance_id VARCHAR(80),
   OUT v_event_user_id VARCHAR(80))
BEGIN
  CALL get_model(
    v_model_name,
    v_control_name_prefix,
    v_control_name_uuid,
    v_model_id,
	v_service_type_id,
	v_deployment_id,
    v_template_name,
    v_template_id,
    v_model_prop_id,
    v_model_prop_user_id,
    v_model_prop_text,
    v_model_blueprint_id,
    v_model_blueprint_user_id,
    v_model_blueprint_text,
	v_event_id,
	v_action_cd,
	v_action_state_cd,
	v_event_process_instance_id,
	v_event_user_id);
  CALL get_template(
    v_template_name,
    v_template_id,
    v_template_bpmn_id,
    v_template_bpmn_user_id,
    v_template_bpmn_text,
    v_template_image_id,
    v_template_image_user_id,
    v_template_image_text,
    v_template_doc_id,
    v_template_doc_user_id,
    v_template_doc_text);
  END;
CREATE PROCEDURE set_model
  (IN v_model_name VARCHAR(80),
   IN v_template_id VARCHAR(36),
   IN v_user_id VARCHAR(80),
   IN v_model_prop_text MEDIUMTEXT,
   IN v_model_blueprint_text MEDIUMTEXT,
   IN v_service_type_id VARCHAR(80),
   IN v_deployment_id VARCHAR(80),
   INOUT v_control_name_prefix VARCHAR(80),
   INOUT v_control_name_uuid VARCHAR(36),
   OUT v_model_id VARCHAR(36),
   OUT v_model_prop_id VARCHAR(36),
   OUT v_model_prop_user_id VARCHAR(80),
   OUT v_model_blueprint_id VARCHAR(36),
   OUT v_model_blueprint_user_id VARCHAR(80),
   OUT v_event_id VARCHAR(36),
   OUT v_action_cd VARCHAR(80),
   OUT v_action_state_cd VARCHAR(80),
   OUT v_event_process_instance_id VARCHAR(80),
   OUT v_event_user_id VARCHAR(80))
BEGIN
  DECLARE v_old_template_name VARCHAR(80);
  DECLARE v_old_template_id VARCHAR(36);
  DECLARE v_old_control_name_prefix VARCHAR(80);
  DECLARE v_old_control_name_uuid VARCHAR(36);
  DECLARE v_old_model_prop_text MEDIUMTEXT;
  DECLARE v_old_model_blueprint_text MEDIUMTEXT;
  DECLARE v_old_service_type_id VARCHAR(80);
  DECLARE v_old_deployment_id VARCHAR(80);
  SET v_model_id = NULL;
  CALL get_model(
    v_model_name,
    v_old_control_name_prefix,
    v_old_control_name_uuid,
    v_model_id,
	v_old_service_type_id,
	v_old_deployment_id,
    v_old_template_name,
    v_old_template_id,
    v_model_prop_id,
    v_model_prop_user_id,
    v_old_model_prop_text,
    v_model_blueprint_id,
    v_model_blueprint_user_id,
    v_old_model_blueprint_text,
	v_event_id,
	v_action_cd,
	v_action_state_cd,
	v_event_process_instance_id,
	v_event_user_id);
  IF v_model_id IS NULL THEN
    BEGIN
      # UUID can be provided initially but cannot be updated
	  # if not provided (this is expected) then it will be set here
      IF v_control_name_uuid IS NULL THEN
	    SET v_control_name_uuid = UUID();
	  END IF;
      SET v_model_id = v_control_name_uuid;
      INSERT INTO model
	    (model_id, model_name, template_id, control_name_prefix, control_name_uuid, service_type_id, deployment_id)
	    VALUES (v_model_id, v_model_name, v_template_id, v_control_name_prefix, v_control_name_uuid, v_service_type_id, v_deployment_id);
	  # since just created model, insert CREATED event as initial default event
	  SET v_action_cd = 'CREATE';
	  SET v_action_state_cd = 'COMPLETED';
	  SET v_event_user_id = v_user_id;
      SET v_event_id = UUID();
      INSERT INTO event
	    (event_id, model_id, action_cd, action_state_cd, user_id)
	    VALUES (v_event_id, v_model_id, v_action_cd, v_action_state_cd, v_event_user_id);
	  UPDATE model
		SET event_id = v_event_id
		WHERE model_id = v_model_id;
	END;
  ELSE
    BEGIN
	  # use old control_name_prefix if null value is provided
      IF v_control_name_prefix IS NULL THEN
	     SET v_control_name_prefix = v_old_control_name_prefix;
	  END IF;
	  # UUID can not be updated after initial insert
	  SET v_control_name_uuid = v_old_control_name_uuid;
	END;
  END IF;
  IF v_model_prop_id IS NULL OR v_model_prop_text <> v_old_model_prop_text THEN
	SET v_model_prop_id = UUID();
    INSERT INTO model_properties
	  (model_prop_id, model_id, model_prop_text, user_id)
	  VALUES (v_model_prop_id, v_model_id, v_model_prop_text, v_user_id);
	SET v_model_prop_user_id = v_user_id;
  END IF;
  IF v_model_blueprint_id IS NULL OR v_model_blueprint_text <> v_old_model_blueprint_text THEN
	SET v_model_blueprint_id = UUID();
    INSERT INTO model_blueprint
	  (model_blueprint_id, model_id, model_blueprint_text, user_id)
	  VALUES (v_model_blueprint_id, v_model_id, v_model_blueprint_text, v_user_id);
	SET v_model_blueprint_user_id = v_user_id;
  END IF;
  UPDATE model
    SET control_name_prefix = v_control_name_prefix,
	    model_prop_id = v_model_prop_id,
	    model_blueprint_id = v_model_blueprint_id,
	    service_type_id = v_service_type_id,
	    deployment_id = v_deployment_id
    WHERE model_id = v_model_id;
END;
CREATE PROCEDURE ins_model_instance
  (IN v_control_name_uuid VARCHAR(36),
   IN v_vm_name VARCHAR(250),
   IN v_location VARCHAR(250),
   OUT v_model_id VARCHAR(36),
   OUT v_model_instance_id VARCHAR(36))
BEGIN
   SELECT m.model_id
    INTO v_model_id
    FROM model m
    WHERE m.control_name_uuid = v_control_name_uuid;
  SET v_model_instance_id = UUID();
  INSERT INTO model_instance
	(model_instance_id, model_id, vm_name, location)
	VALUES (v_model_instance_id, v_model_id, v_vm_name, v_location);
END;
CREATE PROCEDURE del_model_instance
  (IN v_control_name_uuid VARCHAR(36),
   IN v_vm_name VARCHAR(250),
   OUT v_model_id VARCHAR(36),
   OUT v_model_instance_id VARCHAR(36))
BEGIN
   SELECT m.model_id, i.model_instance_id
    INTO v_model_id,
         v_model_instance_id
    FROM model m,
         model_instance i
    WHERE m.model_id = i.model_id
     AND  m.control_name_uuid = v_control_name_uuid
     AND  i.vm_name = v_vm_name;
  DELETE FROM model_instance
  WHERE model_instance_id = v_model_instance_id;
END;
CREATE PROCEDURE del_all_model_instances
  (IN v_control_name_uuid VARCHAR(36),
   OUT v_model_id VARCHAR(36))
BEGIN
  SELECT m.model_id
    INTO v_model_id
    FROM model m
    WHERE m.control_name_uuid = v_control_name_uuid;
  DELETE FROM model_instance
  WHERE model_id = v_model_id;
END;
CREATE PROCEDURE ins_event
  (IN v_model_name VARCHAR(80),
   IN v_control_name_prefix VARCHAR(80),
   IN v_control_name_uuid VARCHAR(36),
   IN v_user_id VARCHAR(80),
   IN v_action_cd VARCHAR(80),
   IN v_action_state_cd VARCHAR(80),
   IN v_process_instance_id VARCHAR(80),
   OUT v_model_id VARCHAR(36),
   OUT v_event_id VARCHAR(36))
BEGIN
  DECLARE v_prev_event_id VARCHAR(36);
  SELECT m.model_id,
		 m.event_id
    INTO v_model_id,
         v_prev_event_id
    FROM model m
    WHERE m.model_name = v_model_name
	  OR  m.control_name_uuid = v_control_name_uuid;
  SET v_event_id = UUID();
  INSERT INTO event
	(event_id, model_id, action_cd, action_state_cd, prev_event_id, process_instance_id, user_id)
	VALUES (v_event_id, v_model_id, v_action_cd, v_action_state_cd, v_prev_event_id, v_process_instance_id, v_user_id);
  UPDATE model
	SET event_id = v_event_id
	WHERE model_id = v_model_id;
END;
CREATE PROCEDURE upd_event
  (IN v_event_id VARCHAR(36),
   IN v_process_instance_id VARCHAR(80))
BEGIN
  UPDATE event
	SET process_instance_id = v_process_instance_id
	WHERE event_id = v_event_id;
END
//
DELIMITER ;