EXPLAIN nombre_de_tabla
O:
EXPLAIN SELECT opciones_de_select
        La sentencia EXPLAIN puede utilizarse como un
        sinónimo de DESCRIBE o también como una
        manera para obtener información acerca de cómo MySQL ejecuta
        una sentencia SELECT:
      
            EXPLAIN
             es
            sinónimo de nombre_de_tablaDESCRIBE
             o
            nombre_de_tablaSHOW COLUMNS FROM
            .
          nombre_de_tabla
            Cuando se precede una sentencia SELECT
            con la palabra EXPLAIN, MySQL muestra
            información del optimizador sobre el plan de ejecución de
            la sentencia. Es decir, MySQL explica cómo procesaría el
            SELECT, proporcionando también
            información acerca de cómo y en qué orden están unidas
            (join) las tablas.
          
        Esta sección trata sobre el segundo uso de
        EXPLAIN.
      
        EXPLAIN es una ayuda para decidir qué
        índices agregar a las tablas, con el fin de que las sentencias
        SELECT encuentren registros más
        rápidamente. EXPLAIN puede utilizarse
        también para verificar si el optimizador une (join) las tablas
        en el orden óptimo. Si no fuera así, se puede forzar al
        optimizador a unir las tablas en el orden en el que se
        especifican en la sentencia SELECT empezando
        la sentencia con SELECT STRAIGHT_JOIN en vez
        de simplemente SELECT.
      
        Si un índice no está siendo utilizado por las sentencias
        SELECT cuando debiera, debe ejecutarse el
        comando ANALYZE TABLE, a fin de actualizar
        las estadísticas de la tabla como la cardinalidad de sus
        claves, que pueden afectar a la decisiones que el optimizador
        toma. Ver Sección 13.5.2.1, “Sintaxis de ANALYZE TABLE”.
      
        EXPLAIN muestra una línea de información
        para cada tabla utilizada en la sentencia
        SELECT. Las tablas se muestran en el mismo
        orden en el que MySQL las leería al procesar la consulta. MySQL
        resuelve todas las uniones (joins) usando un método de
        single-sweep multi-join. Esto significa
        que MySQL lee un registro de la primera tabla; encuentra su
        correspondiente en la segunda tabla, en la tercera, y así
        sucesivamente. Cuando todas las tablas han sido procesadas,
        MySQL muestra las columnas seleccionadas y recorre a la inversa
        la lista de tablas hasta que encuentra aquélla para la que la
        sentencia devuelve más registros. Se lee entonces el siguiente
        registro de esta tabla y el proceso continúa con la siguiente
        tabla.
      
        EXPLAIN retorna una tabla; cada línea de
        esta tabla muestra información acerca de una tabla, y tiene las
        siguientes columnas:
      
            id
          
            The SELECT identifier. This is the
            sequential number of the SELECT within
            the query.
          
            select_type
          
            The type of SELECT, which can be any of
            the following:
          
                SIMPLE
              
                Simple SELECT (not using
                UNION or subqueries)
              
                PRIMARY
              
                Outermost SELECT
              
                UNION
              
                Second or later SELECT statement in a
                UNION
              
                DEPENDENT UNION
              
                Second or later SELECT statement in a
                UNION, dependent on outer query
              
                UNION RESULT
              
                Result of a UNION.
              
                SUBQUERY
              
                First SELECT in subquery
              
                DEPENDENT SUBQUERY
              
                First SELECT in subquery, dependent
                on outer query
              
                DERIVED
              
                Derived table SELECT (subquery in
                FROM clause)
              
            table
          
The table to which the row of output refers.
            type
          
The join type. The different join types are listed here, ordered from the best type to the worst:
                system
              
                The table has only one row (= system table). This is a
                special case of the const join type.
              
                const
              
                The table has at most one matching row, which is read at
                the start of the query. Because there is only one row,
                values from the column in this row can be regarded as
                constants by the rest of the optimizer.
                const tables are very fast because
                they are read only once.
              
                const is used when you compare all
                parts of a PRIMARY KEY or
                UNIQUE index with constant values. In
                the following queries,
                tbl_name can be used as a
                const table:
              
SELECT * FROMtbl_nameWHEREprimary_key=1; SELECT * FROMtbl_nameWHEREprimary_key_part1=1 ANDprimary_key_part2=2;
                eq_ref
              
                One row is read from this table for each combination of
                rows from the previous tables. Other than the
                const types, this is the best
                possible join type. It is used when all parts of an
                index are used by the join and the index is a
                PRIMARY KEY or
                UNIQUE index.
              
                eq_ref can be used for indexed
                columns that are compared using the =
                operator. The comparison value can be a constant or an
                expression that uses columns from tables that are read
                before this table.
              
                In the following examples, MySQL can use an
                eq_ref join to process
                ref_table:
              
SELECT * FROMref_table,other_tableWHEREref_table.key_column=other_table.column; SELECT * FROMref_table,other_tableWHEREref_table.key_column_part1=other_table.columnANDref_table.key_column_part2=1;
                ref
              
                All rows with matching index values are read from this
                table for each combination of rows from the previous
                tables. ref is used if the join uses
                only a leftmost prefix of the key or if the key is not a
                PRIMARY KEY or
                UNIQUE index (in other words, if the
                join cannot select a single row based on the key value).
                If the key that is used matches only a few rows, this is
                a good join type.
              
                ref can be used for indexed columns
                that are compared using the = or
                <=> operator.
              
                In the following examples, MySQL can use a
                ref join to process
                ref_table:
              
SELECT * FROMref_tableWHEREkey_column=expr; SELECT * FROMref_table,other_tableWHEREref_table.key_column=other_table.column; SELECT * FROMref_table,other_tableWHEREref_table.key_column_part1=other_table.columnANDref_table.key_column_part2=1;
                ref_or_null
              
                This join type is like ref, but with
                the addition that MySQL does an extra search for rows
                that contain NULL values. This join
                type optimization is used most often in resolving
                subqueries.
              
                In the following examples, MySQL can use a
                ref_or_null join to process
                ref_table:
              
SELECT * FROMref_tableWHEREkey_column=exprORkey_columnIS NULL;
                index_merge
              
                This join type indicates that the Index Merge
                optimization is used. In this case, the
                key column contains a list of indexes
                used, and key_len contains a list of
                the longest key parts for the indexes used. For more
                information, see
                Sección 7.2.6, “Index Merge Optimization”.
              
                unique_subquery
              
                This type replaces ref for some
                IN subqueries of the following form:
valueIN (SELECTprimary_keyFROMsingle_tableWHEREsome_expr)
                unique_subquery is just an index
                lookup function that replaces the subquery completely
                for better efficiency.
              
                index_subquery
              
                This join type is similar to
                unique_subquery. It replaces
                IN subqueries, but it works for
                non-unique indexes in subqueries of the following form:
              
valueIN (SELECTkey_columnFROMsingle_tableWHEREsome_expr)
                range
              
                Only rows that are in a given range are retrieved, using
                an index to select the rows. The key
                column indicates which index is used. The
                key_len contains the longest key part
                that was used. The ref column is
                NULL for this type.
              
                range can be used for when a key
                column is compared to a constant using any of the
                =, <>,
                >, >=,
                <, <=,
                IS NULL,
                <=>,
                BETWEEN, or IN
                operators:
              
SELECT * FROMtbl_nameWHEREkey_column= 10; SELECT * FROMtbl_nameWHEREkey_columnBETWEEN 10 and 20; SELECT * FROMtbl_nameWHEREkey_columnIN (10,20,30); SELECT * FROMtbl_nameWHEREkey_part1= 10 ANDkey_part2IN (10,20,30);
                index
              
                This join type is the same as ALL,
                except that only the index tree is scanned. This usually
                is faster than ALL, because the index
                file usually is smaller than the data file.
              
MySQL can use this join type when the query uses only columns that are part of a single index.
                ALL
              
                A full table scan is done for each combination of rows
                from the previous tables. This is normally not good if
                the table is the first table not marked
                const, and usually
                very bad in all other cases.
                Normally, you can avoid ALL by adding
                indexes that allow row retrieval from the table based on
                constant values or column values from earlier tables.
              
            possible_keys
          
            The possible_keys column indicates which
            indexes MySQL could use to find the rows in this table. Note
            that this column is totally independent of the order of the
            tables as displayed in the output from
            EXPLAIN. That means that some of the keys
            in possible_keys might not be usable in
            practice with the generated table order.
          
            If this column is NULL, there are no
            relevant indexes. In this case, you may be able to improve
            the performance of your query by examining the
            WHERE clause to see whether it refers to
            some column or columns that would be suitable for indexing.
            If so, create an appropriate index and check the query with
            EXPLAIN again. See
            Sección 13.1.2, “Sintaxis de ALTER TABLE”.
          
            To see what indexes a table has, use SHOW INDEX
            FROM .
          tbl_name
            key
          
            The key column indicates the key (index)
            that MySQL actually decided to use. The key is
            NULL if no index was chosen. To force
            MySQL to use or ignore an index listed in the
            possible_keys column, use FORCE
            INDEX, USE INDEX, or
            IGNORE INDEX in your query. See
            Sección 13.2.7, “Sintaxis de SELECT”.
          
            For MyISAM and BDB
            tables, running ANALYZE TABLE helps the
            optimizer choose better indexes. For
            MyISAM tables, myisamchk
            --analyze does the same. See
            Sección 13.5.2.1, “Sintaxis de ANALYZE TABLE” and
            Sección 5.8.3, “Mantenimiento de tablas y recuperación de un fallo catastrófico
        (crash)”.
          
            key_len
          
            The key_len column indicates the length
            of the key that MySQL decided to use. The length is
            NULL if the key column
            says NULL. Note that the value of
            key_len allows you to determine how many
            parts of a multiple-part key MySQL actually uses.
          
            ref
          
            The ref column shows which columns or
            constants are used with the key to select
            rows from the table.
          
            rows
          
            The rows column indicates the number of
            rows MySQL believes it must examine to execute the query.
          
            Extra
          
This column contains additional information about how MySQL resolves the query. Here is an explanation of the different text strings that can appear in this column:
                Distinct
              
MySQL stops searching for more rows for the current row combination after it has found the first matching row.
                Not exists
              
                MySQL was able to do a LEFT JOIN
                optimization on the query and does not examine more rows
                in this table for the previous row combination after it
                finds one row that matches the LEFT
                JOIN criteria.
              
Here is an example of the type of query that can be optimized this way:
SELECT * FROM t1 LEFT JOIN t2 ON t1.id=t2.id WHERE t2.id IS NULL;
                Assume that t2.id is defined as
                NOT NULL. In this case, MySQL scans
                t1 and looks up the rows in
                t2 using the values of
                t1.id. If MySQL finds a matching row
                in t2, it knows that
                t2.id can never be
                NULL, and does not scan through the
                rest of the rows in t2 that have the
                same id value. In other words, for
                each row in t1, MySQL needs to do
                only a single lookup in t2,
                regardless of how many rows actually match in
                t2.
              
                range checked for each record (index map:
                #)
              
                MySQL found no good index to use, but found that some of
                indexes might be used once column values from preceding
                tables are known. For each row combination in the
                preceding tables, MySQL checks whether it is possible to
                use a range or
                index_merge access method to retrieve
                rows. The applicability criteria are as described in
                Sección 7.2.5, “Optimización de rango” and
                Sección 7.2.6, “Index Merge Optimization”, with the
                exception that all column values for the preceding table
                are known and considered to be constants.
              
This is not very fast, but is faster than performing a join with no index at all.
                Using filesort
              
                MySQL needs to do an extra pass to find out how to
                retrieve the rows in sorted order. The sort is done by
                going through all rows according to the join type and
                storing the sort key and pointer to the row for all rows
                that match the WHERE clause. The keys
                then are sorted and the rows are retrieved in sorted
                order. See Sección 7.2.10, “Cómo optimiza MySQL ORDER BY”.
              
                Using index
              
The column information is retrieved from the table using only information in the index tree without having to do an additional seek to read the actual row. This strategy can be used when the query uses only columns that are part of a single index.
                Using temporary
              
                To resolve the query, MySQL needs to create a temporary
                table to hold the result. This typically happens if the
                query contains GROUP BY and
                ORDER BY clauses that list columns
                differently.
              
                Using where
              
                A WHERE clause is used to restrict
                which rows to match against the next table or send to
                the client. Unless you specifically intend to fetch or
                examine all rows from the table, you may have something
                wrong in your query if the Extra
                value is not Using where and the
                table join type is ALL or
                index.
              
                If you want to make your queries as fast as possible,
                you should look out for Extra values
                of Using filesort and Using
                temporary.
              
                Using sort_union(...), Using
                union(...), Using
                intersect(...)
              
                These indicate how index scans are merged for the
                index_merge join type. See
                Sección 7.2.6, “Index Merge Optimization” for more
                information.
              
                Using index for group-by
              
                Similar to the Using index way of
                accessing a table, Using index for
                group-by indicates that MySQL found an index
                that can be used to retrieve all columns of a
                GROUP BY or
                DISTINCT query without any extra disk
                access to the actual table. Additionally, the index is
                used in the most efficient way so that for each group,
                only a few index entries are read. For details, see
                Sección 7.2.11, “Cómo optimiza MySQL los GROUP BY”.
              
        You can get a good indication of how good a join is by taking
        the product of the values in the rows column
        of the EXPLAIN output. This should tell you
        roughly how many rows MySQL must examine to execute the query.
        If you restrict queries with the
        max_join_size system variable, this product
        also is used to determine which multiple-table
        SELECT statements to execute. See
        Sección 7.5.2, “Afinar parámetros del servidor”.
      
        The following example shows how a multiple-table join can be
        optimized progressively based on the information provided by
        EXPLAIN.
      
        Suppose that you have the SELECT statement
        shown here and you plan to examine it using
        EXPLAIN:
      
EXPLAIN SELECT tt.TicketNumber, tt.TimeIn,
            tt.ProjectReference, tt.EstimatedShipDate,
            tt.ActualShipDate, tt.ClientID,
            tt.ServiceCodes, tt.RepetitiveID,
            tt.CurrentProcess, tt.CurrentDPPerson,
            tt.RecordVolume, tt.DPPrinted, et.COUNTRY,
            et_1.COUNTRY, do.CUSTNAME
        FROM tt, et, et AS et_1, do
        WHERE tt.SubmitTime IS NULL
            AND tt.ActualPC = et.EMPLOYID
            AND tt.AssignedPC = et_1.EMPLOYID
            AND tt.ClientID = do.CUSTNMBR;
For this example, make the following assumptions:
The columns being compared have been declared as follows:
| Table | Column | Column Type | 
| tt | ActualPC | CHAR(10) | 
| tt | AssignedPC | CHAR(10) | 
| tt | ClientID | CHAR(10) | 
| et | EMPLOYID | CHAR(15) | 
| do | CUSTNMBR | CHAR(15) | 
The tables have the following indexes:
| Table | Index | 
| tt | ActualPC | 
| tt | AssignedPC | 
| tt | ClientID | 
| et | EMPLOYID(primary key) | 
| do | CUSTNMBR(primary key) | 
            The tt.ActualPC values are not evenly
            distributed.
          
        Initially, before any optimizations have been performed, the
        EXPLAIN statement produces the following
        information:
      
table type possible_keys key  key_len ref  rows  Extra
et    ALL  PRIMARY       NULL NULL    NULL 74
do    ALL  PRIMARY       NULL NULL    NULL 2135
et_1  ALL  PRIMARY       NULL NULL    NULL 74
tt    ALL  AssignedPC,   NULL NULL    NULL 3872
           ClientID,
           ActualPC
      range checked for each record (key map: 35)
        Because type is ALL for
        each table, this output indicates that MySQL is generating a
        Cartesian product of all the tables; that is, every combination
        of rows. This takes quite a long time, because the product of
        the number of rows in each table must be examined. For the case
        at hand, this product is 74 * 2135 * 74 * 3872 =
        45,268,558,720 rows. If the tables were bigger, you
        can only imagine how long it would take.
      
        One problem here is that MySQL can use indexes on columns more
        efficiently if they are declared as the same type and size. In
        this context, VARCHAR and
        CHAR are considered the same if they are
        declared as the same size. Since tt.ActualPC
        is declared as CHAR(10) and
        et.EMPLOYID is CHAR(15),
        there is a length mismatch.
      
        To fix this disparity between column lengths, use ALTER
        TABLE to lengthen ActualPC from 10
        characters to 15 characters:
      
mysql> ALTER TABLE tt MODIFY ActualPC VARCHAR(15);
        tt.ActualPC and
        et.EMPLOYID are both
        VARCHAR(15). Executing the
        EXPLAIN statement again produces this result:
      
table type   possible_keys key     key_len ref         rows    Extra
tt    ALL    AssignedPC,   NULL    NULL    NULL        3872    Using
             ClientID,                                         where
             ActualPC
do    ALL    PRIMARY       NULL    NULL    NULL        2135
      range checked for each record (key map: 1)
et_1  ALL    PRIMARY       NULL    NULL    NULL        74
      range checked for each record (key map: 1)
et    eq_ref PRIMARY       PRIMARY 15      tt.ActualPC 1
        This is not perfect, but is much better: The product of the
        rows values is less by a factor of 74. This
        version is executed in a couple of seconds.
      
        A second alteration can be made to eliminate the column length
        mismatches for the tt.AssignedPC =
        et_1.EMPLOYID and tt.ClientID =
        do.CUSTNMBR comparisons:
      
mysql> ALTER TABLE tt MODIFY AssignedPC VARCHAR(15),
    ->                MODIFY ClientID   VARCHAR(15);
        EXPLAIN produces the output shown here:
      
table type   possible_keys key      key_len ref           rows Extra
et    ALL    PRIMARY       NULL     NULL    NULL          74
tt    ref    AssignedPC,   ActualPC 15      et.EMPLOYID   52   Using
             ClientID,                                         where
             ActualPC
et_1  eq_ref PRIMARY       PRIMARY  15      tt.AssignedPC 1
do    eq_ref PRIMARY       PRIMARY  15      tt.ClientID   1
This is almost as good as it can get.
        The remaining problem is that, by default, MySQL assumes that
        values in the tt.ActualPC column are evenly
        distributed, and that is not the case for the
        tt table. Fortunately, it is easy to tell
        MySQL to analyze the key distribution:
      
mysql> ANALYZE TABLE tt;
        The join is perfect, and EXPLAIN produces
        this result:
      
table type   possible_keys key     key_len ref           rows Extra
tt    ALL    AssignedPC    NULL    NULL    NULL          3872 Using
             ClientID,                                        where
             ActualPC
et    eq_ref PRIMARY       PRIMARY 15      tt.ActualPC   1
et_1  eq_ref PRIMARY       PRIMARY 15      tt.AssignedPC 1
do    eq_ref PRIMARY       PRIMARY 15      tt.ClientID   1
        Note that the rows column in the output from
        EXPLAIN is an educated guess from the MySQL
        join optimizer. You should check whether the numbers are even
        close to the truth. If not, you may get better performance by
        using STRAIGHT_JOIN in your
        SELECT statement and trying to list the
        tables in a different order in the FROM
        clause.
      
Ésta es una traducción del manual de referencia de MySQL, que puede encontrarse en dev.mysql.com. El manual de referencia original de MySQL está escrito en inglés, y esta traducción no necesariamente está tan actualizada como la versión original. Para cualquier sugerencia sobre la traducción y para señalar errores de cualquier tipo, no dude en dirigirse a mysql-es@vespito.com.

