Supporting numeric comparisons in AppDB on PostgreSQL 9.
SELECT email
, datum1
, ROW(COALESCE(trim(substring(datum1, E'^[^0-9]+')), ''), COALESCE(substring(datum1, E'([0-9]+(\\.[0-9]+)?)')::float,0), datum1) AS orderable
FROM leads4
WHERE unit_id = 3854 AND datum1 IS NOT NULL
AND ROW(COALESCE(trim(substring(datum1, E'^[^0-9]+')), ''), COALESCE(substring(datum1, E'([0-9]+(\\.[0-9]+)?)')::float,0), datum1) > ROW(COALESCE(trim(substring('50', E'^[^0-9]+')), ''), COALESCE(substring('50', E'([0-9]+(\\.[0-9]+)?)')::float,0), '50')
ORDER BY orderable
email |
datum1 |
orderable |
correlr@aweber.com |
69 |
("",69,69) |
correlr+0031@aweber.net |
73.50 |
("",73.5,73.50) |
scottm@aweber.net |
101 |
("",101,101) |
correlr+0033@aweber.net |
215 555 1234 |
("",215,"215 555 1234") |
correlr+0040@aweber.net |
215 555 9372 |
("",215,"215 555 9372") |
correlr+005@aweber.net |
215-555-7777 |
("",215,215-555-7777) |
correlr+0028@aweber.net |
404 |
("",404,404) |
correlr+0032@aweber.net |
404 Apple |
("",404,"404 Apple") |
correlr+0029@aweber.net |
711 |
("",711,711) |
correlr+0037@aweber.net |
$ 112.65 |
($,112.65,"$ 112.65") |
correlr+0034@aweber.net |
$112.65 |
($,112.65,$112.65) |
—–@aweber.com |
A 100 |
(A,100,"A 100") |
correlr+004@aweber.net |
ED-209 |
(ED-,209,ED-209) |
CREATE OR REPLACE FUNCTION public.collate_numerically(value text)
RETURNS RECORD
LANGUAGE SQL STRICT IMMUTABLE AS $$
SELECT ROW(COALESCE(trim(substring($1, E'^[^0-9]+')), ''),
COALESCE(substring($1, E'([0-9]+(\\.[0-9]+)?)')::float,0),
$1);
$$;
SELECT email
, datum1
, CASE
WHEN datum1 IS NULL THEN ''
WHEN datum1 ~ E'^[0-9\.]+$'
THEN lpad(lower(datum1), 30, '0')
ELSE rpad(lower(datum1), 30, '0')
END AS orderable
FROM leads4
WHERE unit_id = 3854 AND datum1 IS NOT NULL
ORDER BY orderable
SELECT email, datum1 FROM leads4
WHERE unit_id = 3854 AND datum1 IS NOT NULL
ORDER BY datum1
SELECT email
, datum1
, ROW(COALESCE(substring(datum1, E'[^0-9]+'), ''), COALESCE(substring(datum1, E'[0-9]+')::int,0), datum1) AS orderable
FROM leads4
WHERE unit_id = 13971
AND ROW(COALESCE(substring('1548862518', E'[^0-9]+'), ''), COALESCE(substring('1548862518', E'[0-9]+')::int,0), '1548862518')
>
ROW(COALESCE(substring(datum1, E'[^0-9]+'), ''), COALESCE(substring(datum1, E'[0-9]+')::int,0), datum1)
ORDER BY orderable;
email |
datum1 |
orderable |
moana.rock.diuwasly@mailosaur.io |
|
("",0,"") |
1548862167.suf.lsb8bll2@mailosaur.io |
|
("",0,) |
1548862018.suf.lsb8bll2@mailosaur.io |
|
("",0,) |
1548861949.suf.lsb8bll2@mailosaur.io |
|
("",0,) |
1548861848.suf.lsb8bll2@mailosaur.io |
|
("",0,) |
1548862325.suf.lsb8bll2@mailosaur.io |
|
("",0,) |
bob.smith.diuwasly@mailosaur.io |
|
("",0,) |
iharh+8df668454@aweber.net |
|
("",0,) |
1548861786.suf.lsb8bll2@mailosaur.io |
|
("",0,) |
iharh+56651@aweber.net |
3 |
("",3,3) |