A.5. Problemas relacionados con consultas

MySQL 5.0

A.5. Problemas relacionados con consultas

A.5.1. Sensibilidad a mayúsculas en búsquedas

By default, MySQL searches are not case sensitive (although there are some character sets that are never case insensitive, such as ). This means that if you search with LIKE 'a%', you get all column values that start with or . If you want to make this search case sensitive, make sure that one of the operands has a case sensitive or binary collation. For example, if you are comparing a column and a string that both have the character set, you can use the operator to cause either operand to have the or collation. For example:

 COLLATE latin1_general_cs LIKE 'a%'
 LIKE 'a%' COLLATE latin1_general_cs
 COLLATE latin1_bin LIKE 'a%'
 LIKE 'a%' COLLATE latin1_bin

If you want a column always to be treated in case-sensitive fashion, declare it with a case sensitive or binary collation. See Sección 13.1.5, “Sintaxis de .

Before MySQL 4.1, is unavailable. Use the operator in expressions to treat a string as a binary string: LIKE 'a%' or LIKE BINARY 'a%'. In column declarations, use the attribute.

Simple comparison operations (, sorting, and grouping) are based on each character's “sort value.” Characters with the same sort value (such as '', '', and '') are treated as the same character.

A.5.2. Problemas en el uso de columnas DATE

The format of a value is . According to standard SQL, no other format is allowed. You should use this format in expressions and in the clause of statements. For example:

mysql> SELECT * FROM  WHERE date >= '2003-05-05';

As a convenience, MySQL automatically converts a date to a number if the date is used in a numeric context (and vice versa). It is also smart enough to allow a “relaxed” string form when updating and in a clause that compares a date to a , , or column. (“Relaxed form” means that any punctuation character may be used as the separator between parts. For example, and are equivalent.) MySQL can also convert a string containing no separators (such as ), provided it makes sense as a date.

When you compare a , , , or to a constant string with the , , , , , or operators, MySQL normally converts the string to an internal long integer for faster comparision (and also for a bit more “relaxed” string checking). However, this conversion is subject to the following exceptions:

  • When you compare two columns

  • When you compare a , , , or column to an expression

  • When you use any other comparison method than those just listed, such as or .

For these exceptional cases, the comparison is done by converting the objects to strings and performing a string comparison.

To keep things safe, assume that strings are compared as strings and use the appropriate string functions if you want to compare a temporal value to a string.

The special date can be stored and retrieved as When using a date through MyODBC, it is automatically converted to in MyODBC 2.50.12 and above, because ODBC can't handle this kind of date.

Because MySQL performs the conversions described above, the following statements work:

mysql> INSERT INTO  (idate) VALUES (19970505);
mysql> INSERT INTO  (idate) VALUES ('19970505');
mysql> INSERT INTO  (idate) VALUES ('97-05-05');
mysql> INSERT INTO  (idate) VALUES ('1997.05.05');
mysql> INSERT INTO  (idate) VALUES ('1997 05 05');
mysql> INSERT INTO  (idate) VALUES ('0000-00-00');

mysql> SELECT idate FROM  WHERE idate >= '1997-05-05';
mysql> SELECT idate FROM  WHERE idate >= 19970505;
mysql> SELECT MOD(idate,100) FROM  WHERE idate >= 19970505;
mysql> SELECT idate FROM  WHERE idate >= '19970505';

However, the following does not work:

mysql> SELECT idate FROM  WHERE STRCMP(idate,'20030505')=0;

is a string function, so it converts to a string in format and performs a string comparison. It does not convert to the date and perform a date comparison.

If you are using the SQL mode, MySQL allows you to store dates that are given only limited checking: MySQL ensures only that the day is in the range from 1 to 31 and the month is in the range from 1 to 12.

This makes MySQL very convenient for Web applications where you obtain year, month, and day in three different fields and you want to store exactly what the user inserted (without date validation).

If you are not using the SQL mode, the day or month part can be zero. This is convenient if you want to store a birthdate in a column and you know only part of the date.

If you are not using the SQL mode, MySQL also allows you to store as a “dummy date.” This is in some cases more convenient than using values.

If the date cannot be converted to any reasonable value, a is stored in the column, which is retrieved as . This is both a speed and a convenience issue. We believe that the database server's responsibility is to retrieve the same date you stored (even if the data was not logically correct in all cases). We think it is up to the application and not the server to check the dates.

If you want MySQL to check all dates and accept only legal dates (unless overriden by IGNORE), you should set to .

Date handling in MySQL 5.0.1 and earlier works like MySQL 5.0.2 with the SQL mode enabled.

A.5.3. Problemas con valores NULL

The concept of the value is a common source of confusion for newcomers to SQL, who often think that is the same thing as an empty string . This is not the case. For example, the following statements are completely different:

mysql> INSERT INTO my_table (phone) VALUES (NULL);
mysql> INSERT INTO my_table (phone) VALUES ('');

Both statements insert a value into the column, but the first inserts a value and the second inserts an empty string. The meaning of the first can be regarded as “phone number is not known” and the meaning of the second can be regarded as “the person is known to have no phone, and thus no phone number.

To help with handling, you can use the and operators and the function.

In SQL, the value is never true in comparison to any other value, even . An expression that contains always produces a value unless otherwise indicated in the documentation for the operators and functions involved in the expression. All columns in the following example return :

mysql> SELECT NULL, 1+NULL, CONCAT('Invisible',NULL);

If you want to search for column values that are , you cannot use an test. The following statement returns no rows, because is never true for any expression:

mysql> SELECT * FROM my_table WHERE phone = NULL;

To look for values, you must use the test. The following statements show how to find the phone number and the empty phone number:

mysql> SELECT * FROM my_table WHERE phone IS NULL;
mysql> SELECT * FROM my_table WHERE phone = '';

You can add an index on a column that can have values if you are using MySQL 3.23.2 or newer and are using the , , or storage engine. As of MySQL 4.0.2, the storage engine also supports values in indexes. Otherwise, you must declare an indexed column and you cannot insert into the column.

When reading data with , empty or missing columns are updated with . If you want a value in a column, you should use in the data file. The literal word “” may also be used under some circumstances. See Sección 13.2.5, “Sintaxis de .

When using , , or , all values are regarded as equal.

When using , values are presented first, or last if you specify to sort in descending order. Exception: In MySQL 4.0.2 through 4.0.10, values sort first regardless of sort order.

Aggregate (summary) functions such as , , and ignore values. The exception to this is , which counts rows and not individual column values. For example, the following statement produces two counts. The first is a count of the number of rows in the table, and the second is a count of the number of non- values in the column:

mysql> SELECT COUNT(*), COUNT(age) FROM person;

For some column types, MySQL handles values specially. If you insert into a column, the current date and time is inserted. If you insert into an integer column that has the attribute, the next number in the sequence is inserted.

A.5.4. Problemas con alias de columnas

You can use an alias to refer to a column in , , or clauses. Aliases can also be used to give columns better names:

SELECT SQRT(a*b) AS root FROM  GROUP BY root HAVING root > 0;
SELECT id, COUNT(*) AS cnt FROM  GROUP BY id HAVING cnt > 0;
SELECT id AS 'Customer identity' FROM ;

Standard SQL doesn't allow you to refer to a column alias in a clause. This is because when the code is executed, the column value may not yet be determined. For example, the following query is illegal:

SELECT id, COUNT(*) AS cnt FROM  WHERE cnt > 0 GROUP BY id;

The statement is executed to determine which rows should be included in the part, whereas is used to decide which rows from the result set should be used.

A.5.5. Fallo en la cancelación de una transacción con tablas no transaccionales

If you receive the following message when trying to perform a , it means that one or more of the tables you used in the transaction do not support transactions:

Warning: Some non-transactional changed tables couldn't be rolled back

These non-transactional tables are not affected by the statement.

If you were not deliberately mixing transactional and non-transactional tables within the transaction, the most likely cause for this message is that a table you thought was transactional actually is not. This can happen if you try to create a table using a transactional storage engine that is not supported by your mysqld server (or that was disabled with a startup option). If mysqld doesn't support a storage engine, it instead creates the table as a table, which is non-transactional.

You can check the table type for a table by using either of these statements:

SHOW TABLE STATUS LIKE '';
SHOW CREATE TABLE ;

See Sección 13.5.4.18, “Sintaxis de and Sección 13.5.4.5, “Sintaxis de .

You can check which storage engines your mysqld server supports by using this statement:

SHOW ENGINES;

Before MySQL 4.1.2, is unavailable. Use the following statement instead and check the value of the variable that is associated with the storage engine in which you are interested:

SHOW VARIABLES LIKE 'have_%';

For example, to determine whether the storage engine is available, check the value of the variable.

See Sección 13.5.4.8, “Sintaxis de and Sección 13.5.4.21, “Sintaxis de .

A.5.6. Borrar registros de tablas relacionadas

MySQL does not support subqueries prior to Version 4.1, or the use of more than one table in the statement prior to Version 4.0. If your version of MySQL does not support subqueries or multiple-table statements, you can use the following approach to delete rows from two related tables:

  1. the rows based on some condition in the main table.

  2. the rows in the main table based on the same condition.

  3. .

If the total length of the statement for is more than 1MB (the default value of the system variable), you should split it into smaller parts and execute multiple statements. You probably get the fastest by specifying only 100 to 1,000 values per statement if the is indexed. If the isn't indexed, the speed is independent of the number of arguments in the clause.

A.5.7. Resolver problemas con registros que no salen

If you have a complicated query that uses many tables but that doesn't return any rows, you should use the following procedure to find out what is wrong:

  1. Test the query with to check whether you can find something that is obviously wrong. See Sección 7.2.1, “Sintaxis de (Obtener información acerca de un )”.

  2. Select only those columns that are used in the clause.

  3. Remove one table at a time from the query until it returns some rows. If the tables are large, it's a good idea to use with the query.

  4. Issue a for the column that should have matched a row against the table that was last removed from the query.

  5. If you are comparing or columns with numbers that have decimals, you can't use equality () comparisons. This problem is common in most computer languages because not all floating-point values can be stored with exact precision. In some cases, changing the to a fixes this. See Sección A.5.8, “Problemas con comparaciones en Floating-Point”.

  6. If you still can't figure out what's wrong, create a minimal test that can be run with that shows your problems. You can create a test file by dumping the tables with mysqldump --quick db_name ... > query.sql. Open the file in an editor, remove some insert lines (if there are more than needed to demonstrate the problem), and add your statement at the end of the file.

    Verify that the test file demonstrates the problem by executing these commands:

    shell> mysqladmin create test2
    shell> mysql test2 < query.sql
    

    Post the test file using mysqlbug to the general MySQL mailing list. See Sección 1.6.1.1, “Las listas de correo de MySQL”.

A.5.8. Problemas con comparaciones en Floating-Point

Note that the following section is relevant primarily for versions of MySQL older than 5.0.3. As of version 5.0.3, MySQL performs operations with a precision of 64 decimal digits, which should solve most common inaccuracy problems when it comes to columns. For and columns, the problems remain because inexactness is the basic nature of floating point numbers.

Floating-point numbers sometimes cause confusion because they are not stored as exact values inside computer architecture. What you can see on the screen usually is not the exact value of the number. The column types , , and are such. columns store values with exact precision because they are represented as strings, but calculations on values before MySQL 5.0.3 are done using floating-point operations.

The following example (for older MySQL version than 5.0.3) demonstrate the problem. It shows that even for the column type, calculations that are done using floating-point operations are subject to floating-point error. (In all MySQL versions, you would have similar problems if you would replace the columns with ).

mysql> CREATE TABLE t1 (i INT, d1 DECIMAL(9,2), d2 DECIMAL(9,2));
mysql> INSERT INTO t1 VALUES (1, 101.40, 21.40), (1, -80.00, 0.00),
    -> (2, 0.00, 0.00), (2, -13.20, 0.00), (2, 59.60, 46.40),
    -> (2, 30.40, 30.40), (3, 37.00, 7.40), (3, -29.60, 0.00),
    -> (4, 60.00, 15.40), (4, -10.60, 0.00), (4, -34.00, 0.00),
    -> (5, 33.00, 0.00), (5, -25.80, 0.00), (5, 0.00, 7.20),
    -> (6, 0.00, 0.00), (6, -51.40, 0.00);

mysql> SELECT i, SUM(d1) AS a, SUM(d2) AS b
    -> FROM t1 GROUP BY i HAVING a <> b;
+------+--------+-------+
| i    | a      | b     |
+------+--------+-------+
|    1 |  21.40 | 21.40 |
|    2 |  76.80 | 76.80 |
|    3 |   7.40 |  7.40 |
|    4 |  15.40 | 15.40 |
|    5 |   7.20 |  7.20 |
|    6 | -51.40 |  0.00 |
+------+--------+-------+

The result is correct. Although the first five records look like they shouldn't pass the comparison test (the values of and do not appear to be different), they may do so because the difference between the numbers shows up around the tenth decimal or so, depending on computer architecture.

As of MySQL 5.0.3, you will get only the last row in the above result.

The problem cannot be solved by using or similar functions, because the result is still a floating-point number:

mysql> SELECT i, ROUND(SUM(d1), 2) AS a, ROUND(SUM(d2), 2) AS b
    -> FROM t1 GROUP BY i HAVING a <> b;
+------+--------+-------+
| i    | a      | b     |
+------+--------+-------+
|    1 |  21.40 | 21.40 |
|    2 |  76.80 | 76.80 |
|    3 |   7.40 |  7.40 |
|    4 |  15.40 | 15.40 |
|    5 |   7.20 |  7.20 |
|    6 | -51.40 |  0.00 |
+------+--------+-------+

This is what the numbers in column look like when displayed with more decimal places:

mysql> SELECT i, ROUND(SUM(d1), 2)*1.0000000000000000 AS a,
    -> ROUND(SUM(d2), 2) AS b FROM t1 GROUP BY i HAVING a <> b;
+------+----------------------+-------+
| i    | a                    | b     |
+------+----------------------+-------+
|    1 |  21.3999999999999986 | 21.40 |
|    2 |  76.7999999999999972 | 76.80 |
|    3 |   7.4000000000000004 |  7.40 |
|    4 |  15.4000000000000004 | 15.40 |
|    5 |   7.2000000000000002 |  7.20 |
|    6 | -51.3999999999999986 |  0.00 |
+------+----------------------+-------+

Depending on your computer architecture, you may or may not see similar results. Different CPUs may evaluate floating-point numbers differently. For example, on some machines you may get the “correct” results by multiplying both arguments by 1, as the following example shows.

Warning: Never use this method in your applications. It is not an example of a trustworthy method!

mysql> SELECT i, ROUND(SUM(d1), 2)*1 AS a, ROUND(SUM(d2), 2)*1 AS b
    -> FROM t1 GROUP BY i HAVING a <> b;
+------+--------+------+
| i    | a      | b    |
+------+--------+------+
|    6 | -51.40 | 0.00 |
+------+--------+------+

The reason that the preceding example seems to work is that on the particular machine where the test was done, CPU floating-point arithmetic happens to round the numbers to the same value. However, there is no rule that any CPU should do so, so this method cannot be trusted.

The correct way to do floating-point number comparison is to first decide on an acceptable tolerance for differences between the numbers and then do the comparison against the tolerance value. For example, if we agree that floating-point numbers should be regarded the same if they are same within a precision of one in ten thousand (0.0001), the comparison should be written to find differences larger than the tolerance value:

mysql> SELECT i, SUM(d1) AS a, SUM(d2) AS b FROM t1
    -> GROUP BY i HAVING ABS(a - b) > 0.0001;
+------+--------+------+
| i    | a      | b    |
+------+--------+------+
|    6 | -51.40 | 0.00 |
+------+--------+------+
1 row in set (0.00 sec)

Conversely, to get rows where the numbers are the same, the test should find differences within the tolerance value:

mysql> SELECT i, SUM(d1) AS a, SUM(d2) AS b FROM t1
    -> GROUP BY i HAVING ABS(a - b) <= 0.0001;
+------+-------+-------+
| i    | a     | b     |
+------+-------+-------+
|    1 | 21.40 | 21.40 |
|    2 | 76.80 | 76.80 |
|    3 |  7.40 |  7.40 |
|    4 | 15.40 | 15.40 |
|    5 |  7.20 |  7.20 |
+------+-------+-------+