David Olbersen wrote:
Now the question: is there a single index I can create that will be
used when my  WHERE clause contains either urlhost or urltld? I could
create two functional indexes, but that seems a bit silly to me.


I can't think of how to do only one index in 7.3.x and earlier, but FWIW, this works in 7.4devel (which should be in beta next Monday):


create or replace function tld(text) returns text as '
select split_part(split_part(substr($1,8,length($1)),''/'',1),''.'',3)
' language 'sql' STRICT IMMUTABLE;

regression=# select tld('http://www.foobar.com/really/long/path/to/a/file');
 tld
-----
 com
(1 row)

create or replace function sld(text) returns text as '
select split_part(split_part(substr($1,8,length($1)),''/'',1),''.'',2)
' language 'sql' STRICT IMMUTABLE;

regression=# select sld('http://www.foobar.com/really/long/path/to/a/file');
  sld
--------
 foobar
(1 row)

create table urls(f1 text);
insert into urls values('http://www.foobar.com/really/long/path/to/a/file');
create index urls_idx1 on urls(tld(f1),sld(f1));

-- just to see index usage on toy table
set enable_seqscan to off;

regression=# explain analyze select * from urls where tld(f1) = 'com';
QUERY PLAN
----------------------------------------------------------------------
Index Scan using urls_idx1 on urls (cost=0.00..4.69 rows=1 width=32) (actual time=0.07..0.07 rows=1 loops=1)
Index Cond: (split_part(split_part(substr(f1, 8, length(f1)), '/'::text, 1), '.'::text, 3) = 'com'::text)
Total runtime: 0.18 msec
(3 rows)


regression=# explain analyze select * from urls where tld(f1) = 'com' and sld(f1) = 'foobar';

QUERY PLAN
---------------------------------------------------------------------
Index Scan using urls_idx1 on urls (cost=0.00..4.70 rows=1 width=32) (actual time=0.08..0.09 rows=1 loops=1)
Index Cond: ((split_part(split_part(substr(f1, 8, length(f1)), '/'::text, 1), '.'::text, 3) = 'com'::text) AND (split_part(split_part(substr(f1, 8, length(f1)), '/'::text, 1), '.'::text, 2) = 'foobar'::text))
Total runtime: 0.21 msec
(3 rows)



Joe



---------------------------(end of broadcast)--------------------------- TIP 7: don't forget to increase your free space map settings

Reply via email to