Thread: Re: [PERFORM] How to force an Index ?

Re: [PERFORM] How to force an Index ?

From
Rhaoni Chiu Pereira
Date:
I solve this problem doing this:

 create function date_to_yyyymm( timestamp ) returns gsames00.ano_mes%type as
 'select to_char($1, ''YYYYMM'');
 ' language sql immutable strict;

And changing the SQL where clause:

 ... gsames00.ano_mes = to_char(ftnfco00.data_emissao,'YYYYMM') AND ...

to:

 ... gsames00.ano_mes = date_to_yyyymm(ftnfco00.data_emissao) AND ...

   Then it uses the gsames00 index instead of a SeqScan 'cuz it is camparing
same data type, but .. I don't want to create this function 'cuz this aplication
is used with Oracle too.
I need to know if there is a way to set the to_char output to varchar instead of
text !
  Any Idea ? So, this way I wont have to change my aplication source.



Atenciosamente,

Rhaoni Chiu Pereira
Sistêmica Computadores

Visite-nos na Web: http://sistemica.info
Fone/Fax : +55 51 3328 1122



Citando Josh Berkus <josh@agliodbs.com>:

<> Rhaoni,
<>
<> First off, thanks for posting such complete info.
<>
<> >    ... gsames00.ano_mes = to_char(ftnfco00.data_emissao,'YYYYMM') AND ...
<> >
<> >    ftnfco00.data_emissao is a timestamp. When I run the explain analyze it
<>
<> says:
<> >
<> > ...
<> >  ->  Seq Scan on gsames00  (cost=100000000.00..100000006.72 rows=372
<> width=10)
<> > (actual time=0.01..0.96 rows=372 loops=19923)
<> > ...
<>
<> Your problem is that you're comparing against a calculated expression based
<> on
<> ftnfco00, which is being filtered in about 18 other ways.  As a result, the
<>
<> planner doesn't know what to estimate (see the cost estimate of 100000000,
<> which is a "blind guess" values) and goes for a seq scan.
<>
<>  Can I ask you to try this workaround, to create an expressional index on
<> ftnfco00 (assuming that data_emmisao is of type DATE)
<>
<> create function date_to_yyyymm( date ) returns text as
<> 'select to_char($1, ''YYYYMM'');
<> ' language sql immutable strict;
<>
<> create index idx_data_yyyymm on ftnfco00(date_to_yyyymm(data_emmisao));
<>
<> --
<> -Josh Berkus
<>  Aglio Database Solutions
<>  San Francisco
<>
<>
<> ---------------------------(end of broadcast)---------------------------
<> TIP 4: Don't 'kill -9' the postmaster
<>


Re: [PERFORM] How to force an Index ?

From
Tom Lane
Date:
Rhaoni Chiu Pereira <rhaoni@sistemica.info> writes:
> I need to know if there is a way to set the to_char output to varchar instead of
> text !

Why don't you change the datatype of ano_mes to text, instead?  It's
unlikely your application would notice the difference.  (You could set
a CHECK constraint on the length if you really want to duplicate the
behavior of varchar(6).)

Alternatively, try 7.4 beta. I believe this issue goes away in 7.4,
because varchar no longer has separate comparison operators.

Of course there's also the option of modifying to_char's result type
in pg_proc, but I won't promise that doing so wouldn't break things.

            regards, tom lane

Re: [PERFORM] How to force an Index ?

From
Josh Berkus
Date:
Rhaoni,

>  ... gsames00.ano_mes = to_char(ftnfco00.data_emissao,'YYYYMM') AND ...

>    Then it uses the gsames00 index instead of a SeqScan 'cuz it is
> camparing same data type, but .. I don't want to create this function 'cuz
> this aplication is used with Oracle too.

You should have said that earlier ....

> I need to know if there is a way to set the to_char output to varchar
> instead of text !

Did you try:

... gsames00.ano_mes = (to_char(ftnfco00.data_emissao,'YYYYMM')::VARCHAR) AND
...


--
Josh Berkus
Aglio Database Solutions
San Francisco