Re: Terrible performance on wide selects

Lists: pgsql-generalpgsql-hackerspgsql-performance
From: Steve Crawford <scrawford(at)pinpointresearch(dot)com>
To: pgsql-general(at)postgresql(dot)org
Subject: Terrible performance on wide selects
Date: 2003-01-17 19:37:26
Message-ID: 20030117193726.1CFCB103E5@polaris.pinpointresearch.com
Views: Raw Message | Whole Thread | Download mbox | Resend email
Lists: pgsql-general pgsql-hackers pgsql-performance

I have a table which is rather wide (~800 columns) and consists of a few
columns of identifying data (run time, channel and such) and up to several
hundred columns of collected data (no, normalization does not suggest putting
collected data in another table - collected item 1 always corresponds to
collected item 1 but is completely different than item 3).

My test table is very short (62 rows) but in production would grow by several
thousand rows per day. Unfortunately if my test data is correct, performance
on wide selects is so bad that it will render the system unusable.

Here's the test. I have created two versions of the table - one stores the
collected data in an array of text and the other stores the data in
individual columns, no joins, no indexes. Times are averages of many runs -
the times varied very little and the data is small enough that I'm sure it
was served from RAM. Postgres CPU utilization observed on the longer runs was
98-99%. Changing the output format didn't seem to change things significantly.

Times for selecting all the columns in the table:
select * from columnversion;
8,000 ms

select * from arrayversion;
110 ms

select * from arraytocolumnview (data in the array version but converted to
columns in the view)
10,000 ms

Times to select a single column in a table:
select runstarttime from columversion;
32 ms

select runstarttime from arrayversion;
6 ms

So the question is, does it seem reasonable that a query on fundamentally
identical data should take 70-90 times as long when displayed as individual
columns vs. when output as a raw array and, more imporantly, what can I do to
get acceptable performance on this query?

Cheers,
Steve


From: Tom Lane <tgl(at)sss(dot)pgh(dot)pa(dot)us>
To: Steve Crawford <scrawford(at)pinpointresearch(dot)com>
Cc: pgsql-general(at)postgresql(dot)org
Subject: Re: Terrible performance on wide selects
Date: 2003-01-17 23:06:52
Message-ID: 19506.1042844812@sss.pgh.pa.us
Views: Raw Message | Whole Thread | Download mbox | Resend email
Lists: pgsql-general pgsql-hackers pgsql-performance

Steve Crawford <scrawford(at)pinpointresearch(dot)com> writes:
> So the question is, does it seem reasonable that a query on fundamentally
> identical data should take 70-90 times as long when displayed as individual
> columns vs. when output as a raw array and, more imporantly, what can I do to
> get acceptable performance on this query?

There are undoubtedly some places that are O(N^2) in the number of
targetlist items. Feel free to do some profiling to identify them.
It probably won't be real hard to fix 'em once identified.

regards, tom lane


From: Tom Lane <tgl(at)sss(dot)pgh(dot)pa(dot)us>
To: Steve Crawford <scrawford(at)pinpointresearch(dot)com>
Cc: pgsql-performance(at)postgreSQL(dot)org, pgsql-hackers(at)postgreSQL(dot)org
Subject: Re: Terrible performance on wide selects
Date: 2003-01-22 23:14:30
Message-ID: 25182.1043277270@sss.pgh.pa.us
Views: Raw Message | Whole Thread | Download mbox | Resend email
Lists: pgsql-general pgsql-hackers pgsql-performance

Steve Crawford sent me some profiling results for queries involving wide
tuples (hundreds of columns).

> Done, results attached. nocachegetattr seems to be the likely suspect.

Yipes, you can say that again.

% cumulative self self total
time seconds seconds calls ms/call ms/call name
93.38 26.81 26.81 885688 0.03 0.03 nocachegetattr

0.00 0.00 1/885688 heapgettup [159]
0.00 0.00 1/885688 CatalogCacheComputeTupleHashValue [248]
0.00 0.00 5/885688 SearchCatCache [22]
13.40 0.00 442840/885688 ExecEvalVar [20]
13.40 0.00 442841/885688 printtup [12]
[11] 93.4 26.81 0.00 885688 nocachegetattr [11]

Half of the calls are coming from printtup(), which seems relatively easy
to fix.

/*
* send the attributes of this tuple
*/
for (i = 0; i < natts; ++i)
{
...
origattr = heap_getattr(tuple, i + 1, typeinfo, &isnull);
...
}

The trouble here is that in the presence of variable-width fields,
heap_getattr requires a linear scan over the tuple --- and so the total
time spent in it is O(N^2) in the number of fields.

What we could do is reinstitute heap_deformtuple() as the inverse of
heap_formtuple() --- but make it extract Datums for all the columns in
a single pass over the tuple. This would reduce the time in printtup()
from O(N^2) to O(N), which would pretty much wipe out that part of the
problem.

The other half of the calls are coming from ExecEvalVar, which is a
harder problem to solve, since those calls are scattered all over the
place. It's harder to see how to get them to share work. Any ideas
out there?

regards, tom lane