├── README.txt ├── bin ├── Template.js ├── Template.vbs ├── archive_oracle_log_files.ksh ├── asm ├── asm_disk_mappings.ksh ├── crontab_header_oracle_packmule.txt ├── crontab_header_oracle_racnode1.txt ├── crontab_header_oracle_racnode2.txt ├── crontab_header_root_thing1.txt ├── crontab_header_root_thing2.txt ├── crs_components_backup_10g.ksh ├── dbora_10g ├── dbora_10g_solaris ├── dbora_grid_10g ├── dbora_rac_10g ├── dg_activate_standby_failover.ksh ├── dg_activate_standby_failover_9i.ksh ├── dg_rebuild_standby.ksh ├── dg_refresh_standby_database.ksh ├── dos2unix.pl ├── dpump_backup_full.bat ├── dpump_backup_full.ksh ├── export_backup_full.bat ├── export_backup_full.ksh ├── get_public_ip_address ├── hugepages_settings.sh ├── ias10gr1_ctl ├── iscsi-ls-map.ksh ├── iscsi_client_services_solaris.ksh ├── metalink_download_patch.sh ├── ocfs2_check_orphaned_files.ksh ├── oem10g_ctl.ksh ├── oemctrl ├── oracle_ADO_example.vbs ├── purge_archived_logs.ksh ├── rac_crs_stat ├── rman_backup_online_full.bat ├── rman_backup_online_full.ksh ├── rman_copy_purge_backupset.bat ├── sp_purge_n_days.vbs ├── standby_database_admin.bat ├── switch_log_file.ksh └── top15 ├── extproc ├── compile_shell.sh └── shell.c └── sql ├── asm_alias.sql ├── asm_clients.sql ├── asm_diskgroups.sql ├── asm_disks.sql ├── asm_disks_perf.sql ├── asm_drop_files.sql ├── asm_files.sql ├── asm_files2.sql ├── asm_files_10g.sql ├── asm_templates.sql ├── asmm_components.sql ├── awr_snapshots_dbtime.sql ├── awr_snapshots_dbtime_xls.sql ├── dba_blocks_used_by_table.sql ├── dba_column_constraints.sql ├── dba_compare_schemas.sql ├── dba_controlfile_records.sql ├── dba_controlfiles.sql ├── dba_cr_init.sql ├── dba_db_growth.sql ├── dba_directories.sql ├── dba_errors.sql ├── dba_file_space_usage.sql ├── dba_file_space_usage_7.sql ├── dba_file_use.sql ├── dba_file_use_7.sql ├── dba_files.sql ├── dba_files_all.sql ├── dba_free_space_frag.sql ├── dba_highwater_mark.sql ├── dba_index_fragmentation.sql ├── dba_index_schema_fragmentation_report.sql ├── dba_index_stats.sql ├── dba_invalid_objects.sql ├── dba_invalid_objects_summary.sql ├── dba_jobs.sql ├── dba_object_cache.sql ├── dba_object_search.sql ├── dba_object_summary.sql ├── dba_options.sql ├── dba_owner_to_tablespace.sql ├── dba_plsql_package_size.sql ├── dba_query_hidden_parameters.sql ├── dba_random_number.sql ├── dba_rebuild_indexes.sql ├── dba_recompile_invalid_objects.sql ├── dba_registry.sql ├── dba_related_child_tables.sql ├── dba_row_size.sql ├── dba_segment_summary.sql ├── dba_snapshot_database_10g.sql ├── dba_snapshot_database_8i.sql ├── dba_snapshot_database_9i.sql ├── dba_table_info.sql ├── dba_tables_all.sql ├── dba_tables_current_user.sql ├── dba_tables_query_user.sql ├── dba_tablespace_mapper.sql ├── dba_tablespace_to_owner.sql ├── dba_tablespaces.sql ├── dba_tablespaces_7.sql ├── dba_tablespaces_8i.sql ├── dba_top_segments.sql ├── dpump_jobs.sql ├── dpump_progress.sql ├── dpump_sessions.sql ├── erp_conc_manager_job_status.sql ├── erp_conc_manager_job_status2.sql ├── erp_conc_manager_user_query.sql ├── example_create_clob.sql ├── example_create_clob_8.sql ├── example_create_dimension.sql ├── example_create_emp_dept_custom.sql ├── example_create_emp_dept_original.sql ├── example_create_index.sql ├── example_create_index_organized_table.sql ├── example_create_materialized_view.sql ├── example_create_not_null_constraints.sql ├── example_create_primary_foreign_key.sql ├── example_create_profile_password_parameters.sql ├── example_create_profile_resource_parameters.sql ├── example_create_resource_plan_multi_resource_plan_9i.sql ├── example_create_sequence.sql ├── example_create_table.sql ├── example_create_table_buffer_pools.sql ├── example_create_tablespace.sql ├── example_create_temporary_tables.sql ├── example_create_user_tables.sql ├── example_database_resource_manager_setup.sql ├── example_drop_unused_column.sql ├── example_lob_demonstration.sql ├── example_move_table.sql ├── example_partition_range_date_oracle_8.sql ├── example_partition_range_number_oracle_8.sql ├── example_transport_tablespace.sql ├── fdb_log_files.sql ├── fdb_redo_time_matrix.sql ├── fdb_status.sql ├── fra_alerts.sql ├── fra_files.sql ├── fra_status.sql ├── help.sql ├── lob_dump_blob.sql ├── lob_dump_clob.sql ├── lob_dump_nclob.sql ├── lob_fragmentation_user.sql ├── locks_blocking.sql ├── locks_blocking2.sql ├── locks_dml_ddl.sql ├── locks_dml_lock_time.sql ├── mts_dispatcher_status.sql ├── mts_dispatcher_utilization.sql ├── mts_queue_information.sql ├── mts_shared_server_statistics.sql ├── mts_shared_server_utilization.sql ├── mts_user_connections.sql ├── owi_event_names.sql ├── perf_db_block_buffer_usage.sql ├── perf_explain_plan.sql ├── perf_file_io.sql ├── perf_file_io_7.sql ├── perf_file_io_efficiency.sql ├── perf_file_waits.sql ├── perf_hit_ratio_by_session.sql ├── perf_hit_ratio_system.sql ├── perf_log_switch_history_bytes_daily_all.sql ├── perf_log_switch_history_count_daily.sql ├── perf_log_switch_history_count_daily_7.sql ├── perf_log_switch_history_count_daily_all.sql ├── perf_lru_latch_contention.sql ├── perf_objects_without_statistics.sql ├── perf_performance_snapshot.sql ├── perf_redo_log_contention.sql ├── perf_sga_free_pool.sql ├── perf_sga_usage.sql ├── perf_shared_pool_memory.sql ├── perf_top_10_procedures.sql ├── perf_top_10_tables.sql ├── perf_top_sql_by_buffer_gets.sql ├── perf_top_sql_by_disk_reads.sql ├── plsql_random_numbers.sql ├── plsql_webdba_utl_pkg.sql ├── rac_instances.sql ├── rc_databases.sql ├── rman_backup_pieces.sql ├── rman_backup_sets.sql ├── rman_backup_sets_8i.sql ├── rman_configuration.sql ├── rman_configuration_clear_all_9i.rcv ├── rman_configuration_setup_9i.rcv ├── rman_controlfiles.sql ├── rman_progress.sql ├── rman_spfiles.sql ├── rollback_segments.sql ├── rollback_users.sql ├── rsrc_plan_status_detail.sql ├── rsrc_plan_status_summary.sql ├── sec_default_passwords.sql ├── sec_roles.sql ├── sec_users.sql ├── sess_current_user_transactions.sql ├── sess_query_sql.sql ├── sess_uncommited_transactions.sql ├── sess_user_sessions.sql ├── sess_user_stats.sql ├── sess_user_trace_file_location.sql ├── sess_users.sql ├── sess_users_8i.sql ├── sess_users_active.sql ├── sess_users_active_8i.sql ├── sess_users_active_sql.sql ├── sess_users_by_cpu.sql ├── sess_users_by_cursors.sql ├── sess_users_by_io.sql ├── sess_users_by_memory.sql ├── sess_users_by_transactions.sql ├── sess_waiting.sql ├── sess_waiting_8i.sql ├── sp_auto.sql ├── sp_auto_15.sql ├── sp_auto_30.sql ├── sp_auto_5.sql ├── sp_list.sql ├── sp_parameters.sql ├── sp_purge.sql ├── sp_purge_30_days_10g.sql ├── sp_purge_30_days_9i.sql ├── sp_purge_n_days_10g.sql ├── sp_purge_n_days_9i.sql ├── sp_snap.sql ├── sp_statspack_custom_pkg_10g.sql ├── sp_statspack_custom_pkg_9i.sql ├── sp_trunc.sql ├── temp_sort_segment.sql ├── temp_sort_users.sql ├── temp_status.sql ├── undo_contention.sql ├── undo_segments.sql ├── undo_users.sql ├── wm_create_workspace.sql ├── wm_disable_versioning.sql ├── wm_enable_versioning.sql ├── wm_freeze_workspace.sql ├── wm_get_workspace.sql ├── wm_goto_workspace.sql ├── wm_merge_workspace.sql ├── wm_refresh_workspace.sql ├── wm_remove_workspace.sql ├── wm_rollback_workspace.sql ├── wm_unfreeze_workspace.sql └── wm_workspaces.sql /bin/crontab_header_root_thing1.txt: -------------------------------------------------------------------------------- 1 | # +-----------------------------------------------------------------------+ 2 | # | RECORD FORMAT | 3 | # | ------------- | 4 | # | minute(0-59) hour(0-23) day(1-31) month(1-12) weekday(0-6 0=Sunday) | 5 | # +-----------------------------------------------------------------------+ 6 | # 7 | # +---------------------------------------------------------+------------------------+ 8 | # | Take nightly backup of OCR File and Voting Disk | Daily at 3:10 a.m. | 9 | # +---------------------------------------------------------+------------------------+ 10 | 10 03 * * * /u01/app/oracle/dba_scripts/bin/crs_components_backup_10g.ksh crs VOTEDISK OCRFILE > /u01/app/oracle/dba_scripts/log/crs_components_backup_10g_crs_THING1.job 2>&1 11 | # 12 | # +---------------------------------------------------------+------------------------+ 13 | # | Check OCFS2 Orphaned Files | Daily at 8:10 p.m. | 14 | # +---------------------------------------------------------+------------------------+ 15 | 10 20 * * * /u01/app/oracle/dba_scripts/bin/ocfs2_check_orphaned_files.ksh /dev/iscsi/thingdbocfs2vol1/part1 0000 5 > /u01/app/oracle/dba_scripts/log/ocfs2_check_orphaned_files_thingdbocfs2vol1_part1_0000_THING1.job 2>&1 16 | # 17 | -------------------------------------------------------------------------------- /bin/crontab_header_root_thing2.txt: -------------------------------------------------------------------------------- 1 | # +-----------------------------------------------------------------------+ 2 | # | RECORD FORMAT | 3 | # | ------------- | 4 | # | minute(0-59) hour(0-23) day(1-31) month(1-12) weekday(0-6 0=Sunday) | 5 | # +-----------------------------------------------------------------------+ 6 | # 7 | # +---------------------------------------------------------+------------------------+ 8 | # | Take nightly backup of OCR File and Voting Disk | Daily at 3:20 a.m. | 9 | # +---------------------------------------------------------+------------------------+ 10 | 20 03 * * * /u01/app/oracle/dba_scripts/bin/crs_components_backup_10g.ksh crs NOVOTEDISK OCRFILE > /u01/app/oracle/dba_scripts/log/crs_components_backup_10g_crs_THING2.job 2>&1 11 | # 12 | # +---------------------------------------------------------+------------------------+ 13 | # | Check OCFS2 Orphaned Files | Daily at 8:20 p.m. | 14 | # +---------------------------------------------------------+------------------------+ 15 | 20 20 * * * /u01/app/oracle/dba_scripts/bin/ocfs2_check_orphaned_files.ksh /dev/iscsi/thingdbocfs2vol1/part1 0001 5 > /u01/app/oracle/dba_scripts/log/ocfs2_check_orphaned_files_thingdbocfs2vol1_part1_0001_THING2.job 2>&1 16 | # 17 | -------------------------------------------------------------------------------- /bin/get_public_ip_address: -------------------------------------------------------------------------------- 1 | : 2 | 3 | # +----------------------------------------------------------------------------+ 4 | # | Jeffrey M. Hunter | 5 | # | jhunter@idevelopment.info | 6 | # | www.idevelopment.info | 7 | # |----------------------------------------------------------------------------| 8 | # | Copyright (c) 1998-2015 Jeffrey M. Hunter. All rights reserved. | 9 | # |----------------------------------------------------------------------------| 10 | # | DATABASE : Oracle | 11 | # | FILE : get_public_ip_address | 12 | # | CLASS : UNIX Shell Scripts | 13 | # | NOTE : As with any code, ensure to test this script in a development | 14 | # | environment before attempting to run it in production. | 15 | # +----------------------------------------------------------------------------+ 16 | 17 | SendMailBinary="/usr/lib/sendmail"; # Linux 18 | # SendMailBinary="/usr/sbin/sendmail"; # FreeBSD 19 | 20 | MAILHEADERFILE=TempMailHeader.txt 21 | MAILBODYFILE=TempMailBody.txt 22 | 23 | cd /tmp 24 | 25 | # [ - OLD METHOD - ] 26 | # wget http://www.whatismyip.com 27 | # mail_message=`grep 'Your IP Address Is' index.html` 28 | # mail_message=`echo $mail_message | sed 's/

//g'` 29 | # mail_message=`echo $mail_message | sed 's/<\/h1>//g'` 30 | # mail_message=`echo $mail_message | sed 's/
//g'` 31 | 32 | 33 | # [ - SUGGESTED METHOD - ] 34 | wget http://www.whatismyip.com/automation/n09230945.asp 35 | mail_message=`cat n09230945.asp` 36 | 37 | s_mail_message=`echo $mail_message | sed 's/Your IP Address Is //g'` 38 | 39 | echo "Subject: Public WAN IP Address - $s_mail_message" > $MAILHEADERFILE 40 | 41 | echo $mail_message > $MAILBODYFILE; 42 | 43 | cat $MAILHEADERFILE $MAILBODYFILE | $SendMailBinary -v -fjhunter@alex.com jhunter@idevelopment.info 44 | 45 | rm -f index.html 46 | rm -f n09230945.asp 47 | rm -f n09230945.asp.* 48 | rm -f $MAILHEADERFILE 49 | rm -f $MAILBODYFILE 50 | -------------------------------------------------------------------------------- /bin/iscsi-ls-map.ksh: -------------------------------------------------------------------------------- 1 | #!/bin/ksh 2 | 3 | # +----------------------------------------------------------------------------+ 4 | # | Jeffrey M. Hunter | 5 | # | jhunter@idevelopment.info | 6 | # | www.idevelopment.info | 7 | # |----------------------------------------------------------------------------| 8 | # | Copyright (c) 1998-2015 Jeffrey M. Hunter. All rights reserved. | 9 | # |----------------------------------------------------------------------------| 10 | # | DATABASE : Oracle | 11 | # | FILE : iscsi-ls-map.ksh | 12 | # | CLASS : UNIX Shell Scripts | 13 | # | PURPOSE : Script used to generate a full mapping of iSCSI target names | 14 | # | to local SCSI device names. | 15 | # | PARAMETERS : None. | 16 | # | | 17 | # | EXAMPLE | 18 | # | OUTPUT : Host / SCSI ID SCSI Device Name iSCSI Target Name | 19 | # | ---------------- ------------------------ ----------------- | 20 | # | 0 /dev/sda1 asm4 | 21 | # | 1 /dev/sdb1 asm3 | 22 | # | 2 /dev/sdd1 asm2 | 23 | # | 3 /dev/sdc1 asm1 | 24 | # | 4 /dev/sde1 crs | 25 | # | | 26 | # | NOTE : As with any code, ensure to test this script in a development | 27 | # | environment before attempting to run it in production. | 28 | # +----------------------------------------------------------------------------+ 29 | 30 | RUN_USERID=root 31 | export RUN_USERID 32 | 33 | RUID=`id | awk -F\( '{print $2}'|awk -F\) '{print $1}'` 34 | if [[ ${RUID} != "$RUN_USERID" ]];then 35 | echo " " 36 | echo "You must be logged in as $RUN_USERID to run this script." 37 | echo "Exiting script." 38 | echo " " 39 | exit 1 40 | fi 41 | 42 | dmesg | grep "^Attach" \ 43 | | awk -F" " '{ print "/dev/"$4 "1 " $6 }' \ 44 | | sed -e 's/,//' | sed -e 's/scsi//' \ 45 | | sort -n -k2 \ 46 | | sed -e '/disk1/d' > /tmp/tmp_scsi_dev 47 | 48 | iscsi-ls | egrep -e "TARGET NAME" -e "HOST ID" \ 49 | | awk -F" " '{ if ($0 ~ /^TARGET.*/) printf $4; if ( $0 ~ /^HOST/) printf " %s\n",$4}' \ 50 | | sort -n -k2 \ 51 | | cut -d':' -f2- \ 52 | | cut -d'.' -f2- > /tmp/tmp_scsi_targets 53 | 54 | join -t" " -1 2 -2 2 /tmp/tmp_scsi_dev /tmp/tmp_scsi_targets > MAP 55 | 56 | 57 | echo "Host / SCSI ID SCSI Device Name iSCSI Target Name" 58 | echo "---------------- ------------------------ -----------------" 59 | 60 | cat MAP | sed -e 's/ / /g' 61 | 62 | rm -f MAP 63 | -------------------------------------------------------------------------------- /bin/oemctrl: -------------------------------------------------------------------------------- 1 | #!/bin/ksh 2 | 3 | echo "Starting OEM Database Control..." 4 | 5 | case "$1" in 6 | start) ACTION=start ;; 7 | stop) ACTION=stop ;; 8 | "") echo "Invalid Parameter";exit ;; 9 | *) echo "Invalid Parameter";exit ;; 10 | esac 11 | 12 | export ORACLE_SID=testdb1 13 | emctl $ACTION dbconsole 14 | 15 | sleep 5 16 | 17 | export ORACLE_SID=testdb2 18 | emctl $ACTION dbconsole 19 | 20 | echo "Finished Starting OEM Database Control!" 21 | -------------------------------------------------------------------------------- /bin/rac_crs_stat: -------------------------------------------------------------------------------- 1 | #!/bin/ksh 2 | 3 | # +----------------------------------------------------------------------------+ 4 | # | Jeffrey M. Hunter | 5 | # | jhunter@idevelopment.info | 6 | # | www.idevelopment.info | 7 | # |----------------------------------------------------------------------------| 8 | # | Copyright (c) 1998-2015 Jeffrey M. Hunter. All rights reserved. | 9 | # |----------------------------------------------------------------------------| 10 | # | DATABASE : Oracle | 11 | # | FILE : rac_crs_stat | 12 | # | CLASS : UNIX Shell Scripts | 13 | # | PURPOSE : This KSH script will query all CRS resources using the crs_stat | 14 | # | script. The report will be a formatted version of the | 15 | # | crs_stat -t command, but in tabular form with resource name | 16 | # | and status. Filtering options are available by passing in a | 17 | # | single string parameter to this script. This argument will be | 18 | # | used to limit the output to HA resources whose names match | 19 | # | that string. | 20 | # | USAGE : rac_crs_stat.ksh [RESOURCE_KEY] | 21 | # | NOTE : This script requires the environment $ORA_CRS_HOME to be set to | 22 | # | your CRS installation. | 23 | # | NOTE : As with any code, ensure to test this script in a development | 24 | # | environment before attempting to run it in production. | 25 | # +----------------------------------------------------------------------------+ 26 | 27 | # +----------------------------------------------------------------------------+ 28 | # | GLOBAL VARIABLES | 29 | # +----------------------------------------------------------------------------+ 30 | 31 | RSC_KEY=$1 32 | QSTAT=-u 33 | AWK=/usr/bin/awk 34 | 35 | # +----------------------------------------------------------------------------+ 36 | # | TABLE HEADER | 37 | # +----------------------------------------------------------------------------+ 38 | 39 | $AWK \ 40 | 'BEGIN {printf "%-50s %-10s %-18s\n", "HA Resource", "Target", "State"; 41 | printf "%-50s %-10s %-18s\n", "-----------", "------", "-----";}' 42 | 43 | # +----------------------------------------------------------------------------+ 44 | # | TABLE BODY | 45 | # +----------------------------------------------------------------------------+ 46 | 47 | $ORA_CRS_HOME/bin/crs_stat $QSTAT | $AWK \ 48 | 'BEGIN { FS="="; state = 0; } 49 | $1~/NAME/ && $2~/'$RSC_KEY'/ {appname = $2; state=1}; 50 | state == 0 {next;} 51 | $1~/TARGET/ && state == 1 {apptarget = $2; state=2;} 52 | $1~/STATE/ && state == 2 {appstate = $2; state=3;} 53 | state == 3 {printf "%-50s %-10s %-18s\n", appname, apptarget, appstate; state=0;}' 54 | -------------------------------------------------------------------------------- /extproc/compile_shell.sh: -------------------------------------------------------------------------------- 1 | #!/bin/bash 2 | 3 | # +----------------------------------------------------------------------------+ 4 | # | Jeffrey M. Hunter | 5 | # | jhunter@idevelopment.info | 6 | # | www.idevelopment.info | 7 | # |----------------------------------------------------------------------------| 8 | # | Copyright (c) 1998-2015 Jeffrey M. Hunter. All rights reserved. | 9 | # |----------------------------------------------------------------------------| 10 | # | DATABASE : Oracle | 11 | # | FILE : compile_shell.sh | 12 | # | CLASS : External Procedures | 13 | # | PURPOSE : This script is responsible for compiling and building the | 14 | # | shared library for the example PL/SQL external procedures | 15 | # | demo. A new PL/SQL specification procedure (wrapper procedure)| 16 | # | named shell and mailx will be created using the shared | 17 | # | library. | 18 | # | NOTE : As with any code, ensure to test this script in a development | 19 | # | environment before attempting to run it in production. | 20 | # +----------------------------------------------------------------------------+ 21 | 22 | # ---------------------------------------- 23 | # Linux 24 | # ---------------------------------------- 25 | gcc -fPIC -c shell.c 26 | gcc -shared -static-libgcc -o shell.so shell.o 27 | chmod 775 shell.so 28 | # --- or --------------------------------- 29 | # gcc -fPIC -DSHARED_OBJECT -c shell.c 30 | # ld -shared -o shell.so shell.o 31 | # chmod 775 shell.so 32 | 33 | # ---------------------------------------- 34 | # Solaris 35 | # ---------------------------------------- 36 | # gcc -m64 -fPIC -c shell.c 37 | # gcc -m64 -shared -static-libgcc -o shell.so shell.o 38 | # chmod 775 shell.so 39 | # --- or --------------------------------- 40 | # gcc -G -c shell.c 41 | # ld -r -o shell.so shell.o 42 | # chmod 775 shell.so 43 | 44 | # ---------------------------------------- 45 | # Create PL/SQL specification procedure. 46 | # ---------------------------------------- 47 | sqlplus -silent scott/tiger < 20 | #include 21 | #include 22 | 23 | 24 | void mailx(char *to, char *subject, char *message) { 25 | 26 | int num; 27 | char command[50000]; 28 | 29 | strcpy(command, "echo \""); 30 | strcat(command, message); 31 | strcat(command, "\" | mailx -s \""); 32 | strcat(command, subject); 33 | strcat(command, "\" "); 34 | strcat(command, to); 35 | 36 | num = system(command); 37 | 38 | } 39 | 40 | void sh(char *command) { 41 | 42 | int num; 43 | 44 | num = system(command); 45 | 46 | } 47 | -------------------------------------------------------------------------------- /sql/asm_clients.sql: -------------------------------------------------------------------------------- 1 | -- +----------------------------------------------------------------------------+ 2 | -- | Jeffrey M. Hunter | 3 | -- | jhunter@idevelopment.info | 4 | -- | www.idevelopment.info | 5 | -- |----------------------------------------------------------------------------| 6 | -- | Copyright (c) 1998-2015 Jeffrey M. Hunter. All rights reserved. | 7 | -- |----------------------------------------------------------------------------| 8 | -- | DATABASE : Oracle | 9 | -- | FILE : asm_clients.sql | 10 | -- | CLASS : Automatic Storage Management | 11 | -- | PURPOSE : Provide a summary report of all clients making use of this ASM | 12 | -- | instance. | 13 | -- | NOTE : As with any code, ensure to test this script in a development | 14 | -- | environment before attempting to run it in production. | 15 | -- +----------------------------------------------------------------------------+ 16 | 17 | SET TERMOUT OFF; 18 | COLUMN current_instance NEW_VALUE current_instance NOPRINT; 19 | SELECT rpad(sys_context('USERENV', 'INSTANCE_NAME'), 17) current_instance FROM dual; 20 | SET TERMOUT ON; 21 | 22 | PROMPT 23 | PROMPT +------------------------------------------------------------------------+ 24 | PROMPT | Report : ASM Clients | 25 | PROMPT | Instance : ¤t_instance | 26 | PROMPT +------------------------------------------------------------------------+ 27 | 28 | SET ECHO OFF 29 | SET FEEDBACK 6 30 | SET HEADING ON 31 | SET LINESIZE 180 32 | SET PAGESIZE 50000 33 | SET TERMOUT ON 34 | SET TIMING OFF 35 | SET TRIMOUT ON 36 | SET TRIMSPOOL ON 37 | SET VERIFY OFF 38 | 39 | CLEAR COLUMNS 40 | CLEAR BREAKS 41 | CLEAR COMPUTES 42 | 43 | COLUMN disk_group_name FORMAT a25 HEAD 'Disk Group Name' 44 | COLUMN instance_name FORMAT a20 HEAD 'Instance Name' 45 | COLUMN db_name FORMAT a9 HEAD 'Database Name' 46 | COLUMN status FORMAT a12 HEAD 'Status' 47 | 48 | SELECT 49 | a.name disk_group_name 50 | , c.instance_name instance_name 51 | , c.db_name db_name 52 | , c.status status 53 | FROM 54 | v$asm_diskgroup a JOIN v$asm_client c USING (group_number) 55 | ORDER BY 56 | a.name 57 | / 58 | 59 | -------------------------------------------------------------------------------- /sql/asm_drop_files.sql: -------------------------------------------------------------------------------- 1 | -- +----------------------------------------------------------------------------+ 2 | -- | Jeffrey M. Hunter | 3 | -- | jhunter@idevelopment.info | 4 | -- | www.idevelopment.info | 5 | -- |----------------------------------------------------------------------------| 6 | -- | Copyright (c) 1998-2015 Jeffrey M. Hunter. All rights reserved. | 7 | -- |----------------------------------------------------------------------------| 8 | -- | DATABASE : Oracle | 9 | -- | FILE : asm_drop_files.sql | 10 | -- | CLASS : Automatic Storage Management | 11 | -- | PURPOSE : Used to create a SQL script that removes all ASM files | 12 | -- | contained within all diskgroups. | 13 | -- | NOTE : As with any code, ensure to test this script in a development | 14 | -- | environment before attempting to run it in production. | 15 | -- +----------------------------------------------------------------------------+ 16 | 17 | SET ECHO OFF 18 | SET FEEDBACK OFF 19 | SET HEADING OFF 20 | SET LINESIZE 256 21 | SET PAGESIZE 50000 22 | SET TERMOUT ON 23 | SET TIMING OFF 24 | SET TRIMOUT ON 25 | SET TRIMSPOOL ON 26 | SET VERIFY OFF 27 | 28 | CLEAR COLUMNS 29 | CLEAR BREAKS 30 | CLEAR COMPUTES 31 | 32 | COLUMN full_alias_path FORMAT a255 HEAD 'File Name' 33 | COLUMN disk_group_name NOPRINT 34 | 35 | SELECT 36 | 'ALTER DISKGROUP ' || 37 | disk_group_name || 38 | ' DROP FILE ''' || CONCAT('+' || disk_group_name, SYS_CONNECT_BY_PATH(alias_name, '/')) || ''';' full_alias_path 39 | FROM 40 | ( SELECT 41 | g.name disk_group_name 42 | , a.parent_index pindex 43 | , a.name alias_name 44 | , a.reference_index rindex 45 | , f.type type 46 | FROM 47 | v$asm_file f RIGHT OUTER JOIN v$asm_alias a USING (group_number, file_number) 48 | JOIN v$asm_diskgroup g USING (group_number) 49 | ) 50 | WHERE type IS NOT NULL 51 | START WITH (MOD(pindex, POWER(2, 24))) = 0 52 | CONNECT BY PRIOR rindex = pindex 53 | / 54 | 55 | SET FEEDBACK 6 56 | SET HEAD ON 57 | 58 | -------------------------------------------------------------------------------- /sql/asm_templates.sql: -------------------------------------------------------------------------------- 1 | -- +----------------------------------------------------------------------------+ 2 | -- | Jeffrey M. Hunter | 3 | -- | jhunter@idevelopment.info | 4 | -- | www.idevelopment.info | 5 | -- |----------------------------------------------------------------------------| 6 | -- | Copyright (c) 1998-2015 Jeffrey M. Hunter. All rights reserved. | 7 | -- |----------------------------------------------------------------------------| 8 | -- | DATABASE : Oracle | 9 | -- | FILE : asm_templates.sql | 10 | -- | CLASS : Automatic Storage Management | 11 | -- | PURPOSE : Provide a summary report of all template information for all | 12 | -- | ASM disk groups. | 13 | -- | NOTE : As with any code, ensure to test this script in a development | 14 | -- | environment before attempting to run it in production. | 15 | -- +----------------------------------------------------------------------------+ 16 | 17 | SET TERMOUT OFF; 18 | COLUMN current_instance NEW_VALUE current_instance NOPRINT; 19 | SELECT rpad(sys_context('USERENV', 'INSTANCE_NAME'), 17) current_instance FROM dual; 20 | SET TERMOUT ON; 21 | 22 | PROMPT 23 | PROMPT +------------------------------------------------------------------------+ 24 | PROMPT | Report : ASM Templates | 25 | PROMPT | Instance : ¤t_instance | 26 | PROMPT +------------------------------------------------------------------------+ 27 | 28 | SET ECHO OFF 29 | SET FEEDBACK 6 30 | SET HEADING ON 31 | SET LINESIZE 180 32 | SET PAGESIZE 50000 33 | SET TERMOUT ON 34 | SET TIMING OFF 35 | SET TRIMOUT ON 36 | SET TRIMSPOOL ON 37 | SET VERIFY OFF 38 | 39 | CLEAR COLUMNS 40 | CLEAR BREAKS 41 | CLEAR COMPUTES 42 | 43 | COLUMN disk_group_name FORMAT a25 HEAD 'Disk Group Name' 44 | COLUMN entry_number FORMAT 999999 HEAD 'Entry Number' 45 | COLUMN redundancy FORMAT a12 HEAD 'Redundancy' 46 | COLUMN stripe FORMAT a8 HEAD 'Stripe' 47 | COLUMN system FORMAT a6 HEAD 'System' 48 | COLUMN template_name FORMAT a30 HEAD 'Template Name' 49 | 50 | BREAK ON report ON disk_group_name SKIP 1 51 | 52 | SELECT 53 | b.name disk_group_name 54 | , a.entry_number entry_number 55 | , a.redundancy redundancy 56 | , a.stripe stripe 57 | , a.system system 58 | , a.name template_name 59 | FROM 60 | v$asm_template a JOIN v$asm_diskgroup b USING (group_number) 61 | ORDER BY 62 | b.name 63 | , a.entry_number 64 | / 65 | 66 | -------------------------------------------------------------------------------- /sql/asmm_components.sql: -------------------------------------------------------------------------------- 1 | -- +----------------------------------------------------------------------------+ 2 | -- | Jeffrey M. Hunter | 3 | -- | jhunter@idevelopment.info | 4 | -- | www.idevelopment.info | 5 | -- |----------------------------------------------------------------------------| 6 | -- | Copyright (c) 1998-2015 Jeffrey M. Hunter. All rights reserved. | 7 | -- |----------------------------------------------------------------------------| 8 | -- | DATABASE : Oracle | 9 | -- | FILE : asmm_components.sql | 10 | -- | CLASS : Automatic Shared Memory Management | 11 | -- | PURPOSE : Provide a summary report of all dynamic components as part of | 12 | -- | Oracle's ASMM configuration. | 13 | -- | NOTE : As with any code, ensure to test this script in a development | 14 | -- | environment before attempting to run it in production. | 15 | -- +----------------------------------------------------------------------------+ 16 | 17 | SET TERMOUT OFF; 18 | COLUMN current_instance NEW_VALUE current_instance NOPRINT; 19 | SELECT rpad(instance_name, 17) current_instance FROM v$instance; 20 | SET TERMOUT ON; 21 | 22 | PROMPT 23 | PROMPT +------------------------------------------------------------------------+ 24 | PROMPT | Report : ASMM Components | 25 | PROMPT | Instance : ¤t_instance | 26 | PROMPT +------------------------------------------------------------------------+ 27 | 28 | SET ECHO OFF 29 | SET FEEDBACK 6 30 | SET HEADING ON 31 | SET LINESIZE 180 32 | SET PAGESIZE 50000 33 | SET TERMOUT ON 34 | SET TIMING OFF 35 | SET TRIMOUT ON 36 | SET TRIMSPOOL ON 37 | SET VERIFY OFF 38 | 39 | CLEAR COLUMNS 40 | CLEAR BREAKS 41 | CLEAR COMPUTES 42 | 43 | COLUMN component FORMAT a25 HEAD 'Component Name' 44 | COLUMN current_size FORMAT 9,999,999,999 HEAD 'Current Size' 45 | COLUMN min_size FORMAT 9,999,999,999 HEAD 'Min Size' 46 | COLUMN max_size FORMAT 9,999,999,999 HEAD 'Max Size' 47 | COLUMN user_specified_size FORMAT 9,999,999,999 HEAD 'User Specified|Size' 48 | COLUMN oper_count FORMAT 9,999 HEAD 'Oper.|Count' 49 | COLUMN last_oper_type FORMAT a10 HEAD 'Last Oper.|Type' 50 | COLUMN last_oper_mode FORMAT a10 HEAD 'Last Oper.|Mode' 51 | COLUMN last_oper_time FORMAT a20 HEAD 'Last Oper.|Time' 52 | COLUMN granule_size FORMAT 999,999,999 HEAD 'Granule Size' 53 | 54 | SELECT 55 | component 56 | , current_size 57 | , min_size 58 | , max_size 59 | , user_specified_size 60 | , oper_count 61 | , last_oper_type 62 | , last_oper_mode 63 | , TO_CHAR(last_oper_time, 'DD-MON-YYYY HH24:MI:SS') last_oper_time 64 | , granule_size 65 | FROM 66 | v$sga_dynamic_components 67 | ORDER BY 68 | component DESC 69 | / 70 | 71 | -------------------------------------------------------------------------------- /sql/dba_blocks_used_by_table.sql: -------------------------------------------------------------------------------- 1 | -- +----------------------------------------------------------------------------+ 2 | -- | Jeffrey M. Hunter | 3 | -- | jhunter@idevelopment.info | 4 | -- | www.idevelopment.info | 5 | -- |----------------------------------------------------------------------------| 6 | -- | Copyright (c) 1998-2015 Jeffrey M. Hunter. All rights reserved. | 7 | -- |----------------------------------------------------------------------------| 8 | -- | DATABASE : Oracle | 9 | -- | FILE : dba_blocks_used_by_table.sql | 10 | -- | CLASS : Database Administration | 11 | -- | PURPOSE : This article describes how to find out how many blocks are | 12 | -- | really being used within a table. (ie. Blocks that are not | 13 | -- | empty) Scripts are included for both Oracle7 and Oracle8. | 14 | -- | NOTE : As with any code, ensure to test this script in a development | 15 | -- | environment before attempting to run it in production. | 16 | -- +----------------------------------------------------------------------------+ 17 | 18 | -------------------------------------------- 19 | HOW MANY BLOCKS CONTAIN DATA (are not empty) 20 | ----------------------------------------------------------------------- 21 | Each row in the table has pseudocolumn called ROWID. 22 | This pseudo contains information about physical location 23 | of the row in format: 24 | 25 | block_number.row.file 26 | 27 | If the table is stored in a tablespace which has one 28 | datafile, all we have to do is to get DISTINCT 29 | number of block_number from ROWID column of this table. 30 | 31 | But if the table is stored in a tablespace with more than one 32 | datafile then you can have the same block_number but in 33 | different datafiles so we have to get DISTINCT number of 34 | block_number+file from ROWID. 35 | 36 | The SELECT statements which give us the number of "really used" 37 | blocks is below. They are different for ORACLE 7 and ORACLE 8 38 | because of different structure of ROWID column in these versions. 39 | 40 | You could ask why the above information could not be determined 41 | by using the ANALYZE TABLE command. The ANALYZE TABLE command only 42 | identifies the number of 'ever' used blocks or the high water mark 43 | for the table. 44 | ----------------------------------------------------------------------- 45 | 46 | 47 | 48 | ------- 49 | ORACLE7 50 | ----------------------------------------------------------------------- 51 | 52 | SELECT 53 | COUNT(DISTINCT(SUBSTR(rowid,1,8) 54 | || 55 | SUBSTR(rowid,15,4))) 56 | FROM &table_name 57 | / 58 | 59 | 60 | -------- 61 | ORACLE8+ 62 | ----------------------------------------------------------------------- 63 | 64 | SELECT COUNT ( DISTINCT 65 | DBMS_ROWID.ROWID_BLOCK_NUMBER(rowid) 66 | || 67 | DBMS_ROWID.ROWID_RELATIVE_FNO(rowid) 68 | ) "Used" 69 | FROM &table_name; 70 | 71 | - or - 72 | 73 | SELECT COUNT (DISTINCT SUBSTR(rowid,1,15)) "Used" 74 | FROM &table_name; 75 | 76 | -------------------------------------------------------------------------------- /sql/dba_column_constraints.sql: -------------------------------------------------------------------------------- 1 | -- +----------------------------------------------------------------------------+ 2 | -- | Jeffrey M. Hunter | 3 | -- | jhunter@idevelopment.info | 4 | -- | www.idevelopment.info | 5 | -- |----------------------------------------------------------------------------| 6 | -- | Copyright (c) 1998-2015 Jeffrey M. Hunter. All rights reserved. | 7 | -- |----------------------------------------------------------------------------| 8 | -- | DATABASE : Oracle | 9 | -- | FILE : dba_column_constraints.sql | 10 | -- | CLASS : Database Administration | 11 | -- | PURPOSE : Reports on all column constraints in the database. | 12 | -- | NOTE : As with any code, ensure to test this script in a development | 13 | -- | environment before attempting to run it in production. | 14 | -- +----------------------------------------------------------------------------+ 15 | 16 | SET TERMOUT OFF; 17 | COLUMN current_instance NEW_VALUE current_instance NOPRINT; 18 | SELECT rpad(instance_name, 17) current_instance FROM v$instance; 19 | SET TERMOUT ON; 20 | 21 | PROMPT 22 | PROMPT +------------------------------------------------------------------------+ 23 | PROMPT | Report : Column Constraints for a Specified Table | 24 | PROMPT | Instance : ¤t_instance | 25 | PROMPT +------------------------------------------------------------------------+ 26 | 27 | PROMPT 28 | ACCEPT schema CHAR PROMPT 'Enter schema : ' 29 | ACCEPT tab_name CHAR PROMPT 'Enter table name : ' 30 | 31 | SET ECHO OFF 32 | SET FEEDBACK 6 33 | SET HEADING ON 34 | SET LINESIZE 180 35 | SET PAGESIZE 50000 36 | SET TERMOUT ON 37 | SET TIMING OFF 38 | SET TRIMOUT ON 39 | SET TRIMSPOOL ON 40 | SET VERIFY OFF 41 | 42 | CLEAR COLUMNS 43 | CLEAR BREAKS 44 | CLEAR COMPUTES 45 | 46 | COLUMN constraint_name FORMAT a20 HEADING 'Constraint Name' 47 | COLUMN table_name FORMAT a20 HEADING 'Table Name' 48 | COLUMN column_name FORMAT a25 HEADING 'Column Name' 49 | COLUMN position FORMAT 999,999,999 HEADING 'Index Position' 50 | 51 | BREAK ON report ON owner ON table_name SKIP 1 52 | 53 | SELECT 54 | owner 55 | , table_name 56 | , constraint_name 57 | , column_name 58 | , position 59 | FROM 60 | dba_cons_columns 61 | WHERE 62 | owner = UPPER('&schema') 63 | AND table_name = UPPER('&tab_name') 64 | ORDER BY 65 | owner 66 | , table_name 67 | , constraint_name 68 | , position 69 | / 70 | 71 | -------------------------------------------------------------------------------- /sql/dba_controlfiles.sql: -------------------------------------------------------------------------------- 1 | -- +----------------------------------------------------------------------------+ 2 | -- | Jeffrey M. Hunter | 3 | -- | jhunter@idevelopment.info | 4 | -- | www.idevelopment.info | 5 | -- |----------------------------------------------------------------------------| 6 | -- | Copyright (c) 1998-2015 Jeffrey M. Hunter. All rights reserved. | 7 | -- |----------------------------------------------------------------------------| 8 | -- | DATABASE : Oracle | 9 | -- | FILE : dba_controlfiles.sql | 10 | -- | CLASS : Database Administration | 11 | -- | PURPOSE : Query all control files from the database. | 12 | -- | NOTE : As with any code, ensure to test this script in a development | 13 | -- | environment before attempting to run it in production. | 14 | -- +----------------------------------------------------------------------------+ 15 | 16 | SET TERMOUT OFF; 17 | COLUMN current_instance NEW_VALUE current_instance NOPRINT; 18 | SELECT rpad(instance_name, 17) current_instance FROM v$instance; 19 | SET TERMOUT ON; 20 | 21 | PROMPT 22 | PROMPT +------------------------------------------------------------------------+ 23 | PROMPT | Report : Control Files | 24 | PROMPT | Instance : ¤t_instance | 25 | PROMPT +------------------------------------------------------------------------+ 26 | 27 | SET ECHO OFF 28 | SET FEEDBACK 6 29 | SET HEADING ON 30 | SET LINESIZE 256 31 | SET PAGESIZE 50000 32 | SET TERMOUT ON 33 | SET TIMING OFF 34 | SET TRIMOUT ON 35 | SET TRIMSPOOL ON 36 | SET VERIFY OFF 37 | 38 | CLEAR COLUMNS 39 | CLEAR BREAKS 40 | CLEAR COMPUTES 41 | 42 | COLUMN name FORMAT a85 HEADING "Controlfile Name" 43 | COLUMN status HEADING "Status" 44 | 45 | SELECT 46 | name 47 | , LPAD(status, 7) status 48 | FROM v$controlfile 49 | ORDER BY name 50 | / 51 | 52 | -------------------------------------------------------------------------------- /sql/dba_db_growth.sql: -------------------------------------------------------------------------------- 1 | -- +----------------------------------------------------------------------------+ 2 | -- | Jeffrey M. Hunter | 3 | -- | jhunter@idevelopment.info | 4 | -- | www.idevelopment.info | 5 | -- |----------------------------------------------------------------------------| 6 | -- | Copyright (c) 1998-2015 Jeffrey M. Hunter. All rights reserved. | 7 | -- |----------------------------------------------------------------------------| 8 | -- | DATABASE : Oracle | 9 | -- | FILE : dba_db_growth.sql | 10 | -- | CLASS : Database Administration | 11 | -- | PURPOSE : Provides a report on physical database growth with respect to | 12 | -- | the date that data files have been added. | 13 | -- | NOTE : As with any code, ensure to test this script in a development | 14 | -- | environment before attempting to run it in production. | 15 | -- +----------------------------------------------------------------------------+ 16 | 17 | SET TERMOUT OFF; 18 | COLUMN current_instance NEW_VALUE current_instance NOPRINT; 19 | SELECT rpad(instance_name, 17) current_instance FROM v$instance; 20 | SET TERMOUT ON; 21 | 22 | PROMPT 23 | PROMPT +------------------------------------------------------------------------+ 24 | PROMPT | Report : Database Growth | 25 | PROMPT | Instance : ¤t_instance | 26 | PROMPT | Note : This script only tracks when a new data file was added to | 27 | PROMPT | the database. Any data file that was manually increased or | 28 | PROMPT | decreased in size or automatically increased using the | 29 | PROMPT | AUTOEXTEND option is not tracked by this script. | 30 | PROMPT +------------------------------------------------------------------------+ 31 | 32 | SET ECHO OFF 33 | SET FEEDBACK 6 34 | SET HEADING ON 35 | SET LINESIZE 180 36 | SET PAGESIZE 50000 37 | SET TERMOUT ON 38 | SET TIMING OFF 39 | SET TRIMOUT ON 40 | SET TRIMSPOOL ON 41 | SET VERIFY OFF 42 | 43 | CLEAR COLUMNS 44 | CLEAR BREAKS 45 | CLEAR COMPUTES 46 | 47 | COLUMN month FORMAT a7 HEADING 'Month' 48 | COLUMN growth FORMAT 999,999,999,999,999 HEADING 'Growth (Bytes)' 49 | 50 | BREAK ON report 51 | 52 | COMPUTE sum OF growth ON report 53 | 54 | SELECT 55 | TO_CHAR(creation_time, 'RRRR-MM') month 56 | , SUM(bytes) growth 57 | FROM sys.v_$datafile 58 | GROUP BY TO_CHAR(creation_time, 'RRRR-MM') 59 | ORDER BY TO_CHAR(creation_time, 'RRRR-MM'); 60 | 61 | -------------------------------------------------------------------------------- /sql/dba_directories.sql: -------------------------------------------------------------------------------- 1 | -- +----------------------------------------------------------------------------+ 2 | -- | Jeffrey M. Hunter | 3 | -- | jhunter@idevelopment.info | 4 | -- | www.idevelopment.info | 5 | -- |----------------------------------------------------------------------------| 6 | -- | Copyright (c) 1998-2015 Jeffrey M. Hunter. All rights reserved. | 7 | -- |----------------------------------------------------------------------------| 8 | -- | DATABASE : Oracle | 9 | -- | FILE : dba_directories.sql | 10 | -- | CLASS : Database Administration | 11 | -- | PURPOSE : Provides a summary report of all Oracle Directory objects. | 12 | -- | NOTE : As with any code, ensure to test this script in a development | 13 | -- | environment before attempting to run it in production. | 14 | -- +----------------------------------------------------------------------------+ 15 | 16 | SET TERMOUT OFF; 17 | COLUMN current_instance NEW_VALUE current_instance NOPRINT; 18 | SELECT rpad(instance_name, 17) current_instance FROM v$instance; 19 | SET TERMOUT ON; 20 | 21 | PROMPT 22 | PROMPT +------------------------------------------------------------------------+ 23 | PROMPT | Report : Oracle Directories | 24 | PROMPT | Instance : ¤t_instance | 25 | PROMPT +------------------------------------------------------------------------+ 26 | 27 | SET ECHO OFF 28 | SET FEEDBACK 6 29 | SET HEADING ON 30 | SET LINESIZE 180 31 | SET PAGESIZE 50000 32 | SET TERMOUT ON 33 | SET TIMING OFF 34 | SET TRIMOUT ON 35 | SET TRIMSPOOL ON 36 | SET VERIFY OFF 37 | 38 | CLEAR COLUMNS 39 | CLEAR BREAKS 40 | CLEAR COMPUTES 41 | 42 | COLUMN owner FORMAT a10 HEADING 'Owner' 43 | COLUMN directory_name FORMAT a30 HEADING 'Directory Name' 44 | COLUMN directory_path FORMAT a85 HEADING 'Directory Path' 45 | 46 | SELECT 47 | owner 48 | , directory_name 49 | , directory_path 50 | FROM 51 | dba_directories 52 | ORDER BY 53 | owner 54 | , directory_name; 55 | 56 | -------------------------------------------------------------------------------- /sql/dba_errors.sql: -------------------------------------------------------------------------------- 1 | -- +----------------------------------------------------------------------------+ 2 | -- | Jeffrey M. Hunter | 3 | -- | jhunter@idevelopment.info | 4 | -- | www.idevelopment.info | 5 | -- |----------------------------------------------------------------------------| 6 | -- | Copyright (c) 1998-2015 Jeffrey M. Hunter. All rights reserved. | 7 | -- |----------------------------------------------------------------------------| 8 | -- | DATABASE : Oracle | 9 | -- | FILE : dba_errors.sql | 10 | -- | CLASS : Database Administration | 11 | -- | PURPOSE : Report on all procedural (PL/SQL, Views, Triggers, etc.) errors.| 12 | -- | NOTE : As with any code, ensure to test this script in a development | 13 | -- | environment before attempting to run it in production. | 14 | -- +----------------------------------------------------------------------------+ 15 | 16 | SET TERMOUT OFF; 17 | COLUMN current_instance NEW_VALUE current_instance NOPRINT; 18 | SELECT rpad(instance_name, 17) current_instance FROM v$instance; 19 | SET TERMOUT ON; 20 | 21 | PROMPT 22 | PROMPT +------------------------------------------------------------------------+ 23 | PROMPT | Report : All Procedural (PL/SQL, Views, Triggers, etc.) Errors | 24 | PROMPT | Instance : ¤t_instance | 25 | PROMPT +------------------------------------------------------------------------+ 26 | 27 | SET ECHO OFF 28 | SET FEEDBACK 6 29 | SET HEADING ON 30 | SET LINESIZE 180 31 | SET PAGESIZE 50000 32 | SET TERMOUT ON 33 | SET TIMING OFF 34 | SET TRIMOUT ON 35 | SET TRIMSPOOL ON 36 | SET VERIFY OFF 37 | 38 | CLEAR COLUMNS 39 | CLEAR BREAKS 40 | CLEAR COMPUTES 41 | 42 | COLUMN type FORMAT a15 HEAD 'Object Type' 43 | COLUMN owner FORMAT a17 HEAD 'Schema' 44 | COLUMN name FORMAT a30 HEAD 'Object Name' 45 | COLUMN sequence FORMAT 999,999 HEAD 'Sequence' 46 | COLUMN line FORMAT 999,999 HEAD 'Line' 47 | COLUMN position FORMAT 999,999 HEAD 'Position' 48 | COLUMN text HEAD 'Text' 49 | 50 | SELECT 51 | type 52 | , owner 53 | , name 54 | , sequence 55 | , line 56 | , position 57 | , text || chr(10) || chr(10) text 58 | FROM 59 | dba_errors 60 | ORDER BY 61 | 1, 2, 3 62 | / 63 | 64 | -------------------------------------------------------------------------------- /sql/dba_index_fragmentation.sql: -------------------------------------------------------------------------------- 1 | -- +----------------------------------------------------------------------------+ 2 | -- | Jeffrey M. Hunter | 3 | -- | jhunter@idevelopment.info | 4 | -- | www.idevelopment.info | 5 | -- |----------------------------------------------------------------------------| 6 | -- | Copyright (c) 1998-2015 Jeffrey M. Hunter. All rights reserved. | 7 | -- |----------------------------------------------------------------------------| 8 | -- | DATABASE : Oracle | 9 | -- | FILE : dba_index_fragmentation.sql | 10 | -- | CLASS : Database Administration | 11 | -- | PURPOSE : To ascertain index fragmentation. As a rule of thumb if 10-15% | 12 | -- | of the table data changes, then you should consider rebuilding | 13 | -- | the index. | 14 | -- | NOTE : As with any code, ensure to test this script in a development | 15 | -- | environment before attempting to run it in production. | 16 | -- +----------------------------------------------------------------------------+ 17 | 18 | SET ECHO OFF 19 | SET FEEDBACK OFF 20 | SET HEADING ON 21 | SET LINESIZE 180 22 | SET PAGESIZE 50000 23 | SET TERMOUT ON 24 | SET TIMING OFF 25 | SET TRIMOUT ON 26 | SET TRIMSPOOL ON 27 | SET VERIFY OFF 28 | 29 | CLEAR COLUMNS 30 | CLEAR BREAKS 31 | CLEAR COMPUTES 32 | 33 | PROMPT 34 | PROMPT +------------------------------------------------------------------------+ 35 | PROMPT | Calculate Index Fragmentation for a Specified Index | 36 | PROMPT +------------------------------------------------------------------------+ 37 | 38 | PROMPT 39 | ACCEPT index_name CHAR prompt 'Enter index name [SCHEMA].index_name : ' 40 | 41 | ANALYZE INDEX &index_name VALIDATE STRUCTURE; 42 | 43 | COLUMN name HEADING 'Index Name' FORMAT a30 44 | COLUMN del_lf_rows HEADING 'Deleted|Leaf Rows' FORMAT 999,999,999,999,999 45 | COLUMN lf_rows_used HEADING 'Used|Leaf Rows' FORMAT 999,999,999,999,999 46 | COLUMN ibadness HEADING '% Deleted|Leaf Rows' FORMAT 999.99999 47 | 48 | SELECT 49 | name 50 | , del_lf_rows 51 | , lf_rows - del_lf_rows lf_rows_used 52 | , TO_CHAR( del_lf_rows /(DECODE(lf_rows,0,0.01,lf_rows))*100,'999.99999') ibadness 53 | FROM index_stats 54 | / 55 | 56 | PROMPT 57 | PROMPT Consider rebuilding any index if % of Deleted Leaf Rows is > 20% 58 | PROMPT 59 | 60 | UNDEFINE index_name 61 | 62 | SET FEEDBACK 6 63 | -------------------------------------------------------------------------------- /sql/dba_invalid_objects.sql: -------------------------------------------------------------------------------- 1 | -- +----------------------------------------------------------------------------+ 2 | -- | Jeffrey M. Hunter | 3 | -- | jhunter@idevelopment.info | 4 | -- | www.idevelopment.info | 5 | -- |----------------------------------------------------------------------------| 6 | -- | Copyright (c) 1998-2015 Jeffrey M. Hunter. All rights reserved. | 7 | -- |----------------------------------------------------------------------------| 8 | -- | DATABASE : Oracle | 9 | -- | FILE : dba_invalid_objects.sql | 10 | -- | CLASS : Database Administration | 11 | -- | PURPOSE : Provide a detailed report of all invalid objects in the | 12 | -- | database. | 13 | -- | NOTE : As with any code, ensure to test this script in a development | 14 | -- | environment before attempting to run it in production. | 15 | -- +----------------------------------------------------------------------------+ 16 | 17 | SET TERMOUT OFF; 18 | COLUMN current_instance NEW_VALUE current_instance NOPRINT; 19 | SELECT rpad(instance_name, 17) current_instance FROM v$instance; 20 | SET TERMOUT ON; 21 | 22 | PROMPT 23 | PROMPT +------------------------------------------------------------------------+ 24 | PROMPT | Report : Invalid Objects | 25 | PROMPT | Instance : ¤t_instance | 26 | PROMPT +------------------------------------------------------------------------+ 27 | 28 | SET ECHO OFF 29 | SET FEEDBACK 6 30 | SET HEADING ON 31 | SET LINESIZE 180 32 | SET PAGESIZE 50000 33 | SET TERMOUT ON 34 | SET TIMING OFF 35 | SET TRIMOUT ON 36 | SET TRIMSPOOL ON 37 | SET VERIFY OFF 38 | 39 | CLEAR COLUMNS 40 | CLEAR BREAKS 41 | CLEAR COMPUTES 42 | 43 | COLUMN owner FORMAT a25 HEADING 'Owner' 44 | COLUMN object_name FORMAT a30 HEADING 'Object Name' 45 | COLUMN object_type FORMAT a20 HEADING 'Object Type' 46 | COLUMN status FORMAT a10 HEADING 'Status' 47 | 48 | BREAK ON owner SKIP 2 ON report 49 | 50 | COMPUTE count LABEL "" OF object_name ON owner 51 | COMPUTE count LABEL "Grand Total: " OF object_name ON report 52 | 53 | SELECT 54 | owner 55 | , object_name 56 | , object_type 57 | , status 58 | FROM dba_objects 59 | WHERE status <> 'VALID' 60 | ORDER BY owner, object_name 61 | / 62 | 63 | -------------------------------------------------------------------------------- /sql/dba_invalid_objects_summary.sql: -------------------------------------------------------------------------------- 1 | -- +----------------------------------------------------------------------------+ 2 | -- | Jeffrey M. Hunter | 3 | -- | jhunter@idevelopment.info | 4 | -- | www.idevelopment.info | 5 | -- |----------------------------------------------------------------------------| 6 | -- | Copyright (c) 1998-2015 Jeffrey M. Hunter. All rights reserved. | 7 | -- |----------------------------------------------------------------------------| 8 | -- | DATABASE : Oracle | 9 | -- | FILE : dba_invalid_objects_summary.sql | 10 | -- | CLASS : Database Administration | 11 | -- | PURPOSE : Provides a summary report of all invalid objects in the | 12 | -- | database. | 13 | -- | NOTE : As with any code, ensure to test this script in a development | 14 | -- | environment before attempting to run it in production. | 15 | -- +----------------------------------------------------------------------------+ 16 | 17 | SET TERMOUT OFF; 18 | COLUMN current_instance NEW_VALUE current_instance NOPRINT; 19 | SELECT rpad(instance_name, 17) current_instance FROM v$instance; 20 | SET TERMOUT ON; 21 | 22 | PROMPT 23 | PROMPT +------------------------------------------------------------------------+ 24 | PROMPT | Report : Invalid Objects Summary | 25 | PROMPT | Instance : ¤t_instance | 26 | PROMPT +------------------------------------------------------------------------+ 27 | 28 | SET ECHO OFF 29 | SET FEEDBACK 6 30 | SET HEADING ON 31 | SET LINESIZE 180 32 | SET PAGESIZE 50000 33 | SET TERMOUT ON 34 | SET TIMING OFF 35 | SET TRIMOUT ON 36 | SET TRIMSPOOL ON 37 | SET VERIFY OFF 38 | 39 | CLEAR COLUMNS 40 | CLEAR BREAKS 41 | CLEAR COMPUTES 42 | 43 | COLUMN owner FORMAT a25 HEADING 'Owner' 44 | COLUMN object_name FORMAT a30 HEADING 'Object Name' 45 | COLUMN object_type FORMAT a20 HEADING 'Object Type' 46 | COLUMN count FORMAT 999,999,999 HEADING 'Count' 47 | 48 | BREAK ON owner SKIP 2 ON REPORT 49 | 50 | COMPUTE sum LABEL "Count: " OF count ON owner 51 | COMPUTE sum LABEL "Grand Total: " OF count ON report 52 | 53 | SELECT 54 | owner 55 | , object_type 56 | , count(*) Count 57 | FROM dba_objects 58 | WHERE status <> 'VALID' 59 | GROUP BY owner, object_type 60 | / 61 | 62 | -------------------------------------------------------------------------------- /sql/dba_jobs.sql: -------------------------------------------------------------------------------- 1 | -- +----------------------------------------------------------------------------+ 2 | -- | Jeffrey M. Hunter | 3 | -- | jhunter@idevelopment.info | 4 | -- | www.idevelopment.info | 5 | -- |----------------------------------------------------------------------------| 6 | -- | Copyright (c) 1998-2015 Jeffrey M. Hunter. All rights reserved. | 7 | -- |----------------------------------------------------------------------------| 8 | -- | DATABASE : Oracle | 9 | -- | FILE : dba_jobs.sql | 10 | -- | CLASS : Database Administration | 11 | -- | PURPOSE : Provides summary report on all registered and scheduled jobs. | 12 | -- | NOTE : As with any code, ensure to test this script in a development | 13 | -- | environment before attempting to run it in production. | 14 | -- +----------------------------------------------------------------------------+ 15 | 16 | SET TERMOUT OFF; 17 | COLUMN current_instance NEW_VALUE current_instance NOPRINT; 18 | SELECT rpad(instance_name, 17) current_instance FROM v$instance; 19 | SET TERMOUT ON; 20 | 21 | PROMPT 22 | PROMPT +------------------------------------------------------------------------+ 23 | PROMPT | Report : Oracle Jobs | 24 | PROMPT | Instance : ¤t_instance | 25 | PROMPT +------------------------------------------------------------------------+ 26 | 27 | SET ECHO OFF 28 | SET FEEDBACK 6 29 | SET HEADING ON 30 | SET LINESIZE 180 31 | SET PAGESIZE 50000 32 | SET TERMOUT ON 33 | SET TIMING OFF 34 | SET TRIMOUT ON 35 | SET TRIMSPOOL ON 36 | SET VERIFY OFF 37 | 38 | CLEAR COLUMNS 39 | CLEAR BREAKS 40 | CLEAR COMPUTES 41 | 42 | COLUMN job FORMAT 9999999 HEADING 'Job ID' 43 | COLUMN username FORMAT a20 HEADING 'User' 44 | COLUMN what FORMAT a30 HEADING 'What' 45 | COLUMN next_date HEADING 'Next Run Date' 46 | COLUMN interval FORMAT a30 HEADING 'Interval' 47 | COLUMN last_date HEADING 'Last Run Date' 48 | COLUMN failures HEADING 'Failures' 49 | COLUMN broken FORMAT a7 HEADING 'Broken?' 50 | 51 | SELECT 52 | job 53 | , log_user username 54 | , what 55 | , TO_CHAR(next_date, 'DD-MON-YYYY HH24:MI:SS') next_date 56 | , interval 57 | , TO_CHAR(last_date, 'DD-MON-YYYY HH24:MI:SS') last_date 58 | , failures 59 | , broken 60 | FROM 61 | dba_jobs; 62 | 63 | -------------------------------------------------------------------------------- /sql/dba_object_search.sql: -------------------------------------------------------------------------------- 1 | -- +----------------------------------------------------------------------------+ 2 | -- | Jeffrey M. Hunter | 3 | -- | jhunter@idevelopment.info | 4 | -- | www.idevelopment.info | 5 | -- |----------------------------------------------------------------------------| 6 | -- | Copyright (c) 1998-2015 Jeffrey M. Hunter. All rights reserved. | 7 | -- |----------------------------------------------------------------------------| 8 | -- | DATABASE : Oracle | 9 | -- | FILE : dba_object_search.sql | 10 | -- | CLASS : Database Administration | 11 | -- | PURPOSE : Prompt the user for a query string and look for any object that | 12 | -- | contains that string. | 13 | -- | NOTE : As with any code, ensure to test this script in a development | 14 | -- | environment before attempting to run it in production. | 15 | -- +----------------------------------------------------------------------------+ 16 | 17 | SET TERMOUT OFF; 18 | COLUMN current_instance NEW_VALUE current_instance NOPRINT; 19 | SELECT rpad(instance_name, 17) current_instance FROM v$instance; 20 | SET TERMOUT ON; 21 | 22 | PROMPT 23 | PROMPT +------------------------------------------------------------------------+ 24 | PROMPT | Report : Object Search Interface | 25 | PROMPT | Instance : ¤t_instance | 26 | PROMPT +------------------------------------------------------------------------+ 27 | 28 | PROMPT 29 | ACCEPT schema CHAR PROMPT 'Enter search string (i.e. GE_LINES) : ' 30 | 31 | SET ECHO OFF 32 | SET FEEDBACK 6 33 | SET HEADING ON 34 | SET LINESIZE 180 35 | SET PAGESIZE 50000 36 | SET TERMOUT ON 37 | SET TIMING OFF 38 | SET TRIMOUT ON 39 | SET TRIMSPOOL ON 40 | SET VERIFY OFF 41 | 42 | CLEAR COLUMNS 43 | CLEAR BREAKS 44 | CLEAR COMPUTES 45 | 46 | COLUMN owner FORMAT A20 HEADING "Owner" 47 | COLUMN object_name FORMAT A45 HEADING "Object Name" 48 | COLUMN object_type FORMAT A18 HEADING "Object Type" 49 | COLUMN created HEADING "Created" 50 | COLUMN status HEADING "Status" 51 | 52 | SELECT 53 | owner 54 | , object_name 55 | , object_type 56 | , TO_CHAR(created, 'DD-MON-YYYY HH24:MI:SS') created 57 | , LPAD(status, 7) status 58 | FROM all_objects 59 | WHERE object_name like UPPER('%&schema%') 60 | ORDER BY owner, object_name, object_type 61 | / 62 | 63 | -------------------------------------------------------------------------------- /sql/dba_object_summary.sql: -------------------------------------------------------------------------------- 1 | -- +----------------------------------------------------------------------------+ 2 | -- | Jeffrey M. Hunter | 3 | -- | jhunter@idevelopment.info | 4 | -- | www.idevelopment.info | 5 | -- |----------------------------------------------------------------------------| 6 | -- | Copyright (c) 1998-2015 Jeffrey M. Hunter. All rights reserved. | 7 | -- |----------------------------------------------------------------------------| 8 | -- | DATABASE : Oracle | 9 | -- | FILE : dba_object_summary.sql | 10 | -- | CLASS : Database Administration | 11 | -- | PURPOSE : Provide a summary report of all objects in the database. | 12 | -- | NOTE : As with any code, ensure to test this script in a development | 13 | -- | environment before attempting to run it in production. | 14 | -- +----------------------------------------------------------------------------+ 15 | 16 | SET TERMOUT OFF; 17 | COLUMN current_instance NEW_VALUE current_instance NOPRINT; 18 | SELECT rpad(instance_name, 17) current_instance FROM v$instance; 19 | SET TERMOUT ON; 20 | 21 | PROMPT 22 | PROMPT +------------------------------------------------------------------------+ 23 | PROMPT | Report : Object Summary | 24 | PROMPT | Instance : ¤t_instance | 25 | PROMPT +------------------------------------------------------------------------+ 26 | 27 | SET ECHO OFF 28 | SET FEEDBACK 6 29 | SET HEADING ON 30 | SET LINESIZE 180 31 | SET PAGESIZE 50000 32 | SET TERMOUT ON 33 | SET TIMING OFF 34 | SET TRIMOUT ON 35 | SET TRIMSPOOL ON 36 | SET VERIFY OFF 37 | 38 | CLEAR COLUMNS 39 | CLEAR BREAKS 40 | CLEAR COMPUTES 41 | 42 | COLUMN owner FORMAT A20 HEADING "Owner" 43 | COLUMN object_type FORMAT A25 HEADING "Object Type" 44 | COLUMN obj_count FORMAT 999,999,999,999 HEADING "Object Count" 45 | 46 | BREAK ON report ON owner SKIP 2 47 | 48 | COMPUTE sum LABEL "" OF obj_count ON owner 49 | COMPUTE sum LABEL "Grand Total: " OF obj_count ON report 50 | 51 | SELECT 52 | owner 53 | , object_type 54 | , count(*) obj_count 55 | FROM 56 | dba_objects 57 | GROUP BY 58 | owner 59 | , object_type 60 | ORDER BY 61 | owner 62 | , object_type 63 | / 64 | 65 | -------------------------------------------------------------------------------- /sql/dba_options.sql: -------------------------------------------------------------------------------- 1 | -- +----------------------------------------------------------------------------+ 2 | -- | Jeffrey M. Hunter | 3 | -- | jhunter@idevelopment.info | 4 | -- | www.idevelopment.info | 5 | -- |----------------------------------------------------------------------------| 6 | -- | Copyright (c) 1998-2015 Jeffrey M. Hunter. All rights reserved. | 7 | -- |----------------------------------------------------------------------------| 8 | -- | DATABASE : Oracle | 9 | -- | FILE : dba_options.sql | 10 | -- | CLASS : Database Administration | 11 | -- | PURPOSE : Report on all Oracle installed options. | 12 | -- | NOTE : As with any code, ensure to test this script in a development | 13 | -- | environment before attempting to run it in production. | 14 | -- +----------------------------------------------------------------------------+ 15 | 16 | SET TERMOUT OFF; 17 | COLUMN current_instance NEW_VALUE current_instance NOPRINT; 18 | SELECT rpad(instance_name, 17) current_instance FROM v$instance; 19 | SET TERMOUT ON; 20 | 21 | PROMPT 22 | PROMPT +------------------------------------------------------------------------+ 23 | PROMPT | Report : Database Options | 24 | PROMPT | Instance : ¤t_instance | 25 | PROMPT +------------------------------------------------------------------------+ 26 | 27 | SET ECHO OFF 28 | SET FEEDBACK 6 29 | SET HEADING ON 30 | SET LINESIZE 180 31 | SET PAGESIZE 50000 32 | SET TERMOUT ON 33 | SET TIMING OFF 34 | SET TRIMOUT ON 35 | SET TRIMSPOOL ON 36 | SET VERIFY OFF 37 | 38 | CLEAR COLUMNS 39 | CLEAR BREAKS 40 | CLEAR COMPUTES 41 | 42 | COLUMN parameter FORMAT a45 HEADING 'Option Name' 43 | COLUMN value FORMAT a10 HEADING 'Installed?' 44 | 45 | SELECT 46 | parameter 47 | , value 48 | FROM 49 | v$option 50 | ORDER BY 51 | parameter; 52 | 53 | -------------------------------------------------------------------------------- /sql/dba_owner_to_tablespace.sql: -------------------------------------------------------------------------------- 1 | -- +----------------------------------------------------------------------------+ 2 | -- | Jeffrey M. Hunter | 3 | -- | jhunter@idevelopment.info | 4 | -- | www.idevelopment.info | 5 | -- |----------------------------------------------------------------------------| 6 | -- | Copyright (c) 1998-2015 Jeffrey M. Hunter. All rights reserved. | 7 | -- |----------------------------------------------------------------------------| 8 | -- | DATABASE : Oracle | 9 | -- | FILE : dba_owner_to_tablespace.sql | 10 | -- | CLASS : Database Administration | 11 | -- | PURPOSE : Provide a summary report of owner to tablespace for all | 12 | -- | segments in the database. | 13 | -- | NOTE : As with any code, ensure to test this script in a development | 14 | -- | environment before attempting to run it in production. | 15 | -- +----------------------------------------------------------------------------+ 16 | 17 | SET TERMOUT OFF; 18 | COLUMN current_instance NEW_VALUE current_instance NOPRINT; 19 | SELECT rpad(instance_name, 17) current_instance FROM v$instance; 20 | SET TERMOUT ON; 21 | 22 | PROMPT 23 | PROMPT +------------------------------------------------------------------------+ 24 | PROMPT | Report : Owner to Tablespace Report | 25 | PROMPT | Instance : ¤t_instance | 26 | PROMPT +------------------------------------------------------------------------+ 27 | 28 | SET ECHO OFF 29 | SET FEEDBACK 6 30 | SET HEADING ON 31 | SET LINESIZE 180 32 | SET PAGESIZE 50000 33 | SET TERMOUT ON 34 | SET TIMING OFF 35 | SET TRIMOUT ON 36 | SET TRIMSPOOL ON 37 | SET VERIFY OFF 38 | 39 | CLEAR COLUMNS 40 | CLEAR BREAKS 41 | CLEAR COMPUTES 42 | 43 | COLUMN owner FORMAT a20 HEADING "Owner" 44 | COLUMN tablespace_name FORMAT a30 HEADING "Tablespace Name" 45 | COLUMN segment_type FORMAT a18 HEADING "Segment Type" 46 | COLUMN bytes FORMAT 9,999,999,999,999 HEADING "Size (in Bytes)" 47 | COLUMN seg_count FORMAT 9,999,999,999 HEADING "Segment Count" 48 | 49 | BREAK ON report ON owner SKIP 2 50 | 51 | COMPUTE sum LABEL "" OF seg_count bytes ON owner 52 | COMPUTE sum LABEL "Grand Total: " OF seg_count bytes ON report 53 | 54 | SELECT 55 | owner 56 | , tablespace_name 57 | , segment_type 58 | , sum(bytes) bytes 59 | , count(*) seg_count 60 | FROM 61 | dba_segments 62 | GROUP BY 63 | owner 64 | , tablespace_name 65 | , segment_type 66 | ORDER BY 67 | owner 68 | , tablespace_name 69 | , segment_type 70 | / 71 | 72 | -------------------------------------------------------------------------------- /sql/dba_plsql_package_size.sql: -------------------------------------------------------------------------------- 1 | -- +----------------------------------------------------------------------------+ 2 | -- | Jeffrey M. Hunter | 3 | -- | jhunter@idevelopment.info | 4 | -- | www.idevelopment.info | 5 | -- |----------------------------------------------------------------------------| 6 | -- | Copyright (c) 1998-2015 Jeffrey M. Hunter. All rights reserved. | 7 | -- |----------------------------------------------------------------------------| 8 | -- | DATABASE : Oracle | 9 | -- | FILE : dba_plsql_package_size.sql | 10 | -- | CLASS : Database Administration | 11 | -- | PURPOSE : Internal size of PL/SQL Packages. | 12 | -- | NOTE : As with any code, ensure to test this script in a development | 13 | -- | environment before attempting to run it in production. | 14 | -- +----------------------------------------------------------------------------+ 15 | 16 | SET TERMOUT OFF; 17 | COLUMN current_instance NEW_VALUE current_instance NOPRINT; 18 | SELECT rpad(instance_name, 17) current_instance FROM v$instance; 19 | SET TERMOUT ON; 20 | 21 | PROMPT 22 | PROMPT +------------------------------------------------------------------------+ 23 | PROMPT | Report : PL/SQL Package Body Size Report | 24 | PROMPT | Instance : ¤t_instance | 25 | PROMPT +------------------------------------------------------------------------+ 26 | 27 | SET ECHO OFF 28 | SET FEEDBACK 6 29 | SET HEADING ON 30 | SET LINESIZE 180 31 | SET PAGESIZE 50000 32 | SET TERMOUT ON 33 | SET TIMING OFF 34 | SET TRIMOUT ON 35 | SET TRIMSPOOL ON 36 | SET VERIFY OFF 37 | 38 | CLEAR COLUMNS 39 | CLEAR BREAKS 40 | CLEAR COMPUTES 41 | 42 | COLUMN owner FORMAT a20 HEAD "Owner" 43 | COLUMN name FORMAT a35 HEAD "Name" 44 | COLUMN type FORMAT a18 HEAD "Type" 45 | COLUMN total_bytes FORMAT 999,999,999,999 HEAD "Total bytes" 46 | 47 | SELECT 48 | owner 49 | , name 50 | , type 51 | , source_size+code_size+parsed_size+error_size total_bytes 52 | FROM 53 | dba_object_size 54 | WHERE 55 | type = 'PACKAGE BODY' 56 | AND owner NOT IN ('SYS') 57 | ORDER BY 58 | 4 DESC; 59 | 60 | -------------------------------------------------------------------------------- /sql/dba_query_hidden_parameters.sql: -------------------------------------------------------------------------------- 1 | -- +----------------------------------------------------------------------------+ 2 | -- | Jeffrey M. Hunter | 3 | -- | jhunter@idevelopment.info | 4 | -- | www.idevelopment.info | 5 | -- |----------------------------------------------------------------------------| 6 | -- | Copyright (c) 1998-2015 Jeffrey M. Hunter. All rights reserved. | 7 | -- |----------------------------------------------------------------------------| 8 | -- | DATABASE : Oracle | 9 | -- | FILE : dba_query_hidden_parameters.sql | 10 | -- | CLASS : Database Administration | 11 | -- | PURPOSE : Reports on all hidden "undocumented" database parameters. You | 12 | -- | must be connected as the SYS user to run this script. | 13 | -- | NOTE : As with any code, ensure to test this script in a development | 14 | -- | environment before attempting to run it in production. | 15 | -- +----------------------------------------------------------------------------+ 16 | 17 | SET TERMOUT OFF; 18 | COLUMN current_instance NEW_VALUE current_instance NOPRINT; 19 | SELECT rpad(instance_name, 17) current_instance FROM v$instance; 20 | SET TERMOUT ON; 21 | 22 | PROMPT 23 | PROMPT +------------------------------------------------------------------------+ 24 | PROMPT | Report : Invalid Objects | 25 | PROMPT | Instance : ¤t_instance | 26 | PROMPT +------------------------------------------------------------------------+ 27 | 28 | SET ECHO OFF 29 | SET FEEDBACK 6 30 | SET HEADING ON 31 | SET LINESIZE 256 32 | SET PAGESIZE 50000 33 | SET TERMOUT ON 34 | SET TIMING OFF 35 | SET TRIMOUT ON 36 | SET TRIMSPOOL ON 37 | SET VERIFY OFF 38 | 39 | CLEAR COLUMNS 40 | CLEAR BREAKS 41 | CLEAR COMPUTES 42 | 43 | COLUMN ksppinm FORMAT a55 HEAD 'Parameter Name' 44 | COLUMN ksppstvl FORMAT a40 HEAD 'Value' 45 | COLUMN ksppdesc FORMAT a60 HEAD 'Description' TRUNC 46 | 47 | SELECT 48 | ksppinm 49 | , ksppstvl 50 | , ksppdesc 51 | FROM 52 | x$ksppi x 53 | , x$ksppcv y 54 | WHERE 55 | x.indx = y.indx 56 | AND TRANSLATE(ksppinm,'_','#') like '#%' 57 | ORDER BY 58 | ksppinm 59 | / 60 | 61 | -------------------------------------------------------------------------------- /sql/dba_random_number.sql: -------------------------------------------------------------------------------- 1 | -- +----------------------------------------------------------------------------+ 2 | -- | Jeffrey M. Hunter | 3 | -- | jhunter@idevelopment.info | 4 | -- | www.idevelopment.info | 5 | -- |----------------------------------------------------------------------------| 6 | -- | Copyright (c) 1998-2015 Jeffrey M. Hunter. All rights reserved. | 7 | -- |----------------------------------------------------------------------------| 8 | -- | DATABASE : Oracle | 9 | -- | FILE : dba_random_number.sql | 10 | -- | CLASS : Database Administration | 11 | -- | PURPOSE : A quick way to produce random numbers using SQL. | 12 | -- | NOTE : As with any code, ensure to test this script in a development | 13 | -- | environment before attempting to run it in production. | 14 | -- +----------------------------------------------------------------------------+ 15 | 16 | SELECT 17 | TRUNC( 18 | (TO_NUMBER(SUBSTR(TO_CHAR(TO_NUMBER(TO_CHAR(SYSDATE,'sssss'))/86399),-7,7))/10000000)*32767 19 | ) random 20 | FROM dual; 21 | -------------------------------------------------------------------------------- /sql/dba_recompile_invalid_objects.sql: -------------------------------------------------------------------------------- 1 | -- +----------------------------------------------------------------------------+ 2 | -- | Jeffrey M. Hunter | 3 | -- | jhunter@idevelopment.info | 4 | -- | www.idevelopment.info | 5 | -- |----------------------------------------------------------------------------| 6 | -- | Copyright (c) 1998-2015 Jeffrey M. Hunter. All rights reserved. | 7 | -- |----------------------------------------------------------------------------| 8 | -- | DATABASE : Oracle | 9 | -- | FILE : dba_recompile_invalid_objects.sql | 10 | -- | CLASS : Database Administration | 11 | -- | PURPOSE : Dynamically create a SQL script to recompile all INVALID | 12 | -- | objects. | 13 | -- | NOTE : As with any code, ensure to test this script in a development | 14 | -- | environment before attempting to run it in production. | 15 | -- +----------------------------------------------------------------------------+ 16 | 17 | SET ECHO OFF 18 | SET FEEDBACK OFF 19 | SET HEADING OFF 20 | SET LINESIZE 180 21 | SET PAGESIZE 0 22 | SET TERMOUT ON 23 | SET TIMING OFF 24 | SET TRIMOUT ON 25 | SET TRIMSPOOL ON 26 | SET VERIFY OFF 27 | 28 | CLEAR COLUMNS 29 | CLEAR BREAKS 30 | CLEAR COMPUTES 31 | 32 | spool compile.sql 33 | 34 | SELECT 'alter ' || 35 | decode(object_type, 'PACKAGE BODY', 'package', object_type) || 36 | ' ' || 37 | object_name|| 38 | ' compile' || 39 | decode(object_type, 'PACKAGE BODY', ' body;', ';') 40 | FROM dba_objects 41 | WHERE status = 'INVALID' 42 | / 43 | 44 | spool off 45 | 46 | SET ECHO off 47 | SET FEEDBACK off 48 | SET HEADING off 49 | SET LINESIZE 180 50 | SET PAGESIZE 0 51 | SET TERMOUT on 52 | SET TIMING off 53 | SET TRIMOUT on 54 | SET TRIMSPOOL on 55 | SET VERIFY off 56 | 57 | @compile 58 | 59 | SET FEEDBACK 6 60 | SET HEADING ON 61 | -------------------------------------------------------------------------------- /sql/dba_registry.sql: -------------------------------------------------------------------------------- 1 | -- +----------------------------------------------------------------------------+ 2 | -- | Jeffrey M. Hunter | 3 | -- | jhunter@idevelopment.info | 4 | -- | www.idevelopment.info | 5 | -- |----------------------------------------------------------------------------| 6 | -- | Copyright (c) 1998-2015 Jeffrey M. Hunter. All rights reserved. | 7 | -- |----------------------------------------------------------------------------| 8 | -- | DATABASE : Oracle | 9 | -- | FILE : dba_registry.sql | 10 | -- | CLASS : Database Administration | 11 | -- | PURPOSE : Provides summary report on all registered components. | 12 | -- | NOTE : As with any code, ensure to test this script in a development | 13 | -- | environment before attempting to run it in production. | 14 | -- +----------------------------------------------------------------------------+ 15 | 16 | SET TERMOUT OFF; 17 | COLUMN current_instance NEW_VALUE current_instance NOPRINT; 18 | SELECT rpad(instance_name, 17) current_instance FROM v$instance; 19 | SET TERMOUT ON; 20 | 21 | PROMPT 22 | PROMPT +------------------------------------------------------------------------+ 23 | PROMPT | Report : Database Registry Components | 24 | PROMPT | Instance : ¤t_instance | 25 | PROMPT +------------------------------------------------------------------------+ 26 | 27 | SET ECHO OFF 28 | SET FEEDBACK 6 29 | SET HEADING ON 30 | SET LINESIZE 180 31 | SET PAGESIZE 50000 32 | SET TERMOUT ON 33 | SET TIMING OFF 34 | SET TRIMOUT ON 35 | SET TRIMSPOOL ON 36 | SET VERIFY OFF 37 | 38 | CLEAR COLUMNS 39 | CLEAR BREAKS 40 | CLEAR COMPUTES 41 | 42 | COLUMN comp_id FORMAT a9 HEADING 'Component|ID' 43 | COLUMN comp_name FORMAT a35 HEADING 'Component|Name' 44 | COLUMN version FORMAT a13 HEADING 'Version' 45 | COLUMN status FORMAT a11 HEADING 'Status' 46 | COLUMN modified HEADING 'Modified' 47 | COLUMN Schema FORMAT a15 HEADING 'Schema' 48 | COLUMN procedure FORMAT a45 HEADING 'Procedure' 49 | 50 | SELECT 51 | comp_id 52 | , comp_name 53 | , version 54 | , status 55 | , modified 56 | , schema 57 | , procedure 58 | FROM 59 | dba_registry 60 | ORDER BY 61 | comp_id; 62 | 63 | -------------------------------------------------------------------------------- /sql/dba_related_child_tables.sql: -------------------------------------------------------------------------------- 1 | -- +----------------------------------------------------------------------------+ 2 | -- | Jeffrey M. Hunter | 3 | -- | jhunter@idevelopment.info | 4 | -- | www.idevelopment.info | 5 | -- |----------------------------------------------------------------------------| 6 | -- | Copyright (c) 1998-2015 Jeffrey M. Hunter. All rights reserved. | 7 | -- |----------------------------------------------------------------------------| 8 | -- | DATABASE : Oracle | 9 | -- | FILE : dba_related_child_tables.sql | 10 | -- | CLASS : Database Administration | 11 | -- | PURPOSE : Query all child tables related to a given parent table name. | 12 | -- | NOTE : As with any code, ensure to test this script in a development | 13 | -- | environment before attempting to run it in production. | 14 | -- +----------------------------------------------------------------------------+ 15 | 16 | SET ECHO OFF 17 | SET FEEDBACK 6 18 | SET HEADING ON 19 | SET LINESIZE 180 20 | SET PAGESIZE 50000 21 | SET TERMOUT ON 22 | SET TIMING OFF 23 | SET TRIMOUT ON 24 | SET TRIMSPOOL ON 25 | SET VERIFY OFF 26 | 27 | CLEAR COLUMNS 28 | CLEAR BREAKS 29 | CLEAR COMPUTES 30 | 31 | PROMPT 32 | PROMPT +------------------------------------------------------------------------+ 33 | PROMPT | All child tables related to a parent table name | 34 | PROMPT +------------------------------------------------------------------------+ 35 | PROMPT 36 | 37 | ACCEPT table_owner prompt 'Enter parent table owner : ' 38 | ACCEPT table_name prompt 'Enter parent table name : ' 39 | 40 | SELECT 41 | p.table_name PARENT_TABLE_NAME 42 | , c.table_name CHILD_TABLE 43 | FROM 44 | dba_constraints p 45 | , dba_constraints c 46 | WHERE 47 | (p.constraint_type = 'P' OR p.constraint_type = 'U') 48 | AND 49 | (c.constraint_type = 'R') 50 | AND 51 | (p.constraint_name = c.r_constraint_name) 52 | AND 53 | (p.owner = UPPER('&table_owner')) 54 | AND 55 | (p.table_name = UPPER('&table_name')) 56 | ORDER BY 2 57 | / 58 | 59 | -------------------------------------------------------------------------------- /sql/dba_row_size.sql: -------------------------------------------------------------------------------- 1 | -- +----------------------------------------------------------------------------+ 2 | -- | Jeffrey M. Hunter | 3 | -- | jhunter@idevelopment.info | 4 | -- | www.idevelopment.info | 5 | -- |----------------------------------------------------------------------------| 6 | -- | Copyright (c) 1998-2015 Jeffrey M. Hunter. All rights reserved. | 7 | -- |----------------------------------------------------------------------------| 8 | -- | DATABASE : Oracle | 9 | -- | FILE : dba_row_size.sql | 10 | -- | CLASS : Database Administration | 11 | -- | PURPOSE : Determines the row sizes for all tables in a given schema. | 12 | -- | NOTE : As with any code, ensure to test this script in a development | 13 | -- | environment before attempting to run it in production. | 14 | -- +----------------------------------------------------------------------------+ 15 | 16 | SET TERMOUT OFF; 17 | COLUMN current_instance NEW_VALUE current_instance NOPRINT; 18 | SELECT rpad(instance_name, 17) current_instance FROM v$instance; 19 | SET TERMOUT ON; 20 | 21 | PROMPT 22 | PROMPT +------------------------------------------------------------------------+ 23 | PROMPT | Report : Calculate Row Size for Tables in a Specified Schema | 24 | PROMPT | Instance : ¤t_instance | 25 | PROMPT +------------------------------------------------------------------------+ 26 | 27 | PROMPT 28 | ACCEPT schema CHAR PROMPT 'Enter schema name : ' 29 | 30 | SET ECHO OFF 31 | SET FEEDBACK 6 32 | SET HEADING ON 33 | SET LINESIZE 180 34 | SET PAGESIZE 50000 35 | SET TERMOUT ON 36 | SET TIMING OFF 37 | SET TRIMOUT ON 38 | SET TRIMSPOOL ON 39 | SET VERIFY OFF 40 | 41 | CLEAR COLUMNS 42 | CLEAR BREAKS 43 | CLEAR COMPUTES 44 | 45 | COLUMN Tot_Size FORMAT 99,999 46 | COLUMN data_type FORMAT a15 47 | 48 | BREAK ON table_name SKIP 2 49 | 50 | COMPUTE sum OF Tot_Size ON table_name 51 | COMPUTE sum OF data_length ON table_name 52 | 53 | SELECT 54 | table_name 55 | , column_name 56 | , DECODE( DATA_TYPE 57 | , 'NUMBER' , DATA_PRECISION+DATA_SCALE 58 | , 'VARCHAR2' , TO_NUMBER(DATA_LENGTH) 59 | , 'CHAR' , TO_NUMBER(DATA_LENGTH) 60 | , 'DATE' , TO_NUMBER(DATA_LENGTH)) Tot_Size 61 | , DATA_TYPE 62 | FROM dba_tab_columns 63 | WHERE owner = UPPER('&schema') 64 | ORDER BY table_name 65 | , column_id 66 | / 67 | 68 | -------------------------------------------------------------------------------- /sql/dba_segment_summary.sql: -------------------------------------------------------------------------------- 1 | -- +----------------------------------------------------------------------------+ 2 | -- | Jeffrey M. Hunter | 3 | -- | jhunter@idevelopment.info | 4 | -- | www.idevelopment.info | 5 | -- |----------------------------------------------------------------------------| 6 | -- | Copyright (c) 1998-2015 Jeffrey M. Hunter. All rights reserved. | 7 | -- |----------------------------------------------------------------------------| 8 | -- | DATABASE : Oracle | 9 | -- | FILE : dba_segment_summary.sql | 10 | -- | CLASS : Database Administration | 11 | -- | PURPOSE : Provide a summary report of all segments in the database. | 12 | -- | NOTE : As with any code, ensure to test this script in a development | 13 | -- | environment before attempting to run it in production. | 14 | -- +----------------------------------------------------------------------------+ 15 | 16 | SET TERMOUT OFF; 17 | COLUMN current_instance NEW_VALUE current_instance NOPRINT; 18 | SELECT rpad(instance_name, 17) current_instance FROM v$instance; 19 | SET TERMOUT ON; 20 | 21 | PROMPT 22 | PROMPT +------------------------------------------------------------------------+ 23 | PROMPT | Report : Segment Summary Report | 24 | PROMPT | Instance : ¤t_instance | 25 | PROMPT +------------------------------------------------------------------------+ 26 | 27 | SET ECHO OFF 28 | SET FEEDBACK 6 29 | SET HEADING ON 30 | SET LINESIZE 180 31 | SET PAGESIZE 50000 32 | SET TERMOUT ON 33 | SET TIMING OFF 34 | SET TRIMOUT ON 35 | SET TRIMSPOOL ON 36 | SET VERIFY OFF 37 | 38 | CLEAR COLUMNS 39 | CLEAR BREAKS 40 | CLEAR COMPUTES 41 | 42 | COLUMN owner FORMAT a20 HEADING "Owner" 43 | COLUMN segment_type FORMAT a18 HEADING "Segment Type" 44 | COLUMN bytes FORMAT 9,999,999,999,999 HEADING "Size (in Bytes)" 45 | COLUMN seg_count FORMAT 9,999,999,999 HEADING "Segment Count" 46 | 47 | BREAK ON report ON owner SKIP 2 48 | 49 | COMPUTE sum LABEL "" OF seg_count bytes ON owner 50 | COMPUTE sum LABEL "Grand Total: " OF seg_count bytes ON report 51 | 52 | SELECT 53 | owner 54 | , segment_type 55 | , sum(bytes) bytes 56 | , count(*) seg_count 57 | FROM 58 | dba_segments 59 | GROUP BY 60 | owner 61 | , segment_type 62 | ORDER BY 63 | owner 64 | , segment_type 65 | / 66 | 67 | -------------------------------------------------------------------------------- /sql/dba_tables_all.sql: -------------------------------------------------------------------------------- 1 | -- +----------------------------------------------------------------------------+ 2 | -- | Jeffrey M. Hunter | 3 | -- | jhunter@idevelopment.info | 4 | -- | www.idevelopment.info | 5 | -- |----------------------------------------------------------------------------| 6 | -- | Copyright (c) 1998-2015 Jeffrey M. Hunter. All rights reserved. | 7 | -- |----------------------------------------------------------------------------| 8 | -- | DATABASE : Oracle | 9 | -- | FILE : dba_tables_all.sql | 10 | -- | CLASS : Database Administration | 11 | -- | PURPOSE : Query all tables (and owners) within the database. | 12 | -- | NOTE : As with any code, ensure to test this script in a development | 13 | -- | environment before attempting to run it in production. | 14 | -- +----------------------------------------------------------------------------+ 15 | 16 | SET TERMOUT OFF; 17 | COLUMN current_instance NEW_VALUE current_instance NOPRINT; 18 | SELECT rpad(instance_name, 17) current_instance FROM v$instance; 19 | SET TERMOUT ON; 20 | 21 | PROMPT 22 | PROMPT +------------------------------------------------------------------------+ 23 | PROMPT | Report : All Database Tables | 24 | PROMPT | Instance : ¤t_instance | 25 | PROMPT +------------------------------------------------------------------------+ 26 | 27 | SET ECHO OFF 28 | SET FEEDBACK 6 29 | SET HEADING ON 30 | SET LINESIZE 180 31 | SET PAGESIZE 50000 32 | SET TERMOUT OFF 33 | SET TIMING OFF 34 | SET TRIMOUT ON 35 | SET TRIMSPOOL ON 36 | SET VERIFY OFF 37 | 38 | CLEAR COLUMNS 39 | CLEAR BREAKS 40 | CLEAR COMPUTES 41 | 42 | COLUMN owner FORMAT a20 HEADING "Owner" 43 | COLUMN table_name FORMAT a30 HEADING "Table Name" 44 | COLUMN tablespace_name FORMAT a30 HEADING "Tablespace" 45 | COLUMN last_analyzed FORMAT a20 HEADING "Last Analyzed" 46 | COLUMN num_rows FORMAT 999,999,999,999 HEADING "# of Rows" 47 | 48 | DEFINE spool_file=database_tables.lst 49 | 50 | SPOOL &spool_file 51 | 52 | SELECT 53 | owner 54 | , table_name 55 | , tablespace_name 56 | , TO_CHAR(last_analyzed, 'DD-MON-YYYY HH24:MI:SS') last_analyzed 57 | , num_rows 58 | FROM 59 | dba_tables 60 | WHERE 61 | owner NOT IN ('SYS', 'SYSTEM') 62 | ORDER BY 63 | owner 64 | , table_name 65 | / 66 | 67 | SPOOL OFF 68 | 69 | SET TERMOUT ON 70 | 71 | PROMPT 72 | PROMPT Report written to &spool_file 73 | PROMPT 74 | -------------------------------------------------------------------------------- /sql/dba_tables_current_user.sql: -------------------------------------------------------------------------------- 1 | -- +----------------------------------------------------------------------------+ 2 | -- | Jeffrey M. Hunter | 3 | -- | jhunter@idevelopment.info | 4 | -- | www.idevelopment.info | 5 | -- |----------------------------------------------------------------------------| 6 | -- | Copyright (c) 1998-2015 Jeffrey M. Hunter. All rights reserved. | 7 | -- |----------------------------------------------------------------------------| 8 | -- | DATABASE : Oracle | 9 | -- | FILE : dba_tables_current_user.sql | 10 | -- | CLASS : Database Administration | 11 | -- | PURPOSE : Query all tables owned by the currently connected user. | 12 | -- | NOTE : As with any code, ensure to test this script in a development | 13 | -- | environment before attempting to run it in production. | 14 | -- +----------------------------------------------------------------------------+ 15 | 16 | SET TERMOUT OFF; 17 | COLUMN current_instance NEW_VALUE current_instance NOPRINT; 18 | COLUMN current_user NEW_VALUE current_user NOPRINT; 19 | SELECT rpad(instance_name, 17) current_instance, rpad(user, 13) current_user FROM v$instance; 20 | SET TERMOUT ON; 21 | 22 | PROMPT 23 | PROMPT +------------------------------------------------------------------------+ 24 | PROMPT | Report : Tables owned by ¤t_user | 25 | PROMPT | Instance : ¤t_instance | 26 | PROMPT +------------------------------------------------------------------------+ 27 | 28 | SET ECHO OFF 29 | SET FEEDBACK 6 30 | SET HEADING ON 31 | SET LINESIZE 180 32 | SET PAGESIZE 50000 33 | SET TERMOUT ON 34 | SET TIMING OFF 35 | SET TRIMOUT ON 36 | SET TRIMSPOOL ON 37 | SET VERIFY OFF 38 | 39 | CLEAR COLUMNS 40 | CLEAR BREAKS 41 | CLEAR COMPUTES 42 | 43 | COLUMN table_name FORMAT a30 HEADING "Table Name" 44 | COLUMN tablespace_name FORMAT a30 HEADING "Tablespace" 45 | COLUMN last_analyzed FORMAT a20 HEADING "Last Analyzed" 46 | COLUMN num_rows FORMAT 999,999,999,990 HEADING "# of Rows" 47 | 48 | SELECT 49 | table_name 50 | , tablespace_name 51 | , TO_CHAR(last_analyzed, 'DD-MON-YYYY HH24:MI:SS') last_analyzed 52 | , num_rows 53 | FROM 54 | user_tables 55 | ORDER BY 56 | table_name 57 | / 58 | 59 | -------------------------------------------------------------------------------- /sql/dba_tables_query_user.sql: -------------------------------------------------------------------------------- 1 | -- +----------------------------------------------------------------------------+ 2 | -- | Jeffrey M. Hunter | 3 | -- | jhunter@idevelopment.info | 4 | -- | www.idevelopment.info | 5 | -- |----------------------------------------------------------------------------| 6 | -- | Copyright (c) 1998-2015 Jeffrey M. Hunter. All rights reserved. | 7 | -- |----------------------------------------------------------------------------| 8 | -- | DATABASE : Oracle | 9 | -- | FILE : dba_tables_query_user.sql | 10 | -- | CLASS : Database Administration | 11 | -- | PURPOSE : Prompt the user for a schema and then query all tables within | 12 | -- | that schema. | 13 | -- | NOTE : As with any code, ensure to test this script in a development | 14 | -- | environment before attempting to run it in production. | 15 | -- +----------------------------------------------------------------------------+ 16 | 17 | SET TERMOUT OFF; 18 | COLUMN current_instance NEW_VALUE current_instance NOPRINT; 19 | SELECT rpad(instance_name, 17) current_instance FROM v$instance; 20 | SET TERMOUT ON; 21 | 22 | PROMPT 23 | PROMPT +------------------------------------------------------------------------+ 24 | PROMPT | Report : Query Tables for Specified Schema | 25 | PROMPT | Instance : ¤t_instance | 26 | PROMPT +------------------------------------------------------------------------+ 27 | 28 | PROMPT 29 | ACCEPT schema CHAR PROMPT 'Enter schema : ' 30 | 31 | SET ECHO OFF 32 | SET FEEDBACK 6 33 | SET HEADING ON 34 | SET LINESIZE 180 35 | SET PAGESIZE 50000 36 | SET TERMOUT ON 37 | SET TIMING OFF 38 | SET TRIMOUT ON 39 | SET TRIMSPOOL ON 40 | SET VERIFY OFF 41 | 42 | CLEAR COLUMNS 43 | CLEAR BREAKS 44 | CLEAR COMPUTES 45 | 46 | COLUMN owner FORMAT a20 HEADING "Owner" 47 | COLUMN table_name FORMAT a30 HEADING "Table Name" 48 | COLUMN tablespace_name FORMAT a30 HEADING "Tablespace" 49 | COLUMN last_analyzed FORMAT a20 HEADING "Last Analyzed" 50 | COLUMN num_rows FORMAT 999,999,999,999 HEADING "# of Rows" 51 | 52 | SELECT 53 | owner 54 | , table_name 55 | , tablespace_name 56 | , TO_CHAR(last_analyzed, 'DD-MON-YYYY HH24:MI:SS') last_analyzed 57 | , num_rows 58 | FROM dba_tables 59 | WHERE owner = UPPER('&schema') 60 | ORDER BY 61 | owner 62 | , table_name 63 | / 64 | 65 | -------------------------------------------------------------------------------- /sql/dba_tablespace_to_owner.sql: -------------------------------------------------------------------------------- 1 | -- +----------------------------------------------------------------------------+ 2 | -- | Jeffrey M. Hunter | 3 | -- | jhunter@idevelopment.info | 4 | -- | www.idevelopment.info | 5 | -- |----------------------------------------------------------------------------| 6 | -- | Copyright (c) 1998-2015 Jeffrey M. Hunter. All rights reserved. | 7 | -- |----------------------------------------------------------------------------| 8 | -- | DATABASE : Oracle | 9 | -- | FILE : dba_tablespace_to_owner.sql | 10 | -- | CLASS : Database Administration | 11 | -- | PURPOSE : Provide a summary report of tablespace to owner for all | 12 | -- | segments in the database. | 13 | -- | NOTE : As with any code, ensure to test this script in a development | 14 | -- | environment before attempting to run it in production. | 15 | -- +----------------------------------------------------------------------------+ 16 | 17 | SET TERMOUT OFF; 18 | COLUMN current_instance NEW_VALUE current_instance NOPRINT; 19 | SELECT rpad(instance_name, 17) current_instance FROM v$instance; 20 | SET TERMOUT ON; 21 | 22 | PROMPT 23 | PROMPT +------------------------------------------------------------------------+ 24 | PROMPT | Report : Tablespace to Owner | 25 | PROMPT | Instance : ¤t_instance | 26 | PROMPT +------------------------------------------------------------------------+ 27 | 28 | SET ECHO OFF 29 | SET FEEDBACK 6 30 | SET HEADING ON 31 | SET LINESIZE 180 32 | SET PAGESIZE 50000 33 | SET TERMOUT ON 34 | SET TIMING OFF 35 | SET TRIMOUT ON 36 | SET TRIMSPOOL ON 37 | SET VERIFY OFF 38 | 39 | CLEAR COLUMNS 40 | CLEAR BREAKS 41 | CLEAR COMPUTES 42 | 43 | COLUMN tablespace_name FORMAT a30 HEADING "Tablespace Name" 44 | COLUMN owner FORMAT a20 HEADING "Owner" 45 | COLUMN segment_type FORMAT a20 HEADING "Segment Type" 46 | COLUMN bytes FORMAT 9,999,999,999,999 HEADING "Size (in Bytes)" 47 | COLUMN seg_count FORMAT 9,999,999,999 HEADING "Segment Count" 48 | 49 | BREAK ON report ON tablespace_name SKIP 2 50 | 51 | COMPUTE sum LABEL "" OF seg_count bytes ON tablespace_name 52 | COMPUTE sum LABEL "Grand Total: " OF seg_count bytes ON report 53 | 54 | SELECT 55 | tablespace_name 56 | , owner 57 | , segment_type 58 | , sum(bytes) bytes 59 | , count(*) seg_count 60 | FROM 61 | dba_segments 62 | GROUP BY 63 | tablespace_name 64 | , owner 65 | , segment_type 66 | ORDER BY 67 | tablespace_name 68 | , owner 69 | , segment_type 70 | / 71 | 72 | -------------------------------------------------------------------------------- /sql/dpump_jobs.sql: -------------------------------------------------------------------------------- 1 | -- +----------------------------------------------------------------------------+ 2 | -- | Jeffrey M. Hunter | 3 | -- | jhunter@idevelopment.info | 4 | -- | www.idevelopment.info | 5 | -- |----------------------------------------------------------------------------| 6 | -- | Copyright (c) 1998-2015 Jeffrey M. Hunter. All rights reserved. | 7 | -- |----------------------------------------------------------------------------| 8 | -- | DATABASE : Oracle | 9 | -- | FILE : dpump_jobs.sql | 10 | -- | CLASS : Data Pump | 11 | -- | PURPOSE : Query all Data Pump jobs. | 12 | -- | NOTE : As with any code, ensure to test this script in a development | 13 | -- | environment before attempting to run it in production. | 14 | -- +----------------------------------------------------------------------------+ 15 | 16 | SET TERMOUT OFF; 17 | COLUMN current_instance NEW_VALUE current_instance NOPRINT; 18 | SELECT rpad(instance_name, 17) current_instance FROM v$instance; 19 | SET TERMOUT ON; 20 | 21 | PROMPT 22 | PROMPT +------------------------------------------------------------------------+ 23 | PROMPT | Report : Data Pump Jobs | 24 | PROMPT | Instance : ¤t_instance | 25 | PROMPT +------------------------------------------------------------------------+ 26 | 27 | SET ECHO OFF 28 | SET FEEDBACK 6 29 | SET HEADING ON 30 | SET LINESIZE 180 31 | SET PAGESIZE 50000 32 | SET TERMOUT ON 33 | SET TIMING OFF 34 | SET TRIMOUT ON 35 | SET TRIMSPOOL ON 36 | SET VERIFY OFF 37 | 38 | CLEAR COLUMNS 39 | CLEAR BREAKS 40 | CLEAR COMPUTES 41 | 42 | COLUMN owner_name FORMAT a15 HEADING 'Owner Name' 43 | COLUMN job_name FORMAT a20 HEADING 'Job Name' 44 | COLUMN operation FORMAT a10 HEADING 'Operation' 45 | COLUMN job_mode FORMAT a10 HEADING 'Job Mode' 46 | COLUMN state FORMAT a10 HEADING 'State' 47 | COLUMN degree FORMAT 999999 HEADING 'Degree' 48 | COLUMN attached_sessions FORMAT 999,999 HEADING 'Attached Sessions' 49 | 50 | SELECT 51 | dpj.owner_name owner_name 52 | , dpj.job_name job_name 53 | , dpj.operation operation 54 | , dpj.job_mode job_mode 55 | , dpj.state state 56 | , dpj.degree degree 57 | , dpj.attached_sessions attached_sessions 58 | FROM 59 | dba_datapump_jobs dpj 60 | ORDER BY 61 | dpj.owner_name 62 | , dpj.job_name; 63 | 64 | -------------------------------------------------------------------------------- /sql/erp_conc_manager_user_query.sql: -------------------------------------------------------------------------------- 1 | -- +----------------------------------------------------------------------------+ 2 | -- | Jeffrey M. Hunter | 3 | -- | jhunter@idevelopment.info | 4 | -- | www.idevelopment.info | 5 | -- |----------------------------------------------------------------------------| 6 | -- | Copyright (c) 1998-2015 Jeffrey M. Hunter. All rights reserved. | 7 | -- |----------------------------------------------------------------------------| 8 | -- | DATABASE : Oracle | 9 | -- | FILE : erp_conc_manager_user_query.sql | 10 | -- | CLASS : Oracle Applications | 11 | -- | PURPOSE : Reports on concurrent manager processes. | 12 | -- | NOTE : As with any code, ensure to test this script in a development | 13 | -- | environment before attempting to run it in production. | 14 | -- +----------------------------------------------------------------------------+ 15 | 16 | SET TERMOUT OFF; 17 | COLUMN current_instance NEW_VALUE current_instance NOPRINT; 18 | SELECT rpad(instance_name, 17) current_instance FROM v$instance; 19 | SET TERMOUT ON; 20 | 21 | PROMPT 22 | PROMPT +------------------------------------------------------------------------+ 23 | PROMPT | Report : Concurrent Manager Processes | 24 | PROMPT | Instance : ¤t_instance | 25 | PROMPT +------------------------------------------------------------------------+ 26 | 27 | SET ECHO OFF 28 | SET FEEDBACK 6 29 | SET HEADING ON 30 | SET LINESIZE 180 31 | SET PAGESIZE 50000 32 | SET TERMOUT ON 33 | SET TIMING OFF 34 | SET TRIMOUT ON 35 | SET TRIMSPOOL ON 36 | SET VERIFY OFF 37 | 38 | CLEAR COLUMNS 39 | CLEAR BREAKS 40 | CLEAR COMPUTES 41 | 42 | COLUMN oracle_process_id FORMAT 9999999 HEADING 'PID'; 43 | COLUMN session_id FORMAT 9999999 HEADING 'Session ID'; 44 | COLUMN oracle_id FORMAT 9999999 HEADING 'Oracle ID'; 45 | COLUMN os_process_id FORMAT a10 HEADING 'OS PID'; 46 | COLUMN request_id FORMAT 9999999999 HEADING 'Request ID'; 47 | COLUMN requested_by FORMAT 9999999 HEADING 'Requested By'; 48 | COLUMN status_code FORMAT a6 HEADING 'Status'; 49 | COLUMN completion_text FORMAT a15 HEADING 'Text'; 50 | COLUMN user_id FORMAT 9999999 HEADING 'User ID'; 51 | COLUMN user_name FORMAT a10 HEADING 'User Name'; 52 | 53 | SELECT 54 | c.os_process_id 55 | , a.oracle_id 56 | , a.request_id 57 | , a.requested_by 58 | , b.user_name 59 | , a.phase_code 60 | , a.completion_text 61 | FROM 62 | applsys.fnd_concurrent_requests a 63 | , applsys.fnd_user b 64 | , applsys.fnd_concurrent_processes c 65 | WHERE 66 | a.requested_by = b.user_id 67 | AND c.concurrent_process_id = a.controlling_manager 68 | AND a.phase_code in ('R', 'T') 69 | ORDER BY 70 | c.os_process_id 71 | / 72 | 73 | -------------------------------------------------------------------------------- /sql/example_create_clob.sql: -------------------------------------------------------------------------------- 1 | -- +----------------------------------------------------------------------------+ 2 | -- | Jeffrey M. Hunter | 3 | -- | jhunter@idevelopment.info | 4 | -- | www.idevelopment.info | 5 | -- |----------------------------------------------------------------------------| 6 | -- | Copyright (c) 1998-2015 Jeffrey M. Hunter. All rights reserved. | 7 | -- |----------------------------------------------------------------------------| 8 | -- | DATABASE : Oracle | 9 | -- | FILE : example_create_clob.sql | 10 | -- | CLASS : Examples | 11 | -- | PURPOSE : Example SQL script that demonstrates how to create tables | 12 | -- | containing a CLOB datatype in Oracle8i and higher. One of the | 13 | -- | biggest differences between creating a CLOB in Oracle8 and | 14 | -- | Oracle8i or higher is the use of the INDEX clause within the LOB| 15 | -- | clause declaration. In Oracle8 it is possible to name the LOB | 16 | -- | INDEX and declare a tablespace and storage clause for it. With | 17 | -- | versions Oracle8i and higher, it is still possible to name the | 18 | -- | INDEX LOB SEGMENT using the INDEX clause but these versions of | 19 | -- | Oracle (8i and higher) will simply ignore anything else within | 20 | -- | the INDEX clause (like tablespaces and storage clause.) From | 21 | -- | what I have read Oracle is deprecating the tablespace and | 22 | -- | storage clauses from being used within the INDEX clause. | 23 | -- | NOTE : As with any code, ensure to test this script in a development | 24 | -- | environment before attempting to run it in production. | 25 | -- +----------------------------------------------------------------------------+ 26 | 27 | DROP TABLE xml_documents 28 | / 29 | 30 | CREATE TABLE xml_documents ( 31 | docname VARCHAR2(200) 32 | , xmldoc CLOB 33 | , log CLOB 34 | , timestamp DATE 35 | ) 36 | LOB (xmldoc) 37 | STORE AS xml_documents_lob ( 38 | TABLESPACE lob_data 39 | STORAGE ( 40 | INITIAL 1m NEXT 1m PCTINCREASE 0 MAXEXTENTS unlimited 41 | ) 42 | INDEX xml_documents_lob_idx 43 | ) 44 | LOB (log) 45 | STORE AS xml_log_lob ( 46 | TABLESPACE lob_data 47 | STORAGE ( 48 | INITIAL 1m NEXT 1m PCTINCREASE 0 MAXEXTENTS unlimited 49 | ) 50 | INDEX xml_log_lob_idx 51 | ) 52 | TABLESPACE users 53 | STORAGE ( 54 | INITIAL 256k 55 | NEXT 256k 56 | MINEXTENTS 1 57 | MAXEXTENTS 121 58 | PCTINCREASE 0 59 | ) 60 | / 61 | 62 | -------------------------------------------------------------------------------- /sql/example_create_dimension.sql: -------------------------------------------------------------------------------- 1 | -- +----------------------------------------------------------------------------+ 2 | -- | Jeffrey M. Hunter | 3 | -- | jhunter@idevelopment.info | 4 | -- | www.idevelopment.info | 5 | -- |----------------------------------------------------------------------------| 6 | -- | Copyright (c) 1998-2015 Jeffrey M. Hunter. All rights reserved. | 7 | -- |----------------------------------------------------------------------------| 8 | -- | DATABASE : Oracle | 9 | -- | FILE : example_create_dimension.sql | 10 | -- | CLASS : Examples | 11 | -- | PURPOSE : Example SQL script to create a dimension object. | 12 | -- | NOTE : As with any code, ensure to test this script in a development | 13 | -- | environment before attempting to run it in production. | 14 | -- +----------------------------------------------------------------------------+ 15 | 16 | CREATE DIMENSION dim_clothes 17 | LEVEL upc IS retail_tab.upc 18 | LEVEL style IS retail_tab.style 19 | LEVEL class IS retail_tab.class 20 | LEVEL department IS retail_tab.department 21 | LEVEL store IS retail_tab.store 22 | LEVEL region IS retail_tab.region 23 | LEVEL company IS retail_tab.company 24 | HIERARCHY sales_rollup ( 25 | upc CHILD OF 26 | style CHILD OF 27 | class CHILD OF 28 | department CHILD OF 29 | store CHILD OF 30 | region CHILD OF 31 | company) 32 | ATTRIBUTE style DETERMINES (color) 33 | ATTRIBUTE upc DETERMINES (item_size); 34 | 35 | -------------------------------------------------------------------------------- /sql/example_create_index.sql: -------------------------------------------------------------------------------- 1 | -- +----------------------------------------------------------------------------+ 2 | -- | Jeffrey M. Hunter | 3 | -- | jhunter@idevelopment.info | 4 | -- | www.idevelopment.info | 5 | -- |----------------------------------------------------------------------------| 6 | -- | Copyright (c) 1998-2015 Jeffrey M. Hunter. All rights reserved. | 7 | -- |----------------------------------------------------------------------------| 8 | -- | DATABASE : Oracle | 9 | -- | FILE : example_create_index.sql | 10 | -- | CLASS : Examples | 11 | -- | PURPOSE : Example SQL script to demonstrate how to create indexes with | 12 | -- | proper naming conventions. | 13 | -- | NOTE : As with any code, ensure to test this script in a development | 14 | -- | environment before attempting to run it in production. | 15 | -- +----------------------------------------------------------------------------+ 16 | 17 | /* 18 | * ------------------------------- 19 | * UNIQUE INDEX 20 | * ------------------------------- 21 | */ 22 | 23 | CREATE UNIQUE INDEX emp_u1 24 | ON emp(emp_id) 25 | TABLESPACE indexes 26 | STORAGE ( 27 | INITIAL 256K 28 | NEXT 256K 29 | MINEXTENTS 1 30 | MAXEXTENTS 121 31 | PCTINCREASE 0 32 | FREELISTS 3 33 | ) 34 | / 35 | 36 | 37 | /* 38 | * ------------------------------- 39 | * NON-UNIQUE (default) INDEX 40 | * ------------------------------- 41 | */ 42 | 43 | CREATE INDEX emp_n1 44 | ON emp(name) 45 | TABLESPACE indexes 46 | STORAGE ( 47 | INITIAL 64K 48 | NEXT 64K 49 | MINEXTENTS 1 50 | MAXEXTENTS 121 51 | PCTINCREASE 0 52 | FREELISTS 3 53 | ) 54 | / 55 | 56 | 57 | /* 58 | * ------------------------------- 59 | * PRIMARY KEY INDEX 60 | * ------------------------------- 61 | */ 62 | 63 | ALTER TABLE emp 64 | ADD CONSTRAINT emp_pk PRIMARY KEY(emp_id) 65 | USING INDEX 66 | TABLESPACE indexes 67 | STORAGE ( 68 | INITIAL 64K 69 | NEXT 64K 70 | MINEXTENTS 1 71 | MAXEXTENTS 121 72 | PCTINCREASE 0 73 | ) 74 | / 75 | 76 | -------------------------------------------------------------------------------- /sql/example_create_index_organized_table.sql: -------------------------------------------------------------------------------- 1 | -- +----------------------------------------------------------------------------+ 2 | -- | Jeffrey M. Hunter | 3 | -- | jhunter@idevelopment.info | 4 | -- | www.idevelopment.info | 5 | -- |----------------------------------------------------------------------------| 6 | -- | Copyright (c) 1998-2015 Jeffrey M. Hunter. All rights reserved. | 7 | -- |----------------------------------------------------------------------------| 8 | -- | DATABASE : Oracle | 9 | -- | FILE : example_create_index_organized_table.sql | 10 | -- | CLASS : Examples | 11 | -- | PURPOSE : Example SQL script that demonstrates how to create an Index | 12 | -- | Organized Table (IOT) object. | 13 | -- | NOTE : As with any code, ensure to test this script in a development | 14 | -- | environment before attempting to run it in production. | 15 | -- +----------------------------------------------------------------------------+ 16 | 17 | /* 18 | * ------------------------ 19 | * NORMAL IOT 20 | * ------------------------ 21 | */ 22 | 23 | DROP TABLE my_iot 24 | / 25 | 26 | CREATE TABLE my_iot ( 27 | id NUMBER 28 | , name VARCHAR2(100) 29 | , hiredate DATE 30 | , CONSTRAINT my_iot_pk PRIMARY KEY (id) 31 | ) 32 | ORGANIZATION INDEX 33 | OVERFLOW TABLESPACE users 34 | / 35 | 36 | 37 | /* 38 | * -------------------------------------------- 39 | * CREATE IOT FROM SELECTING FROM ANOTHER TABLE 40 | * -------------------------------------------- 41 | */ 42 | 43 | DROP TABLE my_iot_from_table 44 | / 45 | 46 | CREATE TABLE my_iot_from_table ( 47 | emp_id 48 | , dept_id 49 | , name 50 | , date_of_birth 51 | , date_of_hire 52 | , monthly_salary 53 | , position 54 | , extension 55 | , office_location 56 | , CONSTRAINT my_iot_from_table_pk PRIMARY KEY (emp_id) 57 | ) 58 | ORGANIZATION INDEX 59 | OVERFLOW TABLESPACE users 60 | AS 61 | SELECT * FROM emp 62 | / 63 | 64 | -------------------------------------------------------------------------------- /sql/example_create_materialized_view.sql: -------------------------------------------------------------------------------- 1 | -- +----------------------------------------------------------------------------+ 2 | -- | Jeffrey M. Hunter | 3 | -- | jhunter@idevelopment.info | 4 | -- | www.idevelopment.info | 5 | -- |----------------------------------------------------------------------------| 6 | -- | Copyright (c) 1998-2015 Jeffrey M. Hunter. All rights reserved. | 7 | -- |----------------------------------------------------------------------------| 8 | -- | DATABASE : Oracle | 9 | -- | FILE : example_create_materialized_view.sql | 10 | -- | CLASS : Examples | 11 | -- | PURPOSE : Example SQL script that demonstrates how to create several | 12 | -- | materialized views. | 13 | -- | NOTE : As with any code, ensure to test this script in a development | 14 | -- | environment before attempting to run it in production. | 15 | -- +----------------------------------------------------------------------------+ 16 | 17 | CREATE MATERIALIZED VIEW flight_fact_mv 18 | BUILD IMMEDIATE 19 | REFRESH COMPLETE ON COMMIT 20 | ENABLE QUERY REWRITE 21 | AS 22 | SELECT 23 | plane_id PLANE_ID 24 | , sum(sale_amount) SUM_SALE_AMOUNT 25 | FROM scott.flight_fact 26 | GROUP BY plane_id 27 | / 28 | 29 | 30 | CREATE MATERIALIZED VIEW monthly_salary_mv 31 | BUILD IMMEDIATE 32 | REFRESH COMPLETE ON COMMIT 33 | ENABLE QUERY REWRITE 34 | AS 35 | SELECT 36 | b.name DEPT_NAME 37 | , a.monthly_salary AVG_MONTHLY_SALARY 38 | FROM emp a, dept b 39 | / 40 | 41 | -------------------------------------------------------------------------------- /sql/example_create_not_null_constraints.sql: -------------------------------------------------------------------------------- 1 | -- +----------------------------------------------------------------------------+ 2 | -- | Jeffrey M. Hunter | 3 | -- | jhunter@idevelopment.info | 4 | -- | www.idevelopment.info | 5 | -- |----------------------------------------------------------------------------| 6 | -- | Copyright (c) 1998-2015 Jeffrey M. Hunter. All rights reserved. | 7 | -- |----------------------------------------------------------------------------| 8 | -- | DATABASE : Oracle | 9 | -- | FILE : example_create_not_null_constraints.sql | 10 | -- | CLASS : Examples | 11 | -- | PURPOSE : It is important when designing tables to name your NOT NULL | 12 | -- | constraints. The following example provides the syntax necessary| 13 | -- | to name your NOT NULL constraints. | 14 | -- | NOTE : As with any code, ensure to test this script in a development | 15 | -- | environment before attempting to run it in production. | 16 | -- +----------------------------------------------------------------------------+ 17 | 18 | 19 | ALTER TABLE user_names 20 | MODIFY ( name CONSTRAINT user_names_nn1 NOT NULL 21 | , age CONSTRAINT user_names_nn2 NOT NULL 22 | , update_log_date CONSTRAINT user_names_nn3 NOT NULL 23 | ) 24 | / 25 | 26 | -------------------------------------------------------------------------------- /sql/example_create_primary_foreign_key.sql: -------------------------------------------------------------------------------- 1 | -- +----------------------------------------------------------------------------+ 2 | -- | Jeffrey M. Hunter | 3 | -- | jhunter@idevelopment.info | 4 | -- | www.idevelopment.info | 5 | -- |----------------------------------------------------------------------------| 6 | -- | Copyright (c) 1998-2015 Jeffrey M. Hunter. All rights reserved. | 7 | -- |----------------------------------------------------------------------------| 8 | -- | DATABASE : Oracle | 9 | -- | FILE : example_create_primary_foreign_key.sql | 10 | -- | CLASS : Examples | 11 | -- | PURPOSE : Example SQL script that creates a Primary / Foreign key | 12 | -- | relationship between the EMP and DEPT tables. It is advisable to| 13 | -- | create a non-unique index on all foreign keys. | 14 | -- | NOTE : As with any code, ensure to test this script in a development | 15 | -- | environment before attempting to run it in production. | 16 | -- +----------------------------------------------------------------------------+ 17 | 18 | -- +-----------------------------------------------------------------+ 19 | -- | ADD PRIMARY KEY | 20 | -- +-----------------------------------------------------------------+ 21 | 22 | ALTER TABLE dept 23 | ADD CONSTRAINT dept_pk PRIMARY KEY(dept_id) 24 | USING INDEX 25 | TABLESPACE indexes 26 | STORAGE ( 27 | INITIAL 64K 28 | NEXT 64K 29 | MINEXTENTS 1 30 | MAXEXTENTS 121 31 | PCTINCREASE 0 32 | ) 33 | / 34 | 35 | 36 | -- +-----------------------------------------------------------------+ 37 | -- | ADD FOREIGN KEY | 38 | -- +-----------------------------------------------------------------+ 39 | 40 | ALTER TABLE emp 41 | ADD CONSTRAINT emp_fk1 FOREIGN KEY (dept_id) 42 | REFERENCES dept(dept_id) 43 | / 44 | 45 | 46 | -- +-----------------------------------------------------------------+ 47 | -- | ADD NON-UNIQUE INDEX FOR THE FOREIGN KEY | 48 | -- +-----------------------------------------------------------------+ 49 | 50 | CREATE INDEX emp_fk_n1 51 | ON emp(dept_id) 52 | TABLESPACE indexes 53 | STORAGE ( 54 | INITIAL 64K 55 | NEXT 64K 56 | MINEXTENTS 1 57 | MAXEXTENTS 121 58 | PCTINCREASE 0 59 | FREELISTS 3 60 | ) 61 | / 62 | 63 | -------------------------------------------------------------------------------- /sql/example_create_sequence.sql: -------------------------------------------------------------------------------- 1 | -- +----------------------------------------------------------------------------+ 2 | -- | Jeffrey M. Hunter | 3 | -- | jhunter@idevelopment.info | 4 | -- | www.idevelopment.info | 5 | -- |----------------------------------------------------------------------------| 6 | -- | Copyright (c) 1998-2015 Jeffrey M. Hunter. All rights reserved. | 7 | -- |----------------------------------------------------------------------------| 8 | -- | DATABASE : Oracle | 9 | -- | FILE : example_create_sequence.sql | 10 | -- | CLASS : Examples | 11 | -- | PURPOSE : Example SQL script that demonstrates how to create a sequence | 12 | -- | number generator. | 13 | -- | NOTE : As with any code, ensure to test this script in a development | 14 | -- | environment before attempting to run it in production. | 15 | -- +----------------------------------------------------------------------------+ 16 | 17 | DROP SEQUENCE user_id_seq 18 | / 19 | 20 | CREATE SEQUENCE user_id_seq 21 | INCREMENT BY 1 22 | START WITH 1000 23 | NOMAXVALUE 24 | NOCYCLE 25 | / 26 | -------------------------------------------------------------------------------- /sql/example_create_temporary_tables.sql: -------------------------------------------------------------------------------- 1 | -- +----------------------------------------------------------------------------+ 2 | -- | Jeffrey M. Hunter | 3 | -- | jhunter@idevelopment.info | 4 | -- | www.idevelopment.info | 5 | -- |----------------------------------------------------------------------------| 6 | -- | Copyright (c) 1998-2015 Jeffrey M. Hunter. All rights reserved. | 7 | -- |----------------------------------------------------------------------------| 8 | -- | DATABASE : Oracle | 9 | -- | FILE : example_create_temporary_tables.sql | 10 | -- | CLASS : Examples | 11 | -- | PURPOSE : Example SQL script that demonstrates how to create temporary | 12 | -- | tables. | 13 | -- | NOTE : As with any code, ensure to test this script in a development | 14 | -- | environment before attempting to run it in production. | 15 | -- +----------------------------------------------------------------------------+ 16 | 17 | 18 | connect scott/tiger 19 | 20 | set serveroutput on 21 | 22 | Prompt ==================================================== 23 | Prompt CREATE TEMPORARY TABLE WITH DEFAULT SETTINGS... 24 | Prompt (Oracle8i will use on commit delete rows by default) 25 | Prompt ==================================================== 26 | Prompt 27 | accept a1 Prompt "Hit to continue"; 28 | 29 | CREATE GLOBAL TEMPORARY TABLE mytemptab1 ( 30 | id NUMBER 31 | , name VARCHAR2(500) 32 | , average_salary NUMBER(15,2) 33 | ) 34 | / 35 | 36 | 37 | Prompt ================================================ 38 | Prompt CREATE TEMPORARY TABLE: on commit delete rows... 39 | Prompt ================================================ 40 | Prompt 41 | accept a1 Prompt "Hit to continue"; 42 | 43 | CREATE GLOBAL TEMPORARY TABLE mytemptab2 ( 44 | id NUMBER 45 | , name VARCHAR2(500) 46 | , average_salary NUMBER(15,2) 47 | ) ON COMMIT DELETE ROWS 48 | / 49 | 50 | 51 | Prompt ================================================== 52 | Prompt CREATE TEMPORARY TABLE: on commit preserve rows... 53 | Prompt ================================================== 54 | Prompt 55 | accept a1 Prompt "Hit to continue"; 56 | 57 | CREATE GLOBAL TEMPORARY TABLE mytemptab3 ( 58 | id NUMBER 59 | , name VARCHAR2(500) 60 | , average_salary NUMBER(15,2) 61 | ) ON COMMIT PRESERVE ROWS 62 | / 63 | 64 | 65 | -------------------------------------------------------------------------------- /sql/example_drop_unused_column.sql: -------------------------------------------------------------------------------- 1 | -- +----------------------------------------------------------------------------+ 2 | -- | Jeffrey M. Hunter | 3 | -- | jhunter@idevelopment.info | 4 | -- | www.idevelopment.info | 5 | -- |----------------------------------------------------------------------------| 6 | -- | Copyright (c) 1998-2015 Jeffrey M. Hunter. All rights reserved. | 7 | -- |----------------------------------------------------------------------------| 8 | -- | DATABASE : Oracle | 9 | -- | FILE : example_drop_unused_column.sql | 10 | -- | CLASS : Examples | 11 | -- | PURPOSE : Example SQL syntax used to drop unused columns from a table. | 12 | -- | NOTE : As with any code, ensure to test this script in a development | 13 | -- | environment before attempting to run it in production. | 14 | -- +----------------------------------------------------------------------------+ 15 | 16 | connect scott/tiger 17 | 18 | set serveroutput on 19 | 20 | Prompt ====================== 21 | Prompt DROP existing table... 22 | Prompt ====================== 23 | Prompt 24 | accept a1 Prompt "Hit to continue"; 25 | 26 | DROP TABLE d_table 27 | / 28 | 29 | 30 | Prompt ======================= 31 | Prompt CREATE TESTING TABLE... 32 | Prompt ======================= 33 | Prompt 34 | accept a1 Prompt "Hit to continue"; 35 | 36 | CREATE TABLE d_table ( 37 | id_no NUMBER 38 | , name VARCHAR2(100) 39 | , d_column VARCHAR2(100) 40 | ) 41 | / 42 | 43 | 44 | Prompt ======================== 45 | Prompt MARK COLUMN AS UNUSED... 46 | Prompt ======================== 47 | Prompt 48 | accept a1 Prompt "Hit to continue"; 49 | 50 | ALTER TABLE d_table SET UNUSED COLUMN d_column; 51 | 52 | 53 | Prompt ======================================= 54 | Prompt QUERY ALL TABLES WITH UNUSED COLUMNS... 55 | Prompt ======================================= 56 | Prompt 57 | accept a1 Prompt "Hit to continue"; 58 | 59 | SELECT * FROM sys.dba_unused_col_tabs; 60 | 61 | 62 | Prompt ====================================== 63 | Prompt PHYSICALLY REMOVE THE UNUSED COLUMN... 64 | Prompt ====================================== 65 | Prompt 66 | accept a1 Prompt "Hit to continue"; 67 | 68 | ALTER TABLE d_table DROP UNUSED COLUMNS; 69 | 70 | 71 | Prompt ================================================ 72 | Prompt IF YOU WANTED TO PHYSICALLY REMOVE THE COLUMN... 73 | Prompt ================================================ 74 | Prompt 75 | accept a1 Prompt "Hit to continue"; 76 | 77 | -- ALTER TABLE d_table DROP COLUMN d_column; 78 | 79 | 80 | Prompt ========================================= 81 | Prompt OPTIONALLY SYNTAX FOR REMOVING COLUMNS... 82 | Prompt ========================================= 83 | Prompt 84 | Prompt ALTER TABLE d_table DROP COLUMN d_column CASCADE CONSTRAINTS; 85 | Prompt ALTER TABLE d_table DROP COLUMN d_column INVALIDATE; 86 | Prompt ALTER TABLE d_table DROP COLUMN d_column CHECKPOINT 1000; 87 | Prompt 88 | accept a1 Prompt "Hit to EXIT"; 89 | 90 | 91 | -------------------------------------------------------------------------------- /sql/example_move_table.sql: -------------------------------------------------------------------------------- 1 | -- +----------------------------------------------------------------------------+ 2 | -- | Jeffrey M. Hunter | 3 | -- | jhunter@idevelopment.info | 4 | -- | www.idevelopment.info | 5 | -- |----------------------------------------------------------------------------| 6 | -- | Copyright (c) 1998-2015 Jeffrey M. Hunter. All rights reserved. | 7 | -- |----------------------------------------------------------------------------| 8 | -- | DATABASE : Oracle | 9 | -- | FILE : example_move_table.sql | 10 | -- | CLASS : Examples | 11 | -- | PURPOSE : Example SQL syntax used to move a table to an alternative | 12 | -- | tablespace. | 13 | -- | NOTE : As with any code, ensure to test this script in a development | 14 | -- | environment before attempting to run it in production. | 15 | -- +----------------------------------------------------------------------------+ 16 | 17 | ALTER TABLE emp MOVE TABLESPACE users2 STORAGE (INITIAL 10M NEXT 1M); 18 | -------------------------------------------------------------------------------- /sql/example_partition_range_date_oracle_8.sql: -------------------------------------------------------------------------------- 1 | -- +----------------------------------------------------------------------------+ 2 | -- | Jeffrey M. Hunter | 3 | -- | jhunter@idevelopment.info | 4 | -- | www.idevelopment.info | 5 | -- |----------------------------------------------------------------------------| 6 | -- | Copyright (c) 1998-2015 Jeffrey M. Hunter. All rights reserved. | 7 | -- |----------------------------------------------------------------------------| 8 | -- | DATABASE : Oracle | 9 | -- | FILE : example_partition_range_date_oracle_8.sql | 10 | -- | CLASS : Examples | 11 | -- | PURPOSE : Example SQL syntax used to create and maintain range partitions | 12 | -- | in Oracle8. The table in this example is partitioned by a date | 13 | -- | range. In Oracle8, only range partitions are available. | 14 | -- | NOTE : As with any code, ensure to test this script in a development | 15 | -- | environment before attempting to run it in production. | 16 | -- +----------------------------------------------------------------------------+ 17 | 18 | CONNECT scott/tiger 19 | 20 | /* 21 | ** +-----------------------------------+ 22 | ** | DROP ALL OBJECTS | 23 | ** +-----------------------------------+ 24 | */ 25 | 26 | DROP TABLE emp_date_part CASCADE CONSTRAINTS 27 | / 28 | 29 | 30 | /* 31 | ** +-------------------------------------------------+ 32 | ** | CREATE (Range) PARTITIONED TABLE | 33 | ** | ----------------------------------------------- | 34 | ** | Create testing table partitioned by a | 35 | ** | "range" of DATE values. | 36 | ** | | 37 | ** | NOTE: The only functions permitted in the | 38 | ** | 'VALUES LESS THAN (value1, value2 ..., valueN)' | 39 | ** | clause are TO_DATE and RPAD. | 40 | ** +-------------------------------------------------+ 41 | */ 42 | 43 | CREATE TABLE emp_date_part ( 44 | empno NUMBER(15) NOT NULL 45 | , ename VARCHAR2(100) 46 | , sal NUMBER(7,2) 47 | , hire_date DATE NOT NULL 48 | ) 49 | TABLESPACE users 50 | STORAGE ( 51 | INITIAL 128K 52 | NEXT 128K 53 | PCTINCREASE 0 54 | MAXEXTENTS UNLIMITED 55 | ) 56 | PARTITION BY RANGE (hire_date) ( 57 | PARTITION emp_date_part_Q1_2001_part 58 | VALUES LESS THAN (TO_DATE('01-APR-2001', 'DD-MON-YYYY')) 59 | TABLESPACE part_1_data_tbs, 60 | PARTITION emp_date_part_Q2_2001_part 61 | VALUES LESS THAN (TO_DATE('01-JUL-2001', 'DD-MON-YYYY')) 62 | TABLESPACE part_2_data_tbs, 63 | PARTITION emp_date_part_Q3_2001_part 64 | VALUES LESS THAN (TO_DATE('01-OCT-2001', 'DD-MON-YYYY')) 65 | TABLESPACE part_3_data_tbs, 66 | PARTITION emp_date_part_Q4_2001_part 67 | VALUES LESS THAN (TO_DATE('01-JAN-2002', 'DD-MON-YYYY')) 68 | TABLESPACE part_4_data_tbs 69 | ) 70 | / 71 | 72 | -------------------------------------------------------------------------------- /sql/fdb_log_files.sql: -------------------------------------------------------------------------------- 1 | -- +----------------------------------------------------------------------------+ 2 | -- | Jeffrey M. Hunter | 3 | -- | jhunter@idevelopment.info | 4 | -- | www.idevelopment.info | 5 | -- |----------------------------------------------------------------------------| 6 | -- | Copyright (c) 1998-2015 Jeffrey M. Hunter. All rights reserved. | 7 | -- |----------------------------------------------------------------------------| 8 | -- | DATABASE : Oracle | 9 | -- | FILE : fdb_log_files.sql | 10 | -- | CLASS : Flashback Database | 11 | -- | PURPOSE : Provide a list of all Flasback log files. | 12 | -- | NOTE : As with any code, ensure to test this script in a development | 13 | -- | environment before attempting to run it in production. | 14 | -- +----------------------------------------------------------------------------+ 15 | 16 | SET TERMOUT OFF; 17 | COLUMN current_instance NEW_VALUE current_instance NOPRINT; 18 | SELECT rpad(sys_context('USERENV', 'INSTANCE_NAME'), 17) current_instance 19 | FROM dual; 20 | SET TERMOUT ON; 21 | 22 | PROMPT 23 | PROMPT +------------------------------------------------------------------------+ 24 | PROMPT | Report : Flashback Database Log Files | 25 | PROMPT | Instance : ¤t_instance | 26 | PROMPT +------------------------------------------------------------------------+ 27 | 28 | SET ECHO OFF 29 | SET FEEDBACK 6 30 | SET HEADING ON 31 | SET LINESIZE 180 32 | SET PAGESIZE 50000 33 | SET TERMOUT ON 34 | SET TIMING OFF 35 | SET TRIMOUT ON 36 | SET TRIMSPOOL ON 37 | SET VERIFY OFF 38 | 39 | CLEAR COLUMNS 40 | CLEAR BREAKS 41 | CLEAR COMPUTES 42 | 43 | COLUMN thread# HEADING 'Thread #' 44 | COLUMN sequence# HEADING 'Sequence #' 45 | COLUMN name FORMAT a65 HEADING 'Log File Name' 46 | COLUMN log# HEADING 'Log #' 47 | COLUMN bytes FORMAT 999,999,999,999 HEADING 'Bytes' 48 | COLUMN first_change# HEADING 'First Change #' 49 | COLUMN first_time HEADING 'First Time' JUST RIGHT 50 | 51 | BREAK ON thread# SKIP 2 52 | 53 | COMPUTE count OF sequence# ON thread# 54 | COMPUTE sum OF bytes ON thread# 55 | 56 | SELECT 57 | thread# 58 | , sequence# 59 | , name 60 | , log# 61 | , bytes 62 | , first_change# 63 | , TO_CHAR(first_time, 'DD-MON-YYYY HH24:MI:SS') first_time 64 | FROM 65 | v$flashback_database_logfile 66 | ORDER BY 67 | thread# 68 | , sequence#; 69 | 70 | -------------------------------------------------------------------------------- /sql/fdb_redo_time_matrix.sql: -------------------------------------------------------------------------------- 1 | -- +----------------------------------------------------------------------------+ 2 | -- | Jeffrey M. Hunter | 3 | -- | jhunter@idevelopment.info | 4 | -- | www.idevelopment.info | 5 | -- |----------------------------------------------------------------------------| 6 | -- | Copyright (c) 1998-2015 Jeffrey M. Hunter. All rights reserved. | 7 | -- |----------------------------------------------------------------------------| 8 | -- | DATABASE : Oracle | 9 | -- | FILE : fdb_redo_time_matrix.sql | 10 | -- | CLASS : Flashback Database | 11 | -- | PURPOSE : Provide details on the amount of redo data being collected by | 12 | -- | Oracle Flashback Database over given time frames. | 13 | -- | NOTE : As with any code, ensure to test this script in a development | 14 | -- | environment before attempting to run it in production. | 15 | -- +----------------------------------------------------------------------------+ 16 | 17 | SET TERMOUT OFF; 18 | COLUMN current_instance NEW_VALUE current_instance NOPRINT; 19 | SELECT rpad(sys_context('USERENV', 'INSTANCE_NAME'), 17) current_instance 20 | FROM dual; 21 | SET TERMOUT ON; 22 | 23 | PROMPT 24 | PROMPT +------------------------------------------------------------------------+ 25 | PROMPT | Report : Flashback Database Redo Time Matrix | 26 | PROMPT | Instance : ¤t_instance | 27 | PROMPT +------------------------------------------------------------------------+ 28 | 29 | SET ECHO OFF 30 | SET FEEDBACK 6 31 | SET HEADING ON 32 | SET LINESIZE 180 33 | SET PAGESIZE 50000 34 | SET TERMOUT ON 35 | SET TIMING OFF 36 | SET TRIMOUT ON 37 | SET TRIMSPOOL ON 38 | SET VERIFY OFF 39 | 40 | CLEAR COLUMNS 41 | CLEAR BREAKS 42 | CLEAR COMPUTES 43 | 44 | COLUMN begin_time FORMAT a21 HEADING 'Begin Time' 45 | COLUMN end_time FORMAT a21 HEADING 'End Time' 46 | COLUMN flashback_data FORMAT 9,999,999,999,999 HEADING 'Flashback Data' 47 | COLUMN db_data FORMAT 9,999,999,999,999 HEADING 'DB Data' 48 | COLUMN redo_data FORMAT 9,999,999,999,999 HEADING 'Redo Data' 49 | COLUMN estimated_flashback_size FORMAT 9,999,999,999,999 HEADING 'Estimated|Flashback Size' 50 | 51 | SELECT 52 | TO_CHAR(begin_time, 'DD-MON-YYYY HH24:MI:SS') begin_time 53 | , TO_CHAR(end_time, 'DD-MON-YYYY HH24:MI:SS') end_time 54 | , flashback_data 55 | , db_data 56 | , redo_data 57 | , estimated_flashback_size 58 | FROM 59 | v$flashback_database_stat 60 | ORDER BY 61 | begin_time; 62 | 63 | -------------------------------------------------------------------------------- /sql/fra_files.sql: -------------------------------------------------------------------------------- 1 | -- +----------------------------------------------------------------------------+ 2 | -- | Jeffrey M. Hunter | 3 | -- | jhunter@idevelopment.info | 4 | -- | www.idevelopment.info | 5 | -- |----------------------------------------------------------------------------| 6 | -- | Copyright (c) 1998-2015 Jeffrey M. Hunter. All rights reserved. | 7 | -- |----------------------------------------------------------------------------| 8 | -- | DATABASE : Oracle | 9 | -- | FILE : fra_files.sql | 10 | -- | CLASS : Flash Recovery Area | 11 | -- | PURPOSE : Provide a list of all files in the Flash Recovery Area. | 12 | -- | NOTE : As with any code, ensure to test this script in a development | 13 | -- | environment before attempting to run it in production. | 14 | -- +----------------------------------------------------------------------------+ 15 | 16 | SET TERMOUT OFF; 17 | COLUMN current_instance NEW_VALUE current_instance NOPRINT; 18 | SELECT rpad(sys_context('USERENV', 'INSTANCE_NAME'), 17) current_instance 19 | FROM dual; 20 | SET TERMOUT ON; 21 | 22 | PROMPT 23 | PROMPT +------------------------------------------------------------------------+ 24 | PROMPT | Report : FRA Files | 25 | PROMPT | Instance : ¤t_instance | 26 | PROMPT +------------------------------------------------------------------------+ 27 | 28 | SET ECHO OFF 29 | SET FEEDBACK 6 30 | SET HEADING ON 31 | SET LINESIZE 180 32 | SET PAGESIZE 50000 33 | SET TERMOUT ON 34 | SET TIMING OFF 35 | SET TRIMOUT ON 36 | SET TRIMSPOOL ON 37 | SET VERIFY OFF 38 | 39 | CLEAR COLUMNS 40 | CLEAR BREAKS 41 | CLEAR COMPUTES 42 | 43 | COLUMN name FORMAT a80 HEADING 'File Name' 44 | COLUMN member FORMAT a80 HEADING 'File Name' 45 | COLUMN handle FORMAT a80 HEADING 'File Name' 46 | COLUMN bytes FORMAT 999,999,999,999,999 HEADING 'File Size (Bytes)' 47 | 48 | SELECT name, (blocks*block_size) bytes 49 | FROM v$datafile_copy 50 | WHERE is_recovery_dest_file = 'YES' 51 | UNION 52 | SELECT name, null 53 | FROM v$controlfile 54 | WHERE is_recovery_dest_file = 'YES' 55 | UNION 56 | SELECT member, null 57 | FROM v$logfile 58 | WHERE is_recovery_dest_file = 'YES' 59 | UNION 60 | SELECT handle, bytes 61 | FROM v$backup_piece 62 | WHERE is_recovery_dest_file = 'YES' 63 | UNION 64 | SELECT name, (blocks*block_size) bytes 65 | FROM v$archived_log 66 | WHERE is_recovery_dest_file = 'YES' 67 | ORDER BY 68 | 1 69 | , 2 70 | / 71 | 72 | -------------------------------------------------------------------------------- /sql/mts_dispatcher_utilization.sql: -------------------------------------------------------------------------------- 1 | -- +----------------------------------------------------------------------------+ 2 | -- | Jeffrey M. Hunter | 3 | -- | jhunter@idevelopment.info | 4 | -- | www.idevelopment.info | 5 | -- |----------------------------------------------------------------------------| 6 | -- | Copyright (c) 1998-2015 Jeffrey M. Hunter. All rights reserved. | 7 | -- |----------------------------------------------------------------------------| 8 | -- | DATABASE : Oracle | 9 | -- | FILE : mts_dispatcher_utilization.sql | 10 | -- | CLASS : Multi-threaded Server (MTS) | 11 | -- | PURPOSE : Display MTS dispatcher utilization. This script is RAC enabled. | 12 | -- | NOTE : As with any code, ensure to test this script in a development | 13 | -- | environment before attempting to run it in production. | 14 | -- +----------------------------------------------------------------------------+ 15 | 16 | SET TERMOUT OFF; 17 | COLUMN current_instance NEW_VALUE current_instance NOPRINT; 18 | SELECT rpad(instance_name, 17) current_instance FROM v$instance; 19 | SET TERMOUT ON; 20 | 21 | PROMPT 22 | PROMPT +------------------------------------------------------------------------+ 23 | PROMPT | Report : Multi-threaded Server: Dispatcher Utilization | 24 | PROMPT | Instance : ¤t_instance | 25 | PROMPT +------------------------------------------------------------------------+ 26 | 27 | SET ECHO OFF 28 | SET FEEDBACK 6 29 | SET HEADING ON 30 | SET LINESIZE 180 31 | SET PAGESIZE 50000 32 | SET TERMOUT ON 33 | SET TIMING OFF 34 | SET TRIMOUT ON 35 | SET TRIMSPOOL ON 36 | SET VERIFY OFF 37 | 38 | CLEAR COLUMNS 39 | CLEAR BREAKS 40 | CLEAR COMPUTES 41 | 42 | COLUMN instance_name FORMAT a10 HEAD 'Instance' 43 | COLUMN dispatcher_name FORMAT a16 HEAD 'Dispatcher Name' 44 | COLUMN busy FORMAT 999.99 HEAD '% Busy' 45 | 46 | SELECT 47 | i.instance_name instance_name 48 | , d.name dispatcher_name 49 | , ROUND(d.busy / (d.busy + d.idle) * 100, 2) busy 50 | FROM 51 | gv$instance i 52 | , gv$dispatcher d 53 | WHERE 54 | i.inst_id = d.inst_id 55 | ORDER BY 56 | i.instance_name 57 | , d.name; 58 | 59 | -------------------------------------------------------------------------------- /sql/mts_shared_server_utilization.sql: -------------------------------------------------------------------------------- 1 | -- +----------------------------------------------------------------------------+ 2 | -- | Jeffrey M. Hunter | 3 | -- | jhunter@idevelopment.info | 4 | -- | www.idevelopment.info | 5 | -- |----------------------------------------------------------------------------| 6 | -- | Copyright (c) 1998-2015 Jeffrey M. Hunter. All rights reserved. | 7 | -- |----------------------------------------------------------------------------| 8 | -- | DATABASE : Oracle | 9 | -- | FILE : mts_shared_server_utilization.sql | 10 | -- | CLASS : Multi-threaded Server (MTS) | 11 | -- | PURPOSE : Display status and metrics related to MTS shared server | 12 | -- | utilization. This script is RAC enabled. | 13 | -- | NOTE : As with any code, ensure to test this script in a development | 14 | -- | environment before attempting to run it in production. | 15 | -- +----------------------------------------------------------------------------+ 16 | 17 | SET TERMOUT OFF; 18 | COLUMN current_instance NEW_VALUE current_instance NOPRINT; 19 | SELECT rpad(instance_name, 17) current_instance FROM v$instance; 20 | SET TERMOUT ON; 21 | 22 | PROMPT 23 | PROMPT +------------------------------------------------------------------------+ 24 | PROMPT | Report : Multi-threaded Server: Shared Server Utilization | 25 | PROMPT | Instance : ¤t_instance | 26 | PROMPT +------------------------------------------------------------------------+ 27 | 28 | SET ECHO OFF 29 | SET FEEDBACK 6 30 | SET HEADING ON 31 | SET LINESIZE 180 32 | SET PAGESIZE 50000 33 | SET TERMOUT ON 34 | SET TIMING OFF 35 | SET TRIMOUT ON 36 | SET TRIMSPOOL ON 37 | SET VERIFY OFF 38 | 39 | CLEAR COLUMNS 40 | CLEAR BREAKS 41 | CLEAR COMPUTES 42 | 43 | COLUMN instance_name FORMAT a10 HEAD 'Instance' 44 | COLUMN s_name FORMAT a25 HEAD 'Server Name' 45 | COLUMN s_busy HEAD '% Busy' 46 | 47 | SELECT 48 | i.instance_name instance_name 49 | , s.name s_name 50 | , ROUND(s.busy / (s.busy + s.idle) * 100, 2) s_busy 51 | FROM 52 | gv$instance i 53 | , gv$shared_server s 54 | WHERE 55 | i.inst_id = s.inst_id 56 | ORDER BY 57 | i.instance_name 58 | , s.name; 59 | 60 | -------------------------------------------------------------------------------- /sql/owi_event_names.sql: -------------------------------------------------------------------------------- 1 | -- +----------------------------------------------------------------------------+ 2 | -- | Jeffrey M. Hunter | 3 | -- | jhunter@idevelopment.info | 4 | -- | www.idevelopment.info | 5 | -- |----------------------------------------------------------------------------| 6 | -- | Copyright (c) 1998-2015 Jeffrey M. Hunter. All rights reserved. | 7 | -- |----------------------------------------------------------------------------| 8 | -- | DATABASE : Oracle | 9 | -- | FILE : owi_event_names.sql | 10 | -- | CLASS : Oracle_Wait_Interface | 11 | -- | PURPOSE : Reports on all defined event names included in the Oracle Wait | 12 | -- | Interface. | 13 | -- | NOTE : As with any code, ensure to test this script in a development | 14 | -- | environment before attempting to run it in production. | 15 | -- +----------------------------------------------------------------------------+ 16 | 17 | SET TERMOUT OFF; 18 | COLUMN current_instance NEW_VALUE current_instance NOPRINT; 19 | SELECT rpad(instance_name, 17) current_instance FROM v$instance; 20 | SET TERMOUT ON; 21 | 22 | PROMPT 23 | PROMPT +------------------------------------------------------------------------+ 24 | PROMPT | Report : Oracle Wait Interface: Event Names | 25 | PROMPT | Instance : ¤t_instance | 26 | PROMPT +------------------------------------------------------------------------+ 27 | 28 | SET ECHO OFF 29 | SET FEEDBACK 6 30 | SET HEADING ON 31 | SET LINESIZE 180 32 | SET PAGESIZE 50000 33 | SET TERMOUT ON 34 | SET TIMING OFF 35 | SET TRIMOUT ON 36 | SET TRIMSPOOL ON 37 | SET VERIFY OFF 38 | 39 | CLEAR COLUMNS 40 | CLEAR BREAKS 41 | CLEAR COMPUTES 42 | 43 | COLUMN event# FORMAT 9999 HEADING 'Event #' 44 | COLUMN name FORMAT a60 HEADING 'Event Name' 45 | COLUMN parameter1 FORMAT a40 HEADING 'Parameter 1' TRUNC 46 | COLUMN parameter2 FORMAT a20 HEADING 'Parameter 2' TRUNC 47 | COLUMN parameter3 FORMAT a20 HEADING 'Parameter 3' TRUNC 48 | 49 | 50 | SELECT 51 | en.event# event# 52 | , en.name name 53 | , en.parameter1 parameter1 54 | , en.parameter2 parameter2 55 | , en.parameter3 parameter3 56 | FROM 57 | v$event_name en 58 | ORDER BY 59 | en.event#; 60 | 61 | -------------------------------------------------------------------------------- /sql/perf_db_block_buffer_usage.sql: -------------------------------------------------------------------------------- 1 | -- +----------------------------------------------------------------------------+ 2 | -- | Jeffrey M. Hunter | 3 | -- | jhunter@idevelopment.info | 4 | -- | www.idevelopment.info | 5 | -- |----------------------------------------------------------------------------| 6 | -- | Copyright (c) 1998-2015 Jeffrey M. Hunter. All rights reserved. | 7 | -- |----------------------------------------------------------------------------| 8 | -- | DATABASE : Oracle | 9 | -- | FILE : perf_db_block_buffer_usage.sql | 10 | -- | CLASS : Tuning | 11 | -- | PURPOSE : Report on the state of all DB_BLOCK_BUFFERS. This script must | 12 | -- | be run as the SYS user. | 13 | -- | NOTE : As with any code, ensure to test this script in a development | 14 | -- | environment before attempting to run it in production. | 15 | -- +----------------------------------------------------------------------------+ 16 | 17 | SET LINESIZE 135 18 | SET PAGESIZE 9999 19 | SET VERIFY off 20 | 21 | COLUMN block_status HEADING "Block Status" 22 | COLUMN count HEADING "Count" 23 | 24 | SELECT 25 | DECODE(state, 0, 'Free', 26 | 1, DECODE(lrba_seq, 0, 'Available', 'Being Modified'), 27 | 2, 'Not Modified', 28 | 3, 'Being Read', 29 | 'Other') block_status 30 | , count(*) count 31 | FROM 32 | sys.x$bh 33 | GROUP BY 34 | DECODE(state, 0, 'Free', 35 | 1, DECODE(lrba_seq, 0, 'Available', 'Being Modified'), 36 | 2, 'Not Modified', 37 | 3, 'Being Read', 38 | 'Other') 39 | / 40 | 41 | -------------------------------------------------------------------------------- /sql/perf_explain_plan.sql: -------------------------------------------------------------------------------- 1 | -- +----------------------------------------------------------------------------+ 2 | -- | Jeffrey M. Hunter | 3 | -- | jhunter@idevelopment.info | 4 | -- | www.idevelopment.info | 5 | -- |----------------------------------------------------------------------------| 6 | -- | Copyright (c) 1998-2015 Jeffrey M. Hunter. All rights reserved. | 7 | -- |----------------------------------------------------------------------------| 8 | -- | DATABASE : Oracle | 9 | -- | FILE : perf_explain_plan.sql | 10 | -- | CLASS : Tuning | 11 | -- | PURPOSE : Report the access path of a given STATEMENT_ID contained within | 12 | -- | a PLAN_TABLE. | 13 | -- | NOTE : As with any code, ensure to test this script in a development | 14 | -- | environment before attempting to run it in production. | 15 | -- +----------------------------------------------------------------------------+ 16 | 17 | SELECT 18 | LPAD(' ',2*level) 19 | ||operation 20 | ||' ' 21 | ||options 22 | ||' ' 23 | ||object_name Q_PLAN 24 | FROM 25 | plan_table 26 | WHERE 27 | statement_id = '&&STATEMENT_ID' 28 | CONNECT BY 29 | prior id = parent_id 30 | AND statement_id = '&&STATEMENT_ID' 31 | START WITH 32 | id = 1 33 | / 34 | -------------------------------------------------------------------------------- /sql/perf_file_io.sql: -------------------------------------------------------------------------------- 1 | -- +----------------------------------------------------------------------------+ 2 | -- | Jeffrey M. Hunter | 3 | -- | jhunter@idevelopment.info | 4 | -- | www.idevelopment.info | 5 | -- |----------------------------------------------------------------------------| 6 | -- | Copyright (c) 1998-2015 Jeffrey M. Hunter. All rights reserved. | 7 | -- |----------------------------------------------------------------------------| 8 | -- | DATABASE : Oracle | 9 | -- | FILE : perf_file_io.sql | 10 | -- | CLASS : Tuning | 11 | -- | PURPOSE : Reports on Read/Write datafile activity. This script was | 12 | -- | designed to work with Oracle8i or higher. It will include all | 13 | -- | tablespaces using any type of extent management as well as true | 14 | -- | TEMPORARY tablespaces. (i.e. use of "tempfiles") | 15 | -- | NOTE : As with any code, ensure to test this script in a development | 16 | -- | environment before attempting to run it in production. | 17 | -- +----------------------------------------------------------------------------+ 18 | 19 | SET LINESIZE 145 20 | SET PAGESIZE 9999 21 | SET VERIFY off 22 | 23 | COLUMN ts_name FORMAT a15 HEAD 'Tablespace' 24 | COLUMN fname FORMAT a45 HEAD 'File Name' 25 | COLUMN phyrds FORMAT 999,999,999 HEAD 'Physical Reads' 26 | COLUMN phywrts FORMAT 999,999,999 HEAD 'Physical Writes' 27 | COLUMN read_pct FORMAT 999.99 HEAD 'Read Pct.' 28 | COLUMN write_pct FORMAT 999.99 HEAD 'Write Pct.' 29 | 30 | BREAK ON report 31 | COMPUTE SUM OF phyrds ON report 32 | COMPUTE SUM OF phywrts ON report 33 | COMPUTE AVG OF read_pct ON report 34 | COMPUTE AVG OF write_pct ON report 35 | 36 | SELECT 37 | df.tablespace_name ts_name 38 | , df.file_name fname 39 | , fs.phyrds phyrds 40 | , (fs.phyrds * 100) / (fst.pr + tst.pr) read_pct 41 | , fs.phywrts phywrts 42 | , (fs.phywrts * 100) / (fst.pw + tst.pw) write_pct 43 | FROM 44 | sys.dba_data_files df 45 | , v$filestat fs 46 | , (select sum(f.phyrds) pr, sum(f.phywrts) pw from v$filestat f) fst 47 | , (select sum(t.phyrds) pr, sum(t.phywrts) pw from v$tempstat t) tst 48 | WHERE 49 | df.file_id = fs.file# 50 | UNION 51 | SELECT 52 | tf.tablespace_name ts_name 53 | , tf.file_name fname 54 | , ts.phyrds phyrds 55 | , (ts.phyrds * 100) / (fst.pr + tst.pr) read_pct 56 | , ts.phywrts phywrts 57 | , (ts.phywrts * 100) / (fst.pw + tst.pw) write_pct 58 | FROM 59 | sys.dba_temp_files tf 60 | , v$tempstat ts 61 | , (select sum(f.phyrds) pr, sum(f.phywrts) pw from v$filestat f) fst 62 | , (select sum(t.phyrds) pr, sum(t.phywrts) pw from v$tempstat t) tst 63 | WHERE 64 | tf.file_id = ts.file# 65 | ORDER BY phyrds DESC 66 | / 67 | 68 | -------------------------------------------------------------------------------- /sql/perf_file_io_7.sql: -------------------------------------------------------------------------------- 1 | -- +----------------------------------------------------------------------------+ 2 | -- | Jeffrey M. Hunter | 3 | -- | jhunter@idevelopment.info | 4 | -- | www.idevelopment.info | 5 | -- |----------------------------------------------------------------------------| 6 | -- | Copyright (c) 1998-2015 Jeffrey M. Hunter. All rights reserved. | 7 | -- |----------------------------------------------------------------------------| 8 | -- | DATABASE : Oracle | 9 | -- | FILE : perf_file_io_7.sql | 10 | -- | CLASS : Tuning | 11 | -- | PURPOSE : Reports on Read/Write datafile activity. This script was | 12 | -- | designed to work with Oracle7 and Oracle8. This script can be | 13 | -- | run against higher database versions (i.e. Oracle8i) but will | 14 | -- | not return information about true TEMPORARY tablespaces. | 15 | -- | (i.e. use of "tempfiles") | 16 | -- | NOTE : As with any code, ensure to test this script in a development | 17 | -- | environment before attempting to run it in production. | 18 | -- +----------------------------------------------------------------------------+ 19 | 20 | SET LINESIZE 145 21 | SET PAGESIZE 9999 22 | SET VERIFY off 23 | 24 | COLUMN phys_reads NEW_VALUE xphys_reads NOPRINT FORMAT a1 25 | COLUMN phys_writes NEW_VALUE xphys_writes NOPRINT FORMAT a1 26 | 27 | SELECT 28 | SUM(phyrds) phys_reads 29 | , SUM(phywrts) phys_writes 30 | FROM v$filestat 31 | / 32 | 33 | COLUMN name FORMAT a45 HEAD 'File Name' 34 | COLUMN phyrds FORMAT 999,999,999 HEAD 'Physical Reads' 35 | COLUMN phywrts FORMAT 999,999,999 HEAD 'Physical Writes' 36 | COLUMN read_pct FORMAT 999.99 HEAD 'Read Pct.' 37 | COLUMN write_pct FORMAT 999.99 HEAD 'Write Pct.' 38 | 39 | BREAK ON report 40 | COMPUTE SUM OF phyrds ON report 41 | COMPUTE SUM OF phywrts ON report 42 | COMPUTE AVG OF read_pct ON report 43 | COMPUTE AVG OF write_pct ON report 44 | 45 | 46 | SELECT 47 | name name 48 | , phyrds phyrds 49 | , phyrds * 100 / &xphys_reads read_pct 50 | , phywrts phywrts 51 | , phywrts * 100 / &xphys_writes write_pct 52 | FROM 53 | v$datafile df 54 | , v$filestat fs 55 | WHERE 56 | df.file# = fs.file# 57 | ORDER BY phyrds DESC 58 | / 59 | 60 | -------------------------------------------------------------------------------- /sql/perf_file_waits.sql: -------------------------------------------------------------------------------- 1 | -- +----------------------------------------------------------------------------+ 2 | -- | Jeffrey M. Hunter | 3 | -- | jhunter@idevelopment.info | 4 | -- | www.idevelopment.info | 5 | -- |----------------------------------------------------------------------------| 6 | -- | Copyright (c) 1998-2015 Jeffrey M. Hunter. All rights reserved. | 7 | -- |----------------------------------------------------------------------------| 8 | -- | DATABASE : Oracle | 9 | -- | FILE : perf_file_waits.sql | 10 | -- | CLASS : Tuning | 11 | -- | PURPOSE : Reports on Busy Buffer Waits per file. | 12 | -- | NOTE : As with any code, ensure to test this script in a development | 13 | -- | environment before attempting to run it in production. | 14 | -- +----------------------------------------------------------------------------+ 15 | 16 | SET LINESIZE 145 17 | SET PAGESIZE 9999 18 | 19 | COLUMN filename FORMAT a58 HEAD "File Name" 20 | COLUMN file# FORMAT 999 HEAD "File #" 21 | COLUMN ct FORMAT 999,999,999 HEAD "Waits (count)" 22 | COLUMN time FORMAT 999,999,999 HEAD "Time (cs)" 23 | COLUMN avg FORMAT 999.999 HEAD "Avg Time" 24 | 25 | 26 | SELECT 27 | a.indx + 1 file# 28 | , b.name filename 29 | , a.count ct 30 | , a.time time 31 | , a.time/(DECODE(a.count,0,1,a.count)) avg 32 | FROM 33 | x$kcbfwait a 34 | , v$datafile b 35 | WHERE 36 | indx < (SELECT count(*) FROM v$datafile) 37 | AND a.indx+1 = b.file# 38 | ORDER BY a.time 39 | / 40 | 41 | -------------------------------------------------------------------------------- /sql/perf_hit_ratio_by_session.sql: -------------------------------------------------------------------------------- 1 | -- +----------------------------------------------------------------------------+ 2 | -- | Jeffrey M. Hunter | 3 | -- | jhunter@idevelopment.info | 4 | -- | www.idevelopment.info | 5 | -- |----------------------------------------------------------------------------| 6 | -- | Copyright (c) 1998-2015 Jeffrey M. Hunter. All rights reserved. | 7 | -- |----------------------------------------------------------------------------| 8 | -- | DATABASE : Oracle | 9 | -- | FILE : perf_hit_ratio_by_session.sql | 10 | -- | CLASS : Tuning | 11 | -- | PURPOSE : Reports on all sessions along with their individual hit ratio. | 12 | -- | NOTE : As with any code, ensure to test this script in a development | 13 | -- | environment before attempting to run it in production. | 14 | -- +----------------------------------------------------------------------------+ 15 | 16 | SET LINESIZE 180 17 | SET PAGESIZE 9999 18 | 19 | COLUMN unix_id FORMAT a10 HEAD Username 20 | COLUMN oracle_id FORMAT a10 HEAD OracleID 21 | COLUMN os_user FORMAT a20 HEAD OS_User 22 | COLUMN sid FORMAT 99999 HEAD SID 23 | COLUMN serial_id FORMAT 999999 HEAD Serial# 24 | COLUMN unix_pid FORMAT a9 HEAD UNIX_Pid 25 | COLUMN consistent_gets FORMAT 999,999,999,999,999 HEAD Cons_Gets 26 | COLUMN block_gets FORMAT 999,999,999,999,999 HEAD Block_Gets 27 | COLUMN physical_reads FORMAT 999,999,999,999,999 HEAD Phys_Reads 28 | COLUMN hit_ratio FORMAT 999.00 HEAD Hit_Ratio 29 | 30 | SELECT 31 | p.username unix_id 32 | , s.username oracle_id 33 | , s.osuser os_user 34 | , s.sid sid 35 | , s.serial# serial_id 36 | , LPAD(p.spid,7) unix_pid 37 | , sio.consistent_gets consistent_gets 38 | , sio.block_gets block_gets 39 | , sio.physical_reads physical_reads 40 | , ROUND((consistent_gets+Block_gets-Physical_reads) / 41 | (Consistent_gets+Block_gets)*100,2) hit_ratio 42 | FROM 43 | v$process p 44 | , v$session s 45 | , v$sess_io sio 46 | WHERE 47 | p.addr (+) = s.paddr 48 | AND s.sid = sio.sid 49 | AND (sio.consistent_gets + sio.block_gets) > 0 50 | AND s.username is not null 51 | ORDER BY hit_ratio 52 | / 53 | 54 | -------------------------------------------------------------------------------- /sql/perf_hit_ratio_system.sql: -------------------------------------------------------------------------------- 1 | -- +----------------------------------------------------------------------------+ 2 | -- | Jeffrey M. Hunter | 3 | -- | jhunter@idevelopment.info | 4 | -- | www.idevelopment.info | 5 | -- |----------------------------------------------------------------------------| 6 | -- | Copyright (c) 1998-2015 Jeffrey M. Hunter. All rights reserved. | 7 | -- |----------------------------------------------------------------------------| 8 | -- | DATABASE : Oracle | 9 | -- | FILE : perf_hit_ratio_system.sql | 10 | -- | CLASS : Tuning | 11 | -- | PURPOSE : Reports buffer cache hit ratio. | 12 | -- | NOTE : As with any code, ensure to test this script in a development | 13 | -- | environment before attempting to run it in production. | 14 | -- +----------------------------------------------------------------------------+ 15 | 16 | SELECT 17 | TO_CHAR(SUM(DECODE(name, 'consistent gets', value, 0)), 18 | '999,999,999,999,999,999') con 19 | , TO_CHAR(SUM(DECODE(name, 'db block gets' , value, 0)), 20 | '999,999,999,999,999,999') dbblockgets 21 | , TO_CHAR(SUM(DECODE(name, 'physical reads' , value, 0)), 22 | '999,999,999,999,999,999') physrds 23 | , ROUND( ( ( 24 | SUM(DECODE(name, 'consistent gets', Value,0)) 25 | + 26 | SUM(DECODE(name, 'db block gets', value,0)) 27 | - 28 | SUM(DECODE(name, 'physical reads', value,0)) 29 | ) 30 | / 31 | ( 32 | SUM(DECODE(name, 'consistent gets', Value,0)) 33 | + 34 | SUM(DECODE(name, 'db block gets', Value,0)) 35 | ) 36 | ) *100,2 37 | ) Hitratio 38 | FROM v$sysstat 39 | / 40 | 41 | -------------------------------------------------------------------------------- /sql/perf_lru_latch_contention.sql: -------------------------------------------------------------------------------- 1 | -- +----------------------------------------------------------------------------+ 2 | -- | Jeffrey M. Hunter | 3 | -- | jhunter@idevelopment.info | 4 | -- | www.idevelopment.info | 5 | -- |----------------------------------------------------------------------------| 6 | -- | Copyright (c) 1998-2015 Jeffrey M. Hunter. All rights reserved. | 7 | -- |----------------------------------------------------------------------------| 8 | -- | DATABASE : Oracle | 9 | -- | FILE : perf_lru_latch_contention.sql | 10 | -- | CLASS : Tuning | 11 | -- | PURPOSE : This script will detect latch contention in the db block buffer | 12 | -- | LRU. The ratio of sleeps/gets should be < 1%. | 13 | -- | NOTE : As with any code, ensure to test this script in a development | 14 | -- | environment before attempting to run it in production. | 15 | -- +----------------------------------------------------------------------------+ 16 | 17 | SET LINESIZE 145 18 | SET PAGESIZE 9999 19 | SET VERIFY off 20 | 21 | COLUMN child_num HEADING "Child Number" 22 | COLUMN ratio_sleeps_gets HEADING "Sleeps / Gets Ratio" 23 | COLUMN ratio HEADING "Ratio" 24 | 25 | SELECT 26 | child# child_num 27 | , ROUND(sleeps/gets * 100,2) ratio_sleeps_gets 28 | , ROUND(((1 - sleeps/gets) * 100),2) ratio 29 | FROM 30 | v$latch_children 31 | WHERE 32 | name = 'cache buffers lru chain' 33 | / 34 | 35 | -------------------------------------------------------------------------------- /sql/perf_objects_without_statistics.sql: -------------------------------------------------------------------------------- 1 | -- +----------------------------------------------------------------------------+ 2 | -- | Jeffrey M. Hunter | 3 | -- | jhunter@idevelopment.info | 4 | -- | www.idevelopment.info | 5 | -- |----------------------------------------------------------------------------| 6 | -- | Copyright (c) 1998-2015 Jeffrey M. Hunter. All rights reserved. | 7 | -- |----------------------------------------------------------------------------| 8 | -- | DATABASE : Oracle | 9 | -- | FILE : perf_objects_without_statistics.sql | 10 | -- | CLASS : Tuning | 11 | -- | PURPOSE : Report on all objects that do not have statistics collected on | 12 | -- | them. | 13 | -- | NOTE : As with any code, ensure to test this script in a development | 14 | -- | environment before attempting to run it in production. | 15 | -- +----------------------------------------------------------------------------+ 16 | 17 | SET LINESIZE 145 18 | SET PAGESIZE 9999 19 | SET VERIFY off 20 | 21 | COLUMN owner FORMAT a17 HEAD 'Owner' 22 | COLUMN object_type FORMAT a15 HEAD 'Object Type' 23 | COLUMN object_name FORMAT a30 HEAD 'Object Name' 24 | COLUMN partition_name FORMAT a30 HEAD 'Partition Name' 25 | 26 | SELECT 27 | owner owner 28 | , 'Table' object_type 29 | , table_name object_name 30 | , NULL partition_name 31 | FROM 32 | sys.dba_tables 33 | WHERE 34 | last_analyzed IS NULL 35 | AND owner NOT IN ('SYS','SYSTEM') 36 | AND partitioned = 'NO' 37 | UNION 38 | SELECT 39 | owner owner 40 | , 'Index' object_type 41 | , index_name object_name 42 | , NULL partition_name 43 | FROM 44 | sys.dba_indexes 45 | WHERE 46 | last_analyzed IS NULL 47 | AND owner NOT IN ('SYS','SYSTEM') 48 | AND partitioned = 'NO' 49 | UNION 50 | SELECT 51 | table_owner owner 52 | , 'Table Partition' object_type 53 | , table_name object_name 54 | , partition_name partition_name 55 | FROM 56 | sys.dba_tab_partitions 57 | WHERE 58 | last_analyzed IS NULL 59 | AND table_owner NOT IN ('SYS','SYSTEM') 60 | UNION 61 | SELECT 62 | index_owner owner 63 | , 'Index Partition' object_type 64 | , index_name object_name 65 | , partition_name partition_name 66 | FROM 67 | sys.dba_ind_partitions 68 | WHERE 69 | last_analyzed IS NULL 70 | AND index_owner NOT IN ('SYS','SYSTEM') 71 | ORDER BY 72 | 1 73 | , 2 74 | , 3 75 | / 76 | 77 | -------------------------------------------------------------------------------- /sql/perf_redo_log_contention.sql: -------------------------------------------------------------------------------- 1 | -- +----------------------------------------------------------------------------+ 2 | -- | Jeffrey M. Hunter | 3 | -- | jhunter@idevelopment.info | 4 | -- | www.idevelopment.info | 5 | -- |----------------------------------------------------------------------------| 6 | -- | Copyright (c) 1998-2015 Jeffrey M. Hunter. All rights reserved. | 7 | -- |----------------------------------------------------------------------------| 8 | -- | DATABASE : Oracle | 9 | -- | FILE : perf_redo_log_contention.sql | 10 | -- | CLASS : Tuning | 11 | -- | PURPOSE : Report on overall redo log contention for the instance since | 12 | -- | the instance was last started. | 13 | -- | NOTE : As with any code, ensure to test this script in a development | 14 | -- | environment before attempting to run it in production. | 15 | -- +----------------------------------------------------------------------------+ 16 | 17 | SET LINESIZE 145 18 | SET PAGESIZE 9999 19 | SET VERIFY off 20 | 21 | prompt 22 | prompt ======================================= 23 | prompt Latches 24 | prompt ======================================= 25 | prompt 26 | 27 | COLUMN name FORMAT a30 HEADING 'Latch Name' 28 | COLUMN gets FORMAT 999,999,999 HEADING 'Gets' 29 | COLUMN misses FORMAT 999,999,999 HEADING 'Misses' 30 | COLUMN sleeps FORMAT 999,999,999 HEADING 'Sleeps' 31 | COLUMN immediate_gets FORMAT 999,999,999 HEADING 'Immediate Gets' 32 | COLUMN immediate_misses FORMAT 999,999,999 HEADING 'Immediate Misses' 33 | 34 | BREAK ON report 35 | COMPUTE SUM OF gets ON report 36 | COMPUTE SUM OF misses ON report 37 | COMPUTE SUM OF sleeps ON report 38 | COMPUTE SUM OF immediate_gets ON report 39 | COMPUTE SUM OF immediate_misses ON report 40 | 41 | SELECT 42 | INITCAP(name) name 43 | , gets 44 | , misses 45 | , sleeps 46 | , immediate_gets 47 | , immediate_misses 48 | FROM sys.v_$latch 49 | WHERE name LIKE 'redo%' 50 | ORDER BY 1; 51 | 52 | 53 | prompt 54 | prompt ======================================= 55 | prompt System Statistics 56 | prompt ======================================= 57 | prompt 58 | 59 | COLUMN name FORMAT a30 HEADING 'Statistics Name' 60 | COLUMN value FORMAT 999,999,999,999 HEADING 'Value' 61 | 62 | SELECT 63 | name 64 | , value 65 | FROM 66 | v$sysstat 67 | WHERE 68 | name LIKE 'redo%'; 69 | 70 | -------------------------------------------------------------------------------- /sql/perf_sga_free_pool.sql: -------------------------------------------------------------------------------- 1 | -- +----------------------------------------------------------------------------+ 2 | -- | Jeffrey M. Hunter | 3 | -- | jhunter@idevelopment.info | 4 | -- | www.idevelopment.info | 5 | -- |----------------------------------------------------------------------------| 6 | -- | Copyright (c) 1998-2015 Jeffrey M. Hunter. All rights reserved. | 7 | -- |----------------------------------------------------------------------------| 8 | -- | DATABASE : Oracle | 9 | -- | FILE : perf_sga_free_pool.sql | 10 | -- | CLASS : Tuning | 11 | -- | PURPOSE : Report on Shared / Java Pool within SGA. | 12 | -- | NOTE : As with any code, ensure to test this script in a development | 13 | -- | environment before attempting to run it in production. | 14 | -- +----------------------------------------------------------------------------+ 15 | 16 | COLUMN pool HEADING "Pool" 17 | COLUMN name HEADING "Name" 18 | COLUMN sgasize HEADING "Allocated" FORMAT 999,999,999 19 | COLUMN bytes HEADING "Free" FORMAT 999,999,999 20 | 21 | SELECT 22 | f.pool 23 | , f.name 24 | , s.sgasize 25 | , f.bytes 26 | , ROUND(f.bytes/s.sgasize*100, 2) "% Free" 27 | FROM 28 | (SELECT SUM(bytes) sgasize, pool FROM v$sgastat GROUP BY pool) s 29 | , v$sgastat f 30 | WHERE 31 | f.name = 'free memory' 32 | AND f.pool = s.pool 33 | / 34 | 35 | -------------------------------------------------------------------------------- /sql/perf_sga_usage.sql: -------------------------------------------------------------------------------- 1 | -- +----------------------------------------------------------------------------+ 2 | -- | Jeffrey M. Hunter | 3 | -- | jhunter@idevelopment.info | 4 | -- | www.idevelopment.info | 5 | -- |----------------------------------------------------------------------------| 6 | -- | Copyright (c) 1998-2015 Jeffrey M. Hunter. All rights reserved. | 7 | -- |----------------------------------------------------------------------------| 8 | -- | DATABASE : Oracle | 9 | -- | FILE : perf_sga_usage.sql | 10 | -- | CLASS : Tuning | 11 | -- | PURPOSE : Report on all components within the SGA. | 12 | -- | NOTE : As with any code, ensure to test this script in a development | 13 | -- | environment before attempting to run it in production. | 14 | -- +----------------------------------------------------------------------------+ 15 | 16 | SET LINESIZE 145 17 | SET PAGESIZE 9999 18 | SET FEEDBACK off 19 | SET VERIFY off 20 | 21 | COLUMN bytes FORMAT 999,999,999 22 | COLUMN percent FORMAT 999.99999 23 | 24 | break on report 25 | 26 | compute sum of bytes on report 27 | compute sum of percent on report 28 | 29 | SELECT 30 | a.name 31 | , a.bytes 32 | , a.bytes/(b.sum_bytes*100) Percent 33 | FROM sys.v_$sgastat a 34 | , (SELECT SUM(value)sum_bytes FROM sys.v_$sga) b 35 | ORDER BY bytes DESC 36 | / 37 | 38 | -------------------------------------------------------------------------------- /sql/perf_shared_pool_memory.sql: -------------------------------------------------------------------------------- 1 | -- +----------------------------------------------------------------------------+ 2 | -- | Jeffrey M. Hunter | 3 | -- | jhunter@idevelopment.info | 4 | -- | www.idevelopment.info | 5 | -- |----------------------------------------------------------------------------| 6 | -- | Copyright (c) 1998-2015 Jeffrey M. Hunter. All rights reserved. | 7 | -- |----------------------------------------------------------------------------| 8 | -- | DATABASE : Oracle | 9 | -- | FILE : perf_shared_pool_memory.sql | 10 | -- | CLASS : Tuning | 11 | -- | PURPOSE : Query the total memory in the Shared Pool and the amount of | 12 | -- | free memory. | 13 | -- | NOTE : As with any code, ensure to test this script in a development | 14 | -- | environment before attempting to run it in production. | 15 | -- +----------------------------------------------------------------------------+ 16 | 17 | SET LINESIZE 145 18 | SET PAGESIZE 9999 19 | 20 | COLUMN value FORMAT 999,999,999,999 HEADING "Shared Pool Size" 21 | COLUMN bytes FORMAT 999,999,999,999 HEADING "Free Bytes" 22 | COLUMN percentfree FORMAT 999 HEADING "Percent Free" 23 | 24 | SELECT 25 | TO_NUMBER(p.value) value 26 | , s.bytes bytes 27 | , (s.bytes/p.value) * 100 percentfree 28 | FROM 29 | v$sgastat s 30 | , v$parameter p 31 | WHERE 32 | s.name = 'free memory' 33 | AND s.pool = 'shared pool' 34 | AND p.name = 'shared_pool_size' 35 | / 36 | 37 | -------------------------------------------------------------------------------- /sql/perf_top_10_procedures.sql: -------------------------------------------------------------------------------- 1 | -- +----------------------------------------------------------------------------+ 2 | -- | Jeffrey M. Hunter | 3 | -- | jhunter@idevelopment.info | 4 | -- | www.idevelopment.info | 5 | -- |----------------------------------------------------------------------------| 6 | -- | Copyright (c) 1998-2015 Jeffrey M. Hunter. All rights reserved. | 7 | -- |----------------------------------------------------------------------------| 8 | -- | DATABASE : Oracle | 9 | -- | FILE : perf_top_10_procedures.sql | 10 | -- | CLASS : Tuning | 11 | -- | PURPOSE : Report on top 10 procedures with respect to usage . | 12 | -- | NOTE : As with any code, ensure to test this script in a development | 13 | -- | environment before attempting to run it in production. | 14 | -- +----------------------------------------------------------------------------+ 15 | 16 | SET LINESIZE 145 17 | SET PAGESIZE 9999 18 | SET VERIFY off 19 | 20 | COLUMN ptyp FORMAT a13 HEADING 'Object Type' 21 | COLUMN obj FORMAT a42 HEADING 'Object Name' 22 | COLUMN noe FORMAT 999,999,999,999,999 HEADING 'Number of Executions' 23 | 24 | BREAK ON report 25 | COMPUTE sum OF noe ON report 26 | 27 | SELECT 28 | ptyp 29 | , obj 30 | , 0 - exem noe 31 | FROM ( select distinct exem, ptyp, obj 32 | from ( select 33 | o.type ptyp 34 | , o.owner || '.' || o.name obj 35 | , 0 - o.executions exem 36 | from v$db_object_cache O 37 | where o.type in ('FUNCTION','PACKAGE','PACKAGE BODY','PROCEDURE','TRIGGER') 38 | ) 39 | ) 40 | WHERE rownum <= 10; 41 | 42 | -------------------------------------------------------------------------------- /sql/perf_top_10_tables.sql: -------------------------------------------------------------------------------- 1 | -- +----------------------------------------------------------------------------+ 2 | -- | Jeffrey M. Hunter | 3 | -- | jhunter@idevelopment.info | 4 | -- | www.idevelopment.info | 5 | -- |----------------------------------------------------------------------------| 6 | -- | Copyright (c) 1998-2015 Jeffrey M. Hunter. All rights reserved. | 7 | -- |----------------------------------------------------------------------------| 8 | -- | DATABASE : Oracle | 9 | -- | FILE : perf_top_10_tables.sql | 10 | -- | CLASS : Tuning | 11 | -- | PURPOSE : Report on top 10 tables with respect to usage and command type. | 12 | -- | NOTE : As with any code, ensure to test this script in a development | 13 | -- | environment before attempting to run it in production. | 14 | -- +----------------------------------------------------------------------------+ 15 | 16 | SET LINESIZE 145 17 | SET PAGESIZE 9999 18 | SET VERIFY off 19 | 20 | COLUMN ctyp FORMAT a13 HEADING 'Command Type' 21 | COLUMN obj FORMAT a30 HEADING 'Object Name' 22 | COLUMN noe FORMAT 999,999,999,999,999 HEADING 'Number of Executions' 23 | COLUMN gets FORMAT 999,999,999,999,999 HEADING 'Buffer Gets' 24 | COLUMN rowp FORMAT 999,999,999,999,999 HEADING 'Rows Processed' 25 | 26 | BREAK ON report 27 | COMPUTE sum OF noe ON report 28 | COMPUTE sum OF gets ON report 29 | COMPUTE sum OF rowp ON report 30 | 31 | SELECT 32 | ctyp 33 | , obj 34 | , 0 - exem noe 35 | , gets 36 | , rowp 37 | FROM ( 38 | select distinct exem, ctyp, obj, gets, rowp 39 | from (select 40 | DECODE( s.command_type 41 | , 2, 'Insert into ' 42 | , 3, 'Select from ' 43 | , 6, 'Update of ' 44 | , 7, 'Delete from ' 45 | , 26, 'Lock of ') ctyp 46 | , o.owner || '.' || o.name obj 47 | , SUM(0 - s.executions) exem 48 | , SUM(s.buffer_gets) gets 49 | , SUM(s.rows_processed) rowp 50 | from 51 | v$sql s 52 | , v$object_dependency d 53 | , v$db_object_cache o 54 | where 55 | s.command_type IN (2,3,6,7,26) 56 | and d.from_address = s.address 57 | and d.to_owner = o.owner 58 | and d.to_name = o.name 59 | and o.type = 'TABLE' 60 | group by 61 | s.command_type 62 | , o.owner 63 | , o.name 64 | ) 65 | ) 66 | WHERE rownum <= 10; 67 | 68 | -------------------------------------------------------------------------------- /sql/perf_top_sql_by_buffer_gets.sql: -------------------------------------------------------------------------------- 1 | -- +----------------------------------------------------------------------------+ 2 | -- | Jeffrey M. Hunter | 3 | -- | jhunter@idevelopment.info | 4 | -- | www.idevelopment.info | 5 | -- |----------------------------------------------------------------------------| 6 | -- | Copyright (c) 1998-2015 Jeffrey M. Hunter. All rights reserved. | 7 | -- |----------------------------------------------------------------------------| 8 | -- | DATABASE : Oracle | 9 | -- | FILE : perf_top_sql_by_buffer_gets.sql | 10 | -- | CLASS : Tuning | 11 | -- | PURPOSE : Report on top SQL statements ordered by most buffer gets. | 12 | -- | NOTE : As with any code, ensure to test this script in a development | 13 | -- | environment before attempting to run it in production. | 14 | -- +----------------------------------------------------------------------------+ 15 | 16 | SET LINESIZE 145 17 | SET PAGESIZE 9999 18 | SET VERIFY off 19 | 20 | COLUMN username FORMAT a18 HEADING 'Username' 21 | COLUMN buffer_gets FORMAT 999,999,999,999,999 HEADING 'Buffer Gets' 22 | COLUMN executions FORMAT 999,999,999,999,999 HEADING 'Executions' 23 | COLUMN gets_per_exec FORMAT 999,999,999,999,999 HEADING 'Gets / Executions' 24 | COLUMN sql HEADING 'SQL Statement' 25 | 26 | BREAK ON report 27 | COMPUTE sum OF buffer_gets ON report 28 | COMPUTE sum OF executions ON report 29 | COMPUTE sum OF gets_per_exec ON report 30 | 31 | prompt 32 | prompt ============================================= 33 | prompt SQL with buffer gets greater than 1000 34 | prompt ============================================= 35 | 36 | 37 | SELECT 38 | UPPER(b.username) username 39 | , a.buffer_gets buffer_gets 40 | , a.executions executions 41 | , a.buffer_gets / decode(a.executions, 0, 1, a.executions) gets_per_exec 42 | , sql_text || chr(10) || chr(10) sql 43 | FROM 44 | sys.v_$sqlarea a 45 | , dba_users b 46 | WHERE 47 | a.parsing_user_id = b.user_id 48 | AND a.buffer_gets > 1000 49 | AND b.username NOT IN ('SYS','SYSTEM') 50 | ORDER BY 51 | buffer_gets desc; 52 | 53 | -------------------------------------------------------------------------------- /sql/perf_top_sql_by_disk_reads.sql: -------------------------------------------------------------------------------- 1 | -- +----------------------------------------------------------------------------+ 2 | -- | Jeffrey M. Hunter | 3 | -- | jhunter@idevelopment.info | 4 | -- | www.idevelopment.info | 5 | -- |----------------------------------------------------------------------------| 6 | -- | Copyright (c) 1998-2015 Jeffrey M. Hunter. All rights reserved. | 7 | -- |----------------------------------------------------------------------------| 8 | -- | DATABASE : Oracle | 9 | -- | FILE : perf_top_sql_by_disk_reads.sql | 10 | -- | CLASS : Tuning | 11 | -- | PURPOSE : Report on top SQL statements ordered by disk reads. | 12 | -- | NOTE : As with any code, ensure to test this script in a development | 13 | -- | environment before attempting to run it in production. | 14 | -- +----------------------------------------------------------------------------+ 15 | 16 | SET LINESIZE 145 17 | SET PAGESIZE 9999 18 | SET VERIFY off 19 | 20 | COLUMN username FORMAT a18 HEADING 'Username' 21 | COLUMN disk_reads FORMAT 999,999,999,999,999 HEADING 'Disk Reads' 22 | COLUMN executions FORMAT 999,999,999,999,999 HEADING 'Executions' 23 | COLUMN reads_per_exec FORMAT 999,999,999,999,999 HEADING 'Reads / Executions' 24 | COLUMN sql HEADING 'SQL Statement' 25 | 26 | BREAK ON report 27 | COMPUTE sum OF disk_reads ON report 28 | COMPUTE sum OF executions ON report 29 | COMPUTE sum OF reads_per_exec ON report 30 | 31 | prompt 32 | prompt ============================================= 33 | prompt SQL with disk reads greater than 1000 34 | prompt ============================================= 35 | 36 | SELECT 37 | UPPER(b.username) username 38 | , a.disk_reads disk_reads 39 | , a.executions executions 40 | , a.disk_reads / decode(a.executions, 0, 1, a.executions) reads_per_exec 41 | , sql_text || chr(10) || chr(10) sql 42 | FROM 43 | sys.v_$sqlarea a 44 | , dba_users b 45 | WHERE 46 | a.parsing_user_id = b.user_id 47 | AND a.disk_reads > 1000 48 | AND b.username NOT IN ('SYS','SYSTEM') 49 | ORDER BY 50 | disk_reads desc; 51 | -------------------------------------------------------------------------------- /sql/rac_instances.sql: -------------------------------------------------------------------------------- 1 | -- +----------------------------------------------------------------------------+ 2 | -- | Jeffrey M. Hunter | 3 | -- | jhunter@idevelopment.info | 4 | -- | www.idevelopment.info | 5 | -- |----------------------------------------------------------------------------| 6 | -- | Copyright (c) 1998-2015 Jeffrey M. Hunter. All rights reserved. | 7 | -- |----------------------------------------------------------------------------| 8 | -- | DATABASE : Oracle | 9 | -- | FILE : rac_instances.sql | 10 | -- | CLASS : Real Application Clusters | 11 | -- | PURPOSE : Provide a summary report of all configured instances for the | 12 | -- | current clustered database. | 13 | -- | NOTE : As with any code, ensure to test this script in a development | 14 | -- | environment before attempting to run it in production. | 15 | -- +----------------------------------------------------------------------------+ 16 | 17 | SET TERMOUT OFF; 18 | COLUMN current_instance NEW_VALUE current_instance NOPRINT; 19 | SELECT rpad(sys_context('USERENV', 'INSTANCE_NAME'), 17) current_instance 20 | FROM dual; 21 | SET TERMOUT ON; 22 | 23 | PROMPT 24 | PROMPT +------------------------------------------------------------------------+ 25 | PROMPT | Report : Oracle RAC Instances | 26 | PROMPT | Instance : ¤t_instance | 27 | PROMPT +------------------------------------------------------------------------+ 28 | 29 | SET ECHO OFF 30 | SET FEEDBACK 6 31 | SET HEADING ON 32 | SET LINESIZE 180 33 | SET PAGESIZE 50000 34 | SET TERMOUT ON 35 | SET TIMING OFF 36 | SET TRIMOUT ON 37 | SET TRIMSPOOL ON 38 | SET VERIFY OFF 39 | 40 | CLEAR COLUMNS 41 | CLEAR BREAKS 42 | CLEAR COMPUTES 43 | 44 | COLUMN instance_name FORMAT a13 HEAD 'Instance|Name / Number' 45 | COLUMN thread# FORMAT 99999999 HEAD 'Thread #' 46 | COLUMN host_name FORMAT a28 HEAD 'Host|Name' 47 | COLUMN status FORMAT a6 HEAD 'Status' 48 | COLUMN startup_time FORMAT a20 HEAD 'Startup|Time' 49 | COLUMN database_status FORMAT a8 HEAD 'Database|Status' 50 | COLUMN archiver FORMAT a8 HEAD 'Archiver' 51 | COLUMN logins FORMAT a10 HEAD 'Logins?' 52 | COLUMN shutdown_pending FORMAT a8 HEAD 'Shutdown|Pending?' 53 | COLUMN active_state FORMAT a6 HEAD 'Active|State' 54 | COLUMN version HEAD 'Version' 55 | 56 | SELECT 57 | instance_name || ' (' || instance_number || ')' instance_name 58 | , thread# 59 | , host_name 60 | , status 61 | , TO_CHAR(startup_time, 'DD-MON-YYYY HH:MI:SS') startup_time 62 | , database_status 63 | , archiver 64 | , logins 65 | , shutdown_pending 66 | , active_state 67 | , version 68 | FROM 69 | gv$instance 70 | ORDER BY 71 | instance_number; 72 | 73 | -------------------------------------------------------------------------------- /sql/rc_databases.sql: -------------------------------------------------------------------------------- 1 | -- +----------------------------------------------------------------------------+ 2 | -- | Jeffrey M. Hunter | 3 | -- | jhunter@idevelopment.info | 4 | -- | www.idevelopment.info | 5 | -- |----------------------------------------------------------------------------| 6 | -- | Copyright (c) 1998-2015 Jeffrey M. Hunter. All rights reserved. | 7 | -- |----------------------------------------------------------------------------| 8 | -- | DATABASE : Oracle | 9 | -- | FILE : rc_databases.sql | 10 | -- | CLASS : Recovery Manager | 11 | -- | PURPOSE : Provide a listing of all databases found in the RMAN recovery | 12 | -- | catalog. | 13 | -- | NOTE : As with any code, ensure to test this script in a development | 14 | -- | environment before attempting to run it in production. | 15 | -- +----------------------------------------------------------------------------+ 16 | 17 | SET TERMOUT OFF; 18 | COLUMN current_instance NEW_VALUE current_instance NOPRINT; 19 | SELECT rpad(instance_name, 17) current_instance FROM v$instance; 20 | SET TERMOUT ON; 21 | 22 | PROMPT 23 | PROMPT +------------------------------------------------------------------------+ 24 | PROMPT | Report : RMAN Registered Databases | 25 | PROMPT | Instance : ¤t_instance | 26 | PROMPT | Note : Listing of all databases in the RMAN recovery catalog. | 27 | PROMPT +------------------------------------------------------------------------+ 28 | 29 | SET ECHO OFF 30 | SET FEEDBACK 6 31 | SET HEADING ON 32 | SET LINESIZE 180 33 | SET PAGESIZE 50000 34 | SET TERMOUT ON 35 | SET TIMING OFF 36 | SET TRIMOUT ON 37 | SET TRIMSPOOL ON 38 | SET VERIFY OFF 39 | 40 | CLEAR COLUMNS 41 | CLEAR BREAKS 42 | CLEAR COMPUTES 43 | 44 | COLUMN db_key FORMAT 999999 HEADING 'DB|Key' 45 | COLUMN dbinc_key FORMAT 999999 HEADING 'DB Inc|Key' 46 | COLUMN dbid HEADING 'DBID' 47 | COLUMN name FORMAT a12 HEADING 'Database|Name' 48 | COLUMN resetlogs_change_num HEADING 'Resetlogs|Change Num' 49 | COLUMN resetlogs FORMAT a21 HEADING 'Reset Logs|Date/Time' 50 | 51 | SELECT 52 | rd.db_key 53 | , rd.dbinc_key 54 | , rd.dbid 55 | , rd.name 56 | , rd.resetlogs_change# resetlogs_change_num 57 | , TO_CHAR(rd.resetlogs_time, 'DD-MON-YYYY HH24:MI:SS') resetlogs 58 | FROM 59 | rc_database rd 60 | ORDER BY 61 | rd.name 62 | / 63 | 64 | -------------------------------------------------------------------------------- /sql/rman_configuration.sql: -------------------------------------------------------------------------------- 1 | -- +----------------------------------------------------------------------------+ 2 | -- | Jeffrey M. Hunter | 3 | -- | jhunter@idevelopment.info | 4 | -- | www.idevelopment.info | 5 | -- |----------------------------------------------------------------------------| 6 | -- | Copyright (c) 1998-2015 Jeffrey M. Hunter. All rights reserved. | 7 | -- |----------------------------------------------------------------------------| 8 | -- | DATABASE : Oracle | 9 | -- | FILE : rman_configuration.sql | 10 | -- | CLASS : Recovery Manager | 11 | -- | PURPOSE : Provide a listing of all non-default RMAN configuration | 12 | -- | parameters. | 13 | -- | NOTE : As with any code, ensure to test this script in a development | 14 | -- | environment before attempting to run it in production. | 15 | -- +----------------------------------------------------------------------------+ 16 | 17 | SET TERMOUT OFF; 18 | COLUMN current_instance NEW_VALUE current_instance NOPRINT; 19 | SELECT rpad(instance_name, 17) current_instance FROM v$instance; 20 | SET TERMOUT ON; 21 | 22 | PROMPT 23 | PROMPT +------------------------------------------------------------------------+ 24 | PROMPT | Report : RMAN Configuration | 25 | PROMPT | Instance : ¤t_instance | 26 | PROMPT | Note : RMAN configuration settings that are not default. | 27 | PROMPT +------------------------------------------------------------------------+ 28 | 29 | SET ECHO OFF 30 | SET FEEDBACK 6 31 | SET HEADING ON 32 | SET LINESIZE 180 33 | SET PAGESIZE 50000 34 | SET TERMOUT ON 35 | SET TIMING OFF 36 | SET TRIMOUT ON 37 | SET TRIMSPOOL ON 38 | SET VERIFY OFF 39 | 40 | CLEAR COLUMNS 41 | CLEAR BREAKS 42 | CLEAR COMPUTES 43 | 44 | COLUMN name FORMAT a48 HEADING 'Name' 45 | COLUMN value FORMAT a55 HEADING 'Value' 46 | 47 | SELECT 48 | name 49 | , value 50 | FROM 51 | v$rman_configuration 52 | ORDER BY 53 | name 54 | / 55 | 56 | -------------------------------------------------------------------------------- /sql/rollback_users.sql: -------------------------------------------------------------------------------- 1 | -- +----------------------------------------------------------------------------+ 2 | -- | Jeffrey M. Hunter | 3 | -- | jhunter@idevelopment.info | 4 | -- | www.idevelopment.info | 5 | -- |----------------------------------------------------------------------------| 6 | -- | Copyright (c) 1998-2015 Jeffrey M. Hunter. All rights reserved. | 7 | -- |----------------------------------------------------------------------------| 8 | -- | DATABASE : Oracle | 9 | -- | FILE : rollback_users.sql | 10 | -- | CLASS : Rollback Segments | 11 | -- | PURPOSE : Query all active rollback segments and the sessions that are | 12 | -- | using them. | 13 | -- | NOTE : As with any code, ensure to test this script in a development | 14 | -- | environment before attempting to run it in production. | 15 | -- +----------------------------------------------------------------------------+ 16 | 17 | SET TERMOUT OFF; 18 | COLUMN current_instance NEW_VALUE current_instance NOPRINT; 19 | SELECT rpad(instance_name, 17) current_instance FROM v$instance; 20 | SET TERMOUT ON; 21 | 22 | PROMPT 23 | PROMPT +------------------------------------------------------------------------+ 24 | PROMPT | Report : Rollback Users | 25 | PROMPT | Instance : ¤t_instance | 26 | PROMPT +------------------------------------------------------------------------+ 27 | 28 | SET ECHO OFF 29 | SET FEEDBACK 6 30 | SET HEADING ON 31 | SET LINESIZE 180 32 | SET PAGESIZE 50000 33 | SET TERMOUT ON 34 | SET TIMING OFF 35 | SET TRIMOUT ON 36 | SET TRIMSPOOL ON 37 | SET VERIFY OFF 38 | 39 | CLEAR COLUMNS 40 | CLEAR BREAKS 41 | CLEAR COMPUTES 42 | 43 | COLUMN rollback_name FORMAT a25 HEADING 'Rollback Name' 44 | COLUMN sid FORMAT 999999 HEADING 'SID' 45 | COLUMN serial_id FORMAT 99999999 HEADING 'Serial ID' 46 | COLUMN session_status FORMAT a9 HEADING 'Status' 47 | COLUMN oracle_username FORMAT a18 HEADING 'Oracle User' 48 | COLUMN os_username FORMAT a18 HEADING 'O/S User' 49 | COLUMN session_machine FORMAT a30 HEADING 'Machine' TRUNC 50 | COLUMN session_program FORMAT a40 HEADING 'Session Program' TRUNC 51 | 52 | SELECT 53 | r.name rollback_name 54 | , s.sid sid 55 | , s.serial# serial_id 56 | , s.status session_status 57 | , s.username oracle_username 58 | , s.osuser os_username 59 | , s.machine session_machine 60 | , s.program session_program 61 | FROM 62 | v$lock l 63 | , v$rollname r 64 | , v$session s 65 | WHERE 66 | s.sid = l.sid 67 | AND TRUNC (l.id1(+)/65536) = r.usn 68 | AND l.type(+) = 'TX' 69 | AND l.lmode(+) = 6 70 | ORDER BY 71 | s.sid; 72 | 73 | -------------------------------------------------------------------------------- /sql/rsrc_plan_status_summary.sql: -------------------------------------------------------------------------------- 1 | -- +----------------------------------------------------------------------------+ 2 | -- | Jeffrey M. Hunter | 3 | -- | jhunter@idevelopment.info | 4 | -- | www.idevelopment.info | 5 | -- |----------------------------------------------------------------------------| 6 | -- | Copyright (c) 1998-2015 Jeffrey M. Hunter. All rights reserved. | 7 | -- |----------------------------------------------------------------------------| 8 | -- | DATABASE : Oracle | 9 | -- | FILE : rsrc_plan_status_summary.sql | 10 | -- | CLASS : Database Resource Manager | 11 | -- | PURPOSE : List all available resource plans and their status. | 12 | -- | NOTE : As with any code, ensure to test this script in a development | 13 | -- | environment before attempting to run it in production. | 14 | -- +----------------------------------------------------------------------------+ 15 | 16 | SET TERMOUT OFF; 17 | COLUMN current_instance NEW_VALUE current_instance NOPRINT; 18 | SELECT rpad(instance_name, 17) current_instance FROM v$instance; 19 | SET TERMOUT ON; 20 | 21 | PROMPT 22 | PROMPT +------------------------------------------------------------------------+ 23 | PROMPT | Report : Database Resource Manager - Resource Plan Summary Report | 24 | PROMPT | Instance : ¤t_instance | 25 | PROMPT +------------------------------------------------------------------------+ 26 | 27 | SET ECHO OFF 28 | SET FEEDBACK 6 29 | SET HEADING ON 30 | SET LINESIZE 180 31 | SET PAGESIZE 50000 32 | SET TERMOUT ON 33 | SET TIMING OFF 34 | SET TRIMOUT ON 35 | SET TRIMSPOOL ON 36 | SET VERIFY OFF 37 | 38 | CLEAR COLUMNS 39 | CLEAR BREAKS 40 | CLEAR COMPUTES 41 | 42 | COLUMN resource_plan_name FORMAT a30 HEAD 'Resource Plan Name' JUST left 43 | COLUMN comments FORMAT a50 HEAD 'Comments' JUST left WRAP 44 | COLUMN num_plan_directives FORMAT 999 HEAD '# of Plan|Directives' JUST left 45 | COLUMN status FORMAT a10 HEAD 'Status' JUST left 46 | COLUMN mandatory FORMAT a10 HEAD 'Mandatory?' JUST left 47 | COLUMN run_status FORMAT a11 HEAD 'Run|Status' JUST left 48 | 49 | SELECT 50 | a.plan resource_plan_name 51 | , a.comments comments 52 | , a.num_plan_directives num_plan_directives 53 | , a.status status 54 | , a.mandatory mandatory 55 | , DECODE(b.name, a.plan, 'Running', 'Not Running') run_status 56 | FROM 57 | dba_rsrc_plans a LEFT OUTER JOIN v$rsrc_plan b ON (a.plan = b.name) 58 | / 59 | 60 | -------------------------------------------------------------------------------- /sql/sec_default_passwords.sql: -------------------------------------------------------------------------------- 1 | -- +----------------------------------------------------------------------------+ 2 | -- | Jeffrey M. Hunter | 3 | -- | jhunter@idevelopment.info | 4 | -- | www.idevelopment.info | 5 | -- |----------------------------------------------------------------------------| 6 | -- | Copyright (c) 1998-2015 Jeffrey M. Hunter. All rights reserved. | 7 | -- |----------------------------------------------------------------------------| 8 | -- | DATABASE : Oracle | 9 | -- | FILE : sec_default_passwords.sql | 10 | -- | CLASS : Security | 11 | -- | PURPOSE : Checks Oracle created users that still have their default | 12 | -- | password. | 13 | -- | NOTE : As with any code, ensure to test this script in a development | 14 | -- | environment before attempting to run it in production. | 15 | -- +----------------------------------------------------------------------------+ 16 | 17 | SET TERMOUT OFF; 18 | COLUMN current_instance NEW_VALUE current_instance NOPRINT; 19 | SELECT rpad(instance_name, 17) current_instance FROM v$instance; 20 | SET TERMOUT ON; 21 | 22 | PROMPT 23 | PROMPT +------------------------------------------------------------------------+ 24 | PROMPT | Report : Security - Users with default database password | 25 | PROMPT | Instance : ¤t_instance | 26 | PROMPT +------------------------------------------------------------------------+ 27 | 28 | SET ECHO OFF 29 | SET FEEDBACK 6 30 | SET HEADING ON 31 | SET LINESIZE 180 32 | SET PAGESIZE 50000 33 | SET TERMOUT ON 34 | SET TIMING OFF 35 | SET TRIMOUT ON 36 | SET TRIMSPOOL ON 37 | SET VERIFY OFF 38 | 39 | CLEAR COLUMNS 40 | CLEAR BREAKS 41 | CLEAR COMPUTES 42 | 43 | COLUMN username FORMAT a30 HEADING 'User(s) with Default Password!' 44 | COLUMN account_status FORMAT a30 HEADING 'Account Status' 45 | 46 | SELECT 47 | username username 48 | , account_status account_status 49 | FROM dba_users 50 | WHERE password IN ( 51 | 'E066D214D5421CCC' -- dbsnmp 52 | , '24ABAB8B06281B4C' -- ctxsys 53 | , '72979A94BAD2AF80' -- mdsys 54 | , 'C252E8FA117AF049' -- odm 55 | , 'A7A32CD03D3CE8D5' -- odm_mtr 56 | , '88A2B2C183431F00' -- ordplugins 57 | , '7EFA02EC7EA6B86F' -- ordsys 58 | , '4A3BA55E08595C81' -- outln 59 | , 'F894844C34402B67' -- scott 60 | , '3F9FBD883D787341' -- wk_proxy 61 | , '79DF7A1BD138CF11' -- wk_sys 62 | , '7C9BA362F8314299' -- wmsys 63 | , '88D8364765FCE6AF' -- xdb 64 | , 'F9DA8977092B7B81' -- tracesvr 65 | , '9300C0977D7DC75E' -- oas_public 66 | , 'A97282CE3D94E29E' -- websys 67 | , 'AC9700FD3F1410EB' -- lbacsys 68 | , 'E7B5D92911C831E1' -- rman 69 | , 'AC98877DE1297365' -- perfstat 70 | , 'D4C5016086B2DC6A' -- sys 71 | , 'D4DF7931AB130E37') -- system 72 | ORDER BY 73 | username 74 | / 75 | 76 | -------------------------------------------------------------------------------- /sql/sec_roles.sql: -------------------------------------------------------------------------------- 1 | -- +----------------------------------------------------------------------------+ 2 | -- | Jeffrey M. Hunter | 3 | -- | jhunter@idevelopment.info | 4 | -- | www.idevelopment.info | 5 | -- |----------------------------------------------------------------------------| 6 | -- | Copyright (c) 1998-2015 Jeffrey M. Hunter. All rights reserved. | 7 | -- |----------------------------------------------------------------------------| 8 | -- | DATABASE : Oracle | 9 | -- | FILE : sec_roles.sql | 10 | -- | CLASS : Security | 11 | -- | PURPOSE : Report on all roles defined in the database and which users | 12 | -- | are assigned to that role. | 13 | -- | NOTE : As with any code, ensure to test this script in a development | 14 | -- | environment before attempting to run it in production. | 15 | -- +----------------------------------------------------------------------------+ 16 | 17 | SET TERMOUT OFF; 18 | COLUMN current_instance NEW_VALUE current_instance NOPRINT; 19 | SELECT rpad(instance_name, 17) current_instance FROM v$instance; 20 | SET TERMOUT ON; 21 | 22 | PROMPT 23 | PROMPT +------------------------------------------------------------------------+ 24 | PROMPT | Report : Security - All Roles | 25 | PROMPT | Instance : ¤t_instance | 26 | PROMPT +------------------------------------------------------------------------+ 27 | 28 | SET ECHO OFF 29 | SET FEEDBACK 6 30 | SET HEADING ON 31 | SET LINESIZE 180 32 | SET PAGESIZE 50000 33 | SET TERMOUT ON 34 | SET TIMING OFF 35 | SET TRIMOUT ON 36 | SET TRIMSPOOL ON 37 | SET VERIFY OFF 38 | 39 | CLEAR COLUMNS 40 | CLEAR BREAKS 41 | CLEAR COMPUTES 42 | 43 | COLUMN role FORMAT a30 HEAD 'Role Name' 44 | COLUMN grantee FORMAT a30 HEAD 'Grantee' 45 | COLUMN admin_option FORMAT a15 HEAD 'Admin Option?' 46 | COLUMN default_role FORMAT a15 HEAD 'Default Role?' 47 | 48 | BREAK ON role SKIP 2 49 | 50 | SELECT 51 | b.role 52 | , a.grantee 53 | , a.admin_option 54 | , a.default_role 55 | FROM 56 | dba_role_privs a 57 | , dba_roles b 58 | WHERE 59 | granted_role(+) = b.role 60 | ORDER BY 61 | b.role 62 | , a.grantee 63 | / 64 | 65 | -------------------------------------------------------------------------------- /sql/sp_list.sql: -------------------------------------------------------------------------------- 1 | -- +----------------------------------------------------------------------------+ 2 | -- | Jeffrey M. Hunter | 3 | -- | jhunter@idevelopment.info | 4 | -- | www.idevelopment.info | 5 | -- |----------------------------------------------------------------------------| 6 | -- | Copyright (c) 1998-2015 Jeffrey M. Hunter. All rights reserved. | 7 | -- |----------------------------------------------------------------------------| 8 | -- | DATABASE : Oracle | 9 | -- | FILE : sp_list.sql | 10 | -- | CLASS : Statspack | 11 | -- | PURPOSE : Provide a summary report of all Statspack snapshot IDs. | 12 | -- | NOTE : As with any code, ensure to test this script in a development | 13 | -- | environment before attempting to run it in production. | 14 | -- +----------------------------------------------------------------------------+ 15 | 16 | SET LINESIZE 145 17 | SET PAGESIZE 9999 18 | SET VERIFY off 19 | 20 | COLUMN snap_id HEAD 'Snap ID' 21 | COLUMN startup_time FORMAT a25 HEAD 'Startup Time' 22 | COLUMN snap_time FORMAT a25 HEAD 'Snap Time' 23 | 24 | BREAK on startup_time SKIP 1 25 | 26 | SELECT 27 | a.snap_id 28 | , TO_CHAR(a.startup_time, 'DD-MON-YYYY HH24:MI:SS') startup_time 29 | , TO_CHAR(a.snap_time, 'DD-MON-YYYY HH24:MI:SS') snap_time 30 | FROM 31 | stats$snapshot a 32 | , v$database b 33 | ORDER BY 34 | snap_id 35 | / 36 | 37 | -------------------------------------------------------------------------------- /sql/sp_parameters.sql: -------------------------------------------------------------------------------- 1 | -- +----------------------------------------------------------------------------+ 2 | -- | Jeffrey M. Hunter | 3 | -- | jhunter@idevelopment.info | 4 | -- | www.idevelopment.info | 5 | -- |----------------------------------------------------------------------------| 6 | -- | Copyright (c) 1998-2015 Jeffrey M. Hunter. All rights reserved. | 7 | -- |----------------------------------------------------------------------------| 8 | -- | DATABASE : Oracle | 9 | -- | FILE : sp_parameters.sql | 10 | -- | CLASS : Statspack | 11 | -- | PURPOSE : Provide a report of all Statspack parameters. | 12 | -- | NOTE : As with any code, ensure to test this script in a development | 13 | -- | environment before attempting to run it in production. | 14 | -- +----------------------------------------------------------------------------+ 15 | 16 | SET LINESIZE 145 17 | SET PAGESIZE 9999 18 | SET VERIFY off 19 | 20 | COLUMN name FORMAT a10 HEAD 'Database|Name' 21 | COLUMN snap_level FORMAT 999999 HEAD 'Snap|Level' 22 | COLUMN num_sql FORMAT 999,999 HEAD 'Number|SQL' 23 | COLUMN executions_th FORMAT 999,999 HEAD 'Executions|(TH)' 24 | COLUMN parse_calls_th FORMAT 999,999 HEAD 'Parse|Calls|(TH)' 25 | COLUMN disk_reads_th FORMAT 999,999 HEAD 'Disk|Reads|(TH)' 26 | COLUMN buffer_gets_th FORMAT 999,999 HEAD 'Buffer|Gets|(TH)' 27 | COLUMN sharable_mem_th FORMAT 999,999,999 HEAD 'Sharable|Mem.|(TH)' 28 | COLUMN version_count_th HEAD 'Version|Count|(TH)' 29 | COLUMN pin_statspack HEAD 'Pin|Statspack' 30 | COLUMN all_init HEAD 'All|Init' 31 | COLUMN last_modified HEAD 'Last|Modified' 32 | 33 | SELECT 34 | b.name 35 | , a.snap_level 36 | , a.num_sql 37 | , a.executions_th 38 | , a.parse_calls_th 39 | , a.disk_reads_th 40 | , a.buffer_gets_th 41 | , a.sharable_mem_th 42 | , a.version_count_th 43 | , a.pin_statspack 44 | , a.all_init 45 | , TO_CHAR(a.last_modified, 'DD-MON-YYYY HH24:MI:SS') last_modified 46 | FROM 47 | stats$statspack_parameter a 48 | , v$database b 49 | / 50 | 51 | -------------------------------------------------------------------------------- /sql/sp_purge.sql: -------------------------------------------------------------------------------- 1 | -- +----------------------------------------------------------------------------+ 2 | -- | Jeffrey M. Hunter | 3 | -- | jhunter@idevelopment.info | 4 | -- | www.idevelopment.info | 5 | -- |----------------------------------------------------------------------------| 6 | -- | Copyright (c) 1998-2015 Jeffrey M. Hunter. All rights reserved. | 7 | -- |----------------------------------------------------------------------------| 8 | -- | DATABASE : Oracle | 9 | -- | FILE : sp_purge.sql | 10 | -- | CLASS : Statspack | 11 | -- | PURPOSE : This is a wrapper script to the Oracle supplied sppurge.sql. | 12 | -- | NOTE : As with any code, ensure to test this script in a development | 13 | -- | environment before attempting to run it in production. | 14 | -- +----------------------------------------------------------------------------+ 15 | 16 | PROMPT 17 | PROMPT ========================================================================= 18 | PROMPT The following script is a wrapper script to the Oracle supplied SQL 19 | PROMPT script ?/rdbms/admin/sppurge.sql. 20 | PROMPT 21 | PROMPT The Oracle supplied script sppurge.sql will prompt the user for two 22 | PROMPT snapshot IDs; a low snapshot ID and a high snapshot ID. The script 23 | PROMPT will then remove all records contained in that range. 24 | PROMPT 25 | PROMPT Note that this script should be run as the owner of the 26 | PROMPT STATSPACK repository. 27 | PROMPT 28 | PROMPT Also note that a major portion of the sppurge.sql script is 29 | PROMPT commented out for performance reasons. Search for the string 30 | PROMPT "Delete any dangling SQLtext" and uncomment out the section 31 | PROMPT below it. 32 | PROMPT ========================================================================= 33 | PROMPT 34 | PROMPT Hit [ENTER] to continue or CTRL-C to cancel ... 35 | PAUSE 36 | 37 | @?/rdbms/admin/sppurge.sql 38 | -------------------------------------------------------------------------------- /sql/sp_snap.sql: -------------------------------------------------------------------------------- 1 | -- +----------------------------------------------------------------------------+ 2 | -- | Jeffrey M. Hunter | 3 | -- | jhunter@idevelopment.info | 4 | -- | www.idevelopment.info | 5 | -- |----------------------------------------------------------------------------| 6 | -- | Copyright (c) 1998-2015 Jeffrey M. Hunter. All rights reserved. | 7 | -- |----------------------------------------------------------------------------| 8 | -- | DATABASE : Oracle | 9 | -- | FILE : sp_snap.sql | 10 | -- | CLASS : Statspack | 11 | -- | PURPOSE : This is a wrapper script used to perform a manual Statspack | 12 | -- | snapshot. | 13 | -- | NOTE : As with any code, ensure to test this script in a development | 14 | -- | environment before attempting to run it in production. | 15 | -- +----------------------------------------------------------------------------+ 16 | 17 | PROMPT 18 | PROMPT ========================================================================= 19 | PROMPT The following script is a wrapper script to the Oracle supplied package 20 | PROMPT Statspack. 21 | PROMPT ========================================================================= 22 | PROMPT Note that this script should be run as the owner of the 23 | PROMPT STATSPACK repository. 24 | PROMPT ========================================================================= 25 | PROMPT 26 | 27 | EXEC statspack.snap; 28 | 29 | -------------------------------------------------------------------------------- /sql/sp_trunc.sql: -------------------------------------------------------------------------------- 1 | -- +----------------------------------------------------------------------------+ 2 | -- | Jeffrey M. Hunter | 3 | -- | jhunter@idevelopment.info | 4 | -- | www.idevelopment.info | 5 | -- |----------------------------------------------------------------------------| 6 | -- | Copyright (c) 1998-2015 Jeffrey M. Hunter. All rights reserved. | 7 | -- |----------------------------------------------------------------------------| 8 | -- | DATABASE : Oracle | 9 | -- | FILE : sp_trunc.sql | 10 | -- | CLASS : Statspack | 11 | -- | PURPOSE : Wrapper script to truncate all Statspack tables. | 12 | -- | NOTE : As with any code, ensure to test this script in a development | 13 | -- | environment before attempting to run it in production. | 14 | -- +----------------------------------------------------------------------------+ 15 | 16 | @?/rdbms/admin/sptrunc.sql 17 | 18 | -------------------------------------------------------------------------------- /sql/undo_contention.sql: -------------------------------------------------------------------------------- 1 | -- +----------------------------------------------------------------------------+ 2 | -- | Jeffrey M. Hunter | 3 | -- | jhunter@idevelopment.info | 4 | -- | www.idevelopment.info | 5 | -- |----------------------------------------------------------------------------| 6 | -- | Copyright (c) 1998-2015 Jeffrey M. Hunter. All rights reserved. | 7 | -- |----------------------------------------------------------------------------| 8 | -- | DATABASE : Oracle | 9 | -- | FILE : undo_contention.sql | 10 | -- | CLASS : Undo Segments | 11 | -- | PURPOSE : Undo contention report. This script is RAC enabled. | 12 | -- | NOTE : As with any code, ensure to test this script in a development | 13 | -- | environment before attempting to run it in production. | 14 | -- +----------------------------------------------------------------------------+ 15 | 16 | SET TERMOUT OFF; 17 | COLUMN current_instance NEW_VALUE current_instance NOPRINT; 18 | SELECT rpad(instance_name, 17) current_instance FROM v$instance; 19 | SET TERMOUT ON; 20 | 21 | PROMPT 22 | PROMPT +------------------------------------------------------------------------+ 23 | PROMPT | Report : Undo Contention | 24 | PROMPT | Instance : ¤t_instance | 25 | PROMPT +------------------------------------------------------------------------+ 26 | 27 | SET ECHO OFF 28 | SET FEEDBACK 6 29 | SET HEADING ON 30 | SET LINESIZE 180 31 | SET PAGESIZE 50000 32 | SET TERMOUT ON 33 | SET TIMING OFF 34 | SET TRIMOUT ON 35 | SET TRIMSPOOL ON 36 | SET VERIFY OFF 37 | 38 | CLEAR COLUMNS 39 | CLEAR BREAKS 40 | CLEAR COMPUTES 41 | 42 | COLUMN instance_name FORMAT a10 HEAD 'Instance' 43 | COLUMN class FORMAT a18 HEADING 'Class' 44 | COLUMN ratio HEADING 'Wait Ratio' 45 | 46 | BREAK ON instance_name SKIP 2 47 | 48 | SELECT 49 | i.instance_name instance_name 50 | , w.class class 51 | , ROUND(100*(w.count/SUM(s.value)),8) ratio 52 | FROM 53 | gv$instance i 54 | , gv$waitstat w 55 | , gv$sysstat s 56 | WHERE 57 | i.inst_id = w.inst_id 58 | AND i.inst_id = s.inst_id 59 | AND w.class IN ( 'system undo header' 60 | , 'system undo block' 61 | , 'undo header' 62 | , 'undo block' 63 | ) 64 | AND s.name IN ('db block gets', 'consistent gets') 65 | GROUP BY 66 | i.instance_name 67 | , w.class 68 | , w.count 69 | ORDER BY 70 | i.instance_name 71 | , w.class; 72 | 73 | -------------------------------------------------------------------------------- /sql/wm_get_workspace.sql: -------------------------------------------------------------------------------- 1 | -- +----------------------------------------------------------------------------+ 2 | -- | Jeffrey M. Hunter | 3 | -- | jhunter@idevelopment.info | 4 | -- | www.idevelopment.info | 5 | -- |----------------------------------------------------------------------------| 6 | -- | Copyright (c) 1998-2015 Jeffrey M. Hunter. All rights reserved. | 7 | -- |----------------------------------------------------------------------------| 8 | -- | DATABASE : Oracle | 9 | -- | FILE : wm_get_workspace.sql | 10 | -- | CLASS : Workspace Manager | 11 | -- | PURPOSE : Identify the current workspace. | 12 | -- | NOTE : As with any code, ensure to test this script in a development | 13 | -- | environment before attempting to run it in production. | 14 | -- +----------------------------------------------------------------------------+ 15 | 16 | SET TERMOUT OFF; 17 | COLUMN current_instance NEW_VALUE current_instance NOPRINT; 18 | SELECT rpad(sys_context('USERENV', 'INSTANCE_NAME'), 17) current_instance 19 | FROM dual; 20 | SET TERMOUT ON; 21 | 22 | PROMPT 23 | PROMPT +------------------------------------------------------------------------+ 24 | PROMPT | Report : Get Current Workspace | 25 | PROMPT | Instance : ¤t_instance | 26 | PROMPT +------------------------------------------------------------------------+ 27 | 28 | SET ECHO OFF 29 | SET FEEDBACK 6 30 | SET HEADING ON 31 | SET LINESIZE 180 32 | SET PAGESIZE 50000 33 | SET TERMOUT ON 34 | SET TIMING OFF 35 | SET TRIMOUT ON 36 | SET TRIMSPOOL ON 37 | SET VERIFY OFF 38 | 39 | CLEAR COLUMNS 40 | CLEAR BREAKS 41 | CLEAR COMPUTES 42 | 43 | COLUMN getworkspace FORMAT a50 HEADING "Current Workspace" 44 | 45 | SELECT dbms_wm.getworkspace 46 | FROM dual; 47 | 48 | --------------------------------------------------------------------------------