From: | Maximilian Tyrtania <maximilian(dot)tyrtania(at)onlinehome(dot)de> |
---|---|
To: | Scott Marlowe <scott(dot)marlowe(at)gmail(dot)com>, Paul Gaspar <devlist(at)revolversoft(dot)com> |
Cc: | 'PostgreSQL pg-general List' <pgsql-general(at)postgresql(dot)org> |
Subject: | Re: Collation in ORDER BY not lexicographical |
Date: | 2009-09-29 12:36:57 |
Message-ID: | C6E7CC09.3B8A7%maximilian.tyrtania@onlinehome.de |
Views: | Raw Message | Whole Thread | Download mbox | Resend email |
Thread: | |
Lists: | pgsql-general |
am 29.09.2009 11:21 Uhr schrieb Scott Marlowe unter scott(dot)marlowe(at)gmail(dot)com:
> On Tue, Sep 29, 2009 at 2:52 AM, Paul Gaspar <devlist(at)revolversoft(dot)com> wrote:
>> Hi!
>>
>> We have big problems with collation in ORDER BY, which happens in binary
>> order, not alphabetic (lexicographical), like:.
>>
>> A
>> B
>> Z
>> a
>> z
>> Ä
>> Ö
>> ä
>> ö
>>
>
>> PG is running on Mac OS X 10.5 and 10.6 Intel.
>
> I seem to recall there were some problem with Mac locales at some
> point being broken. Could be you're running into that issue.
Yep, i ran into this as well. Here is my workaround: Create a function like
this:
CREATE OR REPLACE FUNCTION f_getorderbyfriendlyversion(texttoconvert text)
RETURNS text AS
$BODY$
select
replace(replace(replace(replace(replace(replace($1,'Ä','A'),'Ö','O'),'Ü','U'
),'ä','a'),'ö','o'),'ü','u');
$BODY$
LANGUAGE 'sql' IMMUTABLE STRICT
COST 100;
ALTER FUNCTION f_getorderbyfriendlyversion(text) OWNER TO postgres;
Then create an index like this:
create index idx_personen_nachname_orderByFriendly on personen
(f_getorderbyfriendlyversion(nachname))
Now you can do:
select * from personen order by f_getorderbyfriendlyversion(p.nachname)
Seems pretty fast.
Best,
Maximilian Tyrtania
From | Date | Subject | |
---|---|---|---|
Next Message | Merlin Moncure | 2009-09-29 12:39:54 | Re: Delphi connection ? |
Previous Message | Brian Modra | 2009-09-29 12:30:48 | Re: variables in ad hoc queries |