├── AWR Sizing Instructions.pdf ├── AWR Analysis template spreadsheet.xlsx ├── README.md ├── busiest_statspack.sql ├── busiest_awr.sql └── dbspace.sql /AWR Sizing Instructions.pdf: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/tigormanmsft/az-oracle-sizing/HEAD/AWR Sizing Instructions.pdf -------------------------------------------------------------------------------- /AWR Analysis template spreadsheet.xlsx: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/tigormanmsft/az-oracle-sizing/HEAD/AWR Analysis template spreadsheet.xlsx -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | ## Sizing Azure resources based on an Oracle AWR report 2 | 3 | This package consists of a PDF (i.e. "`AWR Sizing Instructions.pdf`") containing a set of instructions for extracting a small set of metrics from an Oracle AWR report into a spreadsheet. The spreadsheet (i.e. "`AWR Analysis (template) YYYYMMDD.xls`") will then summarize and extrapolate these metrics into estimates used for sizing the on-prem database on Azure virtual machines and storage. 4 | 5 | At present, the spreadsheet does not use the estimated recommendations for CPU, RAM, IOPS, and I/O throughput to automatically pull recommended Azure instance types and storage options; creating recommendations from the calculations is still quite manual, unfortunately. 6 | 7 | To obtain the most accurate observed information from an AWR report, please consider using output from the SQL script "`busiest_awr.sql`" to find peak workloads with the Oracle AWR repository from which to calculate sizing, using a minimum of extrapolation and guesswork. 8 | 9 | Because the Oracle AWR report does not contain any information about database size, please consider running and sharing output from the SQL\*Plus script "`dbspace.sql`", which summarizes datafile, tempfile, controlfile, online redo logfile, and block change tracking file sizes. It also summarizes information about archived redo logfiles and RMAN backupsets by day, to provide a sense of the actual data change rate in the database. 10 | -------------------------------------------------------------------------------- /busiest_statspack.sql: -------------------------------------------------------------------------------- 1 | REM ================================================================================ 2 | REM Name: busiest_statspack.sql 3 | REM Type: Oracle SQL script 4 | REM Date: 27-April 2020 5 | REM From: Americas Customer Success team (CSU) - Microsoft 6 | REM 7 | REM Copyright and license: 8 | REM 9 | REM Licensed under the Apache License, Version 2.0 (the "License"); you may 10 | REM not use this file except in compliance with the License. 11 | REM 12 | REM You may obtain a copy of the License at 13 | REM 14 | REM http://www.apache.org/licenses/LICENSE-2.0 15 | REM 16 | REM Unless required by applicable law or agreed to in writing, software 17 | REM distributed under the License is distributed on an "AS IS" basis, 18 | REM WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. 19 | REM 20 | REM See the License for the specific language governing permissions and 21 | REM limitations under the License. 22 | REM 23 | REM Copyright (c) 2020 by Microsoft. All rights reserved. 24 | REM 25 | REM Ownership and responsibility: 26 | REM 27 | REM This script is offered without warranty by Microsoft Customer Engineering. 28 | REM Anyone using this script accepts full responsibility for use, effect, 29 | REM and maintenance. Please do not contact Microsoft or Oracle support unless 30 | REM there is a problem with a supported SQL or SQL*Plus command. 31 | REM 32 | REM Description: 33 | REM 34 | REM SQL*Plus script to find the top 5 busiest STATSPACK snapshots within the horizon 35 | REM of all information stored within the Oracle STATSPACK repository, based on the 36 | REM STATSPACK statistic "CPU used by this session" and the two I/O statistics 37 | REM "physical reads" and "physical writes", all residing within the STATSPACK 38 | REM table named STATS$SYSSTAT, populated from the view V$SYSSTAT. 39 | REM 40 | REM Modifications: 41 | REM TGorman 09jan23 v0.6 copied from script "busiest_awr.sql" v0.6 42 | REM TGorman 13feb23 v0.7 bug fix, change DBA_HIST_SNAPSHOT to STATS$SNAPSHOT 43 | REM ================================================================================ 44 | set pages 100 lines 180 verify off echo off feedback 6 timing off recsep off 45 | col instance_number format 90 heading 'I#' 46 | col snap_id heading 'Beginning|Snap ID' 47 | col begin_tm format a20 heading 'Beginning|Snap Time' word_wrap 48 | col avg_value heading 'Average|IO and CPU|per second' format 999,999,990.0000 49 | define V_CPU_WEIGHT=1 /* multiplicative factor to favor/disfavor CPU metrics */ 50 | define V_IO_WEIGHT=2 /* multiplicative factor to favor/disfavor I/O metrics */ 51 | spool b 52 | select x.instance_number, 53 | x.snap_id snap_id, 54 | to_char(s.end_interval_time, 'DD-MON-YYYY HH24:MI:SS') begin_tm, 55 | x.avg_value 56 | from (select instance_number, snap_id, avg_value, 57 | row_number() over (partition by instance_number order by avg_sort_value desc) rn 58 | from (select instance_number, snap_id, avg(value) avg_value, avg(sort_value) avg_sort_value 59 | from (select instance_number, snap_id, sum(value)-sum(lag_value) value, ((sum(value)-sum(lag_value))*&&V_CPU_WEIGHT) sort_value 60 | from (select instance_number, snap_id, value, lag(value) over (partition by instance_number order by snap_id) lag_value 61 | from stats$sysstat 62 | where name in ('CPU used by this session') 63 | and dbid = (select dbid from v$database)) 64 | where lag_value is not null 65 | group by instance_number, snap_id 66 | union all 67 | select instance_number, snap_id, sum(value)-sum(lag_value) value, ((sum(value)-sum(lag_value))*&&V_IO_WEIGHT) sort_value 68 | from (select instance_number, snap_id, value, lag(value) over (partition by instance_number, name order by snap_id) lag_value 69 | from stats$sysstat 70 | where name in ('physical reads','physical writes') 71 | and dbid = (select dbid from v$database)) 72 | where lag_value is not null 73 | group by instance_number, snap_id) 74 | group by instance_number, snap_id)) x, 75 | stats$snapshot s 76 | where s.snap_id = x.snap_id 77 | and s.instance_number = x.instance_number 78 | and s.dbid = (select dbid from v$database) 79 | and x.rn <= 5 80 | order by instance_number, rn; 81 | spool off 82 | -------------------------------------------------------------------------------- /busiest_awr.sql: -------------------------------------------------------------------------------- 1 | REM ================================================================================ 2 | REM Name: busiest_awr.sql 3 | REM Type: Oracle SQL script 4 | REM Date: 27-April 2020 5 | REM From: Americas Customer Engineering team (CET) - Microsoft 6 | REM 7 | REM Copyright and license: 8 | REM 9 | REM Licensed under the Apache License, Version 2.0 (the "License"); you may 10 | REM not use this file except in compliance with the License. 11 | REM 12 | REM You may obtain a copy of the License at 13 | REM 14 | REM http://www.apache.org/licenses/LICENSE-2.0 15 | REM 16 | REM Unless required by applicable law or agreed to in writing, software 17 | REM distributed under the License is distributed on an "AS IS" basis, 18 | REM WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. 19 | REM 20 | REM See the License for the specific language governing permissions and 21 | REM limitations under the License. 22 | REM 23 | REM Copyright (c) 2020 by Microsoft. All rights reserved. 24 | REM 25 | REM Ownership and responsibility: 26 | REM 27 | REM This script is offered without warranty by Microsoft Customer Engineering. 28 | REM Anyone using this script accepts full responsibility for use, effect, 29 | REM and maintenance. Please do not contact Microsoft or Oracle support unless 30 | REM there is a problem with a supported SQL or SQL*Plus command. 31 | REM 32 | REM Description: 33 | REM 34 | REM SQL*Plus script to find the top 5 busiest AWR snapshots within the horizon 35 | REM of all information stored within the Oracle AWR repository, based on the 36 | REM statistics "physical reads" (a.k.a. physical I/O or "PIO") and "CPU used 37 | REM by this session" (a.k.a. cumulative session-level CPU usage). 38 | REM 39 | REM Modifications: 40 | REM TGorman 27apr20 v0.1 written 41 | REM TGorman 04may20 v0.2 removed NTILE, using only ROW_NUMBER now... 42 | REM NBhandare 14May21 v0.3 added reference to innermost subqueries as fix for 43 | REM instance restart... 44 | REM TGorman 01jun21 v0.4 cleaned up some mistakes, parameterized 45 | REM ================================================================================ 46 | set pages 100 lines 80 verify off echo off feedback 6 timing off recsep off 47 | col dbid heading 'DB ID' 48 | col con_id format 90 heading 'Con|ID' 49 | col instance_number format 90 heading 'I#' 50 | col snap_id heading 'AWR|Snap ID' 51 | col begin_tm format a20 heading 'Beginning|time' word_wrap 52 | col end_tm format a20 heading 'Ending|time' word_wrap 53 | col pio heading 'Physical|Reads|(PIO)' 54 | col cpu heading 'CPU used by|this session|(CPU)' 55 | define V_BUCKETS=98 /* only retain values from 98th percentile or below */ 56 | define V_CPU_FACTOR=1 /* multiplicative factor to favor/disfavor CPU metrics */ 57 | define V_PIO_FACTOR=5 /* multiplicative factor to favor/disfavor I/O metrics */ 58 | spool busiest_awr 59 | select x.instance_number, 60 | x.snap_id, 61 | to_char(s.begin_interval_time, 'DD-MON-YYYY HH24:MI:SS') begin_tm, 62 | to_char(s.end_interval_time, 'DD-MON-YYYY HH24:MI:SS') end_tm, 63 | x.pio, 64 | x.cpu 65 | from (select instance_number, snap_id, pio, cpu, row_number() over (partition by instance_number order by sortby desc) rn 66 | from (select instance_number, snap_id, 67 | sum(pio) pio, sum(cpu) cpu, avg(sortby) sortby 68 | from (select instance_number, snap_id, pio, cpu, sortby 69 | from (select instance_number, snap_id, value pio, 0 cpu, (value*(&&V_PIO_FACTOR)) sortby, 70 | ntile(100) over (partition by instance_number order by value) bucket 71 | from (select s.instance_number, s.snap_id, 72 | nvl(decode(greatest(value, nvl(lag(value) over (partition by h.startup_time, s.instance_number order by s.snap_id),0)), 73 | value, value - lag(value) over (partition by h.startup_time, s.instance_number order by s.snap_id), value), 0) value 74 | from dba_hist_sysstat s, dba_hist_snapshot h 75 | where stat_name = 'physical reads' 76 | and s.dbid = (select dbid from v$database) 77 | and h.dbid = s.dbid 78 | and h.instance_number = s.instance_number 79 | and h.snap_id = s.snap_id) 80 | union all 81 | select instance_number, snap_id, 0 pio, value cpu, (value*(&&V_CPU_FACTOR)) sortby, 82 | ntile(100) over (partition by instance_number order by value) bucket 83 | from (select s.instance_number, s.snap_id, 84 | nvl(decode(greatest(value, nvl(lag(value) over (partition by h.startup_time, s.instance_number order by s.snap_id),0)), 85 | value, value - lag(value) over (partition by h.startup_time, s.instance_number order by s.snap_id), value), 0) value 86 | from dba_hist_sysstat s, dba_hist_snapshot h 87 | where stat_name = 'CPU used by this session' 88 | and s.dbid = (select dbid from v$database) 89 | and h.dbid = s.dbid 90 | and h.instance_number = s.instance_number 91 | and h.snap_id = s.snap_id)) 92 | where bucket <= &&V_BUCKETS) 93 | group by instance_number, snap_id)) x, 94 | dba_hist_snapshot s 95 | where s.snap_id = x.snap_id 96 | and s.instance_number = x.instance_number 97 | and rn <= 5 98 | order by rn, instance_number; 99 | spool off 100 | -------------------------------------------------------------------------------- /dbspace.sql: -------------------------------------------------------------------------------- 1 | /********************************************************************************* 2 | * File: dbspace.sql 3 | * Type: Oracle SQL*Plus script 4 | * Date: 26-Aug 2020 5 | * Author: Microsoft Customer Architecture & Engineering (CAE) 6 | * 7 | * Licensed under the Apache License, Version 2.0 (the "License"); 8 | * you may not use this file except in compliance with the License. 9 | * You may obtain a copy of the License at 10 | * 11 | * http://www.apache.org/licenses/LICENSE-2.0 12 | * 13 | * Unless required by applicable law or agreed to in writing, software 14 | * distributed under the License is distributed on an "AS IS" BASIS, 15 | * WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. 16 | * See the License for the specific language governing permissions and 17 | * limitations under the License. 18 | * 19 | * Copyright (c) 2020 by Microsoft. All rights reserved. 20 | * 21 | * Description: 22 | * 23 | * Oracle SQL*Plus script to display summary information about the size of an 24 | * Oracle database, summarizing datafiles, tempfiles, controlfiles, online 25 | * redo log files, and block change tracking files. Also summarizes backups 26 | * of datafiles and archived redo log files. 27 | * 28 | * Output is spooled to the present working directory to a file named 29 | * "dbspace_.lst", where "DB-NAME" is the database name. 30 | * 31 | * Modifications: 32 | * TGorman 26-Aug 2020 v1.0 - written 33 | * TGorman 03-Sep 2020 v1.1 - added SQL*Plus "set" for formatting 34 | * TGorman 30-Nov 2020 v1.2 - added queries on V$LOG/V$LOGFILE for redo 35 | * group/member info 36 | * TGorman 30-Nov 2020 v1.3 - added query with HCC recompression calcs 37 | ********************************************************************************/ 38 | set echo off feedback off timing off pagesize 100 linesize 130 trimout on trimspool on verify off 39 | define V_AH_RATIO="18" -- compression ratio for ARCHIVE HIGH 40 | define V_AL_RATIO="15" -- compression ratio for ARCHIVE LOW 41 | define V_QH_RATIO="10" -- compression ratio for QUERY HIGH 42 | define V_QL_RATIO="6" -- compression ratio for QUERY LOW 43 | define V_B_RATIO="3" -- compression ratio for BASIC/OLTP/ADVANCED 44 | col name new_value V_DBNAME noprint 45 | select name from v$database; 46 | set feedback on 47 | spool dbspace_&&V_DBNAME 48 | clear breaks computes 49 | break on report 50 | compute sum of mb on report 51 | col type format a10 heading "File type" 52 | col mb format 999,999,990.00 heading "DB Size (MB)" 53 | select type, sum(bytes)/1048576 mb 54 | from (select 'Datafile' type, bytes from dba_data_files 55 | union all 56 | select 'Tempfile' type, bytes from dba_temp_files 57 | union all 58 | select 'OnlineRedo' type, bytes*members bytes from v$log 59 | union all 60 | select 'Ctlfile' type, file_size_blks*block_size bytes from v$controlfile 61 | union all 62 | select 'BCTfile' type, nvl(bytes,0) bytes from v$block_change_tracking) 63 | group by type 64 | order by type; 65 | 66 | col segment_type heading "Segment Type" 67 | col compression heading "Enabled?" 68 | col compress_for heading "Compression Type" 69 | col rw_ro format a9 heading "Read-Only?" 70 | col mb format 999,999,990.00 heading "Seg Size (MB)" 71 | col recompressed_mb format 999,999,990.00 heading "Addl MB after|Recompression" 72 | col cnt format 999,990 heading "# Segs" 73 | clear breaks computes 74 | break on segment_type on compression on compress_for on rw_ro on report 75 | compute sum of mb on report 76 | compute sum of recompressed_mb on report 77 | compute sum of cnt on report 78 | select s.segment_type, 79 | t.compression, 80 | t.compress_for, 81 | decode(x.status, 'ONLINE', null, x.status) rw_ro, 82 | sum(s.bytes)/1048576 mb, 83 | decode(t.compression, 84 | 'ENABLED', decode(t.compress_for, 85 | 'ARCHIVE LOW', (((sum(s.bytes)*&&V_AL_RATIO)/&&V_B_RATIO)-sum(s.bytes)), 86 | 'ARCHIVE HIGH', (((sum(s.bytes)*&&V_AH_RATIO)/&&V_B_RATIO)-sum(s.bytes)), 87 | 'QUERY LOW', (((sum(s.bytes)*&&V_QL_RATIO)/&&V_B_RATIO)-sum(s.bytes)), 88 | 'QUERY HIGH', (((sum(s.bytes)*&&V_QH_RATIO)/&&V_B_RATIO)-sum(s.bytes)))/1048576) recompressed_mb, 89 | count(*) cnt 90 | from dba_tables t, 91 | dba_segments s, 92 | dba_tablespaces x 93 | where t.partitioned = 'NO' 94 | and t.tablespace_name is not null 95 | and s.segment_type = 'TABLE' 96 | and s.owner = t.owner 97 | and s.segment_name = t.table_name 98 | and x.tablespace_name = s.tablespace_name 99 | group by s.segment_type, 100 | t.compression, 101 | t.compress_for, 102 | decode(x.status, 'ONLINE', null, x.status) 103 | union all 104 | select s.segment_type, 105 | t.compression, 106 | t.compress_for, 107 | decode(x.status, 'ONLINE', null, x.status) rw_ro, 108 | sum(s.bytes)/1048576 mb, 109 | decode(t.compression, 110 | 'ENABLED', decode(t.compress_for, 111 | 'ARCHIVE LOW', (((sum(s.bytes)*&&V_AL_RATIO)/&&V_B_RATIO)-sum(s.bytes)), 112 | 'ARCHIVE HIGH', (((sum(s.bytes)*&&V_AH_RATIO)/&&V_B_RATIO)-sum(s.bytes)), 113 | 'QUERY LOW', (((sum(s.bytes)*&&V_QL_RATIO)/&&V_B_RATIO)-sum(s.bytes)), 114 | 'QUERY HIGH', (((sum(s.bytes)*&&V_QH_RATIO)/&&V_B_RATIO)-sum(s.bytes)))/1048576) recompressed_mb, 115 | count(*) cnt 116 | from dba_tab_partitions t, 117 | dba_segments s, 118 | dba_tablespaces x 119 | where t.subpartition_count = 0 120 | and t.tablespace_name is not null 121 | and s.segment_type = 'TABLE PARTITION' 122 | and s.owner = t.table_owner 123 | and s.segment_name = t.table_name 124 | and s.partition_name = t.partition_name 125 | and x.tablespace_name = s.tablespace_name 126 | group by s.segment_type, 127 | t.compression, 128 | t.compress_for, 129 | decode(x.status, 'ONLINE', null, x.status) 130 | union all 131 | select s.segment_type, 132 | t.compression, 133 | t.compress_for, 134 | decode(x.status, 'ONLINE', null, x.status) rw_ro, 135 | sum(s.bytes)/1048576 mb, 136 | decode(t.compression, 137 | 'ENABLED', decode(t.compress_for, 138 | 'ARCHIVE LOW', (((sum(s.bytes)*&&V_AL_RATIO)/&&V_B_RATIO)-sum(s.bytes)), 139 | 'ARCHIVE HIGH', (((sum(s.bytes)*&&V_AH_RATIO)/&&V_B_RATIO)-sum(s.bytes)), 140 | 'QUERY LOW', (((sum(s.bytes)*&&V_QL_RATIO)/&&V_B_RATIO)-sum(s.bytes)), 141 | 'QUERY HIGH', (((sum(s.bytes)*&&V_QH_RATIO)/&&V_B_RATIO)-sum(s.bytes)))/1048576) recompressed_mb, 142 | count(*) cnt 143 | from dba_tab_subpartitions t, 144 | dba_segments s, 145 | dba_tablespaces x 146 | where t.tablespace_name is not null 147 | and s.segment_type = 'TABLE SUBPARTITION' 148 | and s.owner = t.table_owner 149 | and s.segment_name = t.table_name 150 | and s.partition_name = t.subpartition_name 151 | and x.tablespace_name = s.tablespace_name 152 | group by s.segment_type, 153 | t.compression, 154 | t.compress_for, 155 | decode(x.status, 'ONLINE', null, x.status) 156 | order by 1, 2, 3, 4, 5 desc; 157 | 158 | clear breaks computes 159 | break on thread# on group# on members on report 160 | col thread# heading "Thread" 161 | col group# heading "Group" 162 | col members heading "Members" 163 | col mb format 999,999,990.00 heading "Member Size (MB)" 164 | compute sum of mb on report 165 | select thread#, 166 | group#, 167 | members, 168 | max(bytes)/1048576 mb 169 | from v$log 170 | group by thread#, 171 | group#, 172 | members 173 | order by 1, 2, 3; 174 | 175 | col sort0 noprint 176 | col dbf_mb format 999,999,999,990.00 heading "Source|database|files (MB)" 177 | col day heading "Day" 178 | col backup_type format a4 heading "Bkup|Type" 179 | col incremental_level format 9990 heading "Incr|Lvl" 180 | col read_mb format 999,999,999,990.00 heading "Backup|read|(MB)" 181 | col bkp_mb format 999,999,999,990.00 heading "Database file|backup written|(MB)" 182 | clear breaks computes 183 | break on day on report 184 | compute sum of dbf_mb on report 185 | compute sum of read_mb on report 186 | compute sum of bkp_mb on report 187 | select to_char(f.completion_time,'YYYYMMDD') sort0, 188 | to_char(f.completion_time,'DD-MON-YYYY') day, 189 | s.backup_type, 190 | s.incremental_level, 191 | sum(f.datafile_blocks*f.block_size)/1048576 dbf_mb, 192 | sum(f.blocks_read*f.block_size)/1048576 read_mb, 193 | sum(f.blocks*f.block_size)/1048576 bkp_mb 194 | from v$backup_datafile f, 195 | v$backup_set s 196 | where s.set_stamp = f.set_stamp 197 | and s.set_count = f.set_count 198 | group by to_char(f.completion_time,'YYYYMMDD'), 199 | to_char(f.completion_time,'DD-MON-YYYY'), 200 | s.backup_type, 201 | s.incremental_level 202 | order by sort0; 203 | 204 | clear breaks computes 205 | break on day on report 206 | compute avg of mb on report 207 | compute sum of mb on report 208 | col sort0 noprint 209 | col day heading "Day" 210 | col mb format 999,999,990.00 heading "Archived|redo Size (MB)" 211 | select to_char(next_time,'YYYYMMDD') sort0, 212 | to_char(next_time,'DD-MON-YYYY') day, 213 | sum(blocks*block_size)/1048576 mb 214 | from v$archived_log 215 | group by to_char(next_time,'YYYYMMDD'), 216 | to_char(next_time,'DD-MON-YYYY') 217 | order by sort0; 218 | 219 | clear breaks computes 220 | break on day on report 221 | compute sum of mb on report 222 | col bkp_mb format 999,999,990.00 heading "Archived redo|backup written|(MB)" 223 | select to_char(next_time,'YYYYMMDD') sort0, 224 | to_char(next_time,'DD-MON-YYYY') day, 225 | sum(blocks*block_size)/1048576 bkp_mb 226 | from v$backup_redolog 227 | group by to_char(next_time,'YYYYMMDD'), 228 | to_char(next_time,'DD-MON-YYYY') 229 | order by sort0; 230 | 231 | clear breaks computes 232 | spool off 233 | --------------------------------------------------------------------------------