Beefy Boxes and Bandwidth Generously Provided by pair Networks
Problems? Is your data what you think it is?
 
PerlMonks  

comment on

( #3333=superdoc: print w/replies, xml ) Need Help??
where name like ? || '%'

But that still won't use an index [...]

Well, it depends.

From PostgreSQL 9.1 onwards, indexes (made by the trigram extension pg_trgm, an extension that comes with postgres) can be used in like searches. (careful, trigram indexes are large, and therefore not always appropriate).

A test with a 1-column table, filled with 80-characters 'random' strings; 1 million rows. There happened to be two rows that start with 'erix', so I'll use those as search target (i.e.: where txt like 'erix%').

-- index created like this: create index azjunk6_trgm_re_idx on azjunk6 using gin (txt gin_trgm_ops); -- running a psql session, showing both -- the regular output, and the EXPLAIN: $ psql Timing is on. psql (9.2.4) Type "help" for help. testdb=# prepare ps(text) as select txt from azjunk6 where txt like $1 || '%'; --> $1 is ? in +DBI/DBD::Pg PREPARE Time: 13.785 ms testdb=# execute ps('erix'); txt ---------------------------------------------------------------------- +------------ erixeweq jp ayoyu marqnrjr ughinmfwklvmzxtrfafy mvwf ond wrz lg yso +tkgli ne n erix onka fp ax erk ddcduajmv yrltcfjsfghlt pq cmdfximql jj ckyzhpwhc +q zkakna (2 rows) Time: 54.482 ms testdb=# explain analyze execute ps('erix'); QUERY PLAN ---------------------------------------------------------------------- +------------------------------------------------------------- Bitmap Heap Scan on azjunk6 (cost=108.78..484.93 rows=100 width=81) +(actual time=48.901..48.913 rows=2 loops=1) Recheck Cond: (txt ~~ 'erix%'::text) Rows Removed by Index Recheck: 16 -> Bitmap Index Scan on azjunk6_trgm_re_idx (cost=0.00..108.75 ro +ws=100 width=0) (actual time=48.882..48.882 rows=18 loops=1) Index Cond: (txt ~~ 'erix%'::text) Total runtime: 48.957 ms (6 rows) Time: 49.714 ms -- look mum no hints testdb=#

( And yes, it is faster: with the index removed, it takes 147.060 ms )

Even better: PostgreSQL 9.3 (in beta ATM) lets trgm index on regexen.


In reply to Re^4: DBI placeholders and like statement by erix
in thread DBI placeholders and like statement by jfroebe

Title:
Use:  <p> text here (a paragraph) </p>
and:  <code> code here </code>
to format your post; it's "PerlMonks-approved HTML":



  • Posts are HTML formatted. Put <p> </p> tags around your paragraphs. Put <code> </code> tags around your code and data!
  • Titles consisting of a single word are discouraged, and in most cases are disallowed outright.
  • Read Where should I post X? if you're not absolutely sure you're posting in the right place.
  • Please read these before you post! —
  • Posts may use any of the Perl Monks Approved HTML tags:
    a, abbr, b, big, blockquote, br, caption, center, col, colgroup, dd, del, div, dl, dt, em, font, h1, h2, h3, h4, h5, h6, hr, i, ins, li, ol, p, pre, readmore, small, span, spoiler, strike, strong, sub, sup, table, tbody, td, tfoot, th, thead, tr, tt, u, ul, wbr
  • You may need to use entities for some characters, as follows. (Exception: Within code tags, you can put the characters literally.)
            For:     Use:
    & &amp;
    < &lt;
    > &gt;
    [ &#91;
    ] &#93;
  • Link using PerlMonks shortcuts! What shortcuts can I use for linking?
  • See Writeup Formatting Tips and other pages linked from there for more info.
  • Log In?
    Username:
    Password:

    What's my password?
    Create A New User
    Chatterbox?
    and the web crawler heard nothing...

    How do I use this? | Other CB clients
    Other Users?
    Others exploiting the Monastery: (3)
    As of 2021-05-08 17:26 GMT
    Sections?
    Information?
    Find Nodes?
    Leftovers?
      Voting Booth?
      Perl 7 will be out ...





      Results (96 votes). Check out past polls.

      Notices?