Thread: partial index on a text field
Hi all, I have a text field which I'll be doing LIKE searches against so I wanted to set up an index on it. The data itself is too long to create a full index, so I can't just: chris=> create index blah on ff_index(icontent); ERROR: index row requires 21216 bytes, maximum size is 8191 So I thought I'd set up an index to use the first say 200 chars of the string chris=> create index blah on ff_index(substring(icontent, 0, 200)); ERROR: syntax error at or near "(" at character 40 I've tried many variations of this, same result. I know I can create a partial index on it if the field is less than 200 chars, but that doesn't help me. I'm running v7.4.5. Any suggestions ? Thanks, Chris.
"Chris" <chris@interspire.com> writes: > chris=> create index blah on ff_index(substring(icontent, 0, 200)); > ERROR: syntax error at or near "(" at character 40 > I'm running v7.4.5. Put an extra set of parens around it: create index blah on ff_index((substring(icontent, 0, 200))); "substring" looks like a function invocation but it isn't exactly, so you have to treat this as a general expression index. (This little inconsistency is fixed for 8.0, btw.) Note that the index will only do you any good if your queries are specifically written as "substring(icontent, 0, 200) LIKE 'pattern'". I suspect that you should instead be looking at full-text-indexing methods (see contrib/tsearch2, for instance). regards, tom lane
Hi Tom, Perfect, thanks :) I'll have another look at FTI now to see how it works (though from memory it's a tedious process to get up and running). Chris. -----Original Message----- From: Tom Lane [mailto:tgl@sss.pgh.pa.us] Sent: Monday, October 25, 2004 1:57 PM To: Chris Cc: pgsql-general@postgresql.org Subject: Re: [GENERAL] partial index on a text field "Chris" <chris@interspire.com> writes: > chris=> create index blah on ff_index(substring(icontent, 0, 200)); > ERROR: syntax error at or near "(" at character 40 > I'm running v7.4.5. Put an extra set of parens around it: create index blah on ff_index((substring(icontent, 0, 200))); "substring" looks like a function invocation but it isn't exactly, so you have to treat this as a general expression index. (This little inconsistency is fixed for 8.0, btw.) Note that the index will only do you any good if your queries are specifically written as "substring(icontent, 0, 200) LIKE 'pattern'". I suspect that you should instead be looking at full-text-indexing methods (see contrib/tsearch2, for instance). regards, tom lane