forked from fatdba/Oracle-Database-Scripts
-
Notifications
You must be signed in to change notification settings - Fork 0
/
goldengate_healthcheck.sql
4768 lines (3952 loc) · 207 KB
/
goldengate_healthcheck.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
REM
REM This healthcheck script is for use on Oracle12c (12.1.0.2) databases only.
REM
REM
REM This script should be run by SYS on the instance running the integrated extract,
REM or the goldengate administrator with full privileges, or a user with DBA role
REM When run as SYS, queries on internal dictionary tables will produce output and summary overview
REM information will be available
REM
REM It is recommended to run with markup html ON (default is on) and generate an HTML file for web viewing.
REM Please provide the output in HTML format when Oracle (support or development) requests healthcheck output.
REM To convert output to a text file viewable with a text editor,
REM change the HTML ON to HTML OFF in the set markup command
REM Remember to set up a spool file to capture the output
REM
connect / as sysdba
define hcversion = 'v4.0.6'
set markup HTML ON entmap off spool on
set truncate off
set numwidth 15
set heading off
set feedback off
set verify off
set lines 200
set pages 9999
set numf 9999999999999999
alter session set nls_date_format='YYYY-MM-DD HH24:Mi:SS';
alter session set nls_language=american;
REM
REM spool file name AUTOMATICALLY GENERATED
REM
REM Collection name SRDC_ or MOS_
define COLLNAME='SRDC_'
define SRDCNAME='OGG_HC'
column SRDCSPOOLNAME new_val SRDCSPOOLNAME
select '&&COLLNAME'||upper('&&SRDCNAME')||'_'||upper(instance_name)||'_CDB_'||upper(cdb)||'_'||to_char(sysdate,'YYYYMMDD_HH24MISS')||'.htm' SRDCSPOOLNAME from v$instance, v$database;
spool &SRDCSPOOLNAME
select 'Oracle GoldenGate Integrated Extract/Replicat Health Check (&hcversion) for '||global_name||' on Instance='||instance_name||' generated: '||sysdate o from global_name, v$instance;
set heading on timing off
prompt Configuration: <a href="#Database">Database</a> <a href="#Queues in Database">Queue</a> <a href="#Administrators">Administrators</a> <a href="#Bundle">Bundle</a>
prompt Extract: <a href="#Extract">Configuration</a> <a href="#Capture Processes">Capture</a> <a href="#Capture Statistics">Statistics</a>
prompt Replicat: <a href="#Inbound Server Configuration">Configuration</a> <a href="#Apply Processes">Apply</a> <a href="#GoldenGate Inbound Server Statistics">Statistics</a>
prompt Analysis: <a href="#History">History</a> <a href="#Notification">Notifications</a> <a href="#DBA_OBJECTS">Objects</a> <a href="#Configuration_checks">Checks</a> <a href="#Performance Checks">Performance</a> <a href="#WaitAnalysis"> Wait Analysis </a> <a href="#Topology"> Topology </a> <a href="#AlertLogDetails"> AlertLogDetails</a>
prompt Statistics: <a href="#Statistics">Statistics</a> <a href="#Queue Statistics">Queue</a> <a href="#Capture Statistics">Capture</a> <a href="#Apply Statistics">Apply</a> <a href="#Errors">Apply_Errors</a>
prompt Patch Inventory: <a href="#Inventory">Patch List</a>
prompt
prompt
prompt
prompt ====================================================
prompt =====================<a name="Summary"><b>Summary</b></a> ==============================
prompt ====================================================
prompt
prompt
prompt
prompt ++ Summary Overview ++ ( <a href="#Database">Database</a> )
prompt
COL NAME HEADING 'Name'
col platform_name format a30 wrap
col current_scn format 99999999999999999
col host Heading 'Host'
col version heading 'Version'
col startup_time heading 'Startup|Time'
col database_role Heading 'Database|Role'
col DB_Edition heading 'Database|Edition' format a10
SELECT db.DBid,db.name, db.platform_name ,i.HOST_NAME HOST, i.VERSION,
DECODE(regexp_substr(v.banner, '[^ ]+', 1, 4),'Edition','Standard',regexp_substr(v.banner, '[^ ]+', 1, 4)) DB_Edition,
i.instance_number instance,db.cdb,db.database_role,db.current_scn, db.min_required_capture_change#
from v$database db,v$instance i, v$version v
where banner like 'Oracle%';
prompt
prompt Summary of GoldenGate Integrated Extracts configured in database (<a href="#Capture Processes">ConfigDetails</a> <a href="#Capture Statistics">StatsDetails</a>)
prompt
set lines 180
col extract_name format a8 heading 'Extract|Name'
col capture_name format a20 heading 'Capture|Name'
col capture_type format a10 heading 'Capture|Type'
col real_time_mine format a8 heading 'RealTime|Mine?'
col protocol format a8 heading 'OGG|Capture|Protocol'
col status Heading 'Status'
col state format a50 Heading 'Current|Capture|State'
col capture_user format a12 Heading 'Capture|User'
col inst_id Heading 'Instance'
col version format a12 Heading 'Capture|Version'
col required_checkpoint_scn format 999999999999999999 heading 'Required|Checkpoint|SCN'
col startup_time heading 'Process|Startup|Time'
col mined_MB Heading 'Redo|Mined|MB' format 99999999.999
col sent_MB Heading 'Sent to|Extract|Mb' format 99999999.999
col STATE_CHANGED_TIME Heading 'Last |State Changed|Time'
col Current_time Heading 'Current|Time'
col capture_lag Heading 'Capture|Lag|seconds'
col source_database format a20 heading 'Source DB|Name'
col required_checkpoint_scn format 999999999999999999 heading 'Required|Checkpoint|SCN'
col registered Heading 'Registered'
col last_ddl_time Heading 'Last Admin|Manage Time'
select SYSDATE Current_time, c.client_name extract_name,c.capture_name,
c.capture_user,
c.capture_type,
decode(cp.value,'N','NO', 'YES') Real_time_mine,
c.version,
c.required_checkpoint_scn,
(case
when g.sid=g.server_sid and g.serial#=g.server_serial# then 'V2'
else '<b>V1</b>'
end) protocol,
c.logminer_id,
o.created registered,
o.last_ddl_time,
c.status,
DECODE (g.STATE,'WAITING FOR CLIENT REQUESTS','<b><a href="#Performance Checks">'||g.state||'</a></b>',
'WAITING FOR INACTIVE DEQUEUERS','<b><a href="#Notification">'||g.state||'</a></b>',
'WAITING FOR TRANSACTION;WAITING FOR CLIENT','<b><a href="#Performance Checks">'||g.state||'</a></b>',
g.state) State,
(SYSDATE- g.capture_message_create_time)*86400 capture_lag,
g.bytes_of_redo_mined/1024/1024 mined_MB,
g.bytes_sent/1024/1024 sent_MB,
g.startup_time,
g.con_id,
g.inst_id,
c.source_database
from cdb_capture c, cdb_objects o,
gv$goldengate_capture g,
cdb_capture_parameters cp
where
c.capture_name=g.capture_name
and c.capture_name=cp.capture_name and cp.parameter='DOWNSTREAM_REAL_TIME_MINE'
and c.status='ENABLED' and c.purpose='GoldenGate Capture'
and c.capture_name=o.object_name
and c.capture_name=g.capture_name
union all
select SYSDATE Current_time, c.client_name extract_name,c.capture_name,
c.capture_user,
c.capture_type,
decode(cp.value, 'N','NO', 'YES') Real_time_mine,
c.version,
c.required_checkpoint_scn,
'Unavailable',
c.logminer_id,
o.created registered,
o.last_ddl_time,
c.status,
'Unavailable',
NULL,
NULL,
NULL,
NULL,
NULL,
NULL,
c.source_database
from cdb_capture c, cdb_objects o,
cdb_capture_parameters cp
where
c.status in ('DISABLED', 'ABORTED') and c.purpose='GoldenGate Capture'
and c.capture_name=cp.capture_name and cp.parameter='DOWNSTREAM_REAL_TIME_MINE'
and c.capture_name=o.object_name
order by extract_name;
prompt
prompt
prompt Integrated Extract key parameters (<a href="#CapParameters">Details</a>)
prompt
col parallelism format a20
col max_sga_size format a12
col excludetag format a20
col excludeuser format a20
col getapplops format a10
col getreplicates format a13
col checkpoint_frequency format a20
select cp.capture_name,substr(cp.capture_name,9,8) extract_name,
max(case when parameter='PARALLELISM' then value end) parallelism
,max(case when parameter='MAX_SGA_SIZE' then value end) max_sga_size
,max(case when parameter='EXCLUDETAG' then value end) excludetag
,max(case when parameter='EXCLUDEUSER' then value end) excludeuser
,max(case when parameter='GETAPPLOPS' then value end) getapplops
,max(case when parameter='GETREPLICATES' then value end) getreplicates
,max(case when parameter='_CHECKPOINT_FREQUENCY' then value end) checkpoint_frequency
from cdb_capture_parameters cp, cdb_capture c where c.capture_name=cp.capture_name
and c.purpose='GoldenGate Capture'
group by cp.capture_name;
prompt
prompt Integrated Extract/Logminer session info (<a href="#LogmnrDetails">Details</a>)
prompt
col session_name Heading 'Capture|Name'
col available_txn Heading 'Available|Chunks'
col delivered_txn Heading 'Delivered|Chunks'
col difference Heading 'Ready to Send|Chunks'
col builder_work_size Heading 'Builder|WorkSize'
col prepared_work_size Heading 'Prepared|WorkSize'
col used_memory_size Heading 'Used|Memory'
col max_memory_size Heading 'Max|Memory'
col used_mem_pct Heading 'Used|Memory|Percent'
select session_name, available_txn, delivered_txn,
available_txn-delivered_txn as difference,
builder_work_size, prepared_work_size,
used_memory_size , max_memory_size,
(used_memory_size/max_memory_size)*100 as used_mem_pct
FROM gv$logmnr_session order by session_name;
prompt Summary of GoldenGate Integrated Replicats configured in this database (<a href="#Apply Processes">ConfigDetails</a> <a href="#Apply Statistics">StatsDetails</a>)
prompt
set lines 180
col replicat_name format a8 heading 'Replicat|Name'
col server_name format a20 heading 'Server|Name'
col status Heading 'Status'
col state format a30 Heading 'Current|Coordinator|State'
col rcvstate format a32 Heading 'Current|Receiver|State'
col active_server_count Heading 'Active|Server|Count'
col inst_id Heading 'Instance'
col unassigned_complete_txns Heading 'Unassigned|Complete|Txns'
col apply_user format a12 Heading 'Apply|User'
col startup_time heading 'Process|Startup|Time'
col lwm heading 'Low Watermark|Message|Create Time'
col apply_tag heading 'Apply|Tag' format a20
col registered Heading 'Registered'
col last_ddl_time Heading 'Last Admin/|Manage Time'
col SourceTSrange heading 'Source TS Range|HWM-LWM|(seconds)'
col ApplyTSrange heading 'Apply_Time Range|HWM-LWM|(seconds)'
col applied_time heading 'LWM Apply|Time'
col current_time heading 'Current|Time'
REM 12.1.0.1 version (missing active_server_count)
select sysdate Current_time, ib.replicat_name replicat_name,ib.server_name,
ib.apply_user,
ib.status,
o.created registered,
o.last_ddl_time,
a.apply_tag,
DECODE (r.STATE,'Waiting for memory','<b><a href="#Memory"> Waiting for memory</a></b>',
r.state) rcvstate,
g.state,
g.active_server_count,
g.unassigned_complete_txns,
g.lwm_message_create_time lwm,
NVL(Round((g.hwm_message_create_time-g.lwm_message_create_time)*24*3600,2),0) SourceTSrange,
g.lwm_time apply_time,
NVL(Round((g.hwm_time-g.lwm_time)*24*3600,2),0) ApplyTSrange,
g.startup_time,
g.inst_id,
o.con_id
from cdb_goldengate_inbound ib, cdb_objects o,
cdb_apply a,
gv$gg_apply_coordinator g, gv$gg_apply_receiver r
where
ib.server_name=g.apply_name
and ib.status='ATTACHED'
and ib.server_name=o.object_name
and ib.server_name = g.apply_name
and ib.server_name = r.apply_name
and ib.server_name = a.apply_name
union all
select sysdate Current_time, ib.replicat_name replicat_name,ib.server_name,
ib.apply_user,
ib.status,
o.created registered,
o.last_ddl_time,
a.apply_tag,
'Unavailable',
null,
null,
null,
pg.applied_message_create_time,
null SourceTSrange,
pg.applied_time,
null ApplyTSrange,
null,
null,
o.con_id
from cdb_goldengate_inbound ib,cdb_objects o,
cdb_apply a,
cdb_gg_inbound_progress pg
where
ib.status !='ATTACHED'
and ib.server_name=a.apply_name
and ib.server_name=o.object_name
and ib.server_name=pg.server_name(+)
order by replicat_name;
prompt
prompt Integrated Replicat key parameters (<a href="#AppParameters">Details</a>)
prompt
col max_parallelism format a20
col commit_serialization format a20
col optimize_progress_table format a25
select apply_name,substr(apply_name,5,8) replicat_name,
max(case when parameter='PARALLELISM' then value end) parallelism
,max(case when parameter='MAX_PARALLELISM' then value end) max_parallelism
,max(case when parameter='COMMIT_SERIALIZATION' then value end) commit_serialization
,max(case when parameter='EAGER_SIZE' then value end) eager_size
,max(case when parameter='_DML_REORDER' then value end) batchsql
,max(case when parameter='_BATCHTRANSOPS' then value end) batchtransops
,max(case when parameter='BATCHSQL_MODE' then value end) batchsql_mode
,max(case when parameter='MAX_SGA_SIZE' then value end) max_sga_size
,max(case when parameter='OPTIMIZE_PROGRESS_TABLE' then value end) optimize_progress_table
from cdb_apply_parameters ap, cdb_goldengate_inbound ib where ib.server_name=ap.apply_name
group by apply_name;
prompt
prompt Integrated Replicat Current Open Transaction Summary <a href="#AppOpenTxn">Details</a>
prompt (ordered by LCR count)
prompt
set feedback on
select component_name, count(*) "Open Transactions",sum(cumulative_message_count) "Total LCRs" from gv$Goldengate_transaction where component_type='APPLY' group by component_name order by 3;
prompt +** Count of large transactions (lcrs>10000) **+
select component_name, count(*) "Open Transactions",sum(cumulative_message_count) "Total LCRs" from gv$Goldengate_transaction where component_type='APPLY' and cumulative_message_count > 10000 group by component_name order by 1;
set feedback off
prompt
prompt ++ <a name="Bundle">Replication Bundled Patch Information</a> (<a href="#Registry">Details</a>)
prompt
prompt
col name format A30
col value$ format A30 HEADing 'Bundled Patch version'
select value$ from sys.props$ where name ='REPLICATION_BUNDLE';
prompt
prompt
prompt +++ Outstanding alerts (<a href="#Alerts">Details</a>)
prompt
set feedback on
select message_type,creation_time,reason, suggested_action,
module_id,object_type,
instance_name||' (' ||instance_number||' )' Instance,
time_suggested
from dba_outstanding_alerts
where creation_time >= sysdate -10 and rownum < 11
order by creation_time desc;
prompt
prompt Count of Capture and Apply processes configured in database by purpose
set feedback on
col nmbr heading 'Count'
col type heading 'Process|Type'
select purpose,count(*) nmbr, 'CAPTURE' type from cdb_capture group by purpose
union all
select purpose, count(*) nmbr, 'APPLY' type from cdb_apply group by purpose
order by purpose;
set feedback off
-- note: this function is vulnerable to SQL injection, please do not copy it
create or replace function get_parameter(
param_name IN varchar2,
param_value IN OUT varchar2,
table_name IN varchar2,
table_param_name IN varchar2,
table_value IN varchar2
) return boolean is
statement varchar2(4000);
begin
-- construct query
statement := 'select ' || table_value || ' from ' || table_name || ' where '
|| table_param_name || '=''' || param_name || '''';
begin
execute immediate statement into param_value;
exception when no_data_found then
-- data is not found, so return FALSE
return FALSE;
end;
-- data found, so return TRUE
return TRUE;
end get_parameter;
/
create or replace procedure verify_init_parameter(
param_name IN varchar2,
expected_value IN varchar2,
verbose IN boolean,
more_info IN varchar2 := NULL,
more_info2 IN varchar2 := NULL,
at_least IN boolean := FALSE,
is_error IN boolean := FALSE,
use_like IN boolean := FALSE,
-- may not be necessary
alert_if_not_found IN boolean := TRUE
)
is
current_val_num NUMBER;
expected_val_num NUMBER;
current_value varchar2(512);
prefix varchar2(25);
matches boolean := FALSE;
comparison_str varchar2(20);
begin
-- Set prefix as warning or error
if is_error then
prefix := '+ <b>ERROR:</b> ';
else
prefix := '+ <b>WARNING:</b> ';
end if;
-- Set comparison string
if at_least then
comparison_str := ' at least ';
elsif use_like then
comparison_str := ' like ';
else
comparison_str := ' set to ';
end if;
-- Get value
if get_parameter(param_name, current_value, 'v$parameter', 'name', 'value') = FALSE
and alert_if_not_found then
-- Value isn't set, so output alert
dbms_output.put_line(prefix || 'The parameter ''' || param_name || ''' should be'
|| comparison_str || '''' || expected_value
|| ''', instead it has been left to its default value.');
if verbose and more_info is not null then
dbms_output.put_line(more_info);
if more_info2 is not null then
dbms_output.put_line(more_info2);
end if;
end if;
dbms_output.put_line('+');
return;
end if;
-- See if the expected value is what is actually set
if use_like then
-- Compare with 'like'
if current_value like '%'||expected_value||'%' then
matches := TRUE;
end if;
elsif at_least then
-- Do at least
current_val_num := to_number(current_value);
expected_val_num := to_number(expected_value);
if current_val_num >= expected_val_num then
matches := TRUE;
end if;
else
-- Do normal comparison
if current_value = expected_value then
matches := TRUE;
end if;
end if;
if matches = FALSE then
-- The values don't match, so alert
dbms_output.put_line(prefix || 'The parameter ''' || param_name || ''' should be'
|| comparison_str || '''' || expected_value
|| ''', instead it has the value ''' || current_value || '''.');
if verbose and more_info is not null then
dbms_output.put_line(more_info);
if more_info2 is not null then
dbms_output.put_line(more_info2);
end if;
end if;
dbms_output.put_line('+');
end if;
end verify_init_parameter;
/
prompt
prompt
prompt ++
prompt ++ <a name="Notification"><b>Notifications</b></a> ++
prompt ++
prompt
---Begin Heartbeat --
set serveroutput on size unlimited
col v_table_name new_value v_table_name noprint
variable v_table_name varchar2(64);
begin
execute immediate 'create table no_heartbeat (' ||
'LOCAL_DATABASE VARCHAR2(512),'||
'CURRENT_LOCAL_TS TIMESTAMP(6),'||
'REMOTE_DATABASE VARCHAR2(512),'||
'INCOMING_HEARTBEAT_AGE NUMBER,'||
'INCOMING_PATH VARCHAR2(4000),'||
'INCOMING_LAG NUMBER,'||
'OUTGOING_HEARTBEAT_AGE NUMBER,'||
'OUTGOING_PATH VARCHAR2(4000),'||
'OUTGOING_LAG NUMBER)';
exception when others then null;
end;
/
declare
v_table_name varchar2(64);
begin
select owner||'.'||object_name into :v_table_name from
dba_objects
where object_name='GG_LAG' and object_type='VIEW';
exception when others then
:v_table_name :='no_heartbeat';
end;
/
print v_table_name
set lines 200
SET verify off
define lag_threshold=10
define age_threshold=180
select to_char(current_local_ts,'DD-MON-YYYY HH24:MI:SSxFF') Current_TS,
remote_database ||'=>'|| local_database DB_Routing
, incoming_path
, decode(sign(incoming_lag - &lag_threshold),1, '<font color="red">' || incoming_lag || 's</font>',
incoming_lag||'s') as incoming_lag
, decode(sign(incoming_heartbeat_age - &age_threshold),1,'<font color="red">' || incoming_heartbeat_age || 's</font>',
incoming_heartbeat_age||'s') as incoming_heartbeat_age
, local_database ||'=>'||remote_database DB_RRouting
, outgoing_path
, decode(sign(outgoing_lag - &lag_threshold),1, '<font color="red">' || outgoing_lag || 's</font>',
outgoing_lag||'s') as outgoing_lag
, decode(sign(outgoing_heartbeat_age - &age_threshold),1,'<font color="red">' || outgoing_heartbeat_age || 's</font>',
outgoing_heartbeat_age||'s') as outgoing_heartbeat_age
from &v_table_name
order by remote_database,incoming_path;
declare
red_flag boolean := false;
cursor paths is select * from &v_table_name order by remote_database;
begin
for rec in paths loop
if (rec.incoming_lag>&lag_threshold or rec.incoming_heartbeat_age>&age_threshold) then
if(red_flag = false) then
red_flag := true;
dbms_output.put_line('+ Check path(s) with <font color="red">red</font> lag and/or heartbeat age.');
end if;
dbms_output.put_line('+ Please check path '||rec.incoming_path||' from '||rec.remote_database || ' to ' || rec.local_database ||
' and path '||rec.outgoing_path || ' from '||rec.local_database||' to '||rec.remote_database);
elsif (rec.outgoing_lag>&lag_threshold or rec.outgoing_heartbeat_age>&age_threshold) then
if(red_flag=false) then
red_flag := true;
dbms_output.put_line('+ Check path(s) with <font color="red">red</font> lag and/or heartbeat age.');
end if;
dbms_output.put_line('+ Please check path '||rec.outgoing_path ||' from '||rec.local_database ||' to '||rec.remote_database);
end if;
end loop;
end;
/
---End Heartbeat --
---Check for Data Vault
DECLARE
cursor dv_installed is
SELECT * FROM V$OPTION WHERE PARAMETER = 'Oracle Database Vault' and value = 'TRUE';
BEGIN
-- If Data Vault installed, check for additional DV roles
for rec in dv_installed loop
dbms_output.put_line('+ Database Vault is enabled.');
end loop;
END;
/
---End check for Data Vault
set feedback on
---Begin alert log check for last 24 hours
prompt +* Look for Errors reported in the Alert log for the last 24 hours (<a href="#AlertLogDetails"> GoldenGate module Details </a>)
select inst_id,adr_home,process_id,originating_timestamp,substr(MESSAGE_TEXT, 1, 300) message_text
from V$DIAG_ALERT_EXT d, v$database i
where module_id in ('Streams','GoldenGate','XStream')
and (regexp_like(d.adr_home,'/'||i.name||'/') or regexp_like(d.adr_home,'/'||lower(i.name)||'/') )
and (MESSAGE_TEXT like '%ORA-%' or upper(MESSAGE_TEXT) like '%ERROR%')
and cast(ORIGINATING_TIMESTAMP as DATE) > sysdate - 1440/1440
order by 1,2,3,4;
---End alert log check for last 24 hours
set serveroutput on size unlimited
declare
-- Change the variable below to FALSE if you just want the warnings and errors, not the advice
verbose boolean := TRUE;
-- By default a streams pool usage above 95% will result in output
streams_pool_usage_threshold number := 95;
-- The total number of registered archive logs to have before reporting an error
row_count number;
days_old number;
failed boolean;
streams_pool_usage number;
streams_pool_size varchar2(512);
cursor locked_admin is select username,account_status,con_id from cdb_users
where
username in (select capture_user from cdb_capture where purpose like 'GoldenGate%' union select apply_name from cdb_apply where purpose like 'GoldenGate%' union select username from cdb_goldengate_privileges)
and account_status != 'OPEN'
order by 1;
begin
-- Check for LOCKED GoldenGate Admin Users
for rec in locked_admin loop
dbms_output.put_line('+ <b>ERROR</b>: GoldenGate Admin ' || rec.username ||' account in container '||rec.con_id|| ' is ' ||rec.account_status);
end loop;
dbms_output.put_line('+');
end;
/
declare
countr NUMBER :=0 ;
cursor remote_db is select replace(regexp_substr(program,'@[A-Za-z0-9.-_]+ ',1,1),'@') remote_host from gv$session where (module = 'GoldenGate' or module like 'OGG-%') and (program like 'extract@%' or program like 'replic%@%' )
minus (select host_name||' ' from gv$instance );
begin
--- check if extract or replicat are being run from a remote database (other than an instance of the local database)
for rec in remote_db loop
if countr = 0 then
dbms_output.put_line('+ <b>WARNING</b>: GoldenGate processes are being run from remote hosts (systems other than instances of the local database).');
dbms_output.put_line('+ See <a href="#GGSessions">GoldenGate Session information</a> to identify the specific database sessions ');
countr := countr +1;
end if;
dbms_output.put_line(' '||rec.remote_host);
end loop;
end;
/
prompt
prompt ++ <a name="CAP Notification">Extract Notifications</a> ++
prompt
Prompt + Verify that dbms_logmnr packages have been compiled after patch application (DBA_REGISTRY and DBA_OBJECTS)
prompt + This is an indicator about whether the post_install instructions for the OGG/RDBMS patch have been applied.
---Begin Package time and LOGMNR time ---
column latest_time HEADING 'PATCH APPLIED' format a30
column logmnr_compilation_time HEADING 'LOGMNR COMPILED' format a30
column hide noprint
set heading on
prompt + LOGMNR package compile check
prompt
select distinct(obj.timestamp) hide, reg.ACTION Action, reg.patch_ID Patch_ID, reg.patch_uid Patch_UID, reg.Description Description, to_char(reg.action_time,'YYYY-MM-DD:HH24:MI:SS') latest_time,
obj.timestamp as logmnr_compilation_time,
case
when reg.action_time - to_timestamp(obj.timestamp,'YYYY-MM-DD:HH24:MI:SS') < interval '1' hour
or
reg.action != 'APPLY' then '<font color="green">OK</font>'
else '<font color="red">Please make sure Logminer compilation is up to date.</font>'
end
as "CHECK"
from dba_registry_sqlpatch reg,dba_objects obj
where reg.action_time = (select max(action_time) from dba_registry_sqlpatch) and
obj.timestamp = (select max(timestamp) from dba_objects where object_type like'PACKAGE%' and owner='SYS' and object_name like 'DBMS_LOGMNR%') and
obj.object_type like 'PACKAGE%' and obj.owner='SYS' and obj.object_name like 'DBMS_LOGMNR%';
---End Package time and LOGMNR time ---
prompt
----- Begin Logfile Gap Check
declare
countr Number :=0 ;
cursor logfile_gap is SELECT consumer_name,thread#, name PREVIOUS_ARCHIVELOG,
CASE
WHEN ids + 1 = lead_no - 1 THEN TO_CHAR (ids +1)
ELSE TO_CHAR (ids + 1) || '-' || TO_CHAR (lead_no - 1)
END
Gap_Sequence
FROM (SELECT consumer_name,thread#,name,sequence# ids,
LEAD (sequence#, 1, NULL)
OVER (PARTITION BY consumer_name,thread# ORDER BY consumer_name,thread#,sequence# ASC)
lead_no
FROM DBA_REGISTERED_ARCHIVED_LOG where purgeable='NO' )
WHERE lead_no != ids + 1 and lead_no > ids ;
begin
for rec in logfile_gap loop
dbms_output.put_line('+ <b>WARNING</b>: Missing logfile gap for Capture ' || rec.consumer_name || ' thread# ' ||
rec.thread#||' GAP_SEQUENCE: '||rec.gap_sequence );
dbms_output.put_line('+ PREVIOUS_ARCHIVELOG:'||rec.previous_archivelog);
dbms_output.put_line('+');
countr := countr+1;
end loop;
if countr > 0 then
dbms_output.put_line(' + Logfile GAP in DBA_REGISTERED_ARCHIVED_LOG reported by CAPTURE, thread# and sequence#. ');
dbms_output.put_line(' + PREVIOUS_ARCHIVELOG is name of existing archive log prior to gap. ');
dbms_output.put_line(' + GAP_SEQUENCE is the logfile sequence number or range of missing logfile sequence numbers ');
dbms_output.put_line(' + Purgeable logfiles are ignored for gap query. ');
end if;
end;
/
----- End Logfile Gap Check
prompt
set serveroutput on size unlimited
declare
-- Change the variable below to FALSE if you just want the warnings and errors, not the advice
verbose boolean := TRUE;
-- By default a streams pool usage above 95% will result in output
streams_pool_usage_threshold number := 95;
-- The total number of registered archive logs to have before reporting an error
registered_logs_threshold number := 1000;
-- The total number of days old the oldest archived log should be before reporting an error
registered_age_threshold number := 60; -- days
log_mode varchar2(20);
version varchar2(8);
ckpt_rec boolean;
row_count number;
days_old number;
failed boolean;
streams_pool_usage number;
streams_pool_size varchar2(512);
cursor aborted_capture is
select capture_name, error_number, error_message,con_id from cdb_capture where status='ABORTED';
cursor disabled_capture is select capture_name,con_id from cdb_capture where status='DISABLED' and purpose = 'GoldenGate Capture';
cursor unattached_extract is select capture_name, substr(capture_name,9,8) extract_name from gv$goldengate_capture where state='WAITING FOR INACTIVE DEQUEUERS';
cursor classic_capture is select capture_name from cdb_capture where capture_name like 'OGG%$%' and purpose='Streams';
-- check if state_changed_time is older than 3 minutes (approx .00211 * 86400)
cursor old_state_time is select capture_name,state,state_changed_time,to_char( (SYSDATE- state_changed_time)*1440,'99990.99') mins from gv$goldengate_capture where (SYSDATE - state_changed_time ) >.00211;
cursor ckpt_retention_time is select capture_name,client_name extract_name,
DECODE(checkpoint_retention_time,60,'<b>WARNING</b>: Checkpoint Retention time is set too high (60 days) for extract ',
7,'<b>INFO</b>: Checkpoint Retention time set to OGG default of 7 days for extract ',
'<b>INFO</b>: Checkpoint Retention time set to '||checkpoint_retention_time||' days by extract ') msg
from cdb_capture where purpose='GoldenGate Capture';
cursor cap_param_maxsga is select cp.capture_name, substr(cp.capture_name,9,8) extract_name, value
from cdb_capture_parameters cp, cdb_capture c where c.capture_name=cp.capture_name and purpose = 'GoldenGate Capture' and cp.parameter = 'MAX_SGA_SIZE';
begin
-- Check for aborted capture processes
for rec in aborted_capture loop
dbms_output.put_line('+ <b>ERROR</b>: Capture ''' || rec.capture_name || ''' has aborted with message ' ||
rec.error_message);
dbms_output.put_line('+');
end loop;
-- Check for disabled capture processes
for rec in disabled_capture loop
dbms_output.put_line('+ <b>WARNING</b>: Capture ''' || rec.capture_name || ''' is disabled');
end loop;
dbms_output.put_line('+');
-- Check for classic capture processes
for rec in classic_capture loop
dbms_output.put_line('+ <b>INFO</b>: Capture ''' || rec.capture_name || ''' is Oracle GoldenGate classic capture with LOGRETENTION enabled');
end loop;
dbms_output.put_line('+');
--- capture is started but extract is not attached
for rec in unattached_extract loop
dbms_output.put_line('+ <b>WARNING</b>: Extract '''||rec.extract_name||''' is not attached to capture '''||rec.capture_name||'''. State is WAITING FOR INACTIVE DEQUEUERS');
dbms_output.put_line('+ In GGSCI, use this command to start the extract process: START extract '||rec.extract_name);
dbms_output.put_line('+');
end loop;
dbms_output.put_line('+');
--- capture state has not changed for at least 3 minutes
for rec in old_state_time loop
dbms_output.put_line('+ <b>WARNING</b>: Capture State for '||rec.capture_name||' has not changed for over '|| rec.mins||' minutes.');
dbms_output.put_line('+ Last Capture state change timestamp is '||rec.state_changed_time||' State is '||rec.state);
end loop;
dbms_output.put_line('+');
--- Jobs scheduled to run every second
select count(*) into row_count from dba_scheduler_jobs where repeat_interval ='FREQ=SECONDLY' and enabled='TRUE';
select substr(version,0,8) into version from v$instance;
if row_count>0 and version = '12.1.0.1' then
dbms_output.put_line('+ <b>INFO</b>: There are '||row_count ||' <a href="#SECONDS">jobs scheduled to run every second</a>. Click the link to identify the jobs');
dbms_output.put_line('+ <b>INFO</b>: Jobs scheduled to run every second on an otherwise idle database can cause unexplained extract lag. ');
dbms_output.put_line('+ To workaround the issue, decrease the the scheduled job frequency.Database patch for bug 16796277 resolves the issue.');
dbms_output.put_line('+ Bug 16796277 is included in the OGG/RDBMS recommended bundled patch for 12.1.0.1 (MOS docid 1557031.1) ');
dbms_output.put_line('+ ');
end if;
ckpt_rec := FALSE;
for rec in ckpt_retention_time loop
dbms_output.put_line('+ '''||rec.msg||rec.extract_name);
ckpt_rec := TRUE;
end loop;
if (verbose and ckpt_rec) then
dbms_output.put_line('+ You can set this parameter to a different value by including or modifying the following line in the extract parameter file ');
dbms_output.put_line(' TRANLOGOPTIONS CHECKPOINTRETENTIONTIME number_of_days ');
dbms_output.put_line('+ where number_of_days is the number of days the extract logmining server will retain checkpoints. The default is 7 days');
end if;
dbms_output.put_line('+ ');
for rec in cap_param_maxsga loop
if rec.value = 'INFINITE' then
dbms_output.put_line('+ <b>WARNING</b>: Extract '||rec.extract_name||' has not set the memory size parameter for capture '||rec.capture_name);
dbms_output.put_line('+ Include the following line in the extract parameter file:');
dbms_output.put_line('TRANLOGOPTIONS INTEGRATEDPARAMS( MAX_SGA_SIZE 1000)');
dbms_output.put_line('+ ');
else
dbms_output.put_line('+ <b>INFO</b>: Extract '||rec.extract_name||' memory size for capture '||rec.capture_name||' is configured as '||rec.value||' Megabytes');
dbms_output.put_line('+ ');
end if;
end loop;
-- Check for too many registered archive logs
failed := FALSE;
select count(*) into row_count from dba_registered_archived_log where purgeable = 'NO';
select (sysdate - min(modified_time)) into days_old from dba_registered_archived_log where purgeable = 'NO';
if row_count > registered_logs_threshold then
failed := TRUE;
dbms_output.put_line('+ <b>WARNING</b>: ' || row_count || ' archived logs registered for extracts/captures..');
end if;
if days_old > registered_age_threshold then
failed := TRUE;
dbms_output.put_line('+ <b>WARNING</b>: The oldest archived log is ' || round(days_old) || ' days old!');
end if;
select count(*) into row_count from dba_registered_archived_log where purgeable = 'YES';
if row_count > registered_logs_threshold/2 then
dbms_output.put_line('+ <b>WARNING</b>: There are '|| row_count ||' archived logs ready to be purged from disk.');
dbms_output.put_line('+ Use the following select to identify unneeded logfiles:');
dbms_output.put_line('+ select name from dba_registered_archived_log where purgeable = "YES" ');
end if;
if failed then
dbms_output.put_line('+ A restarting Capture process must mine through each registered archive log.');
dbms_output.put_line('+ To speedup Capture restart, reduce the amount of disk space taken by the archived');
dbms_output.put_line('+ logs, and reduce Capture metadata, consider moving the first_scn automatically by ');
dbms_output.put_line('+ altering the checkpoint_retention_time capture parameter to a different value.');
dbms_output.put_line('+ Include ( or modify an existing line) in the extract parameter file ');
dbms_output.put_line('+ TRANLOGOPTIONS CHECKPOINTRETENTIONTIME number_of_days ');
dbms_output.put_line('+ where number_of_days is the number of days the extract logmining server will retain checkpoints.');
dbms_output.put_line('+ For more information, see the Oracle GoldenGate for Windows and UNIX Reference Guide ');
dbms_output.put_line('+ Note that once the first scn is increased, Capture will no longer be able to mine prior to ' );
dbms_output.put_line('+ this new scn value.');
dbms_output.put_line('+ Successive moves of the first_scn will remove unneeded registered archive');
dbms_output.put_line('+ logs only if the files have been removed from disk');
end if;
dbms_output.put_line('+ ');
end;
/
prompt
prompt ++ <a name="APP Notification">Replicat Notifications</a> ++
prompt
set serveroutput on size unlimited
declare
-- Change the variable below to FALSE if you just want the warnings and errors, not the advice
verbose boolean := TRUE;
-- By default any errors in cdb_apply_error will result in output
apply_error_threshold number := 0;
-- By default a streams pool usage above 95% will result in output
streams_pool_usage_threshold number := 95;
log_mode varchar2(20);
row_count number;
failed boolean;
streams_pool_usage number;
streams_pool_size varchar2(512);
cursor apply_error is select distinct apply_name from cdb_apply_error;
cursor aborted_apply is
select apply_name, error_number, error_message,con_id from cdb_apply where status='ABORTED' and purpose = 'GoldenGate Apply';
cursor disabled_apply is select apply_name,con_id from cdb_apply where status='DISABLED' and purpose = 'GoldenGate Apply';
cursor apply_parameters is select apply_name,substr(apply_name,5,8) replicat_name,
max(case when parameter='PARALLELISM' then value end) parallelism
,max(case when parameter='MAX_PARALLELISM' then value end) max_parallelism
,max(case when parameter='COMMIT_SERIALIZATION' then value end) commit_serialization
,max(case when parameter='EAGER_SIZE' then value end) eager_size
,max(case when parameter='_DML_REORDER' then value end) batchsql
,max(case when parameter='BATCHSQL_MODE' then value end) batchsql_mode
,max(case when parameter='_BATCHTRANSOPS' then value end) batchtransops
,max(case when parameter='MAX_SGA_SIZE' then value end) max_sga_size
,max(case when parameter='OPTIMIZE_PROGRESS_TABLE' then value end) optimize_progress_table
from cdb_apply_parameters ap, cdb_goldengate_inbound ib where ib.server_name=ap.apply_name
group by apply_name order by apply_name;
begin
-- Check for aborted apply processes
for rec in aborted_apply loop
dbms_output.put_line('+ <b>ERROR</b>: Apply ''' || rec.apply_name || ''' has aborted with message ' ||
rec.error_message);
if verbose then
-- Try to give some suggestions
-- TODO: include other errors, suggest how to recover
if rec.error_number = 26714 then
dbms_output.put_line('+ This apply aborted because a non-fatal user error has occurred and the ''disable_on_error'' parameter is ''Y''.');
dbms_output.put_line('+ Please resolve the errors and restart the replicat.');
dbms_output.put_line('+');
elsif rec.error_number = 26688 then
dbms_output.put_line('+ This apply aborted because a column value in a particular change record belonging to a key column was not found. ');
dbms_output.put_line('+ A column value in a particular change record belonging to a key column was not found. ');
dbms_output.put_line('+ For more information, search the trace files for ''26688'' and view the relevant trace file.');
dbms_output.put_line('+ Check that the extract parameter file includes LOGALLSUPCOLS command.');
dbms_output.put_line('+ Also confirm that OGG 12.1.2 (or above) ADD TRANDATA or ADD SCHEMATRANDATA have been performed at source database.');
dbms_output.put_line('+');
end if;
end if;
end loop;
-- Check for apply errors in the error queue
for rec in apply_error loop
select count(*) into row_count from cdb_apply_error where rec.apply_name = apply_name;
if row_count > apply_error_threshold then
dbms_output.put_line('+ <b>ERROR</b>: Apply ''' || rec.apply_name || ''' has placed ' ||
row_count || ' transactions in the error queue! Please check the cdb_apply_error view.');
end if;
end loop;
dbms_output.put_line('+');
-- Check for disabled apply processes
for rec in disabled_apply loop
dbms_output.put_line('+ <b>WARNING</b>: Apply ''' || rec.apply_name || ''' is disabled');
end loop;
dbms_output.put_line('+');
for rec in apply_parameters loop
if rec.max_sga_size <> 'INFINITE' then
if rec.max_sga_size < 1024 then
dbms_output.put_line('+ <b>WARNING</b>: Apply memory from streams pool set to '||rec.max_sga_size||'MB for Integrated Replicat '||rec.replicat_name );
dbms_output.put_line('+ Specify at least 1024 MB for MAX_SGA_SIZE when using Integrated Replicat');
else
dbms_output.put_line('+ <b>INFO</b>: Apply memory from streams pool set to '||rec.max_sga_size||'MB for Integrated Replicat '||rec.replicat_name );
end if;
end if;
if rec.optimize_progress_table = 'Y' then
select LOG_MODE into log_mode from v$database;
if log_mode<>'ARCHIVELOG' then
dbms_output.put_line('+ <b>WARNING</b>: Progress table maintenance configured via redo has been specified, but database is not in ARCHIVELOG mode for Integrated Replicat '||rec.replicat_name);
dbms_output.put_line('+ The progress table maintenance will not be performed via redo. Optimize_progress_table setting is ignored for Integrated Replicat '||rec.replicat_name);
else
dbms_output.put_line('+ <b>INFO</b>: Progress table maintenance configured via redo for Integrated Replicat '||rec.replicat_name);
end if;
end if;
dbms_output.put_line('+ ');
if rec.parallelism=1 then
dbms_output.put_line('+ <b>INFO</b>: Parallelism and autotuning are disabled for Integrated Replicat '||rec.replicat_name);
end if;
if rec.parallelism=rec.max_parallelism and rec.parallelism>1 then
dbms_output.put_line('+ <b>INFO</b>: Parallelism is enabled but autotuning is disabled for Integrated Replicat '||rec.replicat_name);
end if;
if rec.parallelism<>rec.max_parallelism and rec.parallelism>1 then
dbms_output.put_line('+ <b>INFO</b>: Both Parallelism and autotuning are enabled for Integrated Replicat '||rec.replicat_name);
end if;
if rec.commit_serialization='FULL' then
dbms_output.put_line('+ <b>INFO</b>: Apply parallelism restricted to source commit order for Integrated Replicat '||rec.replicat_name);
end if;
if rec.batchsql is not null then