Re: 8.2.4 Won't Build 8.1 Functional Indexes

[Date Prev][Date Next][Thread Prev][Thread Next][Date Index][Thread Index]

 



Well, the one index:
CREATE INDEX acceptedbilling_to_date
_accepted_billing_dt_idx
  ON acceptedbilling
  USING btree
  (to_date(accepted_billing_dt::text, 'yyyymmdd'::text));.

Reject:
ERROR: functions in index _expression_ must be marked IMMUTABLE
SQL state: 42P17

Is actually a date stored in a varchar field (stupid I know, but it's a continual fight between the me (the dba), management, and our COBOL programmers).  I was indexing it as a date so that I can treat it as a date in some of the non-COBOL programs/utilities that we have written.

The second index is rather stupid, it was an early index before I figured out how to split a timestamp.

Anyway, is there a way to make the first index work?  Otherwise we end up with a seq scan on our billing table which is very painful.

Thanks,

Chris


On 6/6/07, Tom Lane <tgl@xxxxxxxxxxxxx> wrote:
Alvaro Herrera <alvherre@xxxxxxxxxxxxxxxxx> writes:
> You can't do this because to_date and other functions are not immutable.
> 8.2 seems to be more picky about this -- the date conversions of
> timestamptz columns are dependent on the current timezone.

The reason 8.2 is more picky is that the function is less immutable
thanks to the addition of locale-dependent functionality:
http://archives.postgresql.org/pgsql-committers/2006-11/msg00264.php

I gather that the underlying column is timestamp without tz, or it would
never have worked in 8.1 either.  That being the case, these index
definitions seem pretty darn stupid anyway --- why aren't you just
indexing on date_trunc or a plain cast to date?

                        regards, tom lane


[Index of Archives]     [KVM ARM]     [KVM ia64]     [KVM ppc]     [Virtualization Tools]     [Spice Development]     [Libvirt]     [Libvirt Users]     [Linux USB Devel]     [Linux Audio Users]     [Yosemite Questions]     [Linux Kernel]     [Linux SCSI]     [XFree86]

  Powered by Linux