├── .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 | 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 | 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 | --------------------------------------------------------------------------------