From: | Sam Mason <sam(at)samason(dot)me(dot)uk> |
---|---|
To: | pgsql-general(at)postgresql(dot)org |
Subject: | Re: Conversion of string to int using digits at beginning |
Date: | 2008-11-19 14:33:13 |
Message-ID: | 20081119143313.GC2459@frubble.xen.chris-lamb.co.uk |
Views: | Raw Message | Whole Thread | Download mbox | Resend email |
Thread: | |
Lists: | pgsql-general |
On Wed, Nov 19, 2008 at 12:50:23PM +0200, Andrus wrote:
> Sam,
> > SELECT MAX(nullif(regexp_replace(test, '^([0-9]*).*$', E'\\1'),'')::INT);
>
> Thank you.
> This seems to work but is bit slow.
It will have to be executed against every row before you get an answer,
so if you're just after the max of a whole table will be pretty slow.
> How to speed it up ?
> Should I create index
>
> CREATE INDEX test ON test ( nullif(regexp_replace(test, '^([0-9]*).*$',
> E'\\1'),'')::INT );
that would work. I'd be tempted to use the substring() function instead
as it looks a bit prettier (peformance seems indistuinguishable). So
I'd use the following pair:
CREATE INDEX test_test_idx ON test
((nullif(substring(test, '^[0-9]*'),'')::int));
and
SELECT MIN(nullif(substring(test, '^[0-9]*'),'')::int) FROM test;
you could use a view as well, at which point you wouldn't have to
remember how you were converting the string into an int:
CREATE VIEW test_v AS
SELECT *, nullif(substring(test, '^[0-9]*'),'')::int AS test_int
FROM test;
allowing a simple:
SELECT MIN(test_int) FROM test_v;
hope that helps!
Sam
From | Date | Subject | |
---|---|---|---|
Next Message | Sam Mason | 2008-11-19 14:38:20 | Re: Any risks in using FUNCTIONs (stored procedures) instead of raw sql queries? |
Previous Message | Alvaro Herrera | 2008-11-19 13:55:14 | Re: Encoding |