DBA Daily/Weekly/Monthly or Quarterly Checklist
In
response of some fresher DBA I am giving quick checklist for a production DBA. Here
I am including reference of some of the script which I already posted as you
know each DBA have its own scripts depending on database environment too.
Please have a look on into daily, weekly and quarterly checklist.
Note: I am not responsible of any of the script
is harming your database so before using directly on Prod DB. Please check it
on Test environment first and make sure then go for it.
------------------------------------------------------------------------------------------------------------------------
Daily
Checks:
Verify all database, instances, Listener are up, every 30 Min.
Verify the status of daily scheduled jobs/daily backups in the morning very first hour.
Verify the status of daily scheduled jobs/daily backups in the morning very first hour.
Verify
the success of archive log backups, based on the backup interval.
Check the space usage of the archive log file system for both primary and standby DB.
Check the space usage and verify all the tablespace usage is below critical level once in a day.
Verify Rollback segments.
Check the space usage and verify all the tablespace usage is below critical level once in a day.
Verify Rollback segments.
Check the
database performance, periodic basis usually in the morning very first
hour after the night shift schedule backup has been completed.
Check the
sync between the primary database and standby database, every 20 min.
Make a
habit to check out the new alert.log entry hourly specially if getting any
error.
Check the
system performance, periodic basis.
Check for
the invalid objects
Check out
the audit files for any suspicious activities.
Identify bad growth projections.
Identify bad growth projections.
Clear the
trace files in the udump and bdump directory as per the policy.
Verify
all the monitoring agent, including OEM agent and third party monitoring agents.
Make a
habit to read DBA Manual.
Weekly
Checks:
Perform
level 0 or cold backup as per the backup policy. Note the backup policy can be
changed as per the requirement. Don’t
forget to check out the space on disk or tape before performing level 0 or cold
backup.
Perform Export
backups of important tables.
Check the
database statistics collection. On some databases this needs to be done every
day depending upon the requirement.
Approve
or plan any scheduled changes for the week.
Verify
the schedule jobs and clear the output directory. You can also automate it.
Look for the object that break rule.
Look for security policy violation.
Look for security policy violation.
Archive
the alert logs (if possible) to reference the similar kind of error in future.
Visit the home page of key vendors.
Visit the home page of key vendors.
Monthly
or Quarterly Checks:
Verify
the accuracy of backups by creating test databases.
Checks
for the critical patch updates from oracle make sure that your systems are in
compliance with CPU patches.
Checkout
the harmful growth rate.
Review Fragmentation.
Look for I/O Contention.
Perform Tuning and Database Maintenance.
Review Fragmentation.
Look for I/O Contention.
Perform Tuning and Database Maintenance.
Verify
the accuracy of the DR mechanism by performing a database switch over test.
This can be done once in six months based on the business requirements.
-------------------------------------------------------------------------------------------------------------------------------------------------------
Verify
all instances are up:
--------------------------------------------------------------------------------------------
Useful Scripts:
--------------------------------------------------------------------------------------------
Script: To check free, pct_free, and allocated space within a tablespace
SELECT tablespace_name, largest_free_chunk, nr_free_chunks, sum_alloc_blocks, sum_free_blocks
, to_char(100*sum_free_blocks/sum_alloc_blocks, '09.99') || '%' AS pct_free
FROM ( SELECT tablespace_name, sum(blocks) AS sum_alloc_blocks
FROM dba_data_files
GROUP BY tablespace_name),
( SELECT tablespace_name AS fs_ts_name, max(blocks) AS largest_free_chunk
, count(blocks) AS nr_free_chunks, sum(blocks) AS sum_free_blocks
FROM dba_free_space
GROUP BY tablespace_name )
WHERE tablespace_name = fs_ts_name;
Script: To analyze tables and indexes
BEGIN
dbms_utility.analyze_schema ( '&OWNER', 'ESTIMATE', NULL, 5 ) ;
END ;
Script: To find out any object reaching <threshold>
SELECT e.owner, e.segment_type , e.segment_name , count(*) as nr_extents , s.max_extents
, to_char ( sum ( e.bytes ) / ( 1024 * 1024 ) , '999,999.90') as MB
FROM dba_extents e , dba_segments s
WHERE e.segment_name = s.segment_name
GROUP BY e.owner, e.segment_type , e.segment_name , s.max_extents
HAVING count(*) > &THRESHOLD
OR ( ( s.max_extents - count(*) ) < &&THRESHOLD )
ORDER BY count(*) desc;
The above query will find out any object reaching <threshold> level extents, and then you have to manually upgrade it to allow unlimited max_extents (thus only objects we expect to be big are allowed to become big.
Script: To identify space-bound objects. If all is well, no rows are returned.
SELECT a.table_name, a.next_extent, a.tablespace_name
FROM all_tables a,( SELECT tablespace_name, max(bytes) as big_chunk
FROM dba_free_space
GROUP BY tablespace_name ) f
WHERE f.tablespace_name = a.tablespace_name AND a.next_extent > f.big_chunk;
Run the above query to find the space bound object . If all is well no rows are returned if found something then look at the value of next extent. Check to find out what happened then use coalesce (alter tablespace <foo> coalesce;). and finally, add another datafile to the tablespace if needed.
Script: To find tables that don't match the tablespace default for NEXT extent.
SELECT segment_name, segment_type, ds.next_extent as Actual_Next
, dt.tablespace_name, dt.next_extent as Default_Next
FROM dba_tablespaces dt, dba_segments ds
WHERE dt.tablespace_name = ds.tablespace_name
AND dt.next_extent !=ds.next_extent AND ds.owner = UPPER ( '&OWNER' )
ORDER BY tablespace_name, segment_type, segment_name;
Script: To check existing extents
SELECT segment_name, segment_type, count(*) as nr_exts
, sum ( DECODE ( dx.bytes,dt.next_extent,0,1) ) as nr_illsized_exts
, dt.tablespace_name, dt.next_extent as dflt_ext_size
FROM dba_tablespaces dt, dba_extents dx
WHERE dt.tablespace_name = dx.tablespace_name
AND dx.owner = '&OWNER'
GROUP BY segment_name, segment_type, dt.tablespace_name, dt.next_extent;
The above query will find how many of each object's extents differ in size from the tablespace's default size. If it shows a lot of different sized extents, your free space is likely to become fragmented. If so, need to reorganize this tablespace.
Script: To find tables without PK constraint
SELECT table_name FROM all_tables
WHERE owner = '&OWNER'
MINUS
SELECT table_name FROM all_constraints
WHERE owner = '&&OWNER' AND constraint_type = 'P';
Script: To find out which primary keys are disabled
SELECT owner, constraint_name, table_name, status
FROM all_constraints
WHERE owner = '&OWNER' AND status = 'DISABLED' AND constraint_type = 'P';
Script: To find tables with nonunique PK indexes.
SELECT index_name, table_name, uniqueness
FROM all_indexes
WHERE index_name like '&PKNAME%'
AND owner = '&OWNER' AND uniqueness = 'NONUNIQUE'
SELECT c.constraint_name, i.tablespace_name, i.uniqueness
FROM all_constraints c , all_indexes i
WHERE c.owner = UPPER ( '&OWNER' ) AND i.uniqueness = 'NONUNIQUE'
AND c.constraint_type = 'P' AND i.index_name = c.constraint_name;
Script: To check datatype consistency between two environments
SELECT table_name, column_name, data_type, data_length,data_precision,data_scale,nullable
FROM all_tab_columns -- first environment
WHERE owner = '&OWNER'
MINUS
SELECT table_name,column_name,data_type,data_length,data_precision,data_scale,nullable
FROM all_tab_columns@&my_db_link -- second environment
WHERE owner = '&OWNER2'
order by table_name, column_name;
Script: To find out any difference in objects between two instances
SELECT object_name, object_type
FROM user_objects
MINUS
SELECT object_name, object_type
FROM user_objects@&my_db_link;
For more about script and Daily DBA Task or Monitoring use the search concept to check my other post. Follow the below link for important Monitoring Script: http://shahiddba.blogspot.com/2012/04/oracle-dba-daily-checklist.html
Below is the brief description about
some of the important concept including important SQL scripts. You can
find more scripts on my different post by using blog search option.
Make sure
the database is available. Log into each instance and run daily reports or test
scripts. You can also automate this procedure but it is better do it manually. Optional
implementation: use Oracle Enterprise Manager's 'probe' event.
Verify
DBSNMP is running:
Log on to
each managed machine to check for the 'dbsnmp' process. For Unix: at the
command line, type ps –ef | grep dbsnmp. There should be two dbsnmp processes running.
If not, restart DBSNMP.
Verify
success of Daily Scheduled Job:
Each
morning one of your prime tasks is to check backup log, backup drive where your
actual backup is stored to verify the night backup.
Verify
success of database archiving to tape or disk:
In the
next subsequent work check the location where daily archiving stored. Verify
the archive backup on disk or tape.
Verify
enough resources for acceptable performance:
For each
instance, verify that enough free space exists in each tablespace to handle the
day’s expected growth. As of <date>, the minimum free space for <repeat
for each tablespace>: [ < tablespace > is < amount > ]. When
incoming data is stable, and average daily growth can be calculated, then the
minimum free space should be at least <time to order, get, and install more
disks> days’ data growth. Go to each instance, run query to check free mb in
tablespaces/datafiles. Compare to the minimum free MB for that tablespace. Note
any low-space conditions and correct it.
Verify
rollback segment:
Status
should be ONLINE, not OFFLINE or FULL, except in some cases you may have a
special rollback segment for large batch jobs whose normal status is OFFLINE. Optional:
each database may have a list of rollback segment names and their expected
statuses.For current status of each ONLINE or FULL rollback segment (by ID not
by name), query on V$ROLLSTAT. For storage parameters and names of ALL rollback
segment, query on DBA_ROLLBACK_SEGS. That view’s STATUS field is less accurate
than V$ROLLSTAT, however, as it lacks the PENDING OFFLINE and FULL statuses, showing
these as OFFLINE and ONLINE respectively.
Look
for any new alert log entries:
Connect
to each managed system. Use 'telnet' or comparable program. For each managed
instance, go to the background dump destination, usually $ORACLE_BASE/<SID>/bdump.
Make sure to look under each managed database's SID. At the prompt, use the
Unix ‘tail’ command to see the alert_<SID>.log, or otherwise examine the
most recent entries in the file. If any ORA-errors have appeared since the
previous time you looked, note them in the Database Recovery Log and
investigate each one. The recovery log is in <file>.
Identify
bad growth projections.
Look for
segments in the database that are running out of resources (e.g. extents) or
growing at an excessive rate. The storage parameters of these segments may need
to be adjusted. For example, if any object reached 200 as the number of current
extents, upgrade the max_extents to unlimited. For that run query to gather
daily sizing information, check current extents, current table sizing
information, current index sizing information and find growth trends
Identify
space-bound objects:
Space-bound
objects’ next_extents are bigger than the largest extent that the tablespace
can offer. Space-bound objects can harm database operation. If we get such
object, first need to investigate the situation. Then we can use ALTER
TABLESPACE <tablespace> COALESCE. Or add another datafile. Run spacebound.sql.
If all is well, zero rows will be returned.
Processes
to review contention for CPU, memory, network or disk resources:
To check
CPU utilization, go to =>system metrics=>CPU utilization page. 400 is the
maximum CPU utilization because there are 4 CPUs on phxdev and phxprd machine. We
need to investigate if CPU utilization keeps above 350 for a while.
Make a
habit to Read DBA Manual:
Nothing
is more valuable in the long run than that the DBA be as widely experienced, and
as widely read, as possible. Readings
should include DBA manuals, trade journals, and possibly newsgroups or mailing
lists.
Look
for objects that break rules:
For each
object-creation policy (naming convention, storage parameters, etc.) have an
automated check to verify that the policy is being followed. Every object in a
given tablespace should have the exact same size for NEXT_EXTENT, which should
match the tablespace default for NEXT_EXTENT. As of 10/03/2012, default NEXT_EXTENT
for DATAHI is 1 gig (1048576 bytes), DATALO is 500 mb (524288 bytes), and
INDEXES is 256 mb (262144 bytes). To check settings for NEXT_EXTENT, run
nextext.sql. To check existing extents, run existext.sql
All
tables should have unique primary keys:
To check
missing PK, run no_pk.sql. To check disabled PK, run disPK.sql. All primary key
indexes should be unique. Run nonuPK.sql to check. All indexes should use
INDEXES tablespace. Run mkrebuild_idx.sql. Schemas should look identical
between environments, especially test and production. To check data type
consistency, run datatype.sql. To check other object consistency, run obj_coord.sql.
Look
for security policy violations:
Look in
SQL*Net logs for errors, issues, Client side logs, Server side logs and Archive
all Alert Logs to history
Visit home pages of key vendors:
For new
update information made a habit to visit home pages of key vendors such as: Oracle
Corporation: http://www.oracle.com, http://technet.oracle.com, http://www.oracle.com/support,
http://www.oramag.com
Quest
Software: http://www.quests.com
Sun
Microsystems: http://www.sun.com
Look
for Harmful Growth Rates:
Review changes
in segment growth when compared to previous reports to identify segments with a
harmful growth rate.
Review
Tuning Opportunities and Perform Tuning Maintainance:
Review
common Oracle tuning points such as cache hit ratio, latch contention, and
other points dealing with memory management. Compare with past reports to
identify harmful trends or determine impact of recent tuning adjustments. Make
the adjustments necessary to avoid contention for system resources.
This may include scheduled down time or request for additional
resources.
Look
for I/O Contention:
Review
database file activity. Compare to past output to identify trends that could
lead to possible contention.
Review
Fragmentation:
Investigate
fragmentation (e.g. row chaining, etc.), Project Performance into the Future
Compare
reports on CPU, memory, network, and disk utilization from both Oracle and the
operating system to identify trends that could lead to contention for any one
of these resources in the near future. Compare performance trends to Service
Level Agreement to see when the system will go out of bounds.
--------------------------------------------------------------------------------------------
Useful Scripts:
--------------------------------------------------------------------------------------------
Script: To check free, pct_free, and allocated space within a tablespace
SELECT tablespace_name, largest_free_chunk, nr_free_chunks, sum_alloc_blocks, sum_free_blocks
, to_char(100*sum_free_blocks/sum_alloc_blocks, '09.99') || '%' AS pct_free
FROM ( SELECT tablespace_name, sum(blocks) AS sum_alloc_blocks
FROM dba_data_files
GROUP BY tablespace_name),
( SELECT tablespace_name AS fs_ts_name, max(blocks) AS largest_free_chunk
, count(blocks) AS nr_free_chunks, sum(blocks) AS sum_free_blocks
FROM dba_free_space
GROUP BY tablespace_name )
WHERE tablespace_name = fs_ts_name;
Script: To analyze tables and indexes
BEGIN
dbms_utility.analyze_schema ( '&OWNER', 'ESTIMATE', NULL, 5 ) ;
END ;
Script: To find out any object reaching <threshold>
SELECT e.owner, e.segment_type , e.segment_name , count(*) as nr_extents , s.max_extents
, to_char ( sum ( e.bytes ) / ( 1024 * 1024 ) , '999,999.90') as MB
FROM dba_extents e , dba_segments s
WHERE e.segment_name = s.segment_name
GROUP BY e.owner, e.segment_type , e.segment_name , s.max_extents
HAVING count(*) > &THRESHOLD
OR ( ( s.max_extents - count(*) ) < &&THRESHOLD )
ORDER BY count(*) desc;
The above query will find out any object reaching <threshold> level extents, and then you have to manually upgrade it to allow unlimited max_extents (thus only objects we expect to be big are allowed to become big.
Script: To identify space-bound objects. If all is well, no rows are returned.
SELECT a.table_name, a.next_extent, a.tablespace_name
FROM all_tables a,( SELECT tablespace_name, max(bytes) as big_chunk
FROM dba_free_space
GROUP BY tablespace_name ) f
WHERE f.tablespace_name = a.tablespace_name AND a.next_extent > f.big_chunk;
Run the above query to find the space bound object . If all is well no rows are returned if found something then look at the value of next extent. Check to find out what happened then use coalesce (alter tablespace <foo> coalesce;). and finally, add another datafile to the tablespace if needed.
Script: To find tables that don't match the tablespace default for NEXT extent.
SELECT segment_name, segment_type, ds.next_extent as Actual_Next
, dt.tablespace_name, dt.next_extent as Default_Next
FROM dba_tablespaces dt, dba_segments ds
WHERE dt.tablespace_name = ds.tablespace_name
AND dt.next_extent !=ds.next_extent AND ds.owner = UPPER ( '&OWNER' )
ORDER BY tablespace_name, segment_type, segment_name;
Script: To check existing extents
SELECT segment_name, segment_type, count(*) as nr_exts
, sum ( DECODE ( dx.bytes,dt.next_extent,0,1) ) as nr_illsized_exts
, dt.tablespace_name, dt.next_extent as dflt_ext_size
FROM dba_tablespaces dt, dba_extents dx
WHERE dt.tablespace_name = dx.tablespace_name
AND dx.owner = '&OWNER'
GROUP BY segment_name, segment_type, dt.tablespace_name, dt.next_extent;
The above query will find how many of each object's extents differ in size from the tablespace's default size. If it shows a lot of different sized extents, your free space is likely to become fragmented. If so, need to reorganize this tablespace.
Script: To find tables without PK constraint
SELECT table_name FROM all_tables
WHERE owner = '&OWNER'
MINUS
SELECT table_name FROM all_constraints
WHERE owner = '&&OWNER' AND constraint_type = 'P';
Script: To find out which primary keys are disabled
SELECT owner, constraint_name, table_name, status
FROM all_constraints
WHERE owner = '&OWNER' AND status = 'DISABLED' AND constraint_type = 'P';
Script: To find tables with nonunique PK indexes.
SELECT index_name, table_name, uniqueness
FROM all_indexes
WHERE index_name like '&PKNAME%'
AND owner = '&OWNER' AND uniqueness = 'NONUNIQUE'
SELECT c.constraint_name, i.tablespace_name, i.uniqueness
FROM all_constraints c , all_indexes i
WHERE c.owner = UPPER ( '&OWNER' ) AND i.uniqueness = 'NONUNIQUE'
AND c.constraint_type = 'P' AND i.index_name = c.constraint_name;
Script: To check datatype consistency between two environments
SELECT table_name, column_name, data_type, data_length,data_precision,data_scale,nullable
FROM all_tab_columns -- first environment
WHERE owner = '&OWNER'
MINUS
SELECT table_name,column_name,data_type,data_length,data_precision,data_scale,nullable
FROM all_tab_columns@&my_db_link -- second environment
WHERE owner = '&OWNER2'
order by table_name, column_name;
Script: To find out any difference in objects between two instances
SELECT object_name, object_type
FROM user_objects
MINUS
SELECT object_name, object_type
FROM user_objects@&my_db_link;
For more about script and Daily DBA Task or Monitoring use the search concept to check my other post. Follow the below link for important Monitoring Script: http://shahiddba.blogspot.com/2012/04/oracle-dba-daily-checklist.html