forked from ehb54/us3_sql
-
Notifications
You must be signed in to change notification settings - Fork 0
/
us3_report_procs.sql
1491 lines (1102 loc) · 43.5 KB
/
us3_report_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
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
450
451
452
453
454
455
456
457
458
459
460
461
462
463
464
465
466
467
468
469
470
471
472
473
474
475
476
477
478
479
480
481
482
483
484
485
486
487
488
489
490
491
492
493
494
495
496
497
498
499
500
501
502
503
504
505
506
507
508
509
510
511
512
513
514
515
516
517
518
519
520
521
522
523
524
525
526
527
528
529
530
531
532
533
534
535
536
537
538
539
540
541
542
543
544
545
546
547
548
549
550
551
552
553
554
555
556
557
558
559
560
561
562
563
564
565
566
567
568
569
570
571
572
573
574
575
576
577
578
579
580
581
582
583
584
585
586
587
588
589
590
591
592
593
594
595
596
597
598
599
600
601
602
603
604
605
606
607
608
609
610
611
612
613
614
615
616
617
618
619
620
621
622
623
624
625
626
627
628
629
630
631
632
633
634
635
636
637
638
639
640
641
642
643
644
645
646
647
648
649
650
651
652
653
654
655
656
657
658
659
660
661
662
663
664
665
666
667
668
669
670
671
672
673
674
675
676
677
678
679
680
681
682
683
684
685
686
687
688
689
690
691
692
693
694
695
696
697
698
699
700
701
702
703
704
705
706
707
708
709
710
711
712
713
714
715
716
717
718
719
720
721
722
723
724
725
726
727
728
729
730
731
732
733
734
735
736
737
738
739
740
741
742
743
744
745
746
747
748
749
750
751
752
753
754
755
756
757
758
759
760
761
762
763
764
765
766
767
768
769
770
771
772
773
774
775
776
777
778
779
780
781
782
783
784
785
786
787
788
789
790
791
792
793
794
795
796
797
798
799
800
801
802
803
804
805
806
807
808
809
810
811
812
813
814
815
816
817
818
819
820
821
822
823
824
825
826
827
828
829
830
831
832
833
834
835
836
837
838
839
840
841
842
843
844
845
846
847
848
849
850
851
852
853
854
855
856
857
858
859
860
861
862
863
864
865
866
867
868
869
870
871
872
873
874
875
876
877
878
879
880
881
882
883
884
885
886
887
888
889
890
891
892
893
894
895
896
897
898
899
900
901
902
903
904
905
906
907
908
909
910
911
912
913
914
915
916
917
918
919
920
921
922
923
924
925
926
927
928
929
930
931
932
933
934
935
936
937
938
939
940
941
942
943
944
945
946
947
948
949
950
951
952
953
954
955
956
957
958
959
960
961
962
963
964
965
966
967
968
969
970
971
972
973
974
975
976
977
978
979
980
981
982
983
984
985
986
987
988
989
990
991
992
993
994
995
996
997
998
999
1000
--
-- us3_report_procs.sql
--
-- Script to set up the MySQL stored procedures for the US3 system
-- These are related to the report tables
-- Run as us3admin
--
DELIMITER $$
-- Verifies that the user has permission to view or modify
-- the specified report
DROP FUNCTION IF EXISTS verify_report_permission$$
CREATE FUNCTION verify_report_permission( p_personGUID CHAR(36),
p_password VARCHAR(80),
p_reportID INT )
RETURNS INT
READS SQL DATA
BEGIN
DECLARE count_reports INT;
DECLARE count_permissions INT;
DECLARE status INT;
CALL config();
SET status = @ERROR;
SET @US3_LAST_ERROR = 'MySQL: error verifying report permission';
SELECT COUNT(*)
INTO count_reports
FROM report
WHERE reportID = p_reportID;
SELECT COUNT(*)
INTO count_permissions
FROM reportPerson
WHERE reportID = p_reportID
AND personID = @US3_ID;
IF ( count_reports = 0 ) THEN
SET @US3_LAST_ERRNO = @NO_REPORT;
SET @US3_LAST_ERROR = 'MySQL: the specified report does not exist';
SET status = @NO_REPORT;
ELSEIF ( verify_userlevel( p_personGUID, p_password, @US3_ADMIN ) = @OK ) THEN
SET @US3_LAST_ERRNO = @OK;
SET @US3_LAST_ERROR = '';
SET status = @OK;
ELSEIF ( ( verify_user( p_personGUID, p_password ) = @OK ) &&
( count_permissions > 0 ) ) THEN
SET @US3_LAST_ERRNO = @OK;
SET @US3_LAST_ERROR = '';
SET status = @OK;
ELSE
SET @US3_LAST_ERRNO = @NOTPERMITTED;
SET @US3_LAST_ERROR = 'MySQL: you do not have permission to view or modify this report';
SET status = @NOTPERMITTED;
END IF;
RETURN( status );
END$$
-- This set of routines deals with the global report structure
-- Returns the count of reports associated with p_ID
-- If p_ID = 0, retrieves count of all reports in db
-- Regular user can only get count of his own reports
DROP FUNCTION IF EXISTS count_reports$$
CREATE FUNCTION count_reports( p_personGUID CHAR(36),
p_password VARCHAR(80),
p_ID INT )
RETURNS INT
READS SQL DATA
BEGIN
DECLARE count_reports INT;
CALL config();
SET count_reports = 0;
IF ( verify_userlevel( p_personGUID, p_password, @US3_ADMIN ) = @OK ) THEN
-- This is an admin; he can get more info
IF ( p_ID > 0 ) THEN
SELECT COUNT(*)
INTO count_reports
FROM reportPerson
WHERE personID = p_ID;
ELSE
SELECT COUNT(*)
INTO count_reports
FROM reportPerson;
END IF;
ELSEIF ( verify_user( p_personGUID, p_password ) = @OK ) THEN
IF ( (p_ID != 0) && (p_ID != @US3_ID) ) THEN
-- Uh oh, can't do that
SET @US3_LAST_ERRNO = @NOTPERMITTED;
SET @US3_LAST_ERROR = 'MySQL: you do not have permission to view those reports';
ELSE
-- This person is asking about his own reports
-- Ignore p_ID and return user's own
SELECT COUNT(*)
INTO count_reports
FROM reportPerson
WHERE personID = @US3_ID;
END IF;
END IF;
RETURN( count_reports );
END$$
-- INSERTs a new global report structure with the specified information
DROP PROCEDURE IF EXISTS new_report$$
CREATE PROCEDURE new_report ( p_personGUID CHAR(36),
p_password VARCHAR(80),
p_reportGUID CHAR(36),
p_runID VARCHAR(255),
p_title VARCHAR(255),
p_html LONGTEXT,
p_ownerID INT )
MODIFIES SQL DATA
BEGIN
DECLARE duplicate_key TINYINT DEFAULT 0;
DECLARE null_field TINYINT DEFAULT 0;
DECLARE count_experiment INT DEFAULT 0;
DECLARE count_reports INT DEFAULT 0;
DECLARE l_experimentID INT DEFAULT -1;
DECLARE CONTINUE HANDLER FOR 1062
SET duplicate_key = 1;
DECLARE CONTINUE HANDLER FOR 1048
SET null_field = 1;
CALL config();
SET @US3_LAST_ERRNO = @OK;
SET @US3_LAST_ERROR = '';
SET @LAST_INSERT_ID = 0;
-- runID is unique for the investigator in the experiment table, too
SELECT COUNT(*)
INTO count_experiment
FROM experimentPerson p, experiment e
WHERE p.personID = p_ownerID
AND p.experimentID = e.experimentID
AND e.runID = p_runID;
-- And now check for uniqueness of the runID for this investigator
SELECT COUNT(*)
INTO count_reports
FROM reportPerson p, report r
WHERE personID = p_ownerID
AND p.reportID = r.reportID
AND runID = p_runID;
SELECT e.experimentID
INTO l_experimentID
FROM experimentPerson p, experiment e
WHERE p.personID = p_ownerID
AND p.experimentID = e.experimentID
AND e.runID = p_runID;
IF ( count_experiment = 0 ) THEN
SET @US3_LAST_ERRNO = @NO_EXPERIMENT;
SET @US3_LAST_ERROR = "MySQL: No experiment with that runID exists";
ELSEIF ( count_reports > 0 ) THEN
SET @US3_LAST_ERRNO = @INSERTDUP;
SET @US3_LAST_ERROR = "MySQL: Duplicate entry for runID field";
ELSEIF ( ( verify_user( p_personGUID, p_password ) = @OK ) &&
( check_GUID ( p_personGUID, p_password, p_reportGUID ) = @OK ) ) THEN
INSERT INTO report SET
reportGUID = p_reportGUID,
experimentID = l_experimentID,
runID = p_runID,
title = p_title,
html = p_html;
IF ( duplicate_key = 1 ) THEN
SET @US3_LAST_ERRNO = @INSERTDUP;
SET @US3_LAST_ERROR = "MySQL: Duplicate entry for reportGUID field";
ELSEIF ( null_field = 1 ) THEN
SET @US3_LAST_ERRNO = @INSERTNULL;
SET @US3_LAST_ERROR = "MySQL: NULL value for reportGUID field";
ELSE
SET @LAST_INSERT_ID = LAST_INSERT_ID();
INSERT INTO reportPerson SET
reportID = @LAST_INSERT_ID,
personID = p_ownerID;
END IF;
END IF;
SELECT @US3_LAST_ERRNO AS status;
END$$
-- UPDATEs an existing global report structure with the specified information
DROP PROCEDURE IF EXISTS update_report$$
CREATE PROCEDURE update_report ( p_personGUID CHAR(36),
p_password VARCHAR(80),
p_reportID INT,
p_title VARCHAR(255),
p_html LONGTEXT )
MODIFIES SQL DATA
BEGIN
DECLARE not_found TINYINT DEFAULT 0;
DECLARE CONTINUE HANDLER FOR NOT FOUND
SET not_found = 1;
CALL config();
SET @US3_LAST_ERRNO = @OK;
SET @US3_LAST_ERROR = '';
IF ( verify_report_permission( p_personGUID, p_password, p_reportID ) = @OK ) THEN
UPDATE report SET
title = p_title,
html = p_html
WHERE reportID = p_reportID;
IF ( not_found = 1 ) THEN
SET @US3_LAST_ERRNO = @NO_REPORT;
SET @US3_LAST_ERROR = "MySQL: No report with that ID exists";
ELSE
SET @LAST_INSERT_ID = LAST_INSERT_ID();
END IF;
END IF;
SELECT @US3_LAST_ERRNO AS status;
END$$
-- Returns the reportID associated with the given reportGUID
DROP PROCEDURE IF EXISTS get_reportID$$
CREATE PROCEDURE get_reportID ( p_personGUID CHAR(36),
p_password VARCHAR(80),
p_reportGUID CHAR(36) )
READS SQL DATA
BEGIN
DECLARE count_reports INT;
CALL config();
SET @US3_LAST_ERRNO = @OK;
SET @US3_LAST_ERROR = '';
SET count_reports = 0;
IF ( verify_user( p_personGUID, p_password ) = @OK ) THEN
SELECT COUNT(*)
INTO count_reports
FROM report
WHERE reportGUID = p_reportGUID;
IF ( TRIM( p_reportGUID ) = '' ) THEN
SET @US3_LAST_ERRNO = @EMPTY;
SET @US3_LAST_ERROR = CONCAT( 'MySQL: The reportGUID parameter to the ',
'get_reportID function cannot be empty' );
ELSEIF ( count_reports < 1 ) THEN
SET @US3_LAST_ERRNO = @NOROWS;
SET @US3_LAST_ERROR = 'MySQL: no rows returned';
SELECT @US3_LAST_ERRNO AS status;
ELSE
SELECT @OK AS status;
SELECT reportID
FROM report
WHERE reportGUID = p_reportGUID;
END IF;
END IF;
END$$
-- Returns the reportID associated with the given runID
DROP PROCEDURE IF EXISTS get_reportID_by_runID$$
CREATE PROCEDURE get_reportID_by_runID ( p_personGUID CHAR(36),
p_password VARCHAR(80),
p_ID INT,
p_runID VARCHAR(255) )
READS SQL DATA
BEGIN
DECLARE count_reports INT;
CALL config();
SET @US3_LAST_ERRNO = @OK;
SET @US3_LAST_ERROR = '';
SET count_reports = 0;
IF ( verify_user( p_personGUID, p_password ) = @OK ) THEN
SELECT COUNT(*)
INTO count_reports
FROM reportPerson p, report r
WHERE personID = p_ID
AND p.reportID = r.reportID
AND runID = p_runID;
IF ( TRIM( p_runID ) = '' ) THEN
SET @US3_LAST_ERRNO = @EMPTY;
SET @US3_LAST_ERROR = CONCAT( 'MySQL: The runID parameter to the ',
'get_reportID_by_runID function cannot be empty' );
ELSEIF ( count_reports < 1 ) THEN
SET @US3_LAST_ERRNO = @NOROWS;
SET @US3_LAST_ERROR = 'MySQL: no rows returned';
SELECT @US3_LAST_ERRNO AS status;
ELSE
SELECT @OK AS status;
SELECT p.reportID
FROM reportPerson p, report r
WHERE personID = p_ID
AND p.reportID = r.reportID
AND runID = p_runID;
END IF;
END IF;
END$$
-- Returns the reportID and title of all reports associated with p_ID
-- If p_ID = 0, retrieves information about all reports in db
-- Regular user can only get info about his own reports
DROP PROCEDURE IF EXISTS get_report_desc$$
CREATE PROCEDURE get_report_desc ( p_personGUID CHAR(36),
p_password VARCHAR(80),
p_ID INT )
READS SQL DATA
BEGIN
CALL config();
SET @US3_LAST_ERRNO = @OK;
SET @US3_LAST_ERROR = '';
IF ( verify_userlevel( p_personGUID, p_password, @US3_ADMIN ) = @OK ) THEN
-- This is an admin; he can get more info
IF ( count_reports( p_personGUID, p_password, p_ID ) < 1 ) THEN
SET @US3_LAST_ERRNO = @NOROWS;
SET @US3_LAST_ERROR = 'MySQL: no rows returned';
SELECT @US3_LAST_ERRNO AS status;
ELSE
SELECT @OK AS status;
IF ( p_ID > 0 ) THEN
SELECT report.reportID, reportGUID, title, experimentID, runID
FROM reportPerson, report
WHERE reportPerson.personID = p_ID
AND reportPerson.reportID = report.reportID
ORDER BY reportID DESC;
ELSE
SELECT report.reportID, reportGUID, title, experimentID, runID
FROM reportPerson, report
WHERE reportPerson.reportID = report.reportID
ORDER BY reportID DESC;
END IF;
END IF;
ELSEIF ( verify_user( p_personGUID, p_password ) = @OK ) THEN
IF ( (p_ID != 0) && (p_ID != @US3_ID) ) THEN
-- Uh oh, can't do that
SET @US3_LAST_ERRNO = @NOTPERMITTED;
SET @US3_LAST_ERROR = 'MySQL: you do not have permission to view this report';
SELECT @US3_LAST_ERRNO AS status;
ELSEIF ( count_reports( p_personGUID, p_password, @US3_ID ) < 1 ) THEN
SET @US3_LAST_ERRNO = @NOROWS;
SET @US3_LAST_ERROR = 'MySQL: no rows returned';
SELECT @US3_LAST_ERRNO AS status;
ELSE
-- Ok, user wants his own info
SELECT @OK AS status;
SELECT report.reportID, reportGUID, title, experimentID, runID
FROM reportPerson, report
WHERE reportPerson.personID = @US3_ID
AND reportPerson.reportID = report.reportID
ORDER BY reportID DESC;
END IF;
END IF;
END$$
-- Returns the reportID and title of all reports that have a given runID
-- that belong to the person identified by p_ID
-- An admin can view anybody's reports; a regular user only his own
-- If p_ID = 0, retrieves information about all reports in db
DROP PROCEDURE IF EXISTS get_report_desc_by_runID$$
CREATE PROCEDURE get_report_desc_by_runID ( p_personGUID CHAR(36),
p_password VARCHAR(80),
p_ID INT,
p_runID VARCHAR(80) )
READS SQL DATA
BEGIN
CALL config();
SET @US3_LAST_ERRNO = @OK;
SET @US3_LAST_ERROR = '';
IF ( verify_userlevel( p_personGUID, p_password, @US3_ADMIN ) = @OK ) THEN
-- This is an admin; he can get more info
IF ( count_reports_by_runID( p_personGUID, p_password, p_ID, p_runID ) < 1 ) THEN
SET @US3_LAST_ERRNO = @NOROWS;
SET @US3_LAST_ERROR = 'MySQL: no rows returned';
SELECT @US3_LAST_ERRNO AS status;
ELSE
SELECT @OK AS status;
IF ( p_ID > 0 ) THEN
SELECT r.reportID, reportGUID, title, experimentID
FROM reportPerson p, report r
WHERE p.personID = p_ID
AND p.reportID = r.reportID
AND runID = p_runID
ORDER BY reportID DESC;
ELSE
SELECT reportID, reportGUID, title, experimentID
FROM report
WHERE runID = p_runID
ORDER BY reportID DESC;
END IF;
END IF;
ELSEIF ( verify_user( p_personGUID, p_password ) = @OK ) THEN
IF ( (p_ID != 0) && (p_ID != @US3_ID) ) THEN
-- Uh oh, can't do that
SET @US3_LAST_ERRNO = @NOTPERMITTED;
SET @US3_LAST_ERROR = 'MySQL: you do not have permission to view this report';
SELECT @US3_LAST_ERRNO AS status;
ELSEIF ( count_reports( p_personGUID, p_password, @US3_ID ) < 1 ) THEN
SET @US3_LAST_ERRNO = @NOROWS;
SET @US3_LAST_ERROR = 'MySQL: no rows returned';
SELECT @US3_LAST_ERRNO AS status;
ELSE
-- Ok, user wants his own info
SELECT @OK AS status;
SELECT r.reportID, reportGUID, title, experimentID
FROM reportPerson p, report r
WHERE p.personID = @US3_ID
AND p.reportID = r.reportID
AND runID = p_runID
ORDER BY reportID DESC;
END IF;
END IF;
END$$
-- Returns all global report information about one report
DROP PROCEDURE IF EXISTS get_report_info$$
CREATE PROCEDURE get_report_info ( p_personGUID CHAR(36),
p_password VARCHAR(80),
p_reportID INT )
READS SQL DATA
BEGIN
DECLARE count_reports INT;
CALL config();
SET @US3_LAST_ERRNO = @OK;
SET @US3_LAST_ERROR = '';
SELECT COUNT(*)
INTO count_reports
FROM report
WHERE reportID = p_reportID;
IF ( verify_report_permission( p_personGUID, p_password, p_reportID ) = @OK ) THEN
IF ( count_reports = 0 ) THEN
SET @US3_LAST_ERRNO = @NOROWS;
SET @US3_LAST_ERROR = 'MySQL: no rows returned';
SELECT @US3_LAST_ERRNO AS status;
ELSE
SELECT @OK AS status;
SELECT report.reportID, reportGUID, experimentID, runID, title, html
FROM reportPerson, report
WHERE report.reportID = p_reportID
AND report.reportID = reportPerson.reportID;
END IF;
ELSE
SELECT @US3_LAST_ERRNO AS status;
END IF;
END$$
-- Returns all global report information about one report
DROP PROCEDURE IF EXISTS get_report_info_by_runID$$
CREATE PROCEDURE get_report_info_by_runID ( p_personGUID CHAR(36),
p_password VARCHAR(80),
p_ID INT,
p_runID VARCHAR(80) )
READS SQL DATA
BEGIN
DECLARE count_reports INT;
DECLARE l_reportID INT;
CALL config();
SET @US3_LAST_ERRNO = @OK;
SET @US3_LAST_ERROR = '';
SELECT COUNT(*)
INTO count_reports
FROM reportPerson p, report r
WHERE personID = p_ID
AND p.reportID = r.reportID
AND runID = p_runID;
SELECT p.reportID
INTO l_reportID
FROM reportPerson p, report r
WHERE personID = p_ID
AND p.reportID = r.reportID
AND runID = p_runID;
IF ( count_reports = 0 ) THEN
SET @US3_LAST_ERRNO = @NOROWS;
SET @US3_LAST_ERROR = 'MySQL: no rows returned';
SELECT @US3_LAST_ERRNO AS status;
ELSEIF ( verify_report_permission( p_personGUID, p_password, l_reportID ) = @OK ) THEN
SELECT @OK AS status;
SELECT report.reportID, reportGUID, experimentID, runID, title, html
FROM reportPerson, report
WHERE report.reportID = l_reportID
AND report.reportID = reportPerson.reportID;
ELSE
SELECT @US3_LAST_ERRNO AS status;
END IF;
END$$
-- DELETEs a report, plus information in related tables
DROP PROCEDURE IF EXISTS delete_report$$
CREATE PROCEDURE delete_report ( p_personGUID CHAR(36),
p_password VARCHAR(80),
p_reportID INT )
MODIFIES SQL DATA
BEGIN
CALL config();
SET @US3_LAST_ERRNO = @OK;
SET @US3_LAST_ERROR = '';
IF ( verify_report_permission( p_personGUID, p_password, p_reportID ) = @OK ) THEN
-- Make sure records match if they have related tables or not
-- Have to do it in a couple of stages because of the constraints
DELETE documentLink, reportDocument
FROM report
LEFT JOIN reportTriple ON ( report.reportID = reportTriple.reportID )
LEFT JOIN documentLink ON ( reportTriple.reportTripleID = documentLink.reportTripleID )
LEFT JOIN reportDocument ON ( documentLink.reportDocumentID = reportDocument.reportDocumentID )
WHERE report.reportID = p_reportID;
DELETE reportTriple
FROM report
LEFT JOIN reportTriple ON ( report.reportID = reportTriple.reportID )
WHERE report.reportID = p_reportID;
DELETE FROM report
WHERE reportID = p_reportID;
DELETE FROM reportPerson
WHERE reportID = p_reportID;
END IF;
SELECT @US3_LAST_ERRNO AS status;
END$$
-- This set of routines deals with all documents relating to a single
-- runID/triple combination
DROP FUNCTION IF EXISTS count_reportTriple$$
CREATE FUNCTION count_reportTriple( p_personGUID CHAR(36),
p_password VARCHAR(80),
p_reportID INT )
RETURNS INT
READS SQL DATA
BEGIN
DECLARE count_reports INT;
CALL config();
SET count_reports = 0;
IF ( verify_report_permission( p_personGUID, p_password, p_reportID ) = @OK ) THEN
-- This is either an admin, or a user getting info about his own reports
SELECT COUNT(*)
INTO count_reports
FROM reportTriple
WHERE reportID = p_reportID;
END IF;
RETURN( count_reports );
END$$
-- INSERTs a new report triple record with the specified information
DROP PROCEDURE IF EXISTS new_reportTriple$$
CREATE PROCEDURE new_reportTriple ( p_personGUID CHAR(36),
p_password VARCHAR(80),
p_reportTripleGUID CHAR(36),
p_reportID INT,
p_resultID INT,
p_triple VARCHAR(20),
p_dataDescription VARCHAR(255) )
MODIFIES SQL DATA
BEGIN
DECLARE duplicate_key TINYINT DEFAULT 0;
DECLARE null_field TINYINT DEFAULT 0;
DECLARE constraint_failed TINYINT DEFAULT 0;
DECLARE CONTINUE HANDLER FOR 1062
SET duplicate_key = 1;
DECLARE CONTINUE HANDLER FOR 1048
SET null_field = 1;
DECLARE CONTINUE HANDLER FOR 1452
SET constraint_failed = 1;
CALL config();
SET @US3_LAST_ERRNO = @OK;
SET @US3_LAST_ERROR = '';
SET @LAST_INSERT_ID = 0;
IF ( ( verify_report_permission( p_personGUID, p_password, p_reportID ) = @OK ) &&
( check_GUID ( p_personGUID, p_password, p_reportTripleGUID ) = @OK ) ) THEN
INSERT INTO reportTriple SET
reportTripleGUID = p_reportTripleGUID,
reportID = p_reportID,
resultID = p_resultID,
triple = p_triple,
dataDescription = p_dataDescription ;
IF ( duplicate_key = 1 ) THEN
SET @US3_LAST_ERRNO = @INSERTDUP;
SET @US3_LAST_ERROR = "MySQL: Duplicate entry for reportTripleGUID field";
ELSEIF ( null_field = 1 ) THEN
SET @US3_LAST_ERRNO = @INSERTNULL;
SET @US3_LAST_ERROR = "MySQL: NULL value for reportTripleGUID field";
ELSEIF ( constraint_failed = 1 ) THEN
SET @US3_LAST_ERRNO = @CONSTRAINT_FAILED;
SET @US3_LAST_ERROR = "MySQL: FK Constraint failed inserting into reportTriple";
ELSE
SET @LAST_INSERT_ID = LAST_INSERT_ID();
END IF;
END IF;
SELECT @US3_LAST_ERRNO AS status;
END$$
-- UPDATEs an existing report triple record with the specified information
DROP PROCEDURE IF EXISTS update_reportTriple$$
CREATE PROCEDURE update_reportTriple ( p_personGUID CHAR(36),
p_password VARCHAR(80),
p_reportTripleID INT,
p_resultID INT,
p_triple VARCHAR(20),
p_dataDescription VARCHAR(255) )
MODIFIES SQL DATA
BEGIN
DECLARE l_reportID INT;
DECLARE not_found TINYINT DEFAULT 0;
DECLARE constraint_failed TINYINT DEFAULT 0;
DECLARE CONTINUE HANDLER FOR NOT FOUND
SET not_found = 1;
DECLARE CONTINUE HANDLER FOR 1452
SET constraint_failed = 1;
CALL config();
SET @US3_LAST_ERRNO = @OK;
SET @US3_LAST_ERROR = '';
SET @LAST_INSERT_ID = 0;
-- Figure out the reportID
SELECT reportID
INTO l_reportID
FROM reportTriple
WHERE reportTripleID = p_reportTripleID;
IF ( verify_report_permission( p_personGUID, p_password, l_reportID ) != @OK ) THEN
-- Can't do that
SET @US3_LAST_ERRNO = @NOTPERMITTED;
SET @US3_LAST_ERROR = 'MySQL: you do not have permission to edit this report';
SELECT @US3_LAST_ERRNO AS status;
ELSE
-- Let's guard against updating dataDescription with an empty string
SET p_dataDescription = TRIM( p_dataDescription );
IF ( LENGTH( p_dataDescription ) < 1 ) THEN
UPDATE reportTriple SET
resultID = p_resultID,
triple = p_triple
WHERE reportTripleID = p_reportTripleID;
ELSE
UPDATE reportTriple SET
resultID = p_resultID,
triple = p_triple,
dataDescription = p_dataDescription
WHERE reportTripleID = p_reportTripleID;
END IF;
IF ( not_found = 1 ) THEN
SET @US3_LAST_ERRNO = @NO_REPORT_TRIPLE;
SET @US3_LAST_ERROR = "MySQL: No report triple record with that ID exists";
ELSEIF ( constraint_failed = 1 ) THEN
SET @US3_LAST_ERRNO = @CONSTRAINT_FAILED;
SET @US3_LAST_ERROR = "MySQL: FK Constraint failed while updating reportTriple";
ELSE
SET @LAST_INSERT_ID = LAST_INSERT_ID();
END IF;
END IF;
SELECT @US3_LAST_ERRNO AS status;
END$$
-- Returns the reportTripleID associated with the given reportTripleGUID
DROP PROCEDURE IF EXISTS get_reportTripleID$$
CREATE PROCEDURE get_reportTripleID ( p_personGUID CHAR(36),
p_password VARCHAR(80),
p_reportTripleGUID CHAR(36) )
READS SQL DATA
BEGIN
DECLARE count_reports INT;
CALL config();
SET @US3_LAST_ERRNO = @OK;
SET @US3_LAST_ERROR = '';
SET count_reports = 0;
IF ( verify_user( p_personGUID, p_password ) = @OK ) THEN
SELECT COUNT(*)
INTO count_reports
FROM reportTriple
WHERE reportTripleGUID = p_reportTripleGUID;
IF ( TRIM( p_reportTripleGUID ) = '' ) THEN
SET @US3_LAST_ERRNO = @EMPTY;
SET @US3_LAST_ERROR = CONCAT( 'MySQL: The reportTripleGUID parameter to the ',
'get_reportTripleID function cannot be empty' );
ELSEIF ( count_reports < 1 ) THEN
SET @US3_LAST_ERRNO = @NOROWS;
SET @US3_LAST_ERROR = 'MySQL: no rows returned';
SELECT @US3_LAST_ERRNO AS status;
ELSE
SELECT @OK AS status;
SELECT reportTripleID
FROM reportTriple
WHERE reportTripleGUID = p_reportTripleGUID;
END IF;
END IF;
END$$
-- Returns all report details associated with p_reportID
DROP PROCEDURE IF EXISTS get_reportTriple_desc$$
CREATE PROCEDURE get_reportTriple_desc ( p_personGUID CHAR(36),
p_password VARCHAR(80),
p_reportID INT )
READS SQL DATA
BEGIN
CALL config();
SET @US3_LAST_ERRNO = @OK;
SET @US3_LAST_ERROR = '';
IF ( verify_report_permission( p_personGUID, p_password, p_reportID ) != @OK ) THEN
SET @US3_LAST_ERRNO = @NOTPERMITTED;
SET @US3_LAST_ERROR = 'MySQL: you do not have permission to view this report';
SELECT @US3_LAST_ERRNO AS status;
ELSEIF ( count_reportTriple( p_personGUID, p_password, p_reportID ) < 1 ) THEN
SET @US3_LAST_ERRNO = @NOROWS;
SET @US3_LAST_ERROR = 'MySQL: no rows returned';
SELECT @US3_LAST_ERRNO AS status;
ELSE
SELECT @OK AS status;
SELECT reportTripleID, reportTripleGUID, resultID, triple, dataDescription
FROM reportTriple
WHERE reportID = p_reportID
ORDER BY triple;
END IF;
END$$
-- Returns all report details associated with a single p_reportTripleID
DROP PROCEDURE IF EXISTS get_reportTriple_info$$
CREATE PROCEDURE get_reportTriple_info ( p_personGUID CHAR(36),
p_password VARCHAR(80),
p_reportTripleID INT )
READS SQL DATA
BEGIN
DECLARE l_reportID INT;
DECLARE count_reports INT;
CALL config();
SET @US3_LAST_ERRNO = @OK;
SET @US3_LAST_ERROR = '';
SELECT reportID
INTO l_reportID
FROM reportTriple
WHERE reportTripleID = p_reportTripleID;
SELECT COUNT(*)
INTO count_reports
FROM reportTriple
WHERE reportTripleID = p_reportTripleID;
IF ( verify_report_permission( p_personGUID, p_password, l_reportID ) != @OK ) THEN
SET @US3_LAST_ERRNO = @NOTPERMITTED;
SET @US3_LAST_ERROR = 'MySQL: you do not have permission to view this report';
SELECT @US3_LAST_ERRNO AS status;
ELSEIF ( count_reports < 1 ) THEN
SET @US3_LAST_ERRNO = @NOROWS;
SET @US3_LAST_ERROR = 'MySQL: no rows returned';
SELECT @US3_LAST_ERRNO AS status;
ELSE
SELECT @OK AS status;
SELECT reportTripleGUID, resultID, triple, dataDescription
FROM reportTriple
WHERE reportTripleID = p_reportTripleID;
END IF;
END$$
-- DELETEs a report detail record, plus information in related tables
DROP PROCEDURE IF EXISTS delete_reportTriple$$
CREATE PROCEDURE delete_reportTriple ( p_personGUID CHAR(36),
p_password VARCHAR(80),
p_reportTripleID INT )
MODIFIES SQL DATA
BEGIN
DECLARE l_reportID INT;
CALL config();
SET @US3_LAST_ERRNO = @OK;
SET @US3_LAST_ERROR = '';
SELECT reportID
INTO l_reportID
FROM reportTriple
WHERE reportTripleID = p_reportTripleID;
IF ( verify_report_permission( p_personGUID, p_password, l_reportID ) = @OK ) THEN
-- Make sure records match if they have related tables or not
-- Have to do it in a couple of stages because of the constraints
DELETE documentLink, reportDocument
FROM reportTriple
LEFT JOIN documentLink ON ( reportTriple.reportTripleID = documentLink.reportTripleID )
LEFT JOIN reportDocument ON ( documentLink.reportDocumentID = reportDocument.reportDocumentID )
WHERE reportTriple.reportTripleID = p_reportTripleID;
DELETE FROM reportTriple
WHERE reportTripleID = p_reportTripleID;
END IF;
SELECT @US3_LAST_ERRNO AS status;
END$$
-- This set of routines deals with one or more documents
DROP FUNCTION IF EXISTS count_reportDocument$$
CREATE FUNCTION count_reportDocument( p_personGUID CHAR(36),
p_password VARCHAR(80),
p_reportTripleID INT )
RETURNS INT
READS SQL DATA
BEGIN
DECLARE l_reportID INT;
DECLARE count_reports INT;
CALL config();
SET count_reports = 0;
SELECT reportID