├── .gitignore
├── README.md
├── pyora.py
└── zabbix-template
├── Pyora.xml
├── Pyora_ExternalCheck.xml
├── Pyora_ExternalCheck_4.0.xml
└── Pyora_zabbix_2.4.xml
/.gitignore:
--------------------------------------------------------------------------------
1 | ### Python template
2 | # Byte-compiled / optimized / DLL files
3 | __pycache__/
4 | *.py[cod]
5 | *$py.class
6 |
7 | # C extensions
8 | *.so
9 |
10 | # Distribution / packaging
11 | .Python
12 | env/
13 | build/
14 | develop-eggs/
15 | dist/
16 | downloads/
17 | eggs/
18 | .eggs/
19 | lib/
20 | lib64/
21 | parts/
22 | sdist/
23 | var/
24 | *.egg-info/
25 | .installed.cfg
26 | *.egg
27 |
28 | # PyInstaller
29 | # Usually these files are written by a python script from a template
30 | # before PyInstaller builds the exe, so as to inject date/other infos into it.
31 | *.manifest
32 | *.spec
33 |
34 | # Installer logs
35 | pip-log.txt
36 | pip-delete-this-directory.txt
37 |
38 | # Unit test / coverage reports
39 | htmlcov/
40 | .tox/
41 | .coverage
42 | .coverage.*
43 | .cache
44 | nosetests.xml
45 | coverage.xml
46 | *,cover
47 |
48 | # Translations
49 | *.mo
50 | *.pot
51 |
52 | # Django stuff:
53 | *.log
54 |
55 | # Sphinx documentation
56 | docs/_build/
57 |
58 | # PyBuilder
59 | target/
60 |
61 | # Created by .ignore support plugin (hsz.mobi)
62 | .idea
63 |
64 | .DS_Store
65 | .vscode
66 |
--------------------------------------------------------------------------------
/README.md:
--------------------------------------------------------------------------------
1 | Pyora
2 | =====
3 |
4 | Python script to monitor oracle
5 |
6 | Requirements
7 | =====
8 | cx-Oracle==8.2.1
9 |
10 | python-argparse
11 |
12 | Note:Try installing python-argparse: `easy_install argparse` or `yum install python-argarse` on RHEL/Centos.
13 |
14 | Tested with python 3.8, should work with any 3.x version. For Python2 version check python2 branch.
15 |
16 | Create Oracle user for Pyora usage
17 | =====
18 |
19 | CREATE USER ZABBIX IDENTIFIED BY DEFAULT TABLESPACE SYSTEM TEMPORARY TABLESPACE TEMP PROFILE DEFAULT ACCOUNT UNLOCK;
20 | GRANT CONNECT TO ZABBIX;
21 | GRANT RESOURCE TO ZABBIX;
22 | ALTER USER ZABBIX DEFAULT ROLE ALL;
23 | GRANT SELECT ANY TABLE TO ZABBIX;
24 | GRANT CREATE SESSION TO ZABBIX;
25 | GRANT SELECT ANY DICTIONARY TO ZABBIX;
26 | GRANT UNLIMITED TABLESPACE TO ZABBIX;
27 | GRANT SELECT ANY DICTIONARY TO ZABBIX;
28 | GRANT SELECT ON V_$SESSION TO ZABBIX;
29 | GRANT SELECT ON V_$SYSTEM_EVENT TO ZABBIX;
30 | GRANT SELECT ON V_$EVENT_NAME TO ZABBIX;
31 | GRANT SELECT ON V_$RECOVERY_FILE_DEST TO ZABBIX;
32 |
33 |
34 | Usage
35 | =====
36 |
37 | » python3 pyora.py
38 | usage: pyora.py [-h] [--username USERNAME] [--password PASSWORD]
39 | [--address ADDRESS] [--database DATABASE]
40 |
41 | {activeusercount,bufbusywaits,check_active,check_archive,commits,db_close,db_connect,dbfilesize,dbprllwrite,dbscattread,dbseqread,dbsize,dbsnglwrite,deadlocks,directread,directwrite,dsksortratio,enqueue,freebufwaits,hparsratio,indexffs,lastapplarclog,lastarclog,latchfree,logfilesync,logonscurrent,logprllwrite,logswcompletion,netresv,netroundtrips,netsent,query_lock,query_redologs,query_rollbacks,query_sessions,query_temp,rcachehit,redowrites,rollbacks,show_tablespaces,tablespace,tblrowsscans,tblscans,uptime,version}
42 | ...
43 | pyora.py: error: too few arguments
44 |
45 |
46 | # Check Oracle version
47 | 0: python3 pyora.py --username pyora --password secret --address 127.0.0.1 --database DATABASE version
48 | Oracle Database 10g Enterprise Edition Release 10.2.0.4.0 - 64bi
49 |
50 | # Check Oracle active user count
51 | 0: python3 pyora.py --username pyora --password secret --address 127.0.0.1 --database DATABASE activeusercount
52 | 68
53 |
54 | # Show the tablespaces names in a JSON format
55 | 0: python3 pyora.py show_tablespaces
56 | {
57 | "data":[
58 | { "{#TABLESPACE}":"ORASDPM"},
59 | { "{#TABLESPACE}":"MDS"},
60 | { "{#TABLESPACE}":"SOADEV_MDS"},
61 | { "{#TABLESPACE}":"ORABAM"},
62 | { "{#TABLESPACE}":"SOAINF"},
63 | { "{#TABLESPACE}":"DATA"},
64 | { "{#TABLESPACE}":"MGMT_AD4J_TS"},
65 | { "{#TABLESPACE}":"MGMT_ECM_DEPOT_TS"},
66 | { "{#TABLESPACE}":"MGMT_TABLESPACE"},
67 | { "{#TABLESPACE}":"RECOVER"},
68 | { "{#TABLESPACE}":"RMAN_CAT"},
69 | { "{#TABLESPACE}":"SYSAUX"},
70 | { "{#TABLESPACE}":"SYSTEM"},
71 | { "{#TABLESPACE}":"TEMP"},
72 | { "{#TABLESPACE}":"UNDOTBS"},
73 | { "{#TABLESPACE}":"VIRTUALCENTER"},
74 | ]
75 | }
76 |
77 | # Show a particular tablespace usage in %
78 | 0: python3 pyora.py --username pyora --password secret --address 127.0.0.1 --database DATABASE tablespace SYSTEM
79 | 92.45
80 |
81 |
82 |
--------------------------------------------------------------------------------
/pyora.py:
--------------------------------------------------------------------------------
1 | #!/usr/bin/env python
2 | # coding: utf-8
3 | # vim: tabstop=2 noexpandtab
4 | """
5 | Author: Danilo F. Chilene
6 | Email: bicofino at gmail dot com
7 | """
8 |
9 | import argparse
10 | import inspect
11 | import json
12 | import re
13 |
14 | import cx_Oracle
15 |
16 | version = 0.0
17 |
18 |
19 | class Checks(object):
20 | def check_active(self):
21 | """Check Intance is active and open"""
22 | sql = "select to_char(case when inst_cnt > 0 then 1 else 0 end, \
23 | 'FM99999999999999990') retvalue from (select count(*) inst_cnt \
24 | from v$instance where status = 'OPEN' and logins = 'ALLOWED' \
25 | and database_status = 'ACTIVE')"
26 | self.cur.execute(sql)
27 | res = self.cur.fetchall()
28 | for i in res:
29 | print(i[0])
30 |
31 | def rcachehit(self):
32 | """Read Cache hit ratio"""
33 | sql = "SELECT nvl(to_char((1 - (phy.value - lob.value - dir.value) / \
34 | ses.value) * 100, 'FM99999990.9999'), '0') retvalue \
35 | FROM v$sysstat ses, v$sysstat lob, \
36 | v$sysstat dir, v$sysstat phy \
37 | WHERE ses.name = 'session logical reads' \
38 | AND dir.name = 'physical reads direct' \
39 | AND lob.name = 'physical reads direct (lob)' \
40 | AND phy.name = 'physical reads'"
41 | self.cur.execute(sql)
42 | res = self.cur.fetchall()
43 | for i in res:
44 | print(i[0])
45 |
46 | def dsksortratio(self):
47 | """Disk sorts ratio"""
48 | sql = "SELECT nvl(to_char(d.value/(d.value + m.value)*100, \
49 | 'FM99999990.9999'), '0') retvalue \
50 | FROM v$sysstat m, v$sysstat d \
51 | WHERE m.name = 'sorts (memory)' \
52 | AND d.name = 'sorts (disk)'"
53 | self.cur.execute(sql)
54 | res = self.cur.fetchall()
55 | for i in res:
56 | print(i[0])
57 |
58 | def activeusercount(self):
59 | """Count of active users"""
60 | sql = "select to_char(count(*)-1, 'FM99999999999999990') retvalue \
61 | from v$session where username is not null \
62 | and status='ACTIVE'"
63 | self.cur.execute(sql)
64 | res = self.cur.fetchall()
65 | for i in res:
66 | print(i[0])
67 |
68 | def dbsize(self):
69 | """Size of user data (without temp)"""
70 | sql = "SELECT to_char(sum( NVL(a.bytes - NVL(f.bytes, 0), 0)), \
71 | 'FM99999999999999990') retvalue \
72 | FROM sys.dba_tablespaces d, \
73 | (select tablespace_name, sum(bytes) bytes from dba_data_files \
74 | group by tablespace_name) a, \
75 | (select tablespace_name, sum(bytes) bytes from \
76 | dba_free_space group by tablespace_name) f \
77 | WHERE d.tablespace_name = a.tablespace_name(+) AND \
78 | d.tablespace_name = f.tablespace_name(+) \
79 | AND NOT (d.extent_management like 'LOCAL' AND d.contents \
80 | like 'TEMPORARY')"
81 | self.cur.execute(sql)
82 | res = self.cur.fetchall()
83 | for i in res:
84 | print(i[0])
85 |
86 | def dbfilesize(self):
87 | """Size of all datafiles"""
88 | sql = "select to_char(sum(bytes), 'FM99999999999999990') retvalue \
89 | from dba_data_files"
90 | self.cur.execute(sql)
91 | res = self.cur.fetchall()
92 | for i in res:
93 | print(i[0])
94 |
95 | def version(self):
96 | """Oracle version (Banner)"""
97 | sql = "select banner from v$version where rownum=1"
98 | self.cur.execute(sql)
99 | res = self.cur.fetchall()
100 | for i in res:
101 | print(i[0])
102 |
103 | def uptime(self):
104 | """Instance Uptime (seconds)"""
105 | sql = "select to_char((sysdate-startup_time)*86400, \
106 | 'FM99999999999999990') retvalue from v$instance"
107 | self.cur.execute(sql)
108 | res = self.cur.fetchmany(numRows=3)
109 | for i in res:
110 | print(i[0])
111 |
112 | def commits(self):
113 | """User Commits"""
114 | sql = "select nvl(to_char(value, 'FM99999999999999990'), '0') retvalue from \
115 | v$sysstat where name = 'user commits'"
116 | self.cur.execute(sql)
117 | res = self.cur.fetchmany(numRows=3)
118 | for i in res:
119 | print(i[0])
120 |
121 | def rollbacks(self):
122 | """User Rollbacks"""
123 | sql = (
124 | "select nvl(to_char(value, 'FM99999999999999990'), '0') retvalue from "
125 | "v$sysstat where name = 'user rollbacks'"
126 | )
127 | self.cur.execute(sql)
128 | res = self.cur.fetchall()
129 | for i in res:
130 | print(i[0])
131 |
132 | def deadlocks(self):
133 | """Deadlocks"""
134 | sql = "select nvl(to_char(value, 'FM99999999999999990'), '0') retvalue from \
135 | v$sysstat where name = 'enqueue deadlocks'"
136 | self.cur.execute(sql)
137 | res = self.cur.fetchall()
138 | for i in res:
139 | print(i[0])
140 |
141 | def redowrites(self):
142 | """Redo Writes"""
143 | sql = "select nvl(to_char(value, 'FM99999999999999990'), '0') retvalue from \
144 | v$sysstat where name = 'redo writes'"
145 | self.cur.execute(sql)
146 | res = self.cur.fetchall()
147 | for i in res:
148 | print(i[0])
149 |
150 | def tblscans(self):
151 | """Table scans (long tables)"""
152 | sql = "select nvl(to_char(value, 'FM99999999999999990'), '0') retvalue from \
153 | v$sysstat where name = 'table scans (long tables)'"
154 | self.cur.execute(sql)
155 | res = self.cur.fetchall()
156 | for i in res:
157 | print(i[0])
158 |
159 | def tblrowsscans(self):
160 | """Table scan rows gotten"""
161 | sql = "select nvl(to_char(value, 'FM99999999999999990'), '0') retvalue from \
162 | v$sysstat where name = 'table scan rows gotten'"
163 | self.cur.execute(sql)
164 | res = self.cur.fetchall()
165 | for i in res:
166 | print(i[0])
167 |
168 | def indexffs(self):
169 | """Index fast full scans (full)"""
170 | sql = "select nvl(to_char(value, 'FM99999999999999990'), '0') retvalue from \
171 | v$sysstat where name = 'index fast full scans (full)'"
172 | self.cur.execute(sql)
173 | res = self.cur.fetchall()
174 | for i in res:
175 | print(i[0])
176 |
177 | def hparsratio(self):
178 | """Hard parse ratio"""
179 | sql = "SELECT nvl(to_char(h.value/t.value*100,'FM99999990.9999'), '0') \
180 | retvalue FROM v$sysstat h, v$sysstat t WHERE h.name = 'parse \
181 | count (hard)' AND t.name = 'parse count (total)'"
182 | self.cur.execute(sql)
183 | res = self.cur.fetchall()
184 | for i in res:
185 | print(i[0])
186 |
187 | def netsent(self):
188 | """Bytes sent via SQL*Net to client"""
189 | sql = "select nvl(to_char(value, 'FM99999999999999990'), '0') retvalue from \
190 | v$sysstat where name = 'bytes sent via SQL*Net to client'"
191 | self.cur.execute(sql)
192 | res = self.cur.fetchall()
193 | for i in res:
194 | print(i[0])
195 |
196 | def netresv(self):
197 | """Bytes received via SQL*Net from client"""
198 | sql = "select nvl(to_char(value, 'FM99999999999999990'), '0') retvalue from \
199 | v$sysstat where name = 'bytes received via SQL*Net from client'"
200 | self.cur.execute(sql)
201 | res = self.cur.fetchall()
202 | for i in res:
203 | print(i[0])
204 |
205 | def netroundtrips(self):
206 | """SQL*Net roundtrips to/from client"""
207 | sql = "select nvl(to_char(value, 'FM99999999999999990'), '0') retvalue from \
208 | v$sysstat where name = 'SQL*Net roundtrips to/from client'"
209 | self.cur.execute(sql)
210 | res = self.cur.fetchall()
211 | for i in res:
212 | print(i[0])
213 |
214 | def logonscurrent(self):
215 | """Logons current"""
216 | sql = "select nvl(to_char(value, 'FM99999999999999990'), '0') retvalue from \
217 | v$sysstat where name = 'logons current'"
218 | self.cur.execute(sql)
219 | res = self.cur.fetchall()
220 | for i in res:
221 | print(i[0])
222 |
223 | def lastarclog(self):
224 | """Last archived log sequence"""
225 | sql = "select to_char(max(SEQUENCE#), 'FM99999999999999990') \
226 | retvalue from v$log where archived = 'YES'"
227 | self.cur.execute(sql)
228 | res = self.cur.fetchall()
229 | for i in res:
230 | print(i[0])
231 |
232 | def lastapplarclog(self):
233 | """Last applied archive log (at standby).Next items requires
234 | [timed_statistics = true]"""
235 | sql = "select to_char(max(lh.SEQUENCE#), 'FM99999999999999990') \
236 | retvalue from v$loghist lh, v$archived_log al \
237 | where lh.SEQUENCE# = al.SEQUENCE# and applied='YES'"
238 | self.cur.execute(sql)
239 | res = self.cur.fetchall()
240 | for i in res:
241 | print(i[0])
242 |
243 | def freebufwaits(self):
244 | """Free buffer waits"""
245 | sql = "select nvl(to_char(time_waited, 'FM99999999999999990'), '0') retvalue \
246 | from v$system_event se, v$event_name en \
247 | where se.event(+) = en.name and en.name = 'free buffer waits'"
248 | self.cur.execute(sql)
249 | res = self.cur.fetchall()
250 | for i in res:
251 | print(i[0])
252 |
253 | def bufbusywaits(self):
254 | """Buffer busy waits"""
255 | sql = "select nvl(to_char(time_waited, 'FM99999999999999990'), '0') retvalue \
256 | from v$system_event se, v$event_name en where se.event(+) = \
257 | en.name and en.name = 'buffer busy waits'"
258 | self.cur.execute(sql)
259 | res = self.cur.fetchall()
260 | for i in res:
261 | print(i[0])
262 |
263 | def logswcompletion(self):
264 | """log file switch completion"""
265 | sql = "select nvl(to_char(time_waited, 'FM99999999999999990'), '0') retvalue \
266 | from v$system_event se, v$event_name en where se.event(+) \
267 | = en.name and en.name = 'log file switch completion'"
268 | self.cur.execute(sql)
269 | res = self.cur.fetchall()
270 | for i in res:
271 | print(i[0])
272 |
273 | def logfilesync(self):
274 | """Log file sync"""
275 | sql = "select nvl(to_char(time_waited, 'FM99999999999999990'), '0') retvalue \
276 | from v$system_event se, v$event_name en \
277 | where se.event(+) = en.name and en.name = 'log file sync'"
278 | self.cur.execute(sql)
279 | res = self.cur.fetchall()
280 | for i in res:
281 | print(i[0])
282 |
283 | def logprllwrite(self):
284 | """Log file parallel write"""
285 | sql = "select nvl(to_char(time_waited, 'FM99999999999999990'), '0') retvalue \
286 | from v$system_event se, v$event_name en where se.event(+) \
287 | = en.name and en.name = 'log file parallel write'"
288 | self.cur.execute(sql)
289 | res = self.cur.fetchall()
290 | for i in res:
291 | print(i[0])
292 |
293 | def enqueue(self):
294 | """Enqueue waits"""
295 | sql = "select nvl(to_char(time_waited, 'FM99999999999999990'), '0') retvalue \
296 | from v$system_event se, v$event_name en \
297 | where se.event(+) = en.name and en.name = 'enqueue'"
298 | self.cur.execute(sql)
299 | res = self.cur.fetchall()
300 | for i in res:
301 | print(i[0])
302 |
303 | def dbseqread(self):
304 | """DB file sequential read waits"""
305 | sql = "select nvl(to_char(time_waited, 'FM99999999999999990'), '0') retvalue \
306 | from v$system_event se, v$event_name en where se.event(+) \
307 | = en.name and en.name = 'db file sequential read'"
308 | self.cur.execute(sql)
309 | res = self.cur.fetchall()
310 | for i in res:
311 | print(i[0])
312 |
313 | def dbscattread(self):
314 | """DB file scattered read"""
315 | sql = "select nvl(to_char(time_waited, 'FM99999999999999990'), '0') retvalue \
316 | from v$system_event se, v$event_name en where se.event(+) \
317 | = en.name and en.name = 'db file scattered read'"
318 | self.cur.execute(sql)
319 | res = self.cur.fetchall()
320 | for i in res:
321 | print(i[0])
322 |
323 | def dbsnglwrite(self):
324 | """DB file single write"""
325 | sql = "select nvl(to_char(time_waited, 'FM99999999999999990'), '0') retvalue \
326 | from v$system_event se, v$event_name en where se.event(+) \
327 | = en.name and en.name = 'db file single write'"
328 | self.cur.execute(sql)
329 | res = self.cur.fetchall()
330 | for i in res:
331 | print(i[0])
332 |
333 | def dbprllwrite(self):
334 | """DB file parallel write"""
335 | sql = "select nvl(to_char(time_waited, 'FM99999999999999990'), '0') retvalue \
336 | from v$system_event se, v$event_name en where se.event(+) \
337 | = en.name and en.name = 'db file parallel write'"
338 | self.cur.execute(sql)
339 | res = self.cur.fetchall()
340 | for i in res:
341 | print(i[0])
342 |
343 | def directread(self):
344 | """Direct path read"""
345 | sql = "select nvl(to_char(time_waited, 'FM99999999999999990'), '0') retvalue \
346 | from v$system_event se, v$event_name en where se.event(+) \
347 | = en.name and en.name = 'direct path read'"
348 | self.cur.execute(sql)
349 | res = self.cur.fetchall()
350 | for i in res:
351 | print(i[0])
352 |
353 | def directwrite(self):
354 | """Direct path write"""
355 | sql = "select nvl(to_char(time_waited, 'FM99999999999999990'), '0') retvalue \
356 | from v$system_event se, v$event_name en where se.event(+) \
357 | = en.name and en.name = 'direct path write'"
358 | self.cur.execute(sql)
359 | res = self.cur.fetchall()
360 | for i in res:
361 | print(i[0])
362 |
363 | def latchfree(self):
364 | """latch free"""
365 | sql = "select nvl(to_char(time_waited, 'FM99999999999999990'), '0') retvalue \
366 | from v$system_event se, v$event_name en where se.event(+) \
367 | = en.name and en.name = 'latch free'"
368 | self.cur.execute(sql)
369 | res = self.cur.fetchall()
370 | for i in res:
371 | print(i[0])
372 |
373 | def tablespace(self, name):
374 | """Get tablespace usage"""
375 | sql = f"""SELECT tablespace_name,
376 | 100-(TRUNC((max_free_mb/max_size_mb) * 100)) AS USED
377 | FROM ( SELECT a.tablespace_name,b.size_mb,a.free_mb,b.max_size_mb,a.free_mb + (b.max_size_mb - b.size_mb) AS max_free_mb
378 | FROM (SELECT tablespace_name,TRUNC(SUM(bytes)/1024/1024) AS free_mb FROM dba_free_space GROUP BY tablespace_name) a,
379 | (SELECT tablespace_name,TRUNC(SUM(bytes)/1024/1024) AS size_mb,TRUNC(SUM(GREATEST(bytes,maxbytes))/1024/1024) AS max_size_mb
380 | FROM dba_data_files GROUP BY tablespace_name) b WHERE a.tablespace_name = b.tablespace_name
381 | ) where tablespace_name='{name}' order by 1"""
382 | self.cur.execute(sql)
383 | res = self.cur.fetchall()
384 | for i in res:
385 | print(i[1])
386 |
387 | def tablespace_abs(self, name):
388 | """Get tablespace in use"""
389 | sql = f"""SELECT df.tablespace_name "TABLESPACE", (df.totalspace - \
390 | tu.totalusedspace) "FREEMB" from (select tablespace_name, \
391 | sum(bytes) TotalSpace from dba_data_files group by tablespace_name) \
392 | df ,(select sum(bytes) totalusedspace,tablespace_name from dba_segments \
393 | group by tablespace_name) tu WHERE tu.tablespace_name = \
394 | df.tablespace_name and df.tablespace_name = '{name}' """
395 | self.cur.execute(sql)
396 | res = self.cur.fetchall()
397 | for i in res:
398 | print(i[1])
399 |
400 | def show_tablespaces(self):
401 | """List tablespace names in a JSON like format for Zabbix use"""
402 | sql = "SELECT tablespace_name FROM dba_tablespaces ORDER BY 1"
403 | self.cur.execute(sql)
404 | res = self.cur.fetchall()
405 | key = ["{#TABLESPACE}"]
406 | lst = []
407 | for i in res:
408 | d = dict(zip(key, i))
409 | lst.append(d)
410 | print(json.dumps({"data": lst}))
411 |
412 | def show_tablespaces_temp(self):
413 | """List temporary tablespace names in a JSON like
414 | format for Zabbix use"""
415 | sql = "SELECT TABLESPACE_NAME FROM DBA_TABLESPACES WHERE \
416 | CONTENTS='TEMPORARY'"
417 | self.cur.execute(sql)
418 | res = self.cur.fetchall()
419 | key = ["{#TABLESPACE_TEMP}"]
420 | lst = []
421 | for i in res:
422 | d = dict(zip(key, i))
423 | lst.append(d)
424 | print(json.dumps({"data": lst}))
425 |
426 | def check_archive(self, archive):
427 | """List archive used"""
428 | sql = f"select trunc((total_mb-free_mb)*100/(total_mb)) PCT from \
429 | v$asm_diskgroup_stat where name='{archive}' \
430 | ORDER BY 1"
431 | self.cur.execute(sql)
432 | res = self.cur.fetchall()
433 | for i in res:
434 | print(i[0])
435 |
436 | def show_asm_volumes(self):
437 | """List als ASM volumes in a JSON like format for Zabbix use"""
438 | sql = "select NAME from v$asm_diskgroup_stat ORDER BY 1"
439 | self.cur.execute(sql)
440 | res = self.cur.fetchall()
441 | key = ["{#ASMVOLUME}"]
442 | lst = []
443 | for i in res:
444 | d = dict(zip(key, i))
445 | lst.append(d)
446 | print(json.dumps({"data": lst}))
447 |
448 | def asm_volume_use(self, name):
449 | """Get ASM volume usage"""
450 | sql = f"select round(((TOTAL_MB-FREE_MB)/TOTAL_MB*100),2) from \
451 | v$asm_diskgroup_stat where name = '{name}'"
452 | self.cur.execute(sql)
453 | res = self.cur.fetchall()
454 | for i in res:
455 | print(i[0])
456 |
457 | def query_lock(self):
458 | """Query lock"""
459 | sql = "SELECT count(*) FROM gv$lock l WHERE block=1"
460 | self.cur.execute(sql)
461 | res = self.cur.fetchall()
462 | for i in res:
463 | print(i[0])
464 |
465 | def query_redologs(self):
466 | """Redo logs"""
467 | sql = "select COUNT(*) from v$LOG WHERE STATUS='ACTIVE'"
468 | self.cur.execute(sql)
469 | res = self.cur.fetchall()
470 | for i in res:
471 | print(i[0])
472 |
473 | def query_rollbacks(self):
474 | """Query Rollback"""
475 | sql = "select nvl(trunc(sum(used_ublk*4096)/1024/1024),0) from \
476 | gv$transaction t,gv$session s where ses_addr = saddr"
477 | self.cur.execute(sql)
478 | res = self.cur.fetchall()
479 | for i in res:
480 | print(i[0])
481 |
482 | def query_sessions(self):
483 | """Query Sessions"""
484 | sql = "select count(*) from gv$session where username is not null \
485 | and status='ACTIVE'"
486 | self.cur.execute(sql)
487 | res = self.cur.fetchall()
488 | for i in res:
489 | print(i[0])
490 |
491 | def tablespace_temp(self, name):
492 | """Query temporary tablespaces"""
493 | sql = f"SELECT round(((TABLESPACE_SIZE-FREE_SPACE)/TABLESPACE_SIZE)*100,2) \
494 | PERCENTUAL FROM dba_temp_free_space where \
495 | tablespace_name='{name}'"
496 | self.cur.execute(sql)
497 | res = self.cur.fetchall()
498 | for i in res:
499 | print(i[0])
500 |
501 | def query_sysmetrics(self, name):
502 | """Query v$sysmetric parameters"""
503 | sql = f"""select value from v$sysmetric where METRIC_NAME ='{name.replace("_", " ")}' and \
504 | rownum <=1 order by INTSIZE_CSEC"""
505 | self.cur.execute(sql)
506 | res = self.cur.fetchall()
507 | for i in res:
508 | print(i[0])
509 |
510 | def fra_use(self):
511 | """Query the Fast Recovery Area usage"""
512 | sql = "select round((SPACE_LIMIT-(SPACE_LIMIT-SPACE_USED))/ \
513 | SPACE_LIMIT*100,2) FROM V$RECOVERY_FILE_DEST"
514 | self.cur.execute(sql)
515 | res = self.cur.fetchall()
516 | for i in res:
517 | print(i[0])
518 |
519 | def show_users(self):
520 | """Query the list of users on the instance"""
521 | sql = "SELECT username FROM dba_users ORDER BY 1"
522 | self.cur.execute(sql)
523 | res = self.cur.fetchall()
524 | key = ["{#DBUSER}"]
525 | lst = []
526 | for i in res:
527 | d = dict(zip(key, i))
528 | lst.append(d)
529 | print(json.dumps({"data": lst}))
530 |
531 | def user_status(self, dbuser):
532 | """Determines whether a user is locked or not"""
533 | sql = f"SELECT account_status FROM dba_users WHERE username='{dbuser}'"
534 | self.cur.execute(sql)
535 | res = self.cur.fetchall()
536 | for i in res:
537 | print(i[0])
538 |
539 |
540 | def query_temp(self):
541 | '''Query temp'''
542 | sql = "select nvl(sum(blocks*8192)/1024/1024,0) from gv$session s, gv$sort_usage u where s.saddr = u.session_addr"
543 | self.cur.execute(sql)
544 | res = self.cur.fetchall()
545 | for i in res:
546 | print(i[0])
547 |
548 |
549 |
550 | class Main(Checks):
551 | def __init__(self):
552 | parser = argparse.ArgumentParser()
553 | parser.add_argument("--username")
554 | parser.add_argument("--password")
555 | parser.add_argument("--address")
556 | parser.add_argument("--database")
557 | parser.add_argument("--port")
558 |
559 | subparsers = parser.add_subparsers()
560 |
561 | for name in dir(self):
562 | if not name.startswith("_"):
563 | p = subparsers.add_parser(name)
564 | method = getattr(self, name)
565 | argnames = inspect.signature(method).parameters
566 | for argname in argnames:
567 | p.add_argument(argname)
568 | p.set_defaults(func=method, argnames=argnames)
569 | self.args = parser.parse_args()
570 |
571 | def db_connect(self):
572 | a = self.args
573 | username = a.username
574 | password = a.password
575 | address = a.address if a.address else "127.0.0.1"
576 | database = a.database if a.database else "orcl"
577 | port = a.port if a.port else 1521
578 | self.db = cx_Oracle.connect(f"{username}/{password}@{address}:{port}/{database}")
579 | self.cur = self.db.cursor()
580 |
581 | def db_close(self):
582 | self.cur.close()
583 | self.db.close()
584 |
585 | def __call__(self):
586 | try:
587 | a = self.args
588 | callargs = [getattr(a, name) for name in a.argnames]
589 | self.db_connect()
590 | try:
591 | return self.args.func(*callargs)
592 | finally:
593 | self.db_close()
594 | except Exception as err:
595 | print(0)
596 | print(str(err))
597 |
598 |
599 | if __name__ == "__main__":
600 | main = Main()
601 | main()
602 |
--------------------------------------------------------------------------------
/zabbix-template/Pyora.xml:
--------------------------------------------------------------------------------
1 |
2 |
3 | 5.0
4 | 2022-01-06T23:14:03Z
5 |
6 |
7 | Pyora
8 |
9 |
10 | Templates
11 |
12 |
13 |
14 |
15 | Pyora
16 | Template App Oracle
17 |
18 |
19 | Pyora
20 |
21 |
22 | Templates
23 |
24 |
25 |
26 |
27 | ASM Volumes
28 |
29 |
30 | Database Users
31 |
32 |
33 | Oracle
34 |
35 |
36 | Tablespaces
37 |
38 |
39 | Temp Tablespaces
40 |
41 |
42 |
43 | -
44 | Oracle/Archive {$ARCHIVE} on {$DATABASE}
45 | pyora[{$USERNAME},{$PASSWORD},{$ADDRESS},{$DATABASE},check_archive,{$ARCHIVE}]
46 | 300
47 | 7d
48 | 90d
49 | %
50 |
51 |
52 | Oracle
53 |
54 |
55 |
56 |
57 | {last(0)}>90
58 | Oracle/Archive {$ARCHIVE} used on {$DATABASE} > 90%
59 | AVERAGE
60 | Database archive used is > 90%
61 |
62 |
63 |
64 | -
65 | Oracle/Active user count on {$DATABASE}
66 | pyora[{$USERNAME},{$PASSWORD},{$ADDRESS},{$PORT},{$DATABASE},activeusercount]
67 | 300
68 | 7d
69 | 90d
70 |
71 |
72 | Oracle
73 |
74 |
75 |
76 | -
77 | Oracle/Buffer busy waits on {$DATABASE}
78 | pyora[{$USERNAME},{$PASSWORD},{$ADDRESS},{$PORT},{$DATABASE},bufbusywaits]
79 | 300
80 | 7d
81 | 90d
82 |
83 |
84 | Oracle
85 |
86 |
87 |
88 | -
89 | Oracle/Instance is active and open on {$DATABASE}
90 | pyora[{$USERNAME},{$PASSWORD},{$ADDRESS},{$PORT},{$DATABASE},check_active]
91 | 300
92 | 7d
93 | 30d
94 |
95 |
96 | Oracle
97 |
98 |
99 |
100 |
101 | {regexp(ORA)}=1
102 | Oracle/Database {$DATABASE} is down or ORA error found
103 | DISASTER
104 | Contact DBA.
105 |
106 |
107 | {nodata(700)}=1
108 | Oracle/Database {$DATABASE} is not responding
109 | DISASTER
110 | Contact DBA.
111 |
112 |
113 |
114 | -
115 | Oracle/User Commits on {$DATABASE}
116 | pyora[{$USERNAME},{$PASSWORD},{$ADDRESS},{$PORT},{$DATABASE},commits]
117 | 600
118 | 7d
119 | 90d
120 |
121 |
122 | Oracle
123 |
124 |
125 |
126 | -
127 | Oracle/Size of all datafiles on {$DATABASE}
128 | pyora[{$USERNAME},{$PASSWORD},{$ADDRESS},{$PORT},{$DATABASE},dbfilesize]
129 | 7200
130 | 7d
131 | 90d
132 | B
133 |
134 |
135 | Oracle
136 |
137 |
138 |
139 | -
140 | Oracle/dbprllwrite on {$DATABASE}
141 | pyora[{$USERNAME},{$PASSWORD},{$ADDRESS},{$PORT},{$DATABASE},dbprllwrite]
142 | 300
143 | 7d
144 | 90d
145 |
146 |
147 | Oracle
148 |
149 |
150 |
151 | -
152 | Oracle/dbscattread on {$DATABASE}
153 | pyora[{$USERNAME},{$PASSWORD},{$ADDRESS},{$PORT},{$DATABASE},dbscattread]
154 | 300
155 | 7d
156 | 90d
157 |
158 |
159 | Oracle
160 |
161 |
162 |
163 | -
164 | Oracle/dbseqread on {$DATABASE}
165 | pyora[{$USERNAME},{$PASSWORD},{$ADDRESS},{$PORT},{$DATABASE},dbseqread]
166 | 300
167 | 7d
168 | 90d
169 |
170 |
171 | Oracle
172 |
173 |
174 |
175 | -
176 | Oracle/Size of user data (without temp) on {$DATABASE}
177 | pyora[{$USERNAME},{$PASSWORD},{$ADDRESS},{$PORT},{$DATABASE},dbsize]
178 | 7200
179 | 7d
180 | 90d
181 | B
182 |
183 |
184 | Oracle
185 |
186 |
187 |
188 | -
189 | Oracle/dbsnglwrite {$DATABASE}
190 | pyora[{$USERNAME},{$PASSWORD},{$ADDRESS},{$PORT},{$DATABASE},dbsnglwrite]
191 | 300
192 | 7d
193 | 90d
194 |
195 |
196 | Oracle
197 |
198 |
199 |
200 | -
201 | Oracle/Deadlocks on {$DATABASE}
202 | pyora[{$USERNAME},{$PASSWORD},{$ADDRESS},{$PORT},{$DATABASE},deadlocks]
203 | 600
204 | 7d
205 | 90d
206 |
207 |
208 | Oracle
209 |
210 |
211 |
212 | -
213 | Oracle/Directread on {$DATABASE}
214 | pyora[{$USERNAME},{$PASSWORD},{$ADDRESS},{$PORT},{$DATABASE},directread]
215 | 300
216 | 7d
217 | 90d
218 |
219 |
220 | Oracle
221 |
222 |
223 |
224 | -
225 | Oracle/Disk sorts ratio on {$DATABASE}
226 | pyora[{$USERNAME},{$PASSWORD},{$ADDRESS},{$PORT},{$DATABASE},dsksortratio]
227 | 600
228 | 7d
229 | 90d
230 | %
231 |
232 |
233 | Oracle
234 |
235 |
236 |
237 | -
238 | Oracle/Enqueue on {$DATABASE}
239 | pyora[{$USERNAME},{$PASSWORD},{$ADDRESS},{$PORT},{$DATABASE},enqueue]
240 | 300
241 | 7d
242 | 90d
243 |
244 |
245 | Oracle
246 |
247 |
248 |
249 | -
250 | Oracle/fra_use on {$DATABASE}
251 | pyora[{$USERNAME},{$PASSWORD},{$ADDRESS},{$PORT},{$DATABASE},fra_use]
252 | 300
253 | 7d
254 | 90d
255 |
256 |
257 | Oracle
258 |
259 |
260 |
261 |
262 | {last(0)}>90
263 | Oracle/fra_use used on {$DATABASE} > 90%
264 | HIGH
265 | Fast Recovery Area usage > 90%
266 |
267 |
268 |
269 | -
270 | Oracle/freebufwaits on {$DATABASE}
271 | pyora[{$USERNAME},{$PASSWORD},{$ADDRESS},{$PORT},{$DATABASE},freebufwaits]
272 | 300
273 | 7d
274 | 90d
275 |
276 |
277 | Oracle
278 |
279 |
280 |
281 | -
282 | Oracle/Hard parse ratio on {$DATABASE}
283 | pyora[{$USERNAME},{$PASSWORD},{$ADDRESS},{$PORT},{$DATABASE},hparsratio]
284 | 600
285 | 7d
286 | 90d
287 | %
288 |
289 |
290 | Oracle
291 |
292 |
293 |
294 | -
295 | Oracle/Index fast full scans (full) on {$DATABASE}
296 | pyora[{$USERNAME},{$PASSWORD},{$ADDRESS},{$PORT},{$DATABASE},indexffs]
297 | 300
298 | 7d
299 | 90d
300 |
301 |
302 | Oracle
303 |
304 |
305 |
306 | -
307 | Oracle/Lastapplarclog on {$DATABASE}
308 | pyora[{$USERNAME},{$PASSWORD},{$ADDRESS},{$PORT},{$DATABASE},lastapplarclog]
309 | 300
310 | 7d
311 | 90d
312 |
313 |
314 | Oracle
315 |
316 |
317 |
318 | -
319 | Oracle/Lastarclog on {$DATABASE}
320 | pyora[{$USERNAME},{$PASSWORD},{$ADDRESS},{$PORT},{$DATABASE},lastarclog]
321 | 300
322 | 7d
323 | 90d
324 |
325 |
326 | Oracle
327 |
328 |
329 |
330 | -
331 | Oracle/Latchfree on {$DATABASE}
332 | pyora[{$USERNAME},{$PASSWORD},{$ADDRESS},{$PORT},{$DATABASE},latchfree]
333 | 300
334 | 7d
335 | 90d
336 |
337 |
338 | Oracle
339 |
340 |
341 |
342 | -
343 | Oracle/Logfilesync on {$DATABASE}
344 | pyora[{$USERNAME},{$PASSWORD},{$ADDRESS},{$PORT},{$DATABASE},logfilesync]
345 | 300
346 | 7d
347 | 90d
348 |
349 |
350 | Oracle
351 |
352 |
353 |
354 | -
355 | Oracle/Logonscurrent on {$DATABASE}
356 | pyora[{$USERNAME},{$PASSWORD},{$ADDRESS},{$PORT},{$DATABASE},logonscurrent]
357 | 300
358 | 7d
359 | 90d
360 |
361 |
362 | Oracle
363 |
364 |
365 |
366 | -
367 | Oracle/Logprllwrite on {$DATABASE}
368 | pyora[{$USERNAME},{$PASSWORD},{$ADDRESS},{$PORT},{$DATABASE},logprllwrite]
369 | 300
370 | 7d
371 | 90d
372 |
373 |
374 | Oracle
375 |
376 |
377 |
378 | -
379 | Oracle/Logswcompletion on {$DATABASE}
380 | pyora[{$USERNAME},{$PASSWORD},{$ADDRESS},{$PORT},{$DATABASE},logswcompletion]
381 | 300
382 | 7d
383 | 90d
384 |
385 |
386 | Oracle
387 |
388 |
389 |
390 | -
391 | Oracle/Netresv on {$DATABASE}
392 | pyora[{$USERNAME},{$PASSWORD},{$ADDRESS},{$PORT},{$DATABASE},netresv]
393 | 300
394 | 7d
395 | 90d
396 | b
397 |
398 |
399 | Oracle
400 |
401 |
402 |
403 | -
404 | Oracle/Netroundtrips on {$DATABASE}
405 | pyora[{$USERNAME},{$PASSWORD},{$ADDRESS},{$PORT},{$DATABASE},netroundtrips]
406 | 300
407 | 7d
408 | 90d
409 |
410 |
411 | Oracle
412 |
413 |
414 |
415 | -
416 | Oracle/Netsent on {$DATABASE}
417 | pyora[{$USERNAME},{$PASSWORD},{$ADDRESS},{$PORT},{$DATABASE},netsent]
418 | 300
419 | 7d
420 | 90d
421 |
422 |
423 | Oracle
424 |
425 |
426 |
427 | -
428 | Oracle/Query Lock on {$DATABASE}
429 | pyora[{$USERNAME},{$PASSWORD},{$ADDRESS},{$PORT},{$DATABASE},query_lock]
430 | 300
431 | 7d
432 | 90d
433 |
434 |
435 | Oracle
436 |
437 |
438 |
439 |
440 | {last(0)}>0
441 | Oracle/Query Lock on {$DATABASE} > 1
442 | HIGH
443 |
444 |
445 |
446 | -
447 | Oracle/Query Redologs on {$DATABASE}
448 | pyora[{$USERNAME},{$PASSWORD},{$ADDRESS},{$PORT},{$DATABASE},query_redologs]
449 | 300
450 | 7d
451 | 90d
452 |
453 |
454 | Oracle
455 |
456 |
457 |
458 | -
459 | Oracle/Query Rollbacks on {$DATABASE}
460 | pyora[{$USERNAME},{$PASSWORD},{$ADDRESS},{$PORT},{$DATABASE},query_rollbacks]
461 | 300
462 | 7d
463 | 90d
464 |
465 |
466 | Oracle
467 |
468 |
469 |
470 | -
471 | Oracle/Query Sessions on {$DATABASE}
472 | pyora[{$USERNAME},{$PASSWORD},{$ADDRESS},{$PORT},{$DATABASE},query_sessions]
473 | 300
474 | 7d
475 | 90d
476 |
477 |
478 | Oracle
479 |
480 |
481 |
482 |
483 | {last(0)}>250
484 | Oracle/Query Sessions on {$DATABASE} > 250
485 | HIGH
486 |
487 |
488 |
489 | -
490 | Oracle/Database CPU Time Ratio on {$DATABASE}
491 | pyora[{$USERNAME},{$PASSWORD},{$ADDRESS},{$PORT},{$DATABASE},query_sysmetrics,Database_CPU_Time_Ratio]
492 | 600
493 | 7d
494 | 90d
495 | %
496 |
497 |
498 | Oracle
499 |
500 |
501 |
502 | -
503 | Oracle/Database Wait Time Ratio on {$DATABASE}
504 | pyora[{$USERNAME},{$PASSWORD},{$ADDRESS},{$PORT},{$DATABASE},query_sysmetrics,Database_Wait_Time_Ratio]
505 | 600
506 | 7d
507 | 90d
508 | %
509 |
510 |
511 | Oracle
512 |
513 |
514 |
515 | -
516 | Oracle/User Transaction Per Sec on {$DATABASE}
517 | pyora[{$USERNAME},{$PASSWORD},{$ADDRESS},{$PORT},{$DATABASE},query_sysmetrics,User_Transaction_Per_Sec]
518 | 600
519 | 7d
520 | 90d
521 |
522 |
523 | Oracle
524 |
525 |
526 |
527 | -
528 | Oracle/Query Temp on {$DATABASE}
529 | pyora[{$USERNAME},{$PASSWORD},{$ADDRESS},{$PORT},{$DATABASE},query_temp]
530 | 300
531 | 7d
532 | 90d
533 |
534 |
535 | Oracle
536 |
537 |
538 |
539 | -
540 | Oracle/Read Cache hit ratio on {$DATABASE}
541 | pyora[{$USERNAME},{$PASSWORD},{$ADDRESS},{$PORT},{$DATABASE},rcachehit]
542 | 600
543 | 7d
544 | 90d
545 | %
546 |
547 |
548 | Oracle
549 |
550 |
551 |
552 | -
553 | Oracle/Redo Writes on {$DATABASE}
554 | pyora[{$USERNAME},{$PASSWORD},{$ADDRESS},{$PORT},{$DATABASE},redowrites]
555 | 600
556 | 7d
557 | 90d
558 |
559 |
560 | Oracle
561 |
562 |
563 |
564 | -
565 | Oracle/Table scan rows gotten on {$DATABASE}
566 | pyora[{$USERNAME},{$PASSWORD},{$ADDRESS},{$PORT},{$DATABASE},tblrowsscans]
567 | 300
568 | 7d
569 | 90d
570 |
571 |
572 | Oracle
573 |
574 |
575 |
576 | -
577 | Oracle/Table scans (long tables) on {$DATABASE}
578 | pyora[{$USERNAME},{$PASSWORD},{$ADDRESS},{$PORT},{$DATABASE},tblscans]
579 | 600
580 | 7d
581 | 90d
582 |
583 |
584 | Oracle
585 |
586 |
587 |
588 | -
589 | Oracle/Uptime on {$DATABASE}
590 | pyora[{$USERNAME},{$PASSWORD},{$ADDRESS},{$PORT},{$DATABASE},uptime]
591 | 600
592 | 7d
593 | 90d
594 | s
595 |
596 |
597 | Oracle
598 |
599 |
600 |
601 | -
602 | Oracle/Version on {$DATABASE}
603 | pyora[{$USERNAME},{$PASSWORD},{$ADDRESS},{$PORT},{$DATABASE},version]
604 | 7200
605 | 30d
606 |
607 |
608 | Oracle
609 |
610 |
611 |
612 |
613 |
614 |
615 | Discovery Oracle ASM volumes
616 | pyora[{$USERNAME},{$PASSWORD},{$ADDRESS},{$PORT},{$DATABASE},show_asm_volumes]
617 | 3600
618 |
619 |
620 |
621 | {#ASMVOLUME}
622 | A
623 |
624 |
625 |
626 |
627 |
628 | ASM Volume Use on {#ASMVOLUME}
629 | pyora[{$USERNAME},{$PASSWORD},{$ADDRESS},{$PORT},{$DATABASE},asm_volume_use,{#ASMVOLUME}]
630 | 300
631 | 7d
632 | 90d
633 | %
634 |
635 |
636 | ASM Volumes
637 |
638 |
639 |
640 |
641 | {last(0)}>{$HIGH}
642 | Oracle/ASM Volume {#ASMVOLUME} used > {$HIGH} %
643 | HIGH
644 |
645 |
646 |
647 |
648 |
649 |
650 | Discovery Oracle tablespaces
651 | pyora[{$USERNAME},{$PASSWORD},{$ADDRESS},{$PORT},{$DATABASE},show_tablespaces]
652 | 3600
653 |
654 |
655 |
656 | {#TABLESPACE}
657 | A
658 |
659 |
660 |
661 |
662 |
663 | Tablespace percentual use on {#TABLESPACE}
664 | pyora[{$USERNAME},{$PASSWORD},{$ADDRESS},{$PORT},{$DATABASE},tablespace,{#TABLESPACE}]
665 | 300
666 | 7d
667 | 90d
668 | %
669 |
670 |
671 | Tablespaces
672 |
673 |
674 |
675 |
676 | Tablespace free on {#TABLESPACE}
677 | pyora[{$USERNAME},{$PASSWORD},{$ADDRESS},{$PORT},{$DATABASE},tablespace_abs,{#TABLESPACE}]
678 | 300
679 | 7d
680 | 90d
681 | bytes
682 |
683 |
684 | Tablespaces
685 |
686 |
687 |
688 |
689 |
690 |
691 | {Pyora:pyora[{$USERNAME},{$PASSWORD},{$ADDRESS},{$PORT},{$DATABASE},tablespace,{#TABLESPACE}].last()}={$FS_P_USED_HIGH} and {Pyora:pyora[{$USERNAME},{$PASSWORD},{$ADDRESS},{$PORT},{$DATABASE},tablespace_abs,{#TABLESPACE}].last()}<{$FS_FREE_LOW}
692 | Oracle/Tablespace {#TABLESPACE} used on {$DATABASE} high
693 | HIGH
694 |
695 |
696 |
697 |
698 | Tablespace use on {#TABLESPACE}
699 |
700 |
701 | 1A7C11
702 | RIGHT
703 | -
704 | Pyora
705 | pyora[{$USERNAME},{$PASSWORD},{$ADDRESS},{$PORT},{$DATABASE},tablespace_abs,{#TABLESPACE}]
706 |
707 |
708 |
709 | 1
710 | F63100
711 | -
712 | Pyora
713 | pyora[{$USERNAME},{$PASSWORD},{$ADDRESS},{$PORT},{$DATABASE},tablespace,{#TABLESPACE}]
714 |
715 |
716 |
717 |
718 |
719 |
720 |
721 | Discovery Oracle temp tablespaces
722 | pyora[{$USERNAME},{$PASSWORD},{$ADDRESS},{$PORT},{$DATABASE},show_tablespaces_temp]
723 | 3600
724 |
725 |
726 |
727 | {#TABLESPACE_TEMP}
728 | A
729 |
730 |
731 |
732 |
733 |
734 | Temp Tablespace Use on {#TABLESPACE_TEMP}
735 | pyora[{$USERNAME},{$PASSWORD},{$ADDRESS},{$PORT},{$DATABASE},tablespace_temp,{#TABLESPACE_TEMP}]
736 | 300
737 | %
738 |
739 |
740 | Temp Tablespaces
741 |
742 |
743 |
744 |
745 | {last(0)}>{$HIGH}
746 | Oracle/Tablespace TEMP {#TABLESPACE_TEMP} used on {$DATABASE} > {$HIGH} %
747 | HIGH
748 |
749 |
750 |
751 |
752 |
753 |
754 | Discovery Oracle users
755 | pyora[{$USERNAME},{$PASSWORD},{$ADDRESS},{$PORT},{$DATABASE},show_users]
756 | 3600
757 |
758 |
759 |
760 | {#DBUSER}
761 | A
762 |
763 |
764 |
765 |
766 |
767 | {#DBUSER} user status
768 | pyora[{$USERNAME},{$PASSWORD},{$ADDRESS},{$PORT},{$DATABASE},user_status,{#DBUSER}]
769 | 300
770 | 0
771 | TEXT
772 |
773 |
774 | Database Users
775 |
776 |
777 |
778 |
779 |
780 |
781 |
782 |
783 | {$FS_FREE_LOW}
784 | 34359738368
785 |
786 |
787 | {$FS_P_USED_HIGH}
788 | 80
789 |
790 |
791 | {$HIGH}
792 | 80
793 |
794 |
795 |
796 |
797 |
798 |
799 | Oracle/dbreads + dbwrites
800 |
801 |
802 | 1A7C11
803 | -
804 | Pyora
805 | pyora[{$USERNAME},{$PASSWORD},{$ADDRESS},{$PORT},{$DATABASE},dbprllwrite]
806 |
807 |
808 |
809 | 1
810 | F63100
811 | -
812 | Pyora
813 | pyora[{$USERNAME},{$PASSWORD},{$ADDRESS},{$PORT},{$DATABASE},dbscattread]
814 |
815 |
816 |
817 | 2
818 | 2774A4
819 | -
820 | Pyora
821 | pyora[{$USERNAME},{$PASSWORD},{$ADDRESS},{$PORT},{$DATABASE},dbseqread]
822 |
823 |
824 |
825 | 3
826 | A54F10
827 | -
828 | Pyora
829 | pyora[{$USERNAME},{$PASSWORD},{$ADDRESS},{$PORT},{$DATABASE},dbsnglwrite]
830 |
831 |
832 |
833 |
834 |
835 | Oracle/Query
836 |
837 |
838 | 1A7C11
839 | RIGHT
840 | -
841 | Pyora
842 | pyora[{$USERNAME},{$PASSWORD},{$ADDRESS},{$PORT},{$DATABASE},query_sessions]
843 |
844 |
845 |
846 | 1
847 | F63100
848 | -
849 | Pyora
850 | pyora[{$USERNAME},{$PASSWORD},{$ADDRESS},{$PORT},{$DATABASE},query_rollbacks]
851 |
852 |
853 |
854 | 2
855 | 2774A4
856 | -
857 | Pyora
858 | pyora[{$USERNAME},{$PASSWORD},{$ADDRESS},{$PORT},{$DATABASE},query_redologs]
859 |
860 |
861 |
862 | 3
863 | FC6EA3
864 | -
865 | Pyora
866 | pyora[{$USERNAME},{$PASSWORD},{$ADDRESS},{$PORT},{$DATABASE},query_lock]
867 |
868 |
869 |
870 |
871 |
872 | Oracle/Size
873 | 250
874 | 250
875 | 0
876 | EXPLODED
877 |
878 |
879 | 1A7C11
880 | -
881 | Pyora
882 | pyora[{$USERNAME},{$PASSWORD},{$ADDRESS},{$PORT},{$DATABASE},dbfilesize]
883 |
884 |
885 |
886 | 1
887 | F63100
888 | -
889 | Pyora
890 | pyora[{$USERNAME},{$PASSWORD},{$ADDRESS},{$PORT},{$DATABASE},dbsize]
891 |
892 |
893 |
894 |
895 |
896 | Oracle/Sysmetrics CPU ratio
897 | STACKED
898 |
899 |
900 | F63100
901 | -
902 | Pyora
903 | pyora[{$USERNAME},{$PASSWORD},{$ADDRESS},{$PORT},{$DATABASE},query_sysmetrics,Database_CPU_Time_Ratio]
904 |
905 |
906 |
907 | 1
908 | 2774A4
909 | -
910 | Pyora
911 | pyora[{$USERNAME},{$PASSWORD},{$ADDRESS},{$PORT},{$DATABASE},query_sysmetrics,Database_Wait_Time_Ratio]
912 |
913 |
914 |
915 |
916 |
917 | Oracle/Table scans + Index scans
918 |
919 |
920 | 1A7C11
921 | RIGHT
922 | -
923 | Pyora
924 | pyora[{$USERNAME},{$PASSWORD},{$ADDRESS},{$PORT},{$DATABASE},indexffs]
925 |
926 |
927 |
928 | 1
929 | F63100
930 | -
931 | Pyora
932 | pyora[{$USERNAME},{$PASSWORD},{$ADDRESS},{$PORT},{$DATABASE},tblrowsscans]
933 |
934 |
935 |
936 | 2
937 | 2774A4
938 | -
939 | Pyora
940 | pyora[{$USERNAME},{$PASSWORD},{$ADDRESS},{$PORT},{$DATABASE},tblscans]
941 |
942 |
943 |
944 |
945 |
946 | Oracle/User
947 |
948 |
949 | 1A7C11
950 | -
951 | Pyora
952 | pyora[{$USERNAME},{$PASSWORD},{$ADDRESS},{$PORT},{$DATABASE},query_sysmetrics,User_Transaction_Per_Sec]
953 |
954 |
955 |
956 | 1
957 | F63100
958 | -
959 | Pyora
960 | pyora[{$USERNAME},{$PASSWORD},{$ADDRESS},{$PORT},{$DATABASE},commits]
961 |
962 |
963 |
964 |
965 |
966 |
--------------------------------------------------------------------------------
/zabbix-template/Pyora_ExternalCheck.xml:
--------------------------------------------------------------------------------
1 |
2 |
3 | 2.0
4 | 2013-12-11T09:33:58Z
5 |
6 |
7 | Templates
8 |
9 |
10 |
11 |
12 | Custom - Service - Oracle
13 | Custom - Service - Oracle
14 |
15 |
16 | Templates
17 |
18 |
19 |
20 |
21 | ASM Volumes
22 |
23 |
24 | Oracle
25 |
26 |
27 | Tablespaces
28 |
29 |
30 | Temp Tablespaces
31 |
32 |
33 |
34 | -
35 | Oracle/Active user count on {$DATABASE}
36 | 10
37 |
38 | 0
39 |
40 | pyora[{$USERNAME},{$PASSWORD},{$ADDRESS},{$DATABASE},activeusercount]
41 | 300
42 | 7
43 | 90
44 | 0
45 | 3
46 |
47 |
48 | 0
49 |
50 | 0
51 |
52 |
53 | 1
54 |
55 |
56 |
57 | 0
58 | 0
59 |
60 |
61 |
62 |
63 |
64 |
65 | 0
66 |
67 |
68 | Oracle
69 |
70 |
71 |
72 |
73 | -
74 | Oracle/Archive {$ARCHIVE} on {$DATABASE}
75 | 10
76 |
77 | 0
78 |
79 | pyora[{$USERNAME},{$PASSWORD},{$ADDRESS},{$DATABASE},check_archive,{$ARCHIVE}]
80 | 300
81 | 7
82 | 90
83 | 0
84 | 3
85 |
86 | %
87 | 0
88 |
89 | 0
90 |
91 |
92 | 1
93 |
94 |
95 |
96 | 0
97 | 0
98 |
99 |
100 |
101 |
102 |
103 |
104 | 0
105 |
106 |
107 | Oracle
108 |
109 |
110 |
111 |
112 | -
113 | Oracle/Buffer busy waits on {$DATABASE}
114 | 10
115 |
116 | 0
117 |
118 | pyora[{$USERNAME},{$PASSWORD},{$ADDRESS},{$DATABASE},bufbusywaits]
119 | 300
120 | 7
121 | 90
122 | 0
123 | 3
124 |
125 |
126 | 0
127 |
128 | 0
129 |
130 |
131 | 1
132 |
133 |
134 |
135 | 0
136 | 0
137 |
138 |
139 |
140 |
141 |
142 |
143 | 0
144 |
145 |
146 | Oracle
147 |
148 |
149 |
150 |
151 | -
152 | Oracle/Database CPU Time Ratio on {$DATABASE}
153 | 10
154 |
155 | 0
156 |
157 | pyora[{$USERNAME},{$PASSWORD},{$ADDRESS},{$DATABASE},query_sysmetrics,Database_CPU_Time_Ratio]
158 | 600
159 | 7
160 | 90
161 | 0
162 | 0
163 |
164 | %
165 | 0
166 |
167 | 0
168 |
169 |
170 | 1
171 |
172 |
173 |
174 | 0
175 | 0
176 |
177 |
178 |
179 |
180 |
181 |
182 | 0
183 |
184 |
185 | Oracle
186 |
187 |
188 |
189 |
190 | -
191 | Oracle/Database Wait Time Ratio on {$DATABASE}
192 | 10
193 |
194 | 0
195 |
196 | pyora[{$USERNAME},{$PASSWORD},{$ADDRESS},{$DATABASE},query_sysmetrics,Database_Wait_Time_Ratio]
197 | 600
198 | 7
199 | 90
200 | 0
201 | 0
202 |
203 | %
204 | 0
205 |
206 | 0
207 |
208 |
209 | 1
210 |
211 |
212 |
213 | 0
214 | 0
215 |
216 |
217 |
218 |
219 |
220 |
221 | 0
222 |
223 |
224 | Oracle
225 |
226 |
227 |
228 |
229 | -
230 | Oracle/dbprllwrite on {$DATABASE}
231 | 10
232 |
233 | 0
234 |
235 | pyora[{$USERNAME},{$PASSWORD},{$ADDRESS},{$DATABASE},dbprllwrite]
236 | 300
237 | 7
238 | 90
239 | 0
240 | 3
241 |
242 |
243 | 0
244 |
245 | 0
246 |
247 |
248 | 1
249 |
250 |
251 |
252 | 3
253 | 0
254 |
255 |
256 |
257 |
258 |
259 |
260 | 0
261 |
262 |
263 | Oracle
264 |
265 |
266 |
267 |
268 | -
269 | Oracle/dbscattread on {$DATABASE}
270 | 10
271 |
272 | 0
273 |
274 | pyora[{$USERNAME},{$PASSWORD},{$ADDRESS},{$DATABASE},dbscattread]
275 | 300
276 | 7
277 | 90
278 | 0
279 | 3
280 |
281 |
282 | 0
283 |
284 | 0
285 |
286 |
287 | 1
288 |
289 |
290 |
291 | 0
292 | 0
293 |
294 |
295 |
296 |
297 |
298 |
299 | 0
300 |
301 |
302 | Oracle
303 |
304 |
305 |
306 |
307 | -
308 | Oracle/dbseqread on {$DATABASE}
309 | 10
310 |
311 | 0
312 |
313 | pyora[{$USERNAME},{$PASSWORD},{$ADDRESS},{$DATABASE},dbseqread]
314 | 300
315 | 7
316 | 90
317 | 0
318 | 3
319 |
320 |
321 | 0
322 |
323 | 0
324 |
325 |
326 | 1
327 |
328 |
329 |
330 | 3
331 | 0
332 |
333 |
334 |
335 |
336 |
337 |
338 | 0
339 |
340 |
341 | Oracle
342 |
343 |
344 |
345 |
346 | -
347 | Oracle/dbsnglwrite {$DATABASE}
348 | 10
349 |
350 | 0
351 |
352 | pyora[{$USERNAME},{$PASSWORD},{$ADDRESS},{$DATABASE},dbsnglwrite]
353 | 300
354 | 7
355 | 90
356 | 0
357 | 3
358 |
359 |
360 | 0
361 |
362 | 0
363 |
364 |
365 | 1
366 |
367 |
368 |
369 | 0
370 | 0
371 |
372 |
373 |
374 |
375 |
376 |
377 | 0
378 |
379 |
380 | Oracle
381 |
382 |
383 |
384 |
385 | -
386 | Oracle/Deadlocks on {$DATABASE}
387 | 10
388 |
389 | 0
390 |
391 | pyora[{$USERNAME},{$PASSWORD},{$ADDRESS},{$DATABASE},deadlocks]
392 | 600
393 | 7
394 | 90
395 | 0
396 | 3
397 |
398 |
399 | 1
400 |
401 | 0
402 |
403 |
404 | 1
405 |
406 |
407 |
408 | 0
409 | 0
410 |
411 |
412 |
413 |
414 |
415 |
416 | 0
417 |
418 |
419 | Oracle
420 |
421 |
422 |
423 |
424 | -
425 | Oracle/Directread on {$DATABASE}
426 | 10
427 |
428 | 0
429 |
430 | pyora[{$USERNAME},{$PASSWORD},{$ADDRESS},{$DATABASE},directread]
431 | 300
432 | 7
433 | 90
434 | 0
435 | 3
436 |
437 |
438 | 0
439 |
440 | 0
441 |
442 |
443 | 1
444 |
445 |
446 |
447 | 0
448 | 0
449 |
450 |
451 |
452 |
453 |
454 |
455 | 0
456 |
457 |
458 | Oracle
459 |
460 |
461 |
462 |
463 | -
464 | Oracle/Disk sorts ratio on {$DATABASE}
465 | 10
466 |
467 | 0
468 |
469 | pyora[{$USERNAME},{$PASSWORD},{$ADDRESS},{$DATABASE},dsksortratio]
470 | 600
471 | 7
472 | 90
473 | 0
474 | 0
475 |
476 | %
477 | 0
478 |
479 | 0
480 |
481 |
482 | 1
483 |
484 |
485 |
486 | 0
487 | 0
488 |
489 |
490 |
491 |
492 |
493 |
494 | 0
495 |
496 |
497 | Oracle
498 |
499 |
500 |
501 |
502 | -
503 | Oracle/Enqueue on {$DATABASE}
504 | 10
505 |
506 | 0
507 |
508 | pyora[{$USERNAME},{$PASSWORD},{$ADDRESS},{$DATABASE},enqueue]
509 | 300
510 | 7
511 | 90
512 | 0
513 | 3
514 |
515 |
516 | 0
517 |
518 | 0
519 |
520 |
521 | 1
522 |
523 |
524 |
525 | 0
526 | 0
527 |
528 |
529 |
530 |
531 |
532 |
533 | 0
534 |
535 |
536 | Oracle
537 |
538 |
539 |
540 |
541 | -
542 | Oracle/fra_use on {$DATABASE}
543 | 10
544 |
545 | 0
546 |
547 | pyora[{$USERNAME},{$PASSWORD},{$ADDRESS},{$DATABASE},fra_use]
548 | 300
549 | 7
550 | 90
551 | 0
552 | 0
553 |
554 |
555 | 0
556 |
557 | 0
558 |
559 |
560 | 1
561 |
562 |
563 |
564 | 0
565 | 0
566 |
567 |
568 |
569 |
570 |
571 |
572 | 0
573 |
574 |
575 | Oracle
576 |
577 |
578 |
579 |
580 | -
581 | Oracle/freebufwaits on {$DATABASE}
582 | 10
583 |
584 | 0
585 |
586 | pyora[{$USERNAME},{$PASSWORD},{$ADDRESS},{$DATABASE},freebufwaits]
587 | 300
588 | 7
589 | 90
590 | 0
591 | 3
592 |
593 |
594 | 0
595 |
596 | 0
597 |
598 |
599 | 1
600 |
601 |
602 |
603 | 0
604 | 0
605 |
606 |
607 |
608 |
609 |
610 |
611 | 0
612 |
613 |
614 | Oracle
615 |
616 |
617 |
618 |
619 | -
620 | Oracle/Hard parse ratio on {$DATABASE}
621 | 10
622 |
623 | 0
624 |
625 | pyora[{$USERNAME},{$PASSWORD},{$ADDRESS},{$DATABASE},hparsratio]
626 | 600
627 | 7
628 | 90
629 | 0
630 | 0
631 |
632 | %
633 | 0
634 |
635 | 0
636 |
637 |
638 | 1
639 |
640 |
641 |
642 | 0
643 | 0
644 |
645 |
646 |
647 |
648 |
649 |
650 | 0
651 |
652 |
653 | Oracle
654 |
655 |
656 |
657 |
658 | -
659 | Oracle/Index fast full scans (full) on {$DATABASE}
660 | 10
661 |
662 | 0
663 |
664 | pyora[{$USERNAME},{$PASSWORD},{$ADDRESS},{$DATABASE},indexffs]
665 | 300
666 | 7
667 | 90
668 | 0
669 | 3
670 |
671 |
672 | 1
673 |
674 | 0
675 |
676 |
677 | 1
678 |
679 |
680 |
681 | 0
682 | 0
683 |
684 |
685 |
686 |
687 |
688 |
689 | 0
690 |
691 |
692 | Oracle
693 |
694 |
695 |
696 |
697 | -
698 | Oracle/Intance is active and open on {$DATABASE}
699 | 10
700 |
701 | 0
702 |
703 | pyora[{$USERNAME},{$PASSWORD},{$ADDRESS},{$DATABASE},check_active]
704 | 300
705 | 7
706 | 90
707 | 0
708 | 3
709 |
710 |
711 | 0
712 |
713 | 0
714 |
715 |
716 | 1
717 |
718 |
719 |
720 | 0
721 | 0
722 |
723 |
724 |
725 |
726 |
727 |
728 | 0
729 |
730 |
731 | Oracle
732 |
733 |
734 |
735 |
736 | -
737 | Oracle/Lastapplarclog on {$DATABASE}
738 | 10
739 |
740 | 0
741 |
742 | pyora[{$USERNAME},{$PASSWORD},{$ADDRESS},{$DATABASE},lastapplarclog]
743 | 300
744 | 7
745 | 90
746 | 0
747 | 3
748 |
749 |
750 | 0
751 |
752 | 0
753 |
754 |
755 | 1
756 |
757 |
758 |
759 | 0
760 | 0
761 |
762 |
763 |
764 |
765 |
766 |
767 | 0
768 |
769 |
770 | Oracle
771 |
772 |
773 |
774 |
775 | -
776 | Oracle/Lastarclog on {$DATABASE}
777 | 10
778 |
779 | 0
780 |
781 | pyora[{$USERNAME},{$PASSWORD},{$ADDRESS},{$DATABASE},lastarclog]
782 | 300
783 | 7
784 | 90
785 | 0
786 | 3
787 |
788 |
789 | 0
790 |
791 | 0
792 |
793 |
794 | 1
795 |
796 |
797 |
798 | 3
799 | 0
800 |
801 |
802 |
803 |
804 |
805 |
806 | 0
807 |
808 |
809 | Oracle
810 |
811 |
812 |
813 |
814 | -
815 | Oracle/Latchfree on {$DATABASE}
816 | 10
817 |
818 | 0
819 |
820 | pyora[{$USERNAME},{$PASSWORD},{$ADDRESS},{$DATABASE},latchfree]
821 | 300
822 | 7
823 | 90
824 | 0
825 | 3
826 |
827 |
828 | 0
829 |
830 | 0
831 |
832 |
833 | 1
834 |
835 |
836 |
837 | 0
838 | 0
839 |
840 |
841 |
842 |
843 |
844 |
845 | 0
846 |
847 |
848 | Oracle
849 |
850 |
851 |
852 |
853 | -
854 | Oracle/Logfilesync on {$DATABASE}
855 | 10
856 |
857 | 0
858 |
859 | pyora[{$USERNAME},{$PASSWORD},{$ADDRESS},{$DATABASE},logfilesync]
860 | 300
861 | 7
862 | 90
863 | 0
864 | 3
865 |
866 |
867 | 0
868 |
869 | 0
870 |
871 |
872 | 1
873 |
874 |
875 |
876 | 0
877 | 0
878 |
879 |
880 |
881 |
882 |
883 |
884 | 0
885 |
886 |
887 | Oracle
888 |
889 |
890 |
891 |
892 | -
893 | Oracle/Logonscurrent on {$DATABASE}
894 | 10
895 |
896 | 0
897 |
898 | pyora[{$USERNAME},{$PASSWORD},{$ADDRESS},{$DATABASE},logonscurrent]
899 | 300
900 | 7
901 | 90
902 | 0
903 | 3
904 |
905 |
906 | 0
907 |
908 | 0
909 |
910 |
911 | 1
912 |
913 |
914 |
915 | 0
916 | 0
917 |
918 |
919 |
920 |
921 |
922 |
923 | 0
924 |
925 |
926 | Oracle
927 |
928 |
929 |
930 |
931 | -
932 | Oracle/Logprllwrite on {$DATABASE}
933 | 10
934 |
935 | 0
936 |
937 | pyora[{$USERNAME},{$PASSWORD},{$ADDRESS},{$DATABASE},logprllwrite]
938 | 300
939 | 7
940 | 90
941 | 0
942 | 3
943 |
944 |
945 | 0
946 |
947 | 0
948 |
949 |
950 | 1
951 |
952 |
953 |
954 | 0
955 | 0
956 |
957 |
958 |
959 |
960 |
961 |
962 | 0
963 |
964 |
965 | Oracle
966 |
967 |
968 |
969 |
970 | -
971 | Oracle/Logswcompletion on {$DATABASE}
972 | 10
973 |
974 | 0
975 |
976 | pyora[{$USERNAME},{$PASSWORD},{$ADDRESS},{$DATABASE},logswcompletion]
977 | 300
978 | 7
979 | 90
980 | 0
981 | 3
982 |
983 |
984 | 0
985 |
986 | 0
987 |
988 |
989 | 1
990 |
991 |
992 |
993 | 0
994 | 0
995 |
996 |
997 |
998 |
999 |
1000 |
1001 | 0
1002 |
1003 |
1004 | Oracle
1005 |
1006 |
1007 |
1008 |
1009 | -
1010 | Oracle/Netresv on {$DATABASE}
1011 | 10
1012 |
1013 | 0
1014 |
1015 | pyora[{$USERNAME},{$PASSWORD},{$ADDRESS},{$DATABASE},netresv]
1016 | 300
1017 | 7
1018 | 90
1019 | 0
1020 | 3
1021 |
1022 | b
1023 | 1
1024 |
1025 | 0
1026 |
1027 |
1028 | 1
1029 |
1030 |
1031 |
1032 | 0
1033 | 0
1034 |
1035 |
1036 |
1037 |
1038 |
1039 |
1040 | 0
1041 |
1042 |
1043 | Oracle
1044 |
1045 |
1046 |
1047 |
1048 | -
1049 | Oracle/Netroundtrips on {$DATABASE}
1050 | 10
1051 |
1052 | 0
1053 |
1054 | pyora[{$USERNAME},{$PASSWORD},{$ADDRESS},{$DATABASE},netroundtrips]
1055 | 300
1056 | 7
1057 | 90
1058 | 0
1059 | 3
1060 |
1061 |
1062 | 0
1063 |
1064 | 0
1065 |
1066 |
1067 | 1
1068 |
1069 |
1070 |
1071 | 0
1072 | 0
1073 |
1074 |
1075 |
1076 |
1077 |
1078 |
1079 | 0
1080 |
1081 |
1082 | Oracle
1083 |
1084 |
1085 |
1086 |
1087 | -
1088 | Oracle/Netsent on {$DATABASE}
1089 | 10
1090 |
1091 | 0
1092 |
1093 | pyora[{$USERNAME},{$PASSWORD},{$ADDRESS},{$DATABASE},netsent]
1094 | 300
1095 | 7
1096 | 90
1097 | 0
1098 | 3
1099 |
1100 |
1101 | 0
1102 |
1103 | 0
1104 |
1105 |
1106 | 1
1107 |
1108 |
1109 |
1110 | 0
1111 | 0
1112 |
1113 |
1114 |
1115 |
1116 |
1117 |
1118 | 0
1119 |
1120 |
1121 | Oracle
1122 |
1123 |
1124 |
1125 |
1126 | -
1127 | Oracle/Query Lock on {$DATABASE}
1128 | 10
1129 |
1130 | 0
1131 |
1132 | pyora[{$USERNAME},{$PASSWORD},{$ADDRESS},{$DATABASE},query_lock]
1133 | 300
1134 | 7
1135 | 90
1136 | 0
1137 | 3
1138 |
1139 |
1140 | 0
1141 |
1142 | 0
1143 |
1144 |
1145 | 1
1146 |
1147 |
1148 |
1149 | 0
1150 | 0
1151 |
1152 |
1153 |
1154 |
1155 |
1156 |
1157 | 0
1158 |
1159 |
1160 | Oracle
1161 |
1162 |
1163 |
1164 |
1165 | -
1166 | Oracle/Query Redologs on {$DATABASE}
1167 | 10
1168 |
1169 | 0
1170 |
1171 | pyora[{$USERNAME},{$PASSWORD},{$ADDRESS},{$DATABASE},query_redologs]
1172 | 300
1173 | 7
1174 | 90
1175 | 0
1176 | 3
1177 |
1178 |
1179 | 0
1180 |
1181 | 0
1182 |
1183 |
1184 | 1
1185 |
1186 |
1187 |
1188 | 0
1189 | 0
1190 |
1191 |
1192 |
1193 |
1194 |
1195 |
1196 | 0
1197 |
1198 |
1199 | Oracle
1200 |
1201 |
1202 |
1203 |
1204 | -
1205 | Oracle/Query Rollbacks on {$DATABASE}
1206 | 10
1207 |
1208 | 0
1209 |
1210 | pyora[{$USERNAME},{$PASSWORD},{$ADDRESS},{$DATABASE},query_rollbacks]
1211 | 300
1212 | 7
1213 | 90
1214 | 0
1215 | 3
1216 |
1217 |
1218 | 0
1219 |
1220 | 0
1221 |
1222 |
1223 | 1
1224 |
1225 |
1226 |
1227 | 0
1228 | 0
1229 |
1230 |
1231 |
1232 |
1233 |
1234 |
1235 | 0
1236 |
1237 |
1238 | Oracle
1239 |
1240 |
1241 |
1242 |
1243 | -
1244 | Oracle/Query Sessions on {$DATABASE}
1245 | 10
1246 |
1247 | 0
1248 |
1249 | pyora[{$USERNAME},{$PASSWORD},{$ADDRESS},{$DATABASE},query_sessions]
1250 | 300
1251 | 7
1252 | 90
1253 | 0
1254 | 3
1255 |
1256 |
1257 | 0
1258 |
1259 | 0
1260 |
1261 |
1262 | 1
1263 |
1264 |
1265 |
1266 | 0
1267 | 0
1268 |
1269 |
1270 |
1271 |
1272 |
1273 |
1274 | 0
1275 |
1276 |
1277 | Oracle
1278 |
1279 |
1280 |
1281 |
1282 | -
1283 | Oracle/Query Temp on {$DATABASE}
1284 | 10
1285 |
1286 | 0
1287 |
1288 | pyora[{$USERNAME},{$PASSWORD},{$ADDRESS},{$DATABASE},query_temp]
1289 | 300
1290 | 7
1291 | 90
1292 | 1
1293 | 3
1294 |
1295 |
1296 | 0
1297 |
1298 | 0
1299 |
1300 |
1301 | 1
1302 |
1303 |
1304 |
1305 | 0
1306 | 0
1307 |
1308 |
1309 |
1310 |
1311 |
1312 |
1313 | 0
1314 |
1315 |
1316 | Oracle
1317 |
1318 |
1319 |
1320 |
1321 | -
1322 | Oracle/Read Cache hit ratio on {$DATABASE}
1323 | 10
1324 |
1325 | 0
1326 |
1327 | pyora[{$USERNAME},{$PASSWORD},{$ADDRESS},{$DATABASE},rcachehit]
1328 | 600
1329 | 7
1330 | 90
1331 | 0
1332 | 0
1333 |
1334 | %
1335 | 0
1336 |
1337 | 0
1338 |
1339 |
1340 | 1
1341 |
1342 |
1343 |
1344 | 0
1345 | 0
1346 |
1347 |
1348 |
1349 |
1350 |
1351 |
1352 | 0
1353 |
1354 |
1355 | Oracle
1356 |
1357 |
1358 |
1359 |
1360 | -
1361 | Oracle/Redo Writes on {$DATABASE}
1362 | 10
1363 |
1364 | 0
1365 |
1366 | pyora[{$USERNAME},{$PASSWORD},{$ADDRESS},{$DATABASE},redowrites]
1367 | 300
1368 | 7
1369 | 90
1370 | 0
1371 | 3
1372 |
1373 |
1374 | 1
1375 |
1376 | 0
1377 |
1378 |
1379 | 1
1380 |
1381 |
1382 |
1383 | 0
1384 | 0
1385 |
1386 |
1387 |
1388 |
1389 |
1390 |
1391 | 0
1392 |
1393 |
1394 | Oracle
1395 |
1396 |
1397 |
1398 |
1399 | -
1400 | Oracle/Size of all datafiles on {$DATABASE}
1401 | 10
1402 |
1403 | 0
1404 |
1405 | pyora[{$USERNAME},{$PASSWORD},{$ADDRESS},{$DATABASE},dbfilesize]
1406 | 7200
1407 | 7
1408 | 90
1409 | 0
1410 | 3
1411 |
1412 | B
1413 | 0
1414 |
1415 | 0
1416 |
1417 |
1418 | 1
1419 |
1420 |
1421 |
1422 | 0
1423 | 0
1424 |
1425 |
1426 |
1427 |
1428 |
1429 |
1430 | 0
1431 |
1432 |
1433 | Oracle
1434 |
1435 |
1436 |
1437 |
1438 | -
1439 | Oracle/Size of user data (without temp) on {$DATABASE}
1440 | 10
1441 |
1442 | 0
1443 |
1444 | pyora[{$USERNAME},{$PASSWORD},{$ADDRESS},{$DATABASE},dbsize]
1445 | 7200
1446 | 7
1447 | 90
1448 | 0
1449 | 3
1450 |
1451 | B
1452 | 0
1453 |
1454 | 0
1455 |
1456 |
1457 | 1
1458 |
1459 |
1460 |
1461 | 0
1462 | 0
1463 |
1464 |
1465 |
1466 |
1467 |
1468 |
1469 | 0
1470 |
1471 |
1472 | Oracle
1473 |
1474 |
1475 |
1476 |
1477 | -
1478 | Oracle/Table scan rows gotten on {$DATABASE}
1479 | 10
1480 |
1481 | 0
1482 |
1483 | pyora[{$USERNAME},{$PASSWORD},{$ADDRESS},{$DATABASE},tblrowsscans]
1484 | 300
1485 | 7
1486 | 90
1487 | 0
1488 | 3
1489 |
1490 |
1491 | 1
1492 |
1493 | 0
1494 |
1495 |
1496 | 1
1497 |
1498 |
1499 |
1500 | 0
1501 | 0
1502 |
1503 |
1504 |
1505 |
1506 |
1507 |
1508 | 0
1509 |
1510 |
1511 | Oracle
1512 |
1513 |
1514 |
1515 |
1516 | -
1517 | Oracle/Table scans (long tables) on {$DATABASE}
1518 | 10
1519 |
1520 | 0
1521 |
1522 | pyora[{$USERNAME},{$PASSWORD},{$ADDRESS},{$DATABASE},tblscans]
1523 | 600
1524 | 7
1525 | 90
1526 | 0
1527 | 3
1528 |
1529 |
1530 | 1
1531 |
1532 | 0
1533 |
1534 |
1535 | 1
1536 |
1537 |
1538 |
1539 | 0
1540 | 0
1541 |
1542 |
1543 |
1544 |
1545 |
1546 |
1547 | 0
1548 |
1549 |
1550 | Oracle
1551 |
1552 |
1553 |
1554 |
1555 | -
1556 | Oracle/Uptime on {$DATABASE}
1557 | 10
1558 |
1559 | 0
1560 |
1561 | pyora[{$USERNAME},{$PASSWORD},{$ADDRESS},{$DATABASE},uptime]
1562 | 600
1563 | 7
1564 | 90
1565 | 0
1566 | 3
1567 |
1568 | s
1569 | 0
1570 |
1571 | 0
1572 |
1573 |
1574 | 1
1575 |
1576 |
1577 |
1578 | 0
1579 | 0
1580 |
1581 |
1582 |
1583 |
1584 |
1585 |
1586 | 0
1587 |
1588 |
1589 | Oracle
1590 |
1591 |
1592 |
1593 |
1594 | -
1595 | Oracle/User Commits on {$DATABASE}
1596 | 10
1597 |
1598 | 0
1599 |
1600 | pyora[{$USERNAME},{$PASSWORD},{$ADDRESS},{$DATABASE},commits]
1601 | 600
1602 | 7
1603 | 90
1604 | 0
1605 | 3
1606 |
1607 |
1608 | 1
1609 |
1610 | 0
1611 |
1612 |
1613 | 1
1614 |
1615 |
1616 |
1617 | 0
1618 | 0
1619 |
1620 |
1621 |
1622 |
1623 |
1624 |
1625 | 0
1626 |
1627 |
1628 | Oracle
1629 |
1630 |
1631 |
1632 |
1633 | -
1634 | Oracle/User Transaction Per Sec on {$DATABASE}
1635 | 10
1636 |
1637 | 0
1638 |
1639 | pyora[{$USERNAME},{$PASSWORD},{$ADDRESS},{$DATABASE},query_sysmetrics,User_Transaction_Per_Sec]
1640 | 600
1641 | 7
1642 | 90
1643 | 0
1644 | 0
1645 |
1646 |
1647 | 0
1648 |
1649 | 0
1650 |
1651 |
1652 | 1
1653 |
1654 |
1655 |
1656 | 0
1657 | 0
1658 |
1659 |
1660 |
1661 |
1662 |
1663 |
1664 | 0
1665 |
1666 |
1667 | Oracle
1668 |
1669 |
1670 |
1671 |
1672 | -
1673 | Oracle/Version on {$DATABASE}
1674 | 10
1675 |
1676 | 0
1677 |
1678 | pyora[{$USERNAME},{$PASSWORD},{$ADDRESS},{$DATABASE},version]
1679 | 7200
1680 | 90
1681 | 365
1682 | 0
1683 | 1
1684 |
1685 |
1686 | 0
1687 |
1688 | 0
1689 |
1690 |
1691 | 1
1692 |
1693 |
1694 |
1695 | 0
1696 | 0
1697 |
1698 |
1699 |
1700 |
1701 |
1702 |
1703 | 0
1704 |
1705 |
1706 | Oracle
1707 |
1708 |
1709 |
1710 |
1711 |
1712 |
1713 |
1714 | Discovery Oracle ASM volumes
1715 | 10
1716 |
1717 |
1718 | pyora[{$USERNAME},{$PASSWORD},{$ADDRESS},{$DATABASE},show_asm_volumes]
1719 | 3600
1720 | 0
1721 |
1722 |
1723 | 0
1724 |
1725 |
1726 |
1727 |
1728 |
1729 | 0
1730 |
1731 |
1732 |
1733 |
1734 |
1735 | {#ASMVOLUME}:
1736 | 30
1737 |
1738 |
1739 |
1740 | ASM Volume Use on {#ASMVOLUME}
1741 | 10
1742 |
1743 | 0
1744 |
1745 | pyora[{$USERNAME},{$PASSWORD},{$ADDRESS},{$DATABASE},asm_volume_use,{#ASMVOLUME}]
1746 | 30
1747 | 7
1748 | 90
1749 | 0
1750 | 0
1751 |
1752 | %
1753 | 0
1754 |
1755 | 0
1756 |
1757 |
1758 | 1
1759 |
1760 |
1761 |
1762 | 0
1763 | 0
1764 |
1765 |
1766 |
1767 |
1768 |
1769 |
1770 | 0
1771 |
1772 |
1773 | ASM Volumes
1774 |
1775 |
1776 |
1777 |
1778 |
1779 |
1780 |
1781 | {Custom - Service - Oracle:pyora[{$USERNAME},{$PASSWORD},{$ADDRESS},{$DATABASE},asm_volume_use,{#ASMVOLUME}].last(0)}>{$HIGH}
1782 | Oracle/ASM Volume {#ASMVOLUME} used > {$HIGH} %
1783 |
1784 | 0
1785 | 4
1786 |
1787 | 0
1788 |
1789 |
1790 |
1791 |
1792 |
1793 | Discovery Oracle tablespaces
1794 | 10
1795 |
1796 |
1797 | pyora[{$USERNAME},{$PASSWORD},{$ADDRESS},{$DATABASE},show_tablespaces]
1798 | 3600
1799 | 0
1800 |
1801 |
1802 | 0
1803 |
1804 |
1805 |
1806 |
1807 |
1808 | 0
1809 |
1810 |
1811 |
1812 |
1813 |
1814 | {#TABLESPACE}:
1815 | 30
1816 |
1817 |
1818 |
1819 | Tablespace Use on {#TABLESPACE}
1820 | 10
1821 |
1822 | 0
1823 |
1824 | pyora[{$USERNAME},{$PASSWORD},{$ADDRESS},{$DATABASE},tablespace,{#TABLESPACE}]
1825 | 300
1826 | 7
1827 | 90
1828 | 0
1829 | 0
1830 |
1831 | %
1832 | 0
1833 |
1834 | 0
1835 |
1836 |
1837 | 1
1838 |
1839 |
1840 |
1841 | 0
1842 | 0
1843 |
1844 |
1845 |
1846 |
1847 |
1848 |
1849 | 0
1850 |
1851 |
1852 | Tablespaces
1853 |
1854 |
1855 |
1856 |
1857 |
1858 |
1859 |
1860 | {Custom - Service - Oracle:pyora[{$USERNAME},{$PASSWORD},{$ADDRESS},{$DATABASE},tablespace,{#TABLESPACE}].last(0)}>{$HIGH}
1861 | Oracle/Tablespace {#TABLESPACE} used on {$DATABASE} > {$HIGH} %
1862 |
1863 | 0
1864 | 4
1865 |
1866 | 0
1867 |
1868 |
1869 |
1870 |
1871 |
1872 | Discovery Oracle temp tablespaces
1873 | 10
1874 |
1875 |
1876 | pyora[{$USERNAME},{$PASSWORD},{$ADDRESS},{$DATABASE},show_tablespaces_temp]
1877 | 3600
1878 | 0
1879 |
1880 |
1881 | 0
1882 |
1883 |
1884 |
1885 |
1886 |
1887 | 0
1888 |
1889 |
1890 |
1891 |
1892 |
1893 | {#TABLESPACE_TEMP}:
1894 | 30
1895 |
1896 |
1897 |
1898 | Temp Tablespace Use on {#TABLESPACE_TEMP}
1899 | 10
1900 |
1901 | 0
1902 |
1903 | pyora[{$USERNAME},{$PASSWORD},{$ADDRESS},{$DATABASE},tablespace_temp,{#TABLESPACE_TEMP}]
1904 | 300
1905 | 90
1906 | 365
1907 | 0
1908 | 0
1909 |
1910 | %
1911 | 0
1912 |
1913 | 0
1914 |
1915 |
1916 | 1
1917 |
1918 |
1919 |
1920 | 0
1921 | 0
1922 |
1923 |
1924 |
1925 |
1926 |
1927 |
1928 | 0
1929 |
1930 |
1931 | Temp Tablespaces
1932 |
1933 |
1934 |
1935 |
1936 |
1937 |
1938 |
1939 | {Custom - Service - Oracle:pyora[{$USERNAME},{$PASSWORD},{$ADDRESS},{$DATABASE},tablespace_temp,{#TABLESPACE_TEMP}].last(0)}>{$HIGH}
1940 | Oracle/Tablespace TEMP {#TABLESPACE_TEMP} used on {$DATABASE} > {$HIGH} %
1941 |
1942 | 0
1943 | 4
1944 |
1945 | 0
1946 |
1947 |
1948 |
1949 |
1950 |
1951 |
1952 |
1953 | {$HIGH}
1954 | 97
1955 |
1956 |
1957 |
1958 |
1959 |
1960 |
1961 |
1962 |
1963 | {Custom - Service - Oracle:pyora[{$USERNAME},{$PASSWORD},{$ADDRESS},{$DATABASE},check_archive,{$ARCHIVE}].last(0)}>90
1964 | Oracle/Archive {$ARCHIVE} used on {$DATABASE} > 90%
1965 |
1966 | 0
1967 | 3
1968 | Database archive used is > 90%
1969 | 0
1970 |
1971 |
1972 |
1973 | {Custom - Service - Oracle:pyora[{$USERNAME},{$PASSWORD},{$ADDRESS},{$DATABASE},check_active].last(0)}#1
1974 | Oracle/Database {$DATABASE} is down
1975 |
1976 | 0
1977 | 5
1978 | Banco de dados fora do ar - Acionar o DBA de Plantão.
1979 | 0
1980 |
1981 |
1982 |
1983 | {Custom - Service - Oracle:pyora[{$USERNAME},{$PASSWORD},{$ADDRESS},{$DATABASE},check_active].nodata(700)}=1
1984 | Oracle/Database {$DATABASE} is not responding
1985 |
1986 | 0
1987 | 5
1988 | Banco de dados fora do ar - Acionar o DBA de Plantão.
1989 | 0
1990 |
1991 |
1992 |
1993 | {Custom - Service - Oracle:pyora[{$USERNAME},{$PASSWORD},{$ADDRESS},{$DATABASE},fra_use].last(0)}>90
1994 | Oracle/fra_use used on {$DATABASE} > 90%
1995 |
1996 | 0
1997 | 4
1998 | Fast Recovery Area usage > 90%
1999 | 0
2000 |
2001 |
2002 |
2003 | {Custom - Service - Oracle:pyora[{$USERNAME},{$PASSWORD},{$ADDRESS},{$DATABASE},query_lock].last(0)}>0
2004 | Oracle/Query Lock on {$DATABASE} > 1
2005 |
2006 | 0
2007 | 4
2008 |
2009 | 0
2010 |
2011 |
2012 |
2013 | {Custom - Service - Oracle:pyora[{$USERNAME},{$PASSWORD},{$ADDRESS},{$DATABASE},query_sessions].last(0)}>250
2014 | Oracle/Query Sessions on {$DATABASE} > 250
2015 |
2016 | 0
2017 | 4
2018 |
2019 | 0
2020 |
2021 |
2022 |
2023 |
2024 |
--------------------------------------------------------------------------------