Beefy Boxes and Bandwidth Generously Provided by pair Networks
P is for Practical
 
PerlMonks  

comment on

( [id://3333]=superdoc: print w/replies, xml ) Need Help??

There are a few ways of achieving what you want.

  • The one you are using (SELECT ... ORDER BY RAND() LIMIT 1) is easy and immediate. As you said, efficiency could be very poor when your table size increases.

    However, you can improve the execution speed if you only select the primary key column in your query.

    Note that this code can be used also if you want to get more than one random question at once.

    my $limit = 1; my $query = qq{SELECT id FROM table ORDER BY RAND() LIMIT $limit}; my $ids = $dbh->selectcol_arrayref($query) or die "execution error ($DBI::errstr\n"; $query = qq{SELECT question, answer FROM table WHERE id in (} . (join ",", @$ids) . " ) " ;

    Selecting only the primary key will reduce the amount of data that the DBMS has to process. Therefore, selecting and sorting will be faster.

  • A very fast alternative is available when your data doesn't change so often. If your data changes, say, once a day but you are querying around the clock, then you can make an auxiliary table each time you update or insert something.

    mysql> create table if not exists support_tbl -> (cnt int not null auto_increment primary key, -> id int not null); mysql> truncate support_tbl; mysql> insert into support_tbl (id) select id from table order by rand +();

    Here you have a supporting table with primary keys in random order. Yopu can get a pageload of IDs very easily:

    my $cnt =1; my $ids = $dbh->selectcol_arrayref(qq{select id from support_tbl where cnt = ?}, undef, $cnt);

    For your next request, you will increase $cnt according to your needs.

  • Another possibility is calculating the random value in Perl.

    # make sure our random value is not higher than # any value in the primary key my ($max) = @{$dbh->selectcol_arrayref(qq{select max(id) from table})} +; my $cnt = rand($max); my $query = qq{SELECT question, answer FROM table WHERE id = $cnt };

    WARNING! Although this solution is fast, there is a catch. It will only work if your data does not have any gaps in your primary key column, i.e. if you deleted any row this method may not work as expected.

HTH

 _  _ _  _  
(_|| | |(_|><
 _|   

In reply to Re: Is there a good way of retrieving entries randomly from a database (MySQL perhaps)? by gmax
in thread Is there a good way of retrieving entries randomly from a database (MySQL perhaps)? by soon_j

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



  • Are you posting in the right place? Check out Where do I post X? to know for sure.
  • Posts may use any of the Perl Monks Approved HTML tags. Currently these include the following:
    <code> <a> <b> <big> <blockquote> <br /> <dd> <dl> <dt> <em> <font> <h1> <h2> <h3> <h4> <h5> <h6> <hr /> <i> <li> <nbsp> <ol> <p> <small> <strike> <strong> <sub> <sup> <table> <td> <th> <tr> <tt> <u> <ul>
  • Snippets of code should be wrapped in <code> tags not <pre> tags. In fact, <pre> tags should generally be avoided. If they must be used, extreme care should be taken to ensure that their contents do not have long lines (<70 chars), in order to prevent horizontal scrolling (and possible janitor intervention).
  • Want more info? How to link or How to display code and escape characters are good places to start.
Log In?
Username:
Password:

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

How do I use this?Last hourOther CB clients
Other Users?
Others drinking their drinks and smoking their pipes about the Monastery: (7)
As of 2024-03-29 01:11 GMT
Sections?
Information?
Find Nodes?
Leftovers?
    Voting Booth?

    No recent polls found