SHOW TABLE STATUS [{FROM | IN} db_name]
    [LIKE 'pattern' | WHERE expr]
        SHOW TABLE STATUS works likes
        SHOW TABLES, but provides a lot
        of information about each non-TEMPORARY
        table. You can also get this list using the mysqlshow
        --status db_name command.
        The LIKE clause, if present,
        indicates which table names to match. The
        WHERE clause can be given to select rows
        using more general conditions, as discussed in
        Section 19.28, “Extensions to SHOW Statements”.
      
This statement also displays information about views.
        SHOW TABLE STATUS returns the
        following fields:
      
            Name
          
The name of the table.
            Engine
          
The storage engine for the table. See Chapter 13, Storage Engines.
            Version
          
            The version number of the table's .frm
            file.
          
            Row_format
          
            The row storage format (Fixed,
            Dynamic, Compressed,
            Redundant, Compact).
            For MyISAM tables,
            (Dynamic corresponds to what
            myisamchk -dvv reports as
            Packed. The format of
            InnoDB tables is reported as
            Redundant or Compact.
            For the Barracuda file format of the
            InnoDB Plugin, the format may be
            Compressed or Dynamic.
          
            Rows
          
            The number of rows. Some storage engines, such as
            MyISAM, store the exact count. For other
            storage engines, such as InnoDB, this
            value is an approximation, and may vary from the actual
            value by as much as 40 to 50%. In such cases, use
            SELECT COUNT(*) to obtain an accurate
            count.
          
            The Rows value is NULL
            for tables in the INFORMATION_SCHEMA
            database.
          
            Avg_row_length
          
The average row length.
            Data_length
          
The length of the data file.
            Max_data_length
          
The maximum length of the data file. This is the total number of bytes of data that can be stored in the table, given the data pointer size used.
            Index_length
          
The length of the index file.
            Data_free
          
The number of allocated but unused bytes.
            This information is also shown for InnoDB
            tables (previously, it was in the Comment
            value). InnoDB tables report the free
            space of the tablespace to which the table belongs. For a
            table located in the shared tablespace, this is the free
            space of the shared tablespace. If you are using multiple
            tablespaces and the table has its own tablespace, the free
            space is for only that table. Free space means the number of
            completely free 1MB extents minus a safety margin. Even if
            free space displays as 0, it may be possible to insert rows
            as long as new extents need not be allocated.
          
            For partitioned tables, this value is only an estimate and
            may not be absolutely correct. A more accurate method of
            obtaining this information in such cases is to query the
            INFORMATION_SCHEMA.PARTITIONS table, as
            shown in this example:
          
SELECT    SUM(DATA_FREE)
    FROM  INFORMATION_SCHEMA.PARTITIONS
    WHERE TABLE_SCHEMA = 'mydb'
    AND   TABLE_NAME   = 'mytable';
            For more information, see
            Section 19.19, “The INFORMATION_SCHEMA PARTITIONS Table”.
          
            Auto_increment
          
            The next AUTO_INCREMENT value.
          
            Create_time
          
When the table was created.
            Update_time
          
            When the data file was last updated. For some storage
            engines, this value is NULL. For example,
            InnoDB stores multiple tables in its
            tablespace and the data file timestamp does not apply. For
            MyISAM, the data file timestamp is used;
            however, on Windows the timestamp is not updated by updates
            so the value is inaccurate.
          
            Check_time
          
            When the table was last checked. Not all storage engines
            update this time, in which case the value is always
            NULL.
          
            Collation
          
The table's character set and collation.
            Checksum
          
The live checksum value (if any).
            Create_options
          
            Extra options used with CREATE
            TABLE. The original options supplied when
            CREATE TABLE is called are
            retained and the options reported here may differ from the
            active table settings and options.
          
            Comment
          
The comment used when creating the table (or information as to why MySQL could not access the table information).
        For MEMORY tables, the
        Data_length,
        Max_data_length, and
        Index_length values approximate the actual
        amount of allocated memory. The allocation algorithm reserves
        memory in large amounts to reduce the number of allocation
        operations.
      
        For views, all the fields displayed by SHOW
        TABLE STATUS are NULL except that
        Name indicates the view name and
        Comment says view.
      


User Comments
If you need to get hold of only one of these columns, there are sometimes another way. E.g. if you don't need row format, type, name, average row length and all the other stuff, but only want to see the total number of rows in a table, use COUNT(*).
I was looking for a way to show the relationship of tables based on unique key, key, index, and foreign key constraints. I found that I can get some of the data using the admin statement SHOW INDEX FROM <<TBL>>. However this will give only the index name and the Column_name in the table that I am requesting from. I then did a SHOW CREATE TABLE <<TBL>> and this dumps the DDL script used to create the table. I would have to parse this information but could get everything I needed. I then found that SHOW TABLE STATUS LIKE <<TBL>> gave me The REFER information mapped to the column name. Unfortunatlly it did so in the Comments field as a string so uh! more parsing. This is what I have been able to discover so far and am still looking for a clean way to gather key, index, and constraint information to dynamically build table relationships. Also I noticed that the constraint names set in the DDL have not been preserved and mysql has given the constraints their own names. Names given keys are preserved. you can see this by running the show create table <<TBL>> on any table you have set constraints on.
Here is an example of using this command with php and get results...
<?php
mysql_connect("localhost","root","");
$result = mysql_query("SHOW TABLE STATUS FROM test;");
while($array = mysql_fetch_array($result)) {
$total = $array[Data_length]+$array[Index_length];
echo '
Table: '.$array[Name].'<br />
Data Size: '.$array[Data_length].'<br />
Index Size: '.$array[Index_length].'<br />
Total Size: '.$total.'<br />
Total Rows: '.$array[Rows].'<br />
Average Size Per Row: '.$array[Avg_row_length].'<br /><br />
';
}
?>
Here is a perl script to add up free space per engine. Whether you are out of space depends on how you have configured MySQL. The InnoDB engine might be limited space, or it might be allowed to grow. The MyISAM space is probably in the file system, which has as much left as it has.
This script is a hack. Feel free to improve and post.
For some reason, I can't get it to format nicely, either.
#!/opt/gnu/bin/perl -w
use strict;
use Getopt::Long;
my @options;
# Get output immediately. It won't hurt performance.
use FileHandle;
autoflush STDERR;
autoflush STDOUT;
my $pw;
push(@options, "password=s", \$pw);
my $host = "localhost";
push(@options, "host=s", \$host);
die "Couldn't parse options" if !GetOptions(@options);
die "Must give -password\n" if !defined($pw);
my $cmd = mysql_cmd("show databases");
open(CMD, $cmd) or die "Couldn't $cmd: $!\n";
my @databases;
my $header = <CMD>;
while ( <CMD> ) {
s/[\r\n]$//g;
#print "$_\n";
push (@databases, $_);
}
close(CMD);
#print "@databases";
my %colmap = ( 'Data_length' => 6,
'Index_length' => 8,
'Engine' => 1,
'Comment' => 17 );
my %size;
my %total_size;
my %engine_map;
my $inno_db_free;
foreach my $db (@databases) {
print STDERR ".";
$cmd = mysql_cmd("use $db; show table status");
open(CMD, $cmd) or die "Couldn't $cmd: $!\n";
my $header = <CMD>;
my $total_size = 0;
if (defined($header)) {
$header =~ s/[\r\n]$//g;
my @head = split("\t", $header);
foreach my $col (keys %colmap) {
die "$db: Expected '$col', found '" . $head[$colmap{$col}] . "'"
if $head[$colmap{$col}] ne $col;
}
while (<CMD>) {
my @data = split("\t");
my ($data_length, $index_length) = @data[6,8];
my ($engine, $comment) = @data[1,17];
$engine_map{$engine}++;
$size{$db}{$engine} += $data_length + $index_length;
$total_size{$db} += $data_length + $index_length;
if ( $comment =~ /InnoDB free: (\d+) kB/ ) {
die "Found two different inno DB free sized.\n"
if defined($inno_db_free) && $inno_db_free != $1;
$inno_db_free = $1;
}
}
close(CMD);
}
}
print STDERR "\n";
print "NOTE: All numbers are in megabytes (M).\n";
printf("Inno DB free: %.1f\n", $inno_db_free / 1024)
if defined($inno_db_free);
printf("%-30s ", "database");
foreach my $engine (sort keys(%engine_map)) {
printf "%7s ", $engine;
}
printf "%8s", "total";
print "\n";
foreach my $db (sort {$total_size{$b} <=> $total_size{$a}} keys %total_size) {
printf("%-30s ", $db);
foreach my $engine (sort keys(%engine_map)) {
my $size= $size{$db}{$engine};
$size = 0 if !defined($size);
printf("%7.1f ", $size / 1024 / 1024);
}
printf("%8.1f\n", $total_size{$db} / 1024 / 1024);
}
sub mysql_cmd {
my $mysql_cmd = shift;
return "mysql -uroot -h$host -p$pw -e '$mysql_cmd'|";
}
Example output:
% ./db-space.pl -p ...
....................
NOTE: All numbers are in megabytes (M).
Inno DB free: 10755.0
database HEAP InnoDB MyISAM total
tldan 0.0 339.1 720.3 1059.4
ml3test7 0.0 1010.8 0.0 1010.8
ml3test6 0.0 930.4 0.0 930.4
test 0.0 655.4 0.0 655.4
blarg4 0.0 39.5 0.0 39.5
For InnoDB tables, the Comment field of SHOW TABLE STATUS is useful for extracting foreign key information for older versions of MySQL. For versions since 5.0.6, you can query INFORMATION_SCHEMA. (See http://dev.mysql.com/doc/refman/5.0/en/key-column-usage-table.html)
The way the foreign key info is stored in the Comment field can be a pain to parse. Here's a snippet of PHP code that shows how to do this.
<?php
//DB connection already established
$res = mysql_query("SHOW TABLE STATUS LIKE 'MY_TABLE'");
$row = mysql_fetch_assoc($res);
mysql_free_result($res);
$commentArr = preg_split('/; */', $row['Comment']);
$foreignKeyArr = array(); //<-- We want to fill this.
foreach($commentArr as $comment) {
//Only work on InnoDB foreign key info.
if(preg_match(
'/\(`(.*)`\) REFER `(.*)\/(.*)`\(`(.*)`\)/',
$comment,
$matchArr)) {
$primaryKeyFieldArr = preg_split('/` `/', matchArr[1]);
$foreignKeyDatabase = $matchArr[2];
$foreignKeyTable = $matchArr[3];
$foreignKeyFieldArr = preg_split('/` `/', $matchArr[4]);
for($i = 0; $i < count($primaryKeyFieldArr); $i++) {
$foreignKeyArr[ $primaryKeyFieldArr[$i] ] = array(
'db' => $foreignKeyDatabase,
'table' => $foreignKeyTable,
'field' => $foreignKeyFieldArr[$i]);
}
}
?>
Now $foreignKeyArr holds a list of fields from MY_TABLE
that have a foreign key constraint. If MY_FK is a foreign
key referencing YOUR_ID in YOUR_TABLE, you will get:
$foreignKeyArr['MY_FK']['db'] == 'THIS_DATABASE'
$foreignKeyArr['MY_FK']['table'] == 'YOUR_TABLE'
$foreignKeyArr['MY_FK']['field'] == 'YOUR_ID'
If you are REALLY desperate to get FK relationships you can always use a bit of JAVA code.
I know you Perl guys will balk at this - but the JDBC METADATA can give you this information quite easily.
maybe there is something similar for Perl DBI?
Yes!
http://search.cpan.org/src/TIMB/DBI_AdvancedTalk_2004/sld086.htm
Or you can read the foreign key relationships out of the information_schema. Java's not magic, you know, all that info is in there to be used by anything that can read it. ;-)
A handy one liner to get the total table size...requires ruby
mysqlshow -u <user> --password=<password> --status <dbname> | ruby -e 'puts STDIN.readlines[4..-2].inject(0) {|s,e| s += e.split("|")[7].to_i}'
I've amended the above PHP script to format the output for an HTML table.
<?php
print('<table cols="6"><th>Table</th><th>Data Size</th><th>Index Size</th><th>Total size</th><th>Total Rows</th><th>Avg. Size per Row</th>');
mysql_connect("localhost","my_user","password");
$result = mysql_query("SHOW TABLE STATUS FROM test;");
while($array = mysql_fetch_array($result)) {
$total = $array[Data_length]+$array[Index_length];
if ( $array[Data_length] > 0 ) {
print('<tr><td align="center">');
print(' ' . $array[Name] . '<br /></td><td align="center">');
if ( $array[Data_length] < 1024 ) {
echo ' '.$array[Data_length].'</td><td align="center">';
} elseif ( ($array[Data_length] > 1024) && ($array[Data_length] < 1048576 ) ) {
printf('%.0fK',($array[Data_length] / 1024) );
print('</td><td align="center">');
} elseif ( $array[Data_length] >= 1048576 ) {
printf('%.2fMB',($array[Data_length] / 1048576) );
print('</td><td align="center">');
}
if ( $array[Index_length] < 1024 ) {
echo ' '.$array[Index_length].'<br /></td><td align="center">';
} elseif ( ($array[Index_length] > 1024) && ($array[Index_length] < 1048576 ) ) {
printf('%.0fK',($array[Index_length] / 1024) );
print('<br /></td><td align="center">');
} elseif ( $array[Index_length] >= 1048576 ) {
printf('%.2fMB',($array[Index_length] / 1048576) );
print('<br /></td><td align="center">');
}
if ( $total < 1024 ) {
echo ' '.$total.'<br /></td><td align="center">';
} elseif ( ($total > 1024) && ($total < 1048576 ) ) {
printf('%.0fK',($total / 1024) );
print('<br /></td><td align="center">');
} elseif ( $total >= 1048576 ) {
printf('%.2fMB',($total / 1048576) );
print('<br /></td><td align="center">');
}
echo '
'.$array[Rows].'</td><td align="center">
'.$array[Avg_row_length].'</td></tr>
';
}
}
?>
Since MySQL 5.1.23 the InnoDB free space that was present in INFORMATION_SCHEMA.TABLES.TABLE_COMMENT and in "SHOW ..." is moved to INFORMATION_SCHEMA.TABLES.DATA_FREE. The value is in kilobytes. Programs that parse TABLE_COMMENT need to be adjusted. See http://bugs.mysql.com/32440
To Marc Zizka:
I tried your script BUT got a problem with "SHOW TABLE STATUS". It only returns the first foreign key (in MySql 5.0.27).
Instead of it, I'm using "SHOW CREATE TABLE" and this regular expression:
'/FOREIGN KEY \(`(.*)`\) REFERENCES `(.*)` \(`(.*)`\)/'
I'm assuming that all the references are located in the same database.
Add your own comment.