Thread: TOAST not working

TOAST not working

From
list_man
Date:
Hi,

I wonder if anyone can help.

I have a VERY wide table and rows. There are over 800 columns of type:
numeric(11,2)

I can create the table no problem, but when I go to fill out a full row
with data, I get the message about reaching the 8k limit.

Can someone tell me if I have to 'enable' TOAST on columns to have  it
kick in. According to my research, numeric data types are toastable.

I'd appreciate if anyone can give me lit1e.

Thanks

PS. I'm running Postgres v8.0x


Re: TOAST not working

From
Tom Lane
Date:
list_man <listman@elkenserver.net> writes:
> I have a VERY wide table and rows. There are over 800 columns of type:
> numeric(11,2)

Perhaps you should reconsider your data design.  Maybe some of those
columns would more logically form an array?

            regards, tom lane

Re: TOAST not working

From
list_man
Date:
Thanks for the suggestion Tom... I'm looking into it.

To continue however and educate me on datatypes & TOAST, should a row of
10k+, in this case consisting of the datatype listed below, store OK,
when TOAST kicks in?

thanks... Angus

On Sat, 2006-06-10 at 12:28 -0400, Tom Lane wrote:
> list_man <listman@elkenserver.net> writes:
> > I have a VERY wide table and rows. There are over 800 columns of type:
> > numeric(11,2)
>
> Perhaps you should reconsider your data design.  Maybe some of those
> columns would more logically form an array?
>
>             regards, tom lane
>
> ---------------------------(end of broadcast)---------------------------
> TIP 6: explain analyze is your friend
>


Re: TOAST not working

From
Christopher Browne
Date:
Centuries ago, Nostradamus foresaw when listman@elkenserver.net (list_man) would write:
> Can someone tell me if I have to 'enable' TOAST on columns to have  it
> kick in. According to my research, numeric data types are toastable.

TOAST is only used on individual columns that exceed 8K in size.

The only way you'll be TOASTing numeric columns is if they are
individually defined to occupy > 8192 bytes.

Those are *BIG* numeric values; perhaps you're misunderstanding the
intent of TOAST...
--
let name="cbbrowne" and tld="gmail.com" in String.concat "@" [name;tld];;
http://linuxdatabases.info/info/slony.html
What do little birdies see when they get knocked unconscious?

Re: TOAST not working

From
"Jim C. Nasby"
Date:
On Sat, Jun 10, 2006 at 05:10:06PM -0400, Christopher Browne wrote:
> Centuries ago, Nostradamus foresaw when listman@elkenserver.net (list_man) would write:
> > Can someone tell me if I have to 'enable' TOAST on columns to have  it
> > kick in. According to my research, numeric data types are toastable.
>
> TOAST is only used on individual columns that exceed 8K in size.
>
> The only way you'll be TOASTing numeric columns is if they are
> individually defined to occupy > 8192 bytes.

Actually, it's BLCKSZ/4. From
http://www.postgresql.org/docs/8.1/interactive/storage-toast.html:

"The TOAST code is triggered only when a row value to be stored in a
table is wider than BLCKSZ/4 bytes (normally 2Kb)."

BTW, 'row value' seems a bit prone to confusion (could be interpreted as
the row itself). It'd probably be better to say 'field'. Barring
objections, I'll submit a patch.
--
Jim C. Nasby, Sr. Engineering Consultant      jnasby@pervasive.com
Pervasive Software      http://pervasive.com    work: 512-231-6117
vcard: http://jim.nasby.net/pervasive.vcf       cell: 512-569-9461

Re: TOAST not working

From
Tom Lane
Date:
"Jim C. Nasby" <jnasby@pervasive.com> writes:
> Actually, it's BLCKSZ/4. From
> http://www.postgresql.org/docs/8.1/interactive/storage-toast.html:

> "The TOAST code is triggered only when a row value to be stored in a
> table is wider than BLCKSZ/4 bytes (normally 2Kb)."

> BTW, 'row value' seems a bit prone to confusion (could be interpreted as
> the row itself). It'd probably be better to say 'field'.

No, because that would be wrong; the statement is correct as written.
The toaster tries to do something about rows that are wider than
BLCKSZ/4 (well, actually MaxTupleSize/4 ... try grepping the source
for TOAST_TUPLE_THRESHOLD).

The OP's problem is that he's got too dang many fields.  A TOAST pointer
is 20 bytes wide (on most machines, at least) so even if we toast every
single field out-of-line, we can't support more than about 400 toastable
fields in a row.  The FAQ says

   Maximum number of columns in a table? 250-1600 depending on column
   types

but the 1600 figure is for datatypes like int4 that only take 4 bytes
anyway.

The OP was trying to store numeric(11,2) fields.  If I'm counting on my
fingers correctly, such a value would occupy 16 bytes natively, which
means that pushing it out-of-line would be a dead loss anyway.  But he's
still not going to get more than 512 of them into an 8K page.

            regards, tom lane

Re: TOAST not working

From
Angus Berry
Date:
Ahhh... thank you. This clarifies TOAST for me. I see how TOAST applies
to individual columns that exceed the 8k page size.

Postgres specs state it's possible to have 2GB rows and up to 1,600
columns. Can you tell me what data type would get to fill this spec. I
wouldn't normally push to this limit, but I am expecting to have to
defend Postgres specs. to a 3rd party.

Questions like this also help me get to grips with Postgres internals.

thanks... Angus

On Sat, 2006-06-10 at 17:10 -0400, Christopher Browne wrote:
> Centuries ago, Nostradamus foresaw when listman@elkenserver.net (list_man) would write:
> > Can someone tell me if I have to 'enable' TOAST on columns to have  it
> > kick in. According to my research, numeric data types are toastable.
>
> TOAST is only used on individual columns that exceed 8K in size.
>
> The only way you'll be TOASTing numeric columns is if they are
> individually defined to occupy > 8192 bytes.
>
> Those are *BIG* numeric values; perhaps you're misunderstanding the
> intent of TOAST...


Re: TOAST not working

From
Martijn van Oosterhout
Date:
On Sat, Jun 10, 2006 at 10:43:02PM -0400, Angus Berry wrote:
> Ahhh... thank you. This clarifies TOAST for me. I see how TOAST applies
> to individual columns that exceed the 8k page size.
>
> Postgres specs state it's possible to have 2GB rows and up to 1,600
> columns. Can you tell me what data type would get to fill this spec. I
> wouldn't normally push to this limit, but I am expecting to have to
> defend Postgres specs. to a 3rd party.

Any variable length datatype might be able to go to 2GB. Things like
text, char, varchar and bytea are the obvious ones. Arrays too IIRC.

However, as pointed out, even a toasted field takes about 20 bytes,
which means you're limited to maybe 400 toasted fields. If you use
integers you can get to 1600.

Normally however, in cases where you need to store a lot of columns,
what you really want is an array. You could easily store an array with
a few million numerics in a single field...

Have a nice day,
--
Martijn van Oosterhout   <kleptog@svana.org>   http://svana.org/kleptog/
> From each according to his ability. To each according to his ability to litigate.

Attachment