When monitoring Tablespace Usage (see my Tablespace Usage blog post for more info), there comes a point when you need to add a datafile to a tablespace to allow for growth and more importantly get below a monitoring threshold for example in OEM or OpsView.
Query to see Current Datafiles State
To see the current state of the datafiles:
set pages 999 set lines 400 col FILE_NAME format a75 select d.TABLESPACE_NAME, d.FILE_NAME, d.BYTES/1024/1024 SIZE_MB, d.AUTOEXTENSIBLE, d.MAXBYTES/1024/1024 MAXSIZE_MB, d.INCREMENT_BY*(v.BLOCK_SIZE/1024)/1024 INCREMENT_BY_MB from dba_data_files d, v$datafile v where d.FILE_ID = v.FILE# order by d.TABLESPACE_NAME, d.FILE_NAME;
Output from Current Datafiles State
This is the output you will get from the query:
TABLESPACE_NAME FILE_NAME SIZE_MB AUT MAXSIZE_MB INCREMENT_BY_MB --------------- ---------------------------------------------- ------- --- ---------- --------------- VERS_DATA +DATAC1/VERS/DATAFILE/vers_data.395.891367103 32767 YES 32767 1024 ... VERS_DATA +DATAC1/VERS/DATAFILE/vers_data.772.947087161 4096 YES 32767 1024 VERS_INDEX +DATAC1/VERS/DATAFILE/vers_index.434.891367657 3072 YES 32767 1024 VERS_INDX +DATAC1/VERS/DATAFILE/vers_indx.422.891367801 32767 YES 32767 1024 ... VERS_INDX +DATAC1/VERS/DATAFILE/vers_indx.783.947764359 10240 YES 32767 1024 SNP_DATA +DATAC1/VERS/DATAFILE/snp_data.421.891367815 1024 YES 32767 1024 SYSAUX +DATAC1/VERS/DATAFILE/sysaux.488.891349085 31500 YES 32767.9844 10 SYSAUX +DATAC1/VERS/DATAFILE/sysaux.577.909753421 12288 YES 12288 10 SYSTEM +DATAC1/VERS/DATAFILE/system.487.891349083 890 YES 32767.9844 10 UNDOTBS1 +DATAC1/VERS/DATAFILE/undotbs1.489.891349085 30565 YES 32767.9844 5 UNDOTBS2 +DATAC1/VERS/DATAFILE/undotbs2.491.891349091 20555 YES 32767.9844 5 USERS +DATAC1/VERS/DATAFILE/users.492.891349091 5 YES 32767.9844 1.25 273 rows selected. SQL>
The … represents the several lines removed to make the output readable 🙂
Add Datafile to Tablespace
To add a datafile to ‘VERS_DATA‘ to be initially 10G, auto extendable by 1G to maxsize of 32Gb:
ALTER TABLESPACE VERS_DATA ADD DATAFILE '+DATAC1' SIZE 10G AUTOEXTEND ON NEXT 1G MAXSIZE 32767M;
See Oracle Documentation for more info and Syntax:
https://docs.oracle.com/database/121/SQLRF/statements_3002.htm
Once added you’ll see the datafile in the above query:
TABLESPACE_NAME FILE_NAME SIZE_MB AUT MAXSIZE_MB INCREMENT_BY_MB
--------------- ---------------------------------------------- ------- --- ---------- ---------------
VERS_DATA +DATAC1/VERS/DATAFILE/vers_data.395.891367103 32767 YES 32767 1024
...
VERS_DATA +DATAC1/VERS/DATAFILE/vers_data.772.947087161 4096 YES 32767 1024
VERS_DATA +DATAC1/VERS/DATAFILE/vers_data.774.947426643 10240 YES 32767 1024
VERS_INDEX +DATAC1/VERS/DATAFILE/vers_index.434.891367657 3072 YES 32767 1024
VERS_INDX +DATAC1/VERS/DATAFILE/vers_indx.422.891367801 32767 YES 32767 1024
...
VERS_INDX +DATAC1/VERS/DATAFILE/vers_indx.783.947764359 10240 YES 32767 1024
SNP_DATA +DATAC1/VERS/DATAFILE/snp_data.421.891367815 1024 YES 32767 1024
SYSAUX +DATAC1/VERS/DATAFILE/sysaux.488.891349085 31500 YES 32767.9844 10
SYSAUX +DATAC1/VERS/DATAFILE/sysaux.577.909753421 12288 YES 12288 10
SYSTEM +DATAC1/VERS/DATAFILE/system.487.891349083 890 YES 32767.9844 10
UNDOTBS1 +DATAC1/VERS/DATAFILE/undotbs1.489.891349085 30565 YES 32767.9844 5
UNDOTBS2 +DATAC1/VERS/DATAFILE/undotbs2.491.891349091 20555 YES 32767.9844 5
USERS +DATAC1/VERS/DATAFILE/users.492.891349091 5 YES 32767.9844 1.25
274 rows selected.
SQL>
Related Blog Posts:
Querying Tablespace Usage
Adding a Datafile to Temp Tablespace
If you found this blog post useful, please like as well as follow me through my various Social Media avenues available on the sidebar and/or subscribe to this oracle blog via WordPress/e-mail.
Thanks
Zed DBA (Zahid Anwar)
Pingback: Querying Tablespace Usage | Zed DBA's Oracle Blog
Pingback: Adding a Datafile to Temp Tablespace | Zed DBA's Oracle Blog