Discussions
Categories
- 196.8K All Categories
- 2.2K Data
- 235 Big Data Appliance
- 1.9K Data Science
- 449.9K Databases
- 221.6K General Database Discussions
- 3.8K Java and JavaScript in the Database
- 31 Multilingual Engine
- 549 MySQL Community Space
- 478 NoSQL Database
- 7.9K Oracle Database Express Edition (XE)
- 3K ORDS, SODA & JSON in the Database
- 532 SQLcl
- 4K SQL Developer Data Modeler
- 186.9K SQL & PL/SQL
- 21.3K SQL Developer
- 295.5K Development
- 17 Developer Projects
- 138 Programming Languages
- 292.1K Development Tools
- 104 DevOps
- 3.1K QA/Testing
- 645.9K Java
- 28 Java Learning Subscription
- 37K Database Connectivity
- 154 Java Community Process
- 105 Java 25
- 22.1K Java APIs
- 138.1K Java Development Tools
- 165.3K Java EE (Java Enterprise Edition)
- 17 Java Essentials
- 158 Java 8 Questions
- 85.9K Java Programming
- 79 Java Puzzle Ball
- 65.1K New To Java
- 1.7K Training / Learning / Certification
- 13.8K Java HotSpot Virtual Machine
- 94.2K Java SE
- 13.8K Java Security
- 203 Java User Groups
- 24 JavaScript - Nashorn
- Programs
- 401 LiveLabs
- 37 Workshops
- 10.2K Software
- 6.7K Berkeley DB Family
- 3.5K JHeadstart
- 5.6K Other Languages
- 2.3K Chinese
- 171 Deutsche Oracle Community
- 1.1K Español
- 1.9K Japanese
- 230 Portuguese
Calculate disk space needed for INDEX

guruparan
Member Posts: 150
Hi,
How to calculate disk space needed for creating an INDEX? Please point me to resources where I can get detail.
For Example:
I need to create an non UNIQUE INDEX on the following columns, a rough size would do.
<PRE>
EVENT_DATE NOT NULL DATE
APPT_DATE_SLOT VARCHAR2(15)
EVENT_STATUS VARCHAR2(4)
</PRE>
The table has some 7,300,000 rows. Let me know how to calculate too.
All helps are greatly appreciated.
How to calculate disk space needed for creating an INDEX? Please point me to resources where I can get detail.
For Example:
I need to create an non UNIQUE INDEX on the following columns, a rough size would do.
<PRE>
EVENT_DATE NOT NULL DATE
APPT_DATE_SLOT VARCHAR2(15)
EVENT_STATUS VARCHAR2(4)
</PRE>
The table has some 7,300,000 rows. Let me know how to calculate too.
All helps are greatly appreciated.
Best Answer
-
A rough estimate of the space the index will need can be made by
adding the expected actual length of each column plus 6 for the rowid plus 2 for the header X number of table rows that will have an entry so
Date are 7 bytes internal + 15 + 4 + 2 + 6 = 34 X 7.3M = 248200000 X overhead for block header, initrans, etc...
we will use 20% for block overhead or 1.2 X 248200000 = 297840000 which is about 285M
The actual allocation will vary depending on your tablespace extent allocation method.
HTH -- Mark D Powell --
Answers
-
-
I haven't created yet! But I can still run this proc? BTW, I am in Oracle 9.2
-
Looks like Oracle 9.2 doesn't have it,
<pre>
SQL> desc dbms_space.create_index_cost
ERROR:
ORA-04043: object dbms_space.create_index_cost does not exist
</pre> -
A rough estimate of the space the index will need can be made by
adding the expected actual length of each column plus 6 for the rowid plus 2 for the header X number of table rows that will have an entry so
Date are 7 bytes internal + 15 + 4 + 2 + 6 = 34 X 7.3M = 248200000 X overhead for block header, initrans, etc...
we will use 20% for block overhead or 1.2 X 248200000 = 297840000 which is about 285M
The actual allocation will vary depending on your tablespace extent allocation method.
HTH -- Mark D Powell -- -
Thanks Mark. That's about it.
-
You are welcome. Thank you for the points. If you get to build the index soon and can remember post back with the actual results.
-- mark -- -
Yes is it to known the future size BEFORE create index by using statistics
look the Ask Tom http://asktom.oracle.com/pls/asktom/f?p=100:11:0::::P11_QUESTION_ID:1833377500346797242
for psoug this package exist since 7.3.4. I use it on 10.2.0[2-4] and 11g ({ORACLE_HOME}/rdbms/admin/dbmsspu.sql)
http://psoug.org/reference/dbms_space.html
my test also :
SQL*Plus: Release 11.1.0.6.0
[email protected]>create table tsygale as select level num from dual connect by level<=100000;
Table created.
[email protected]>@seg_tab
Enter value for segment_name: TSYGALE
old 3: where segment_name in ('&segment_name')
new 3: where segment_name in ('TSYGALE')
TABLESPACE_NAME SEGMENT_NAME MO
-------------------- ----------------------------------- ----------
SYSTEM TSYGALE 2
[email protected]>exec dbms_stats.gather_table_stats(user,'TSYGALE');
PL/SQL procedure successfully completed.
Elapsed: 00:00:02.95
[email protected]>variable used number
[email protected]>variable alloc number
exec dbms_space.create_index_cost( 'create index isygale on tsygale(object_name,object_type,owner)', :used, :alloc );
PL/SQL procedure successfully completed.
Elapsed: 00:00:00.25
16:56:38 [email protected]>print used
USED
----------
2761720
16:56:49 [email protected]>print alloc
ALLOC
----------
4194304
[email protected]>create index isygale on tsygale(object_name,object_type,owner);
Index created.
Elapsed: 00:00:00.50
[email protected]>@seg_tabind
Segment name ?TSYGALE
old 3: where (segment_name in ('&&segment_name')
new 3: where (segment_name in ('TSYGALE')
old 5: segment_name in (select index_name from dba_indexes where table_name in ('&&segment_name'))
new 5: segment_name in (select index_name from dba_indexes where table_name in ('TSYGALE'))
TABLESPACE_NAME SEGMENT_TYPE SEGMENT_NAME MO
-------------------- ------------------ ----------------------------------- ----------
SYSTEM TABLE TSYGALE 8
SYSTEM INDEX ISYGALE 4
Elapsed: 00:01:22.31
So package estimate to 4 194 304 Octets and after the index created the size is to 4MO, so ....
Edited by: Sygale on Apr 8, 2010 5:02 PM -
Sygale wrote:Unfortunately the OP says he is using 9.2, and although the package has been around since 7.3 that particular procedure was not introduced until 10g - and it has a couple of flaws built in, see: http://jonathanlewis.wordpress.com/2009/05/22/index-size/
for psoug this package exist since 7.3.4. I use it on 10.2.0[2-4] and 11g ({ORACLE_HOME}/rdbms/admin/dbmsspu.sql)
http://psoug.org/reference/dbms_space.html
Regards
Jonathan Lewis
http://jonathanlewis.wordpress.com
http://www.jlcomp.demon.co.uk
To post code, statspack/AWR report, execution plans or trace files, start and end the section with the tag {noformat}{noformat} (lowercase, curly brackets, no spaces) so that the text appears in
fixed format. There is a +"Preview"+ tab at the top of the text entry panel. Use this to check what your message will look like before you post the message. If it looks a complete mess you're unlikely to get a response. (Click on the +"Plain text"+ tab if you want to edit the text to tidy it up.) +"I believe in evidence. I believe in observation, measurement, and reasoning, confirmed by independent observers. I'll believe anything, no matter how wild and ridiculous, if there is evidence for it. The wilder and more ridiculous something is, however, the firmer and more solid the evidence will have to be."+ Isaac Asimov
-
Jonathan Lewis wrote:Sorry for this mistake, have you a method to define on which version a functionality is delivered ?
Unfortunately the OP says he is using 9.2, and although the package has been around since 7.3 that particular procedure was not introduced until 10g - and it has a couple of flaws built in, see: http://jonathanlewis.wordpress.com/2009/05/22/index-size/
I read your article, I see some errors in this package,
but it can help us to define if we have enough space on disk to create index or table in Clone environment. Before create it on production
A real test is always better than an estimate test
I recommend to add 10% margin from development to production (the production database is always run)
Thanks
This discussion has been closed.