-
Notifications
You must be signed in to change notification settings - Fork 6
/
Copy pathbackup_html_file.sql
541 lines (517 loc) · 22.4 KB
/
backup_html_file.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
CREATE OR REPLACE PROCEDURE backup_html_file (
database IN VARCHAR2 DEFAULT NULL,
p_dir in varchar2,
p_filename in varchar2,
excludermanoutput IN BOOLEAN DEFAULT FALSE)
IS
l_database VARCHAR2 (500) := database;
l_exclude BOOLEAN := excludermanoutput;
l_output utl_file.file_type;
dbid NUMBER;
inst_id NUMBER;
bid NUMBER;
eid NUMBER;
db_unique_name VARCHAR2 (30);
host_name VARCHAR2 (64);
starttime CHAR (5);
endtime CHAR (5);
lineoutput VARCHAR2 (100);
output1 VARCHAR2 (2000);
output2 VARCHAR2 (2000);
output3 VARCHAR2 (2000);
output2_1 VARCHAR2 (2000);
output2_2 VARCHAR2 (2000);
BEGIN
DECLARE
/*
Cursor c1_rec builds the list of databases to be checked for backup.
This list will include all databases in the repository even if the
backup was not successful. If a database was passed to this function
it will be the only database that shows up in the report, otherwise
all of the databases will show.
Cursor c2_rec will pull the actual rman session output for the entire
backup session for each database being checked and add it to the report.
If the database being checked does not have a backup recoreded in the
repository, the rman session output section for that database
will be skipped.
*/
CURSOR c1_rec
IS
SELECT session_key, operation, dbid, db_name
FROM bkupadm.last_backup
WHERE operation = 'BACKUP SESSION'
AND NVL2 (l_database, db_name, 1) =
NVL (UPPER (l_database), 1)
ORDER BY db_name;
CURSOR c2_rec
IS
SELECT DISTINCT session_key, db_name, dbid
FROM rman.rc_rman_output
JOIN
bkupadm.last_backup
USING (session_key)
WHERE operation = 'BACKUP SESSION'
AND NVL2 (l_database, db_name, 1) =
NVL (UPPER (l_database), 1)
AND EXISTS
(SELECT 1
FROM bkupadm.last_backup_details
JOIN
bkupadm.last_backup
USING (session_key)
WHERE status <> 'MISSING');
BEGIN
/*
check_backups is a separate function that builds the last_backup table that
the c1_rec cursor will pull data from. It contains the latest backup and latest
block corruption check sessions pulled from the rman catalog repository.
It needs to be run everytime so this function has the latest data to work with.
*/
bkupadm.check_backups;
-- Open the SMTP connection
l_output := UTL_file.fopen (p_dir, p_filename, 'w');
lineoutput := 'Report Generated at: '||TO_CHAR( CAST ( FROM_TZ ( CAST (sysdate AS TIMESTAMP), 'GMT') AT TIME ZONE 'US/Central' AS DATE), 'MM-DD-YYYY HH:MI AM');
utl_file.put_line (l_output, lineoutput);
utl_file.put_line (l_output, '<p>');
/*
This is the beginning of the master table. It will contain a header row and a row
for each database. The first and last cell of each row will span three rows in order
to separate the backup report from the block corruption report and eventually the
datapump export report.
*/
lineoutput := '<table border=1 align="left">';
utl_file.put_line (l_output, lineoutput);
-- Header line of the table
lineoutput :=
'<tr><th width=60>Database Name/Server</th><th>Operation</th>';
utl_file.put_line (l_output, lineoutput);
lineoutput :=
'<th>Start Time</th><th>End Time</th><th>Elapsed</th><th>Status</th>';
utl_file.put_line (l_output, lineoutput);
lineoutput := '<th>Backup Breakdown</th></tr>';
utl_file.put_line (l_output, lineoutput);
/*
For each loop, a database from the c1_rec cursor is checked and printed. There are
multiple output variables because html puts exclamation points in funny places if
lines code are too long. Each output variable is built such that the limit is not
met resulting in exclamation point free code.
*/
FOR i IN c1_rec
LOOP
BEGIN
-- The first cell spans three rows and contains the database name and the server
-- or cluster name in which it resides. The second cell spans only one row and is
-- labeled as backup.
BEGIN
SELECT '<tr><td rowspan=3>'
|| database_name
|| '<p>'
|| server
|| '</p></td><td>BACKUP</td>'
INTO output1
FROM bkupadm.database_inventory
WHERE dbid = i.dbid;
EXCEPTION
WHEN NO_DATA_FOUND
THEN
output1 := '<tr><td rowspan=3>'
|| 'Update <p> Inventory for <p>'
|| i.db_name || '<p>'
|| to_char(i.dbid)
|| '</p></td><td>BACKUP</td>';
END;
/*
The third cell is the start time of the backup session. If the backup started
two days ago, the cell will be yellow. If the backup started three days ago or
earlier the cell will be red. If the start time is null then the cell will be
blank and white. The cell will otherwise be green indicating the backup started
sometime today or yesterday.
*/
SELECT '<td '
|| CASE
WHEN TRUNC (start_time) = TRUNC (SYSDATE - 2)
THEN
'bgcolor="yellow"> '
WHEN TRUNC (start_time) < TRUNC (SYSDATE - 3)
THEN
'bgcolor="red"> '
WHEN start_time IS NULL
THEN
'bgcolor="white"> '
ELSE
'bgcolor="lime"> '
END
|| TO_CHAR (start_time, 'MM-DD-YY HH:MI PM')
|| '</td><td '
/*
The fourth cell is the end time of the backup session. If the backup ended
two days ago, the cell will be yellow. If the backup ended three days ago or
earlier the cell will be red. If the end time is null then the cell will be
blank and white. The cell will otherwise be green indicating the backup ended
sometime today or yesterday.
*/
|| CASE
WHEN TRUNC (end_time) = TRUNC (SYSDATE - 2)
THEN
'bgcolor="yellow"> '
WHEN TRUNC (end_time) < TRUNC (SYSDATE - 3)
THEN
'bgcolor="red"> '
WHEN end_time IS NULL
THEN
'bgcolor="white"> '
ELSE
'bgcolor="lime"> '
END
|| CASE
WHEN status = 'RUNNING' THEN ''
ELSE TO_CHAR (end_time, 'MM-DD-YY HH:MI PM')
END
|| '</td><td '
/*
The fifth cell is the amount of time the backup took in hours and minutes
separated by a colon.
If the backup took less than an our the cell will be green. If the backup took
at least an hour but less than two, the cell will be yellow. If the backup
took two hours or more, the cell will be red. If the backup time is null,
the cell will be blank and white. The cell will otherwise be green.
*/
|| CASE
WHEN FLOOR ( (end_time - start_time) * 24) = 0
THEN
'bgcolor="lime"> '
WHEN FLOOR ( (end_time - start_time) * 24) = 1
THEN
'bgcolor="yellow"> '
WHEN FLOOR ( (end_time - start_time) * 24) > 1
THEN
'bgcolor="red"> '
WHEN end_time IS NULL
THEN
'bgcolor="white"> '
ELSE
'bgcolor="lime"> '
END
/*
FM00 is a variable for to_char to prevent blank spaces in front of the number.
The first number is the total number of hours that the backup took.
The floor function is used to strip the decimal from the product of 24 and
the end time less the start time. The actual number of hours is printed as the
first number in the cell.
*/
|| TO_CHAR (FLOOR ( (end_time - start_time) * 24), 'FM00')
-- A colon separates the hours and minutes of the total backup time but will
-- not be printed if the end time is null.
|| NVL2 (end_time, ':', NULL)
/*
FM00 is a variable for to_char to prevent blank spaces in front of the number.
The second number is the total number of minutes in addition to the hours
that the backup took. The floor function is used to strip the decimal from the
product of 24 and the end time less the start time multiplied by 60. Mod then
divides that number by 60 and returns the remainder. The actual number of
minutes is printed as the second number in the cell following the colon.
*/
|| TO_CHAR (
MOD (FLOOR ( (end_time - start_time) * 24 * 60), 60),
'FM00')
|| '</td><td '
/*
The sixth cell is the status of the backup according to the parent row of the
backup session in the repository. The value will be one of COMPLETED, RUNNING,
MISSING or null.
*/
|| CASE
WHEN status = 'COMPLETED'
THEN
'bgcolor="lime">'
WHEN SUBSTR (status, -6) = 'ERRORS'
THEN
'bgcolor="red">'
WHEN SUBSTR (status, -8) = 'WARNINGS'
THEN
'bgcolor="yellow">'
WHEN status = 'RUNNING'
THEN
'bgcolor="gold">'
WHEN status = 'MISSING'
THEN
'bgcolor="moccasin">'
ELSE
'>'
END
|| '<a href="#'
|| session_key
|| '">'
|| status
|| '</a></td>'
INTO output2
FROM bkupadm.last_backup
JOIN
(SELECT session_key,
operation,
status,
CASE (SELECT local_timezone
FROM bkupadm.database_inventory
WHERE dbid = l.dbid)
WHEN 'US/Central'
THEN
start_time
ELSE
CAST (
FROM_TZ (
CAST (start_time AS TIMESTAMP),
NVL ( (SELECT local_timezone
FROM bkupadm.database_inventory
WHERE dbid = l.dbid),
'GMT'))
AT TIME ZONE 'US/Central' AS DATE)
END
start_time,
CASE (SELECT local_timezone
FROM bkupadm.database_inventory
WHERE dbid = l.dbid)
WHEN 'US/Central'
THEN
end_time
ELSE
CAST (
FROM_TZ (CAST (end_time AS TIMESTAMP),
NVL ( (SELECT local_timezone
FROM bkupadm.database_inventory
WHERE dbid = l.dbid),
'GMT'))
AT TIME ZONE 'US/Central' AS DATE)
END
end_time
FROM bkupadm.last_backup_details lbd
JOIN
bkupadm.last_backup l
USING (session_key, operation))
USING (session_key, operation)
WHERE session_key = i.session_key AND operation = i.operation;
EXCEPTION
WHEN OTHERS
THEN
RAISE_APPLICATION_ERROR (
-20000,
'An error has occurred in the first loop on session_key '||i.session_key||', operation '||i.operation||': ' || SQLERRM);
utl_file.fclose (l_output);
END;
BEGIN
SELECT '<td rowspan=3><table border=0 align="left">'
|| '<font size="1">'
|| REPLACE (SYS_CONNECT_BY_PATH (operation, ','), ',')
|| '</font></table></td></tr>'
INTO output3
FROM (SELECT session_key,
'<tr><td width=200>'
|| LTRIM (operation)
|| '</td><td>'
|| status
|| '</td></tr>'
AS operation,
ROW_NUMBER () OVER (ORDER BY start_time) - 1
AS seq
FROM bkupadm.last_backup_details
WHERE session_key = (SELECT i.session_key FROM DUAL))
WHERE CONNECT_BY_ISLEAF = 1
CONNECT BY seq = PRIOR seq + 1
START WITH seq = 1;
EXCEPTION
WHEN NO_DATA_FOUND
THEN
output3 := '<td></td></tr>';
END;
SELECT '<tr><td>BLKCHK</td>' INTO output2_1 FROM DUAL;
BEGIN
SELECT '<td '
|| CASE
WHEN TRUNC (start_time) = TRUNC (SYSDATE - 2)
THEN
'bgcolor="yellow"> '
WHEN TRUNC (start_time) < TRUNC (SYSDATE - 3)
THEN
'bgcolor="red"> '
WHEN start_time IS NULL
THEN
'bgcolor="white"> '
ELSE
'bgcolor="lime"> '
END
|| TO_CHAR (start_time, 'MM-DD-YY HH:MI PM')
|| '</td><td '
|| CASE
WHEN TRUNC (end_time) = TRUNC (SYSDATE - 2)
THEN
'bgcolor="yellow"> '
WHEN TRUNC (end_time) < TRUNC (SYSDATE - 3)
THEN
'bgcolor="red"> '
WHEN end_time IS NULL
THEN
'bgcolor="white"> '
ELSE
'bgcolor="lime"> '
END
|| CASE
WHEN status = 'RUNNING' THEN ''
ELSE TO_CHAR (end_time, 'MM-DD-YY HH:MI PM')
END
|| '</td><td '
|| CASE
WHEN FLOOR ( (end_time - start_time) * 24) = 0
THEN
'bgcolor="lime"> '
WHEN FLOOR ( (end_time - start_time) * 24) = 1
THEN
'bgcolor="yellow"> '
WHEN FLOOR ( (end_time - start_time) * 24) > 1
THEN
'bgcolor="red"> '
WHEN end_time IS NULL
THEN
'bgcolor="white"> '
ELSE
'bgcolor="lime"> '
END
|| TO_CHAR (FLOOR ( (end_time - start_time) * 24), 'FM00')
|| NVL2 (end_time, ':', NULL)
|| TO_CHAR (
MOD (FLOOR ( (end_time - start_time) * 24 * 60), 60),
'FM00')
|| '</td><td '
|| CASE
WHEN status = 'COMPLETED'
THEN
'bgcolor="lime">'
WHEN SUBSTR (status, -6) = 'ERRORS'
THEN
'bgcolor="red">'
WHEN SUBSTR (status, -8) = 'WARNINGS'
THEN
'bgcolor="yellow">'
WHEN status = 'RUNNING'
THEN
'bgcolor="gold">'
WHEN status = 'MISSING'
THEN
'bgcolor="moccasin">'
ELSE
'>'
END
|| status
|| '</td></tr>'
INTO output2_2
FROM bkupadm.last_backup
JOIN
(SELECT session_key,
operation,
status,
CASE (SELECT local_timezone
FROM bkupadm.database_inventory
WHERE dbid = l.dbid)
WHEN 'US/Central'
THEN
start_time
ELSE
CAST (
FROM_TZ (
CAST (start_time AS TIMESTAMP),
NVL ( (SELECT local_timezone
FROM bkupadm.database_inventory
WHERE dbid = l.dbid),
'GMT'))
AT TIME ZONE 'US/Central' AS DATE)
END
start_time,
CASE (SELECT local_timezone
FROM bkupadm.database_inventory
WHERE dbid = l.dbid)
WHEN 'US/Central'
THEN
end_time
ELSE
CAST (
FROM_TZ (CAST (end_time AS TIMESTAMP),
NVL ( (SELECT local_timezone
FROM bkupadm.database_inventory
WHERE dbid = l.dbid),
'GMT'))
AT TIME ZONE 'US/Central' AS DATE)
END
end_time
FROM bkupadm.last_backup_details lbd
JOIN
bkupadm.last_backup l
USING (session_key, operation))
USING (session_key, operation)
WHERE dbid = i.dbid AND operation = 'BACKUP VALIDATE SESSION';
EXCEPTION
WHEN OTHERS
THEN
RAISE_APPLICATION_ERROR (
-20000,
'An error has occurred in the second loop: ' || SQLERRM);
utl_file.fclose (l_output);
END;
utl_file.put_line (l_output, output1);
utl_file.put_line (l_output, output2);
utl_file.put_line (l_output, output3);
utl_file.put_line (l_output, output2_1);
utl_file.put_line (l_output, output2_2);
utl_file.put_line (l_output,
'<tr><td></td><td></td><td></td><td></td><td></td></tr>');
END LOOP;
IF l_exclude = FALSE
THEN
lineoutput := '</table><p><br clear="left">';
utl_file.put_line (l_output, lineoutput);
FOR i IN c2_rec
LOOP
BEGIN
lineoutput := '<table border=1 align="left">';
utl_file.put_line (l_output, lineoutput);
lineoutput :=
'<tr><th bgcolor="#D8D8D8"><a name="'
|| i.session_key
|| '">'
|| i.db_name
|| ' ('
|| i.dbid
|| ') '
|| 'Output</a></th></tr>';
utl_file.put_line (l_output, lineoutput);
FOR c2_subrec
IN ( SELECT '<tr><td bgcolor="#F0F0F0"'
|| DECODE (output, ' ', ' height="20"')
|| '>'
|| output
|| '</td></tr>'
output
FROM rman.rc_rman_output
WHERE session_key = i.session_key
ORDER BY recid)
LOOP
utl_file.put_line (l_output,
c2_subrec.output);
END LOOP;
lineoutput := '</table><p><br clear="left">';
utl_file.put_line (l_output, lineoutput);
EXCEPTION
WHEN OTHERS
THEN
RAISE_APPLICATION_ERROR (
-20000,
'An error has occurred in the backup validation loop: ' || SQLERRM);
utl_file.fclose (l_output);
END;
END LOOP;
END IF;
utl_file.fclose (l_output);
EXCEPTION
WHEN OTHERS
THEN
RAISE_APPLICATION_ERROR (-20000, 'An error has occurred in the overall procedure: ' || SQLERRM);
END;
END backup_html_file;
/