Thread: Is there an equivalent for Oracle's user_tables.num_rows

Is there an equivalent for Oracle's user_tables.num_rows

From
"Virag Saksena"
Date:
All,
    I am looking to automate analyze table in my application.
 
I have some insert only tables in my application which I need to analyze as data grows.
Since the inserts are application controlled, I can choose to run analyze when I determine the
data has grown more than x% since last analyze.
 
However since users can truncate the tables too, I need to be able to tell the numbers of rows
in the table as perceived by the optimizer.
 
I could not decipher a good way of telling the number of table rows from pg_stats/pg_statistics.
 
Does someone know of a way of telling what the optimizer believes the number of rows are ?
 
The tables in question have multi-column primary keys.
 
Regards,
 
Virag

Re: Is there an equivalent for Oracle's user_tables.num_rows

From
Tom Lane
Date:
"Virag Saksena" <virag@auptyma.com> writes:
> Does someone know of a way of telling what the optimizer believes the =
> number of rows are ?

You're looking in the wrong place; see pg_class.relpages and reltuples.

But note that in recent releases neither one is taken as gospel.
Instead the planner uses the current physical table size in place of
relpages, and scales reltuples correspondingly.  So neither steady
growth nor truncation create a need for re-ANALYZE; at least not as long
as the other statistics don't change too much.

            regards, tom lane

Re: Is there an equivalent for Oracle's user_tables.num_rows

From
"Virag Saksena"
Date:
Thanks, that is exactly what I was looking for

I know that number of rows may not be the best indicator, but it is a
heuristic that can be tracked
easily, causing analyze for the first x insert events, and then only doing
it only when an insert event causes
total rows to exceed y % of the optimizer perceived rows

Other more accurate heuristics like relative distribution of columns would
be harder to track in the application,
and I'd rather let the database do that by issuing the analyze

Regards,

Virag

----- Original Message -----
From: "Tom Lane" <tgl@sss.pgh.pa.us>
To: "Virag Saksena" <virag@auptyma.com>
Cc: <pgsql-performance@postgresql.org>
Sent: Friday, February 09, 2007 4:45 PM
Subject: Re: [PERFORM] Is there an equivalent for Oracle's
user_tables.num_rows


> "Virag Saksena" <virag@auptyma.com> writes:
>> Does someone know of a way of telling what the optimizer believes the =
>> number of rows are ?
>
> You're looking in the wrong place; see pg_class.relpages and reltuples.
>
> But note that in recent releases neither one is taken as gospel.
> Instead the planner uses the current physical table size in place of
> relpages, and scales reltuples correspondingly.  So neither steady
> growth nor truncation create a need for re-ANALYZE; at least not as long
> as the other statistics don't change too much.
>
> regards, tom lane
>


Re: Is there an equivalent for Oracle'suser_tables.num_rows

From
"Simon Riggs"
Date:
On Fri, 2007-02-09 at 19:45 -0500, Tom Lane wrote:
> "Virag Saksena" <virag@auptyma.com> writes:
> > Does someone know of a way of telling what the optimizer believes the =
> > number of rows are ?
>
> You're looking in the wrong place; see pg_class.relpages and reltuples.
>
> But note that in recent releases neither one is taken as gospel.
> Instead the planner uses the current physical table size in place of
> relpages, and scales reltuples correspondingly.  So neither steady
> growth nor truncation create a need for re-ANALYZE; at least not as long
> as the other statistics don't change too much.

That does work very well for Production systems, but not for
Development.

In 8.4, I'll be looking for a way to export Production system stats to a
Dev server that *acts* as if it really had 10^lots rows in it. That will
also help us support the optimiser when it is acting in extreme
conditions that are not sensibly reproducible in reality by hackers. It
will also provide us with what-if capability for system expansion.

--
  Simon Riggs
  EnterpriseDB   http://www.enterprisedb.com