http://www.perlmonks.org?node_id=163074


in reply to Re: Re: The fine art of database programming
in thread The fine art of database programming

I am sorry, pdcawley, but I have to disagree.
One of the fundaments of the relational model is that you don't make assumptions on the physical storage of the records. What you are suggesting is quite dangerous, as the following example shows.
mysql> describe test_order; +-------+----------+------+-----+---------+-------+ | Field | Type | Null | Key | Default | Extra | +-------+----------+------+-----+---------+-------+ | id | int(11) | | PRI | 0 | | | name | char(10) | YES | | NULL | | +-------+----------+------+-----+---------+-------+ 2 rows in set (0.00 sec) mysql> select * from test_order; #all the records +----+------+ | id | name | +----+------+ | 1 | aaaa | | 2 | bbbb | | 3 | cccc | | 4 | dddd | | 5 | eeee | | 6 | ffff | | 7 | gggg | | 8 | hhhh | | 9 | iiii | | 10 | jjjj | +----+------+ 10 rows in set (0.01 sec) mysql> select * from test_order limit 4,3; #1st request. OK so far +----+------+ | id | name | +----+------+ | 5 | eeee | | 6 | ffff | | 7 | gggg | +----+------+ 3 rows in set (0.00 sec) # now we remove one of the records we were selecting through LIMIT mysql> delete from test_order where id = 5; Query OK, 1 row affected (0.00 sec) # and we insert another record mysql> insert into test_order values (11, "kkkk"); Query OK, 1 row affected (0.00 sec) # Then we insert the deleted record again mysql> insert into test_order values (5, "eeee"); Query OK, 1 row affected (0.00 sec) mysql> select * from test_order limit 4,3; +----+------+ | id | name | +----+------+ | 11 | kkkk | | 6 | ffff | | 7 | gggg | +----+------+ 3 rows in set (0.00 sec)
The same query, after a couple of delete/insert statements, gives you different results.
It is true that you can correct the result using the ORDER BY clause, but you are not dealing with "record numbers".
The LIMIT clause, for those database that support it, guarantees that N records from the result dataset, starting at a given position are returned. There is no assumption about their position in the table.
If you want to return correct records, use the WHERE clause.
 _  _ _  _  
(_|| | |(_|><
 _|