Skip to Main Content
  • Questions
  • Default size of a range partition for a migrated table

Breadcrumb

Question and Answer

Chris Saxon

Thanks for the question.

Asked: October 01, 2024 - 11:19 am UTC

Last updated: October 02, 2024 - 1:42 pm UTC

Version: 19.3

Viewed 1000+ times

You Asked

I have an old table that was created once with an initial extent. E.g.

create table a (id number(3), col_date timestamp(6)) storage (initial 128M) 


Now data growed and a partitioning was applied:

alter table a modify partition by range (col_date) less than (TIMESTAMP '2024-01-01 00:00:00.000000') (partition old_data values less than (TIMESTAMP '2024-01-01 00:00:00.000000')) storage (initial 8M) 


Now when a new partition is created, the initial 128M is allocated, not 8M. Can this somehow be changed? This is just an example and my real initial values are much larger and therefore not that nice to handle.

and Chris said...

The alter table statement is invalid, so it's unclear what exactly you've tried.

You can specify the initial size for each partition when modifying the table to partitioned. After this you can change the default initial size for new partitions.

create table a (id number(3), col_date timestamp(6)) 
storage ( initial 128M );

select initial_extent from user_tables
where  table_name = 'A';

INITIAL_EXTENT
--------------
     134217728

alter table a modify 
  partition by range (col_date) 
  interval ( interval '1' month ) (
    partition old_data values less than (TIMESTAMP '2024-01-01 00:00:00')
    storage (initial 16M),
    partition newer_data values less than (TIMESTAMP '2024-03-01 00:00:00')
    storage (initial 32M)
  );

alter table a modify 
  default attributes storage ( initial 8M );

select partition_name, initial_extent from user_tab_partitions
where  table_name = 'A';

PARTITION_ INITIAL_EXTENT
---------- --------------
NEWER_DATA       33554432
OLD_DATA         16777216

insert into a values ( 1, systimestamp );

select partition_name, initial_extent from user_tab_partitions
where  table_name = 'A';

PARTITION_ INITIAL_EXTENT
---------- --------------
NEWER_DATA       33554432
OLD_DATA         16777216
SYS_P4722         8388608

Rating

  (1 rating)

Comments

A reader, October 02, 2024 - 11:47 am UTC

Thanks a lot, this statement is the key: alter table a modify default attributes storage ( initial 8M );

I always tried to modify it and got an error: alter table a storage (initial 8M);
Chris Saxon
October 02, 2024 - 1:42 pm UTC

You're welcome

More to Explore

VLDB

If you are new to partitioning, check out Connor McDonald's introduction series here.

VLDB

Documentation set on VLDB and Partitioning.