Search Postgresql Archives

Re: Postgres case insensitive searches

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

 



On 06/29/2013 09:02 AM, bhanu udaya wrote:
Hello,
I agree that it is just search condition. But, in a 2.5 million record table search, upper function is not that fast.  The expectation is to get the query retrieved in 100 ms...with all indexes used.
 
I tried with upper, Citext, but the result set was more than a second.
 
The OS server we are using is Linux 64 bit.
 
Thanks and Regards
Radha Krishna
 
> Subject: Re: [pgadmin-support] Postgres case insensitive searches
> From: haramrae@xxxxxxxxx
> Date: Sat, 29 Jun 2013 09:37:51 +0200
> CC: laurenz.albe@xxxxxxxxxx; pgsql-general@xxxxxxxxxxxxxx; pgadmin-support@xxxxxxxxxxxxxx
> To: udayabhanu1984@xxxxxxxxxxx
>
> On Jun 29, 2013, at 3:59, bhanu udaya <udayabhanu1984@xxxxxxxxxxx> wrote:
>
> > Thanks. But, I do not want to convert into upper and show the result.
>
> Why not? It won't modify your results, just the search condition:
>
> SELECT id, val FROM t WHERE upper(val) LIKE 'AB%' ORDER BY val;
>
> Or:
>
> SELECT id, val FROM t WHERE upper(val) LIKE 'AB%' ORDER BY upper(val), val;
>
>
> > Example, if I have records as below:
> > id type
> > 1. abcd
> > 2. Abcdef
> > 3. ABcdefg
> > 4. aaadf
> >
> > The below query should report all the above
> >
> > select * from table where type like 'ab%'. It should get all above 3 records. Is there a way the database itself can be made case-insensitive with UTF8 characterset. I tried with character type & collation POSIX, but it did not really help.
>
> I was under the impression this would work, but ISTR that not every OS has this capability (Postgres makes use of the OS collation mechanics). So, what OS are you running the server on?
>

Duplicate the column with an upper or lowercase version and run all queries against that.

CREATE TABLE foo (
    id serial PRIMARY KEY,
    val text,
    val_lower text
);

Index val_lower. Use triggers to keep val and val_lower in sync and discard all attempts to write directly to val_lower. Then all queries would be of the form

SELECT id, val
FROM foo
WHERE val_lower LIKE 'ab%';

Wouldn't want to write every table like this, but if (a) query speed trumps all other requirements and (b) functional index, CITEXT, etc. have all been rejected as not fast enough…

--Lee


-- 
Lee Hachadoorian
Assistant Professor in Geography, Dartmouth College
http://freecity.commons.gc.cuny.edu

[Date Prev][Date Next][Thread Prev][Thread Next][Date Index][Thread Index]
[Index of Archives]     [Postgresql Jobs]     [Postgresql Admin]     [Postgresql Performance]     [Linux Clusters]     [PHP Home]     [PHP on Windows]     [Kernel Newbies]     [PHP Classes]     [PHP Books]     [PHP Databases]     [Postgresql & PHP]     [Yosemite]
  Powered by Linux