├── LICENSE ├── README.md ├── backup_rman.sh ├── dbbatch.sh ├── fix_index_naming.sql ├── free.sql ├── functions.sh ├── index_drops.sql ├── index_monitoring.sql ├── index_selectivity.sql ├── index_shrinks.sql ├── indexes.sql ├── install_OPatch.sh ├── oracle_aliases.sh ├── ownership_conflict.sql ├── redo.sql ├── rman_db_params.txt.sample ├── rman_params.txt.sample └── sample_rman_crontab /LICENSE: -------------------------------------------------------------------------------- 1 | GNU GENERAL PUBLIC LICENSE 2 | Version 2, June 1991 3 | 4 | Copyright (C) 1989, 1991 Free Software Foundation, Inc., 5 | 51 Franklin Street, Fifth Floor, Boston, MA 02110-1301 USA 6 | Everyone is permitted to copy and distribute verbatim copies 7 | of this license document, but changing it is not allowed. 8 | 9 | Preamble 10 | 11 | The licenses for most software are designed to take away your 12 | freedom to share and change it. By contrast, the GNU General Public 13 | License is intended to guarantee your freedom to share and change free 14 | software--to make sure the software is free for all its users. This 15 | General Public License applies to most of the Free Software 16 | Foundation's software and to any other program whose authors commit to 17 | using it. (Some other Free Software Foundation software is covered by 18 | the GNU Lesser General Public License instead.) You can apply it to 19 | your programs, too. 20 | 21 | When we speak of free software, we are referring to freedom, not 22 | price. Our General Public Licenses are designed to make sure that you 23 | have the freedom to distribute copies of free software (and charge for 24 | this service if you wish), that you receive source code or can get it 25 | if you want it, that you can change the software or use pieces of it 26 | in new free programs; and that you know you can do these things. 27 | 28 | To protect your rights, we need to make restrictions that forbid 29 | anyone to deny you these rights or to ask you to surrender the rights. 30 | These restrictions translate to certain responsibilities for you if you 31 | distribute copies of the software, or if you modify it. 32 | 33 | For example, if you distribute copies of such a program, whether 34 | gratis or for a fee, you must give the recipients all the rights that 35 | you have. You must make sure that they, too, receive or can get the 36 | source code. And you must show them these terms so they know their 37 | rights. 38 | 39 | We protect your rights with two steps: (1) copyright the software, and 40 | (2) offer you this license which gives you legal permission to copy, 41 | distribute and/or modify the software. 42 | 43 | Also, for each author's protection and ours, we want to make certain 44 | that everyone understands that there is no warranty for this free 45 | software. If the software is modified by someone else and passed on, we 46 | want its recipients to know that what they have is not the original, so 47 | that any problems introduced by others will not reflect on the original 48 | authors' reputations. 49 | 50 | Finally, any free program is threatened constantly by software 51 | patents. We wish to avoid the danger that redistributors of a free 52 | program will individually obtain patent licenses, in effect making the 53 | program proprietary. To prevent this, we have made it clear that any 54 | patent must be licensed for everyone's free use or not licensed at all. 55 | 56 | The precise terms and conditions for copying, distribution and 57 | modification follow. 58 | 59 | GNU GENERAL PUBLIC LICENSE 60 | TERMS AND CONDITIONS FOR COPYING, DISTRIBUTION AND MODIFICATION 61 | 62 | 0. This License applies to any program or other work which contains 63 | a notice placed by the copyright holder saying it may be distributed 64 | under the terms of this General Public License. The "Program", below, 65 | refers to any such program or work, and a "work based on the Program" 66 | means either the Program or any derivative work under copyright law: 67 | that is to say, a work containing the Program or a portion of it, 68 | either verbatim or with modifications and/or translated into another 69 | language. (Hereinafter, translation is included without limitation in 70 | the term "modification".) Each licensee is addressed as "you". 71 | 72 | Activities other than copying, distribution and modification are not 73 | covered by this License; they are outside its scope. The act of 74 | running the Program is not restricted, and the output from the Program 75 | is covered only if its contents constitute a work based on the 76 | Program (independent of having been made by running the Program). 77 | Whether that is true depends on what the Program does. 78 | 79 | 1. You may copy and distribute verbatim copies of the Program's 80 | source code as you receive it, in any medium, provided that you 81 | conspicuously and appropriately publish on each copy an appropriate 82 | copyright notice and disclaimer of warranty; keep intact all the 83 | notices that refer to this License and to the absence of any warranty; 84 | and give any other recipients of the Program a copy of this License 85 | along with the Program. 86 | 87 | You may charge a fee for the physical act of transferring a copy, and 88 | you may at your option offer warranty protection in exchange for a fee. 89 | 90 | 2. You may modify your copy or copies of the Program or any portion 91 | of it, thus forming a work based on the Program, and copy and 92 | distribute such modifications or work under the terms of Section 1 93 | above, provided that you also meet all of these conditions: 94 | 95 | a) You must cause the modified files to carry prominent notices 96 | stating that you changed the files and the date of any change. 97 | 98 | b) You must cause any work that you distribute or publish, that in 99 | whole or in part contains or is derived from the Program or any 100 | part thereof, to be licensed as a whole at no charge to all third 101 | parties under the terms of this License. 102 | 103 | c) If the modified program normally reads commands interactively 104 | when run, you must cause it, when started running for such 105 | interactive use in the most ordinary way, to print or display an 106 | announcement including an appropriate copyright notice and a 107 | notice that there is no warranty (or else, saying that you provide 108 | a warranty) and that users may redistribute the program under 109 | these conditions, and telling the user how to view a copy of this 110 | License. (Exception: if the Program itself is interactive but 111 | does not normally print such an announcement, your work based on 112 | the Program is not required to print an announcement.) 113 | 114 | These requirements apply to the modified work as a whole. If 115 | identifiable sections of that work are not derived from the Program, 116 | and can be reasonably considered independent and separate works in 117 | themselves, then this License, and its terms, do not apply to those 118 | sections when you distribute them as separate works. But when you 119 | distribute the same sections as part of a whole which is a work based 120 | on the Program, the distribution of the whole must be on the terms of 121 | this License, whose permissions for other licensees extend to the 122 | entire whole, and thus to each and every part regardless of who wrote it. 123 | 124 | Thus, it is not the intent of this section to claim rights or contest 125 | your rights to work written entirely by you; rather, the intent is to 126 | exercise the right to control the distribution of derivative or 127 | collective works based on the Program. 128 | 129 | In addition, mere aggregation of another work not based on the Program 130 | with the Program (or with a work based on the Program) on a volume of 131 | a storage or distribution medium does not bring the other work under 132 | the scope of this License. 133 | 134 | 3. You may copy and distribute the Program (or a work based on it, 135 | under Section 2) in object code or executable form under the terms of 136 | Sections 1 and 2 above provided that you also do one of the following: 137 | 138 | a) Accompany it with the complete corresponding machine-readable 139 | source code, which must be distributed under the terms of Sections 140 | 1 and 2 above on a medium customarily used for software interchange; or, 141 | 142 | b) Accompany it with a written offer, valid for at least three 143 | years, to give any third party, for a charge no more than your 144 | cost of physically performing source distribution, a complete 145 | machine-readable copy of the corresponding source code, to be 146 | distributed under the terms of Sections 1 and 2 above on a medium 147 | customarily used for software interchange; or, 148 | 149 | c) Accompany it with the information you received as to the offer 150 | to distribute corresponding source code. (This alternative is 151 | allowed only for noncommercial distribution and only if you 152 | received the program in object code or executable form with such 153 | an offer, in accord with Subsection b above.) 154 | 155 | The source code for a work means the preferred form of the work for 156 | making modifications to it. For an executable work, complete source 157 | code means all the source code for all modules it contains, plus any 158 | associated interface definition files, plus the scripts used to 159 | control compilation and installation of the executable. However, as a 160 | special exception, the source code distributed need not include 161 | anything that is normally distributed (in either source or binary 162 | form) with the major components (compiler, kernel, and so on) of the 163 | operating system on which the executable runs, unless that component 164 | itself accompanies the executable. 165 | 166 | If distribution of executable or object code is made by offering 167 | access to copy from a designated place, then offering equivalent 168 | access to copy the source code from the same place counts as 169 | distribution of the source code, even though third parties are not 170 | compelled to copy the source along with the object code. 171 | 172 | 4. You may not copy, modify, sublicense, or distribute the Program 173 | except as expressly provided under this License. Any attempt 174 | otherwise to copy, modify, sublicense or distribute the Program is 175 | void, and will automatically terminate your rights under this License. 176 | However, parties who have received copies, or rights, from you under 177 | this License will not have their licenses terminated so long as such 178 | parties remain in full compliance. 179 | 180 | 5. You are not required to accept this License, since you have not 181 | signed it. However, nothing else grants you permission to modify or 182 | distribute the Program or its derivative works. These actions are 183 | prohibited by law if you do not accept this License. Therefore, by 184 | modifying or distributing the Program (or any work based on the 185 | Program), you indicate your acceptance of this License to do so, and 186 | all its terms and conditions for copying, distributing or modifying 187 | the Program or works based on it. 188 | 189 | 6. Each time you redistribute the Program (or any work based on the 190 | Program), the recipient automatically receives a license from the 191 | original licensor to copy, distribute or modify the Program subject to 192 | these terms and conditions. You may not impose any further 193 | restrictions on the recipients' exercise of the rights granted herein. 194 | You are not responsible for enforcing compliance by third parties to 195 | this License. 196 | 197 | 7. If, as a consequence of a court judgment or allegation of patent 198 | infringement or for any other reason (not limited to patent issues), 199 | conditions are imposed on you (whether by court order, agreement or 200 | otherwise) that contradict the conditions of this License, they do not 201 | excuse you from the conditions of this License. If you cannot 202 | distribute so as to satisfy simultaneously your obligations under this 203 | License and any other pertinent obligations, then as a consequence you 204 | may not distribute the Program at all. For example, if a patent 205 | license would not permit royalty-free redistribution of the Program by 206 | all those who receive copies directly or indirectly through you, then 207 | the only way you could satisfy both it and this License would be to 208 | refrain entirely from distribution of the Program. 209 | 210 | If any portion of this section is held invalid or unenforceable under 211 | any particular circumstance, the balance of the section is intended to 212 | apply and the section as a whole is intended to apply in other 213 | circumstances. 214 | 215 | It is not the purpose of this section to induce you to infringe any 216 | patents or other property right claims or to contest validity of any 217 | such claims; this section has the sole purpose of protecting the 218 | integrity of the free software distribution system, which is 219 | implemented by public license practices. Many people have made 220 | generous contributions to the wide range of software distributed 221 | through that system in reliance on consistent application of that 222 | system; it is up to the author/donor to decide if he or she is willing 223 | to distribute software through any other system and a licensee cannot 224 | impose that choice. 225 | 226 | This section is intended to make thoroughly clear what is believed to 227 | be a consequence of the rest of this License. 228 | 229 | 8. If the distribution and/or use of the Program is restricted in 230 | certain countries either by patents or by copyrighted interfaces, the 231 | original copyright holder who places the Program under this License 232 | may add an explicit geographical distribution limitation excluding 233 | those countries, so that distribution is permitted only in or among 234 | countries not thus excluded. In such case, this License incorporates 235 | the limitation as if written in the body of this License. 236 | 237 | 9. The Free Software Foundation may publish revised and/or new versions 238 | of the General Public License from time to time. Such new versions will 239 | be similar in spirit to the present version, but may differ in detail to 240 | address new problems or concerns. 241 | 242 | Each version is given a distinguishing version number. If the Program 243 | specifies a version number of this License which applies to it and "any 244 | later version", you have the option of following the terms and conditions 245 | either of that version or of any later version published by the Free 246 | Software Foundation. If the Program does not specify a version number of 247 | this License, you may choose any version ever published by the Free Software 248 | Foundation. 249 | 250 | 10. If you wish to incorporate parts of the Program into other free 251 | programs whose distribution conditions are different, write to the author 252 | to ask for permission. For software which is copyrighted by the Free 253 | Software Foundation, write to the Free Software Foundation; we sometimes 254 | make exceptions for this. Our decision will be guided by the two goals 255 | of preserving the free status of all derivatives of our free software and 256 | of promoting the sharing and reuse of software generally. 257 | 258 | NO WARRANTY 259 | 260 | 11. BECAUSE THE PROGRAM IS LICENSED FREE OF CHARGE, THERE IS NO WARRANTY 261 | FOR THE PROGRAM, TO THE EXTENT PERMITTED BY APPLICABLE LAW. EXCEPT WHEN 262 | OTHERWISE STATED IN WRITING THE COPYRIGHT HOLDERS AND/OR OTHER PARTIES 263 | PROVIDE THE PROGRAM "AS IS" WITHOUT WARRANTY OF ANY KIND, EITHER EXPRESSED 264 | OR IMPLIED, INCLUDING, BUT NOT LIMITED TO, THE IMPLIED WARRANTIES OF 265 | MERCHANTABILITY AND FITNESS FOR A PARTICULAR PURPOSE. THE ENTIRE RISK AS 266 | TO THE QUALITY AND PERFORMANCE OF THE PROGRAM IS WITH YOU. SHOULD THE 267 | PROGRAM PROVE DEFECTIVE, YOU ASSUME THE COST OF ALL NECESSARY SERVICING, 268 | REPAIR OR CORRECTION. 269 | 270 | 12. IN NO EVENT UNLESS REQUIRED BY APPLICABLE LAW OR AGREED TO IN WRITING 271 | WILL ANY COPYRIGHT HOLDER, OR ANY OTHER PARTY WHO MAY MODIFY AND/OR 272 | REDISTRIBUTE THE PROGRAM AS PERMITTED ABOVE, BE LIABLE TO YOU FOR DAMAGES, 273 | INCLUDING ANY GENERAL, SPECIAL, INCIDENTAL OR CONSEQUENTIAL DAMAGES ARISING 274 | OUT OF THE USE OR INABILITY TO USE THE PROGRAM (INCLUDING BUT NOT LIMITED 275 | TO LOSS OF DATA OR DATA BEING RENDERED INACCURATE OR LOSSES SUSTAINED BY 276 | YOU OR THIRD PARTIES OR A FAILURE OF THE PROGRAM TO OPERATE WITH ANY OTHER 277 | PROGRAMS), EVEN IF SUCH HOLDER OR OTHER PARTY HAS BEEN ADVISED OF THE 278 | POSSIBILITY OF SUCH DAMAGES. 279 | 280 | END OF TERMS AND CONDITIONS 281 | 282 | How to Apply These Terms to Your New Programs 283 | 284 | If you develop a new program, and you want it to be of the greatest 285 | possible use to the public, the best way to achieve this is to make it 286 | free software which everyone can redistribute and change under these terms. 287 | 288 | To do so, attach the following notices to the program. It is safest 289 | to attach them to the start of each source file to most effectively 290 | convey the exclusion of warranty; and each file should have at least 291 | the "copyright" line and a pointer to where the full notice is found. 292 | 293 | Oracle database administration scripts 294 | Copyright (C) 2013 Sean Scott 295 | 296 | This program is free software; you can redistribute it and/or modify 297 | it under the terms of the GNU General Public License as published by 298 | the Free Software Foundation; either version 2 of the License, or 299 | (at your option) any later version. 300 | 301 | This program is distributed in the hope that it will be useful, 302 | but WITHOUT ANY WARRANTY; without even the implied warranty of 303 | MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the 304 | GNU General Public License for more details. 305 | 306 | You should have received a copy of the GNU General Public License along 307 | with this program; if not, write to the Free Software Foundation, Inc., 308 | 51 Franklin Street, Fifth Floor, Boston, MA 02110-1301 USA. 309 | 310 | Also add information on how to contact you by electronic and paper mail. 311 | 312 | If the program is interactive, make it output a short notice like this 313 | when it starts in an interactive mode: 314 | 315 | Gnomovision version 69, Copyright (C) year name of author 316 | Gnomovision comes with ABSOLUTELY NO WARRANTY; for details type `show w'. 317 | This is free software, and you are welcome to redistribute it 318 | under certain conditions; type `show c' for details. 319 | 320 | The hypothetical commands `show w' and `show c' should show the appropriate 321 | parts of the General Public License. Of course, the commands you use may 322 | be called something other than `show w' and `show c'; they could even be 323 | mouse-clicks or menu items--whatever suits your program. 324 | 325 | You should also get your employer (if you work as a programmer) or your 326 | school, if any, to sign a "copyright disclaimer" for the program, if 327 | necessary. Here is a sample; alter the names: 328 | 329 | Yoyodyne, Inc., hereby disclaims all copyright interest in the program 330 | `Gnomovision' (which makes passes at compilers) written by James Hacker. 331 | 332 | {signature of Ty Coon}, 1 April 1989 333 | Ty Coon, President of Vice 334 | 335 | This General Public License does not permit incorporating your program into 336 | proprietary programs. If your program is a subroutine library, you may 337 | consider it more useful to permit linking proprietary applications with the 338 | library. If this is what you want to do, use the GNU Lesser General 339 | Public License instead of this License. 340 | -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | oracle 2 | ====== 3 | 4 | Oracle database administration scripts 5 | -------------------------------------------------------------------------------- /backup_rman.sh: -------------------------------------------------------------------------------- 1 | #!/bin/sh 2 | 3 | # backup_rman.sh 4 | # Copyright (C) 2004, 2013, 2016 Sean Scott 5 | 6 | # This program is free software; you can redistribute it and/or modify 7 | # it under the terms of the GNU General Public License as published by 8 | # the Free Software Foundation; either version 2 of the License, or 9 | # (at your option) any later version. 10 | 11 | # This program is distributed in the hope that it will be useful, 12 | # but WITHOUT ANY WARRANTY; without even the implied warranty of 13 | # MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the 14 | # GNU General Public License for more details. 15 | 16 | # You should have received a copy of the GNU General Public License along 17 | # with this program; if not, write to the Free Software Foundation, Inc., 18 | # 51 Franklin Street, Fifth Floor, Boston, MA 02110-1301 USA. 19 | 20 | # This is a highly adaptable RMAN backup script for Oracle 10g/11g databases. 21 | # It facilitates a variety of backup options and was designed to be a single 22 | # source for performing a variety of cron-based Oracle database backups. 23 | # 24 | # FEATURES 25 | # Disk or tape backup destinations 26 | # Full, incremental (differential/cumulative), copy, archive log, spfile backup options 27 | # Multiple channels; channel size limits; channel options 28 | # Control deletion of archive logs by backup count and age in hours 29 | # Compression, encryption, optimization, parallelization, validation options 30 | # Failure and success notification options 31 | # Pre- and post- backup SQL execution options 32 | # Preview (no backup) option 33 | # Directory cleanup options 34 | # Builds a recovery script with each backup 35 | # Extensive before/after diagnostic logging of the Oracle environment including: 36 | # filesystem, memory, semaphores, processes 37 | 38 | # Requires $HOME/dbbatch.sh, $DBA/functions.sh 39 | 40 | # Execute batch profile (since crontab's default is to not run .profile) 41 | . /mnt/dbscripts/dbbatch.sh 42 | . $DBA/functions.sh 43 | 44 | # See if nawk should be used instead of awk 45 | (nawk '{ print ; exit }' /etc/passwd) > /dev/null 2>&1 46 | if [ ${?} -eq 0 ] 47 | then cmd=nawk 48 | else cmd=awk 49 | fi 50 | 51 | #**************************************************************** 52 | # Functions 53 | #**************************************************************** 54 | error() 55 | { 56 | echo "$@" 1>&2 57 | if [ -n "$email_failure" ] 58 | then 59 | if [ -n "$logmail" ] 60 | then mailto $email_failure $logmail "BACKUP FAILURE while $phase of $sid database on $machine" FILE 61 | else mailto $email_failure "$1" "BACKUP FAILURE while $phase of $sid database on $machine" 62 | fi 63 | fi 64 | exit 1 65 | } 66 | 67 | usage() 68 | { 69 | version 70 | echo "usage: $PROGRAM -d oracle_sid -b backuptype [-l directory | -T SBT_channel] " 71 | echo " [-acefFhHprRsStvx] --catalog --compress --deletearchive --encrypt " 72 | echo " [-i level {--id}] --maxopenfiles files --maxsetsize kbytes " 73 | echo " --nocrosscheck --nodeleteexpired --nodeleteobsolete --preview " 74 | echo " --skipreadonly --spfile --validate " 75 | echo " " 76 | echo "Arguments:" 77 | echo " -d oracle_sid SID of the database to back up " 78 | echo " -b type of backup (full, incremental, copy, archivelog, spfile) " 79 | echo " -l directory local directory to store the files " 80 | echo " -T SBT_channel SBT channel to allocate for tape backups (default is disk backup) " 81 | echo " " 82 | echo "Optional arguments: " 83 | echo " -a channels channels to allocate for backup operations (default 1) " 84 | echo " -B backup_count minimum count of backups to device of archive logs before deletion " 85 | echo " -c kbytes channel size limit, in kbytes (default 2GB) " 86 | echo " -C hours minimum age of archive logs (in hours) before deletion " 87 | echo " --catalog string catalog database connection string or path to file with connection information " 88 | echo " --compress compression backup " 89 | echo " --deletearchive delete archivelog input (overrides settings of log backup count and age) " 90 | echo " -e email comma delimited list of emails to be used for failure notification " 91 | echo " --encrypt encrypt backup " 92 | echo " -f files per backup set, database backups (default 5) " 93 | echo " -F files per backup set, archive log backups (default 50) " 94 | echo " -h display this message " 95 | echo " -H ORACLE_HOME define an ORACLE_HOME directory " 96 | echo " -i level level for incremental backup, 0-4 (default 0) " 97 | echo " --ic perform a cumulative incremental backup " 98 | echo " --maxopenfiles maximum number of open files (default 1) " 99 | echo " --maxsetsize kbytes maximum backup set size, in kbytes (default 2GB) " 100 | echo " --nocrosscheck do not crosscheck backups " 101 | echo " --nodeleteexpired do not delete expired backups " 102 | echo " --nodeleteobsolete do not delete obsolete backups " 103 | echo " -p prefix backup files base name (default SID_backup) " 104 | echo " -P PARMS parms option for channel allocation " 105 | echo " --pre SQL sql commands to be run before backup starts " 106 | echo " --post SQL sql commands to be run after backup completes " 107 | echo " --preview preview the backup; generate files, but don't execute them " 108 | echo " -r redundancy level of backup redundancy (default 1) " 109 | echo " -R retention minimum days of backup retention (default 14) " 110 | echo " --resync resync catalog " 111 | echo " -s suffix backup files extension (default bak) " 112 | echo " -S email comma delimited list of emails to be used for success notification " 113 | echo " --skipreadonly skip read-only tablespaces " 114 | echo " --spfile backup the spfile " 115 | echo " --summary log summary information only " 116 | echo " -t tag backup set tag " 117 | echo " --trace backup control file to trace file " 118 | echo " -v display version information " 119 | echo " --validate validate backup when complete " 120 | echo " -x days cleanup logs and scripts more than days old " 121 | echo " " 122 | } 123 | 124 | usage_and_exit() 125 | { 126 | usage 127 | exit $1 128 | } 129 | 130 | version() 131 | { 132 | echo " " 133 | echo "$PROGRAM version $VERSION" 134 | echo " " 135 | } 136 | 137 | do_dbenv() 138 | { 139 | # Get environment settings from the database. This is much easier than trying to figure 140 | # out the current version, discover the trace location (ORACLE_BASE/admin/SID/bdump vs 141 | # ADR_HOME or a non-standard location). We want the node in the event that we're backing 142 | # up spfiles from more than one node of a RAC instance, so that they can be destinguished 143 | # and don't overwrite each other. 144 | 145 | dbenv=$(mktemp) 146 | if [ $? -ne 0 ] 147 | then error "Could not create the Oracle environment file" 148 | fi 149 | 150 | $ORACLE_HOME/bin/sqlplus -s "/ as sysdba" < $dbenv 151 | set heading off 152 | set feedback off 153 | select '#!/bin/sh' from dual; 154 | select 'export tracedir=' || value from v\$parameter where name = 'background_dump_dest'; 155 | select 'export dbuname=' || value from v\$parameter where name = 'db_unique_name'; 156 | select 'export node=' || value from v\$parameter where name = 'instance_number'; 157 | select 'export nls=' || a.value || '_' || b.value || '.' || c.value 158 | from v\$nls_parameters a, v\$nls_parameters b, v\$nls_parameters c 159 | where a.parameter = 'NLS_LANGUAGE' and b.parameter = 'NLS_TERRITORY' and c.parameter = 'NLS_CHARACTERSET'; 160 | exit 161 | EOF 162 | source $dbenv 163 | rm $dbenv 164 | } 165 | 166 | do_logdelete() 167 | { 168 | if [ "$backdir" ] 169 | # We're backing up to disk... 170 | then logdest="disk" 171 | else logdest="SBT_TAPE" 172 | fi 173 | 174 | # Determine if there's a retention count of log backups requested 175 | if [ "$logbackupcount" ] 176 | then logdeletecount=" backed up $logbackupcount times to $logdest" 177 | fi 178 | 179 | # Determine if there's a retention age of log backups requested 180 | if [ "$logbackuphours" ] 181 | then logdeletehours=" completed before 'sysdate - $logbackuphours / 24'" 182 | fi 183 | 184 | logdelete="delete force noprompt expired archivelog all $logdeletecount $logdeletehours;" 185 | } 186 | 187 | do_backup_script() 188 | { 189 | # Write the backup and recovery scripts based on the user entries. 190 | echo "!#/bin/sh" | tee $restorescript 191 | echo "export ORACLE_BASE=$ORACLE_BASE" | tee -a $restorescript 192 | echo "export ORACLE_HOME=$ORACLE_HOME" | tee -a $restorescript 193 | echo "export ORACLE_SID=$sid" | tee -a $restorescript 194 | echo "export CLASSPATH=$CLASSPATH" | tee -a $restorescript 195 | echo "export LD_LIBRARY_PATH=$LD_LIBRARY_PATH" | tee -a $restorescript 196 | echo "export ORAENV_ASK=NO" | tee -a $restorescript 197 | # The following addresses a bug where RMAN duplicate fails due to missing NLS_LANG 198 | echo "export NLS_LANG=$nls" | tee -a $restorescript 199 | echo "export PATH=$PATH" | tee -a $restorescript 200 | echo ". $ORACLE_HOME/bin/oraenv" | tee -a $restorescript 201 | echo "$ORACLE_HOME/bin/rman target / $catalog <&2 96 | OPTARG="$OPTOPT"; 97 | OPTOPT="?" 98 | return 1; 99 | fi 100 | OPTIND=$[OPTIND+1] # skip option's argument 101 | return 0 102 | ;; 103 | "--$OPTOPT="*) 104 | if [ "$opttype" = ";" ]; 105 | then # error: must not have arguments 106 | let OPTERR && echo "$0: error: $OPTOPT must not have arguments" >&2 107 | OPTARG="$OPTOPT" 108 | OPTOPT="?" 109 | return 1 110 | fi 111 | OPTARG=${o#"--$OPTOPT="} 112 | return 0 113 | ;; 114 | esac 115 | else # short-named option 116 | case "$o" in 117 | "-$OPTOPT") 118 | unset OPTOFS 119 | [ "$opttype" != ":" ] && return 0 120 | OPTARG="$2" 121 | 122 | # Added test on following argument being an option identified by '-' this way # 123 | # the routine no longer takes options as an argument thus breaking error # 124 | # detection. 2004-04-04 by raphael at oninet dot pt # 125 | 126 | if [ -z "$OPTARG" -o "${OPTARG:0:1}" = "-" ] ; 127 | then 128 | echo "$0: error: -$OPTOPT must have an argument" >&2 129 | OPTARG="$OPTOPT" 130 | OPTOPT="?" 131 | return 1 132 | fi 133 | OPTIND=$[OPTIND+1] # skip option's argument 134 | return 0 135 | ;; 136 | "-$OPTOPT"*) 137 | if [ $opttype = ";" ] 138 | then # an option with no argument is in a chain of options 139 | OPTOFS="$OPTOFS?" # move to the next option in the chain 140 | OPTIND=$[OPTIND-1] # the chain still has other options 141 | return 0 142 | else 143 | unset OPTOFS 144 | OPTARG="${o#-$OPTOPT}" 145 | return 0 146 | fi 147 | ;; 148 | esac 149 | fi 150 | done 151 | echo "$0: error: invalid option: $o" 152 | fi; fi 153 | OPTOPT="?" 154 | unset OPTARG 155 | return 1 156 | } 157 | 158 | function optlistex 159 | { 160 | local l="$1" 161 | local m # mask 162 | local r # to store result 163 | while [ ${#m} -lt $[${#l}-1] ]; do m="$m?"; done # create a "???..." mask 164 | while [ -n "$l" ] 165 | do 166 | r="${r:+"$r "}${l%$m}" # append the first character of $l to $r 167 | l="${l#?}" # cut the first charecter from $l 168 | m="${m#?}" # cut one "?" sign from m 169 | if [ -n "${l%%[^:.;]*}" ] 170 | then # a special character (";", ".", or ":") was found 171 | r="$r${l%$m}" # append it to $r 172 | l="${l#?}" # cut the special character from l 173 | m="${m#?}" # cut one more "?" sign 174 | fi 175 | done 176 | echo $r 177 | } 178 | 179 | function getopt() 180 | { 181 | local optlist=`optlistex "$1"` 182 | shift 183 | getoptex "$optlist" "$@" 184 | return $? 185 | } 186 | 187 | mailto() 188 | { 189 | # mailto to body subject file 190 | if [ $# -eq 0 ] 191 | then echo "No email provided" 192 | else 193 | subj= 194 | file= 195 | 196 | if [ $# -ge 3 ] 197 | then subj=$3 198 | fi 199 | 200 | if [ $# -ge 4 ] 201 | then file=$4 202 | fi 203 | 204 | if [ "$file" != "FILE" ] 205 | then 206 | if [ "$subj" != "" ] 207 | then echo "$2" | mail -s "$3" $1 208 | else echo "$2" | mail $1 209 | fi 210 | else 211 | if [ -r $2 ] 212 | then 213 | if [ "$subj" != "" ] 214 | then cat "$2" | mail -s "$3" $1 215 | else cat "$2" | mail $1 216 | fi 217 | else 218 | if [ "$subj" != "" ] 219 | then echo "Error: Trying to mail non-existent file: $2" | mail -s "$3" $1 220 | else echo "Error: Trying to mail non-existent file: $2" | mail $1 221 | fi 222 | fi 223 | fi 224 | fi 225 | } 226 | 227 | valid_db() 228 | { 229 | if [ ! $# ] 230 | then echo "Error - No SID specified" 231 | return 1 232 | fi 233 | mysid=`fixcase $1` 234 | 235 | if [ -r /etc/oratab ] 236 | then ORATAB=/etc/oratab 237 | else 238 | if [ -r /var/opt/oracle/oratab ] 239 | then ORATAB=/var/opt/oracle/oratab 240 | else echo "Error - Can't find an oratab file" 241 | return 1 242 | fi 243 | fi 244 | 245 | for ORACLE_SID in `grep -v "^#" $ORATAB | grep -v "^$" | cut -d: -f1` 246 | do 247 | if [ "$ORACLE_SID" = "$mysid" ] 248 | then return 0 249 | fi 250 | done 251 | echo "Error - Invalid database SID: $1" 252 | return 1 253 | } 254 | 255 | db_status() 256 | { 257 | ps $PS_OPTS | grep -v grep | grep -i ora_pmon_$1 >/dev/null 258 | if [ $? -eq 0 ] 259 | then return 0 260 | else return 1 261 | fi 262 | } 263 | -------------------------------------------------------------------------------- /index_drops.sql: -------------------------------------------------------------------------------- 1 | /* index_drops.sql 2 | Copyright (C) 2013 Sean Scott 3 | 4 | This program is free software; you can redistribute it and/or modify 5 | it under the terms of the GNU General Public License as published by 6 | the Free Software Foundation; either version 2 of the License, or 7 | (at your option) any later version. 8 | 9 | This program is distributed in the hope that it will be useful, 10 | but WITHOUT ANY WARRANTY; without even the implied warranty of 11 | MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the 12 | GNU General Public License for more details. 13 | 14 | You should have received a copy of the GNU General Public License along 15 | with this program; if not, write to the Free Software Foundation, Inc., 16 | 51 Franklin Street, Fifth Floor, Boston, MA 02110-1301 USA. 17 | 18 | These scripts provide a variety of different methods for looking at indexes that 19 | are candidates to be dropped. */ 20 | 21 | /* Indexes that don't have statistics */ 22 | select index_name 23 | from dba_indexes 24 | where index_name not in ( 25 | select index_name 26 | from v$segment_statistics); 27 | 28 | /* Indexes that are candidates for being dropped (not part of a constraint, not in 29 | an execution plan). */ 30 | select owner 31 | , index_name 32 | from dba_indexes 33 | where (owner, index_name) not in ( 34 | select owner, object_name 35 | from dba_hist_sql_plan 36 | where object_type = 'INDEX') --Exclude indexes that have been used in an execution plan. 37 | and (owner, index_name) not in ( 38 | select owner, index_name 39 | from dba_constraints 40 | where constraint_type in ('P','R')) --Exclude indexes that are part of a referential integrity constraint. 41 | order by 1; 42 | 43 | column cardinality format 999,999,999.90 44 | column sample_pct format 999,999,999.90 45 | 46 | /* Indexes that may be empty/droppable because they have 0 distinct keys, 0 rows, 47 | and aren't part of a PK/FK constraint. */ 48 | select owner 49 | , index_name 50 | , uniqueness 51 | , index_type 52 | , num_rows 53 | , decode(distinct_keys, NULL, 0, 0, 0, distinct_keys/num_rows) as cardinality 54 | , status 55 | , last_analyzed 56 | from dba_indexes 57 | where distinct_keys = 0 58 | and num_rows = 0 59 | and (owner, index_name) not in ( 60 | select owner, index_name 61 | from dba_constraints 62 | where constraint_type in ('P','R')); 63 | 64 | /* Small indexes that may be droppable because they're small and not used in a 65 | FK/PK constraint. Sometimes, a FTS may be as good or better than doing an index 66 | lookup against a tiny index/table. */ 67 | select owner 68 | , index_name 69 | , pct_free 70 | , logging 71 | , index_type 72 | , distinct_keys 73 | , num_rows 74 | , decode(distinct_keys, NULL, 0, 0, 0, distinct_keys/num_rows) as cardinality 75 | , status 76 | , last_analyzed 77 | , decode(distinct_keys, NULL, 0, 0, 0, distinct_keys/sample_size) * 100 as sample_pct 78 | from dba_indexes 79 | where (distinct_keys < 20 80 | or num_rows < 20) 81 | and distinct_keys != 0 82 | and num_rows != 0 83 | and (owner, index_name) not in ( 84 | select owner, index_name 85 | from dba_constraints 86 | where constraint_type in ('P','R')) 87 | order by 8 desc, 1, 2; 88 | 89 | select owner 90 | , index_name 91 | , pct_free 92 | , logging 93 | , index_type 94 | , distinct_keys 95 | , num_rows 96 | , decode(distinct_keys, NULL, 0, 0, 0, distinct_keys/num_rows) as cardinality 97 | , status 98 | , last_analyzed 99 | , decode(distinct_keys, NULL, 0, 0, 0, distinct_keys/sample_size) * 100 as sample_pct 100 | from dba_indexes 101 | where uniqueness != 'UNIQUE' 102 | and distinct_keys != 0 103 | and num_rows != 0 104 | order by 8 desc, 1, 2; 105 | 106 | /* Identify potentially redundant indexes based on predicates */ 107 | column column_name_list format a50 108 | column column_name_list_dup format a50 109 | 110 | select /*+ rule */ 111 | a.table_owner 112 | , a.table_name 113 | , a.index_owner 114 | , a.index_name 115 | , column_name_list 116 | , column_name_list_dup 117 | , dup duplicate_indexes 118 | , i.uniqueness 119 | , i.partitioned 120 | , i.leaf_blocks 121 | , i.distinct_keys 122 | , i.num_rows 123 | , i.clustering_factor 124 | from ( 125 | select table_owner 126 | , table_name 127 | , index_owner 128 | , index_name 129 | , column_name_list_dup 130 | , dup 131 | , max(dup) OVER (partition by table_owner, table_name, index_name) dup_mx 132 | from ( 133 | select table_owner 134 | , table_name 135 | , index_owner 136 | , index_name 137 | , substr(SYS_CONNECT_BY_PATH(column_name, ','), 2) column_name_list_dup 138 | , dup 139 | from ( 140 | select index_owner 141 | , index_name 142 | , table_owner 143 | , table_name 144 | , column_name 145 | , count(1) OVER (partition by index_owner, index_name) cnt 146 | , ROW_NUMBER () OVER (partition by index_owner, index_name order by column_position) as seq 147 | , count(1) OVER (partition by table_owner, table_name, column_name, column_position) as dup 148 | from dba_ind_columns 149 | where index_owner in ('&OWNER')) 150 | where dup != 1 151 | start with seq = 1 152 | connect by prior seq + 1 = seq 153 | and prior index_owner = index_owner 154 | and prior index_name = index_name)) a 155 | , ( 156 | select table_owner 157 | , table_name 158 | , index_owner 159 | , index_name 160 | , substr(SYS_CONNECT_BY_PATH(column_name, ','), 2) column_name_list 161 | from ( 162 | select index_owner 163 | , index_name 164 | , table_owner 165 | , table_name 166 | , column_name 167 | , count(1) OVER (partition by index_owner, index_name) cnt 168 | , ROW_NUMBER () OVER (partition by index_owner, index_name order by column_position) as seq 169 | from dba_ind_columns 170 | where index_owner in ('&OWNER')) 171 | where seq = cnt 172 | start with seq = 1 173 | connect by prior seq + 1 = seq 174 | and prior index_owner = index_owner 175 | and prior index_name = index_name) b 176 | , dba_indexes i 177 | where a.dup = a.dup_mx 178 | and a.index_owner = b.index_owner 179 | and a.index_name = b.index_name 180 | and a.index_owner = i.owner 181 | and a.index_name = i.index_name 182 | order by a.table_owner 183 | , a.table_name 184 | , column_name_list_dup; 185 | -------------------------------------------------------------------------------- /index_monitoring.sql: -------------------------------------------------------------------------------- 1 | -- Index monitoring usage scripts 2 | 3 | select 'alter index '||owner||'.'||index_name||' monitoring usage;' 4 | from dba_indexes 5 | where owner = '&OWNER'; 6 | 7 | select index_name 8 | , table_name 9 | , monitoring 10 | , used 11 | , start_monitoring 12 | , end_monitoring 13 | from v$object_usage; 14 | 15 | select p.object_name 16 | , p.operation 17 | , p.options 18 | count(*) 19 | from dba_hist_sql_plan p 20 | , dba_hist_sqlstat s 21 | where p.object_owner != 'SYS' 22 | and p.operation like '%INDEX%' 23 | and p.sql_id = s.sql_id 24 | group by p.object_name 25 | , p.operation 26 | , p.options 27 | order by 1, 2, 3; 28 | 29 | column mbytes format 999,999,999.990 30 | select io.name 31 | , t.name 32 | , decode(bitand(i.flags, 65536), 0, 'NO', 'YES') 33 | , decode(bitand(ou.flags, 1), 0, 'NO', 'YES') 34 | , ou.start_monitoring 35 | --, ou.end_monitoring 36 | , sum(ds.bytes/1024/1024) as mbytes 37 | from sys.obj$ io 38 | , sys.obj$ t 39 | , sys.ind$ i 40 | , sys.object_usage ou 41 | , dba_users du 42 | , dba_segments ds 43 | where io.owner# = du.user_id 44 | and du.username = '&OWNER' 45 | and du.username = ds.owner 46 | and io.name = ds.segment_name 47 | and i.obj# = ou.obj# 48 | and io.obj# = ou.obj# 49 | and t.obj# = i.bo# 50 | group by io.name 51 | , t.name 52 | , decode(bitand(i.flags, 65536), 0, 'NO', 'YES') 53 | , decode(bitand(ou.flags, 1), 0, 'NO', 'YES') 54 | , ou.start_monitoring 55 | order by 6 asc; 56 | -------------------------------------------------------------------------------- /index_selectivity.sql: -------------------------------------------------------------------------------- 1 | /* index_selectivity.sql 2 | Copyright (C) 2013 Sean Scott 3 | 4 | This program is free software; you can redistribute it and/or modify 5 | it under the terms of the GNU General Public License as published by 6 | the Free Software Foundation; either version 2 of the License, or 7 | (at your option) any later version. 8 | 9 | This program is distributed in the hope that it will be useful, 10 | but WITHOUT ANY WARRANTY; without even the implied warranty of 11 | MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the 12 | GNU General Public License for more details. 13 | 14 | You should have received a copy of the GNU General Public License along 15 | with this program; if not, write to the Free Software Foundation, Inc., 16 | 51 Franklin Street, Fifth Floor, Boston, MA 02110-1301 USA. 17 | 18 | Report on the selectivity and size of indexes. */ 19 | 20 | select i.owner 21 | , i.table_name 22 | , i.index_name 23 | , to_char((i.distinct_keys / i.num_rows) * 100, '999.99') selectivity 24 | , i.distinct_keys 25 | , i.num_rows 26 | , i.index_type 27 | , s.bytes / 1024 / 1024 MB 28 | , c.constraint_name 29 | from dba_indexes i 30 | , dba_segments s 31 | , dba_constraints c 32 | where i.num_rows > 0 33 | and i.distinct_keys / i.num_rows < 0.2 34 | and i.owner not in ('SYS','SYSTEM','SYSMAN') 35 | and i.owner = s.owner 36 | and i.index_name = s.segment_name 37 | and s.segment_type = 'INDEX' 38 | and i.owner = c.index_owner (+) 39 | and i.index_name = c.index_name (+) 40 | order by i.distinct_keys asc 41 | , s.bytes desc 42 | , i.distinct_keys / i.num_rows; 43 | -------------------------------------------------------------------------------- /index_shrinks.sql: -------------------------------------------------------------------------------- 1 | /* index_shrinks.sql 2 | Copyright (C) 2013 Sean Scott 3 | 4 | This program is free software; you can redistribute it and/or modify 5 | it under the terms of the GNU General Public License as published by 6 | the Free Software Foundation; either version 2 of the License, or 7 | (at your option) any later version. 8 | 9 | This program is distributed in the hope that it will be useful, 10 | but WITHOUT ANY WARRANTY; without even the implied warranty of 11 | MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the 12 | GNU General Public License for more details. 13 | 14 | You should have received a copy of the GNU General Public License along 15 | with this program; if not, write to the Free Software Foundation, Inc., 16 | 51 Franklin Street, Fifth Floor, Boston, MA 02110-1301 USA. 17 | 18 | Build out alter index shrink space statements for a particular tablespace. */ 19 | 20 | column table_owner format a12 21 | column table_name format a30 22 | column index_name format a30 23 | column table_size_mb format 999,999.90 24 | column index_size_mb format 999,999.90 25 | select 'alter index ' || table_owner || '.' || index_name || ' shrink space COMPACT;;' || chr(10) || 26 | 'alter index ' || table_owner || '.' || index_name || ' shrink space;' || chr(10) || 27 | '-- extents = ' || extents || ' size = ' || index_size_mb || chr(10) || 28 | 'select extents, bytes / 1024 / 1024 from dba_segments where owner = ''' || table_owner || ''' and segment_name = ''' || index_name || ''';' 29 | from ( 30 | select t.owner as table_owner 31 | , t.segment_name as table_name 32 | , sum(t.bytes) / 1024 / 1024 as table_size_mb 33 | , i.segment_name as index_name 34 | , sum(i.bytes) / 1024 / 1024 as index_size_mb 35 | , i.extents 36 | from dba_segments t 37 | , dba_segments i 38 | , dba_indexes x 39 | where t.owner = x.table_owner 40 | and t.segment_name = x.table_name 41 | and i.owner = x.owner 42 | and i.segment_name = x.index_name 43 | and t.tablespace_name = '&TABLESPACE_NAME' 44 | group by t.owner 45 | , t.segment_name 46 | , i.segment_name 47 | , i.extents 48 | having sum(t.bytes) < sum(i.bytes) 49 | order by 5 asc); 50 | -------------------------------------------------------------------------------- /indexes.sql: -------------------------------------------------------------------------------- 1 | /* indexes.sql 2 | Copyright (C) 2001, 2013 Sean Scott oracle_sean@mac.com 3 | 4 | This program is free software; you can redistribute it and/or modify 5 | it under the terms of the GNU General Public License as published by 6 | the Free Software Foundation; either version 2 of the License, or 7 | (at your option) any later version. 8 | 9 | This program is distributed in the hope that it will be useful, 10 | but WITHOUT ANY WARRANTY; without even the implied warranty of 11 | MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the 12 | GNU General Public License for more details. 13 | 14 | You should have received a copy of the GNU General Public License along 15 | with this program; if not, write to the Free Software Foundation, Inc., 16 | 51 Franklin Street, Fifth Floor, Boston, MA 02110-1301 USA. 17 | Report information on indexes for a given table. 18 | 19 | Oracle hasn't taken their own advice regarding the LONG datatype and 20 | is still using it in DBA_IND_EXPRESSIONS, else I would have wrapped the 21 | contents of function-based indexes into the column_name column with a 22 | decode. One day I'll address the technical debt and write up something 23 | to handle this. */ 24 | 25 | set lines 265 26 | column column_name format a30 27 | column segment_size format 999,999 heading SIZE 28 | column tablespace_name format a25 29 | column column_expression format a40 heading '' 30 | column clustering_factor heading CLUSTERING 31 | break on index_name on segment_size on uniqueness on index_type on visibility on tablespace_name on blevel on leaf_blocks on distinct_keys on num_rows on clustering_factor 32 | select c.index_name 33 | , s.bytes/1024/1024 as segment_size 34 | , i.uniqueness 35 | , i.index_type 36 | , i.visibility 37 | , i.tablespace_name 38 | , i.blevel 39 | , i.leaf_blocks 40 | , i.distinct_keys 41 | , i.num_rows 42 | , i.clustering_factor 43 | , c.column_name 44 | , e.column_expression 45 | from dba_ind_columns c 46 | , dba_ind_expressions e 47 | , dba_segments s 48 | , dba_indexes i 49 | where i.table_owner = upper('&OWNER') 50 | and i.table_name = upper('&TABLE') 51 | and i.owner = s.owner 52 | and i.index_name = s.segment_name 53 | and i.owner = c.index_owner 54 | and i.index_name = c.index_name 55 | and s.segment_type = 'INDEX' 56 | and c.index_owner = e.index_owner (+) 57 | and c.index_name = e.index_name (+) 58 | and c.column_position = e.column_position (+) 59 | order by i.index_name 60 | , c.column_position; 61 | clear breaks 62 | -------------------------------------------------------------------------------- /install_OPatch.sh: -------------------------------------------------------------------------------- 1 | #!/bin/sh 2 | 3 | # Update the OPatch directory for the local Oracle installation. It backs up the current OPatch 4 | # directory to OPatch_old and copies the response file (assuming the file name is the default ocm.rsp). 5 | 6 | # For GRID 11.2.0 installations and above, this must be run as the grid owner. 7 | 8 | # Pass four command line arguments: 9 | # $1 ORACLE_HOME 10 | # $2 GRID_HOME 11 | # $3 Full patch and file name for the OPatch patch. 12 | # $4 The location to unzip the OPatch patch unzip. 13 | 14 | # The patch is usually p6880880_VERSION_OS.zip 15 | 16 | su - oracle -c "rm -fR $4/OPatch" 17 | su - oracle -c "unzip $1 -d $4/" 18 | 19 | su - oracle -c "mv -f $ORACLE_HOME/OPatch $ORACLE_HOME/OPatch_old" 20 | mv -f $GRID_HOME/OPatch $GRID_HOME/OPatch_old 21 | 22 | su - oracle -c "cp -fpr $4/OPatch $ORACLE_HOME/" 23 | cp -fpr /oracle/software/OPatch $GRID_HOME/ 24 | 25 | su - oracle -c "cp -fpr $ORACLE_HOME/OPatch_old/ocm.rsp $ORACLE_HOME/OPatch/" 26 | cp -fpr $GRID_HOME/OPatch_old/ocm.rsp $GRID_HOME/OPatch/ 27 | 28 | su - oracle -c "$ORACLE_HOME/OPatch/opatch version" 29 | su - oracle -c "$GRID_HOME/OPatch/opatch version" 30 | 31 | # Example usage: 32 | # ./update_opatch.sh /oracle/product/11.2.0/db_1/ /grid/11.2.0/ ~/p6880880_112000_Linux-x86-64.zip /oracle/software 33 | -------------------------------------------------------------------------------- /oracle_aliases.sh: -------------------------------------------------------------------------------- 1 | # oracle_aliases.sh 2 | # Copyright (C) 2004, 2013 Sean Scott oracle_sean@mac.com 3 | 4 | # This program is free software; you can redistribute it and/or modify 5 | # it under the terms of the GNU General Public License as published by 6 | # the Free Software Foundation; either version 2 of the License, or 7 | # (at your option) any later version. 8 | 9 | # This program is distributed in the hope that it will be useful, 10 | # but WITHOUT ANY WARRANTY; without even the implied warranty of 11 | # MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the 12 | # GNU General Public License for more details. 13 | 14 | # You should have received a copy of the GNU General Public License along 15 | # with this program; if not, write to the Free Software Foundation, Inc., 16 | # 51 Franklin Street, Fifth Floor, Boston, MA 02110-1301 USA. 17 | 18 | # Useful aliases for working with Oracle databases 19 | alias goalert="cd /oracle/diag/$INST_TYPE/$ORACLE_DBNAME/$ORACLE_SID/trace" 20 | alias goinit="cd $ORACLE_HOME/dbs" 21 | alias gotns="cd $ORACLE_HOME/network/admin" 22 | alias h="fc -l" 23 | alias ll="ls -latr" 24 | alias psg="ps -ef|grep" 25 | alias sqlasm='sqlplus "/as sysasm"' 26 | -------------------------------------------------------------------------------- /ownership_conflict.sql: -------------------------------------------------------------------------------- 1 | /* ownership_conflict.sql 2 | Copyright (C) 2013 Sean Scott 3 | 4 | This program is free software; you can redistribute it and/or modify 5 | it under the terms of the GNU General Public License as published by 6 | the Free Software Foundation; either version 2 of the License, or 7 | (at your option) any later version. 8 | 9 | This program is distributed in the hope that it will be useful, 10 | but WITHOUT ANY WARRANTY; without even the implied warranty of 11 | MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the 12 | GNU General Public License for more details. 13 | 14 | You should have received a copy of the GNU General Public License along 15 | with this program; if not, write to the Free Software Foundation, Inc., 16 | 51 Franklin Street, Fifth Floor, Boston, MA 02110-1301 USA. 17 | 18 | These scripts provide a variety of different methods for looking at indexes that 19 | are candidates to be dropped. */ 20 | 21 | column MB format 999,999,999.990 22 | column objects format 999,999 23 | break on owner skip 1 on tablespace_name on segment_type on report 24 | compute sum of objects on owner on report 25 | compute sum of MB on owner 26 | compute sum of objects on report 27 | compute sum of MB on report 28 | 29 | /* Get the total space used and count of objects for all non-system owners. */ 30 | select owner 31 | , tablespace_name 32 | , segment_type 33 | , count(segment_name) objects 34 | , sum(bytes) / 1024 / 1024 MB 35 | from dba_segments 36 | where owner not in ('SYS', 'SYSTEM', 'SYSMAN', 'WMSYS', 'TSMSYS', 'OUTLN', 'DBSNMP') 37 | group by owner 38 | , tablespace_name 39 | , segment_type 40 | order by 1, 2, 3; 41 | 42 | /* Find objects that aren't created under the correct owner/schema. */ 43 | break on owner on segment_type on tablespace_name on segment_name skip 1 44 | select s.owner 45 | , s.segment_name 46 | , s.segment_type 47 | , s.tablespace_name 48 | , decode(s.owner, r.owner, NULL, r.owner) r_owner 49 | , decode(s.owner, r.owner, NULL, r.tablespace_name) r_tbs 50 | from dba_segments s 51 | , dba_segments r 52 | where s.segment_name (+) = r.segment_name 53 | and s.segment_name like 'XX%' 54 | and (s.owner not like 'XX%' 55 | or s.tablespace_name not like 'XX%') 56 | order by 2, 3, 1, 5; 57 | 58 | /* Indexes that aren't owned by the table owner. */ 59 | select owner 60 | , index_name 61 | , table_owner 62 | , table_name 63 | from dba_indexes 64 | where owner != table_owner; 65 | -------------------------------------------------------------------------------- /redo.sql: -------------------------------------------------------------------------------- 1 | /* redo.sql 2 | Copyright (C) 2001, 2013 Sean Scott oracle_sean@mac.com 3 | 4 | This program is free software; you can redistribute it and/or modify 5 | it under the terms of the GNU General Public License as published by 6 | the Free Software Foundation; either version 2 of the License, or 7 | (at your option) any later version. 8 | 9 | This program is distributed in the hope that it will be useful, 10 | but WITHOUT ANY WARRANTY; without even the implied warranty of 11 | MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the 12 | GNU General Public License for more details. 13 | 14 | You should have received a copy of the GNU General Public License along 15 | with this program; if not, write to the Free Software Foundation, Inc., 16 | 51 Franklin Street, Fifth Floor, Boston, MA 02110-1301 USA. 17 | */ 18 | 19 | --Report of online redo log file information 20 | col group# format 999 21 | col thread# format 999 22 | col member format a70 wrap 23 | col status format a10 24 | col archived format a10 25 | col fsize format 9999 heading "Size (MB)" 26 | break on thread# skip 1 on group# 27 | 28 | select l.thread# 29 | , l.group# 30 | , f.member 31 | , l.archived 32 | , l.status 33 | , (bytes/1024/1024) fsize 34 | from v$log l 35 | , v$logfile f 36 | where f.group# = l.group# 37 | order by 1, 2; 38 | 39 | clear breaks 40 | -------------------------------------------------------------------------------- /rman_db_params.txt.sample: -------------------------------------------------------------------------------- 1 | # Sample file for passing different parameters to backup_rman.sh cron jobs for different databases, backup types. 2 | # This is useful if you want to send email to different users for each database, have different retention parameters, 3 | # backup locations, etc. 4 | #DB1 5 | -d db1 -l /oracle/backup/db1/db -p db1_full -t db1_full -b incremental -i 0 -S dba@company.com,me@mail.com --spfile -x 14 6 | -d db1 -l /oracle/backup/db1/db -p db1_incr -t db1_incr -b incremental -i 1 -S dba@company.com,me@mail.com --spfile -x 14 --ic 7 | -d db1 -l /oracle/backup/db1/db -p db1_arch -t db1_arch -b archivelog --nocrosscheck --nodeleteexpired --nodeleteobsolete 8 | #DB2 9 | -d db2 -l /oracle/backup/db2/db -p db2_full -t db2_full -b incremental -i 0 -S dba@company.com,me@mail.com --spfile -x 14 10 | -d db2 -l /oracle/backup/db2/db -p db2_incr -t db2_incr -b incremental -i 1 -S dba@company.com,me@mail.com --spfile -x 14 --ic 11 | -d db2 -l /oracle/backup/db2/db -p db2_arch -t db2_arch -b archivelog --nocrosscheck --nodeleteexpired --nodeleteobsolete 12 | -------------------------------------------------------------------------------- /rman_params.txt.sample: -------------------------------------------------------------------------------- 1 | # Sample parameter file for setting global RMAN backup parameters in backup_rman.sh. Remove these comments before use. 2 | -f 4 -r 2 --maxopenfiles 4 --compress --deletearchive --trace -e alert_me@company.com 3 | -------------------------------------------------------------------------------- /sample_rman_crontab: -------------------------------------------------------------------------------- 1 | # Sample crontab for running backup_rman.sh 2 | 00 18 * * 0 /home/oracle/scripts/backup_rman.sh `cat /home/oracle/scripts/rman_params.txt` `cat /home/oracle/scripts/rman_db_params.txt | grep mydb | grep full | grep -v \# ` > /var/tmp/backup_rman.mydb.full.log 3 | 00 18 * * 1-6 /home/oracle/scripts/backup_rman.sh `cat /home/oracle/scripts/rman_params.txt` `cat /home/oracle/scripts/rman_db_params.txt | grep mydb | grep incr | grep -v \# ` > /var/tmp/backup_rman.mydb.incr.log 4 | 00 * * * * /home/oracle/scripts/backup_rman.sh `cat /home/oracle/scripts/rman_params.txt` `cat /home/oracle/scripts/rman_db_params.txt | grep mydb | grep arch | grep -v \# ` > /var/tmp/backup_rman.mydb.arch.log 5 | --------------------------------------------------------------------------------