1MYISAMCHK(1)                 MySQL Database System                MYISAMCHK(1)
2
3
4

NAME

6       myisamchk - MyISAM table-maintenance utility
7

SYNOPSIS

9       myisamchk [options] tbl_name ...
10

DESCRIPTION

12       The myisamchk utility gets information about your database tables or
13       checks, repairs, or optimizes them.  myisamchk works with MyISAM tables
14       (tables that have .MYD and .MYI files for storing data and indexes).
15
16       You can also use the CHECK TABLE and REPAIR TABLE statements to check
17       and repair MyISAM tables. See Section 13.7.3.2, “CHECK TABLE
18       Statement”, and Section 13.7.3.5, “REPAIR TABLE Statement”.
19
20       The use of myisamchk with partitioned tables is not supported.
21
22           Caution
23           It is best to make a backup of a table before performing a table
24           repair operation; under some circumstances the operation might
25           cause data loss. Possible causes include but are not limited to
26           file system errors.
27
28       Invoke myisamchk like this:
29
30           myisamchk [options] tbl_name ...
31
32       The options specify what you want myisamchk to do. They are described
33       in the following sections. You can also get a list of options by
34       invoking myisamchk --help.
35
36       With no options, myisamchk simply checks your table as the default
37       operation. To get more information or to tell myisamchk to take
38       corrective action, specify options as described in the following
39       discussion.
40
41       tbl_name is the database table you want to check or repair. If you run
42       myisamchk somewhere other than in the database directory, you must
43       specify the path to the database directory, because myisamchk has no
44       idea where the database is located. In fact, myisamchk does not
45       actually care whether the files you are working on are located in a
46       database directory. You can copy the files that correspond to a
47       database table into some other location and perform recovery operations
48       on them there.
49
50       You can name several tables on the myisamchk command line if you wish.
51       You can also specify a table by naming its index file (the file with
52       the .MYI suffix). This enables you to specify all tables in a directory
53       by using the pattern *.MYI. For example, if you are in a database
54       directory, you can check all the MyISAM tables in that directory like
55       this:
56
57           myisamchk *.MYI
58
59       If you are not in the database directory, you can check all the tables
60       there by specifying the path to the directory:
61
62           myisamchk /path/to/database_dir/*.MYI
63
64       You can even check all tables in all databases by specifying a wildcard
65       with the path to the MySQL data directory:
66
67           myisamchk /path/to/datadir/*/*.MYI
68
69       The recommended way to quickly check all MyISAM tables is:
70
71           myisamchk --silent --fast /path/to/datadir/*/*.MYI
72
73       If you want to check all MyISAM tables and repair any that are
74       corrupted, you can use the following command:
75
76           myisamchk --silent --force --fast --update-state \
77                     --key_buffer_size=64M --myisam_sort_buffer_size=64M \
78                     --read_buffer_size=1M --write_buffer_size=1M \
79                     /path/to/datadir/*/*.MYI
80
81       This command assumes that you have more than 64MB free. For more
82       information about memory allocation with myisamchk, see the section
83       called “MYISAMCHK MEMORY USAGE”.
84
85       For additional information about using myisamchk, see Section 7.6,
86       “MyISAM Table Maintenance and Crash Recovery”.
87
88           Important
89           You must ensure that no other program is using the tables while you
90           are running myisamchk. The most effective means of doing so is to
91           shut down the MySQL server while running myisamchk, or to lock all
92           tables that myisamchk is being used on.
93
94           Otherwise, when you run myisamchk, it may display the following
95           error message:
96
97               warning: clients are using or haven't closed the table properly
98
99           This means that you are trying to check a table that has been
100           updated by another program (such as the mysqld server) that hasn't
101           yet closed the file or that has died without closing the file
102           properly, which can sometimes lead to the corruption of one or more
103           MyISAM tables.
104
105           If mysqld is running, you must force it to flush any table
106           modifications that are still buffered in memory by using FLUSH
107           TABLES. You should then ensure that no one is using the tables
108           while you are running myisamchk
109
110           However, the easiest way to avoid this problem is to use CHECK
111           TABLE instead of myisamchk to check tables. See Section 13.7.3.2,
112           “CHECK TABLE Statement”.
113
114       myisamchk supports the following options, which can be specified on the
115       command line or in the [myisamchk] group of an option file. For
116       information about option files used by MySQL programs, see
117       Section 4.2.2.2, “Using Option Files”.
118

MYISAMCHK GENERAL OPTIONS

120       The options described in this section can be used for any type of table
121       maintenance operation performed by myisamchk. The sections following
122       this one describe options that pertain only to specific operations,
123       such as table checking or repairing.
124
125--help, -?  Display a help message and exit. Options are grouped by
126           type of operation.
127
128--HELP, -H Display a help message and exit. Options are presented
129           in a single list.
130
131--debug=debug_options, -# debug_options Write a debugging log. A
132           typical debug_options string is d:t:o,file_name. The default is
133           d:t:o,/tmp/myisamchk.trace.
134
135           This option is available only if MySQL was built using WITH_DEBUG.
136           MySQL release binaries provided by Oracle are not built using this
137           option.
138
139--defaults-extra-file=file_name Read this option file after the
140           global option file but (on Unix) before the user option file. If
141           the file does not exist or is otherwise inaccessible, an error
142           occurs. If file_name is not an absolute path name, it is
143           interpreted relative to the current directory.
144
145           For additional information about this and other option-file
146           options, see Section 4.2.2.3, “Command-Line Options that Affect
147           Option-File Handling”.
148
149--defaults-file=file_name Use only the given option file. If the
150           file does not exist or is otherwise inaccessible, an error occurs.
151           If file_name is not an absolute path name, it is interpreted
152           relative to the current directory.
153
154           For additional information about this and other option-file
155           options, see Section 4.2.2.3, “Command-Line Options that Affect
156           Option-File Handling”.
157
158--defaults-group-suffix=str Read not only the usual option groups,
159           but also groups with the usual names and a suffix of str. For
160           example, myisamchk normally reads the [myisamchk] group. If this
161           option is given as --defaults-group-suffix=_other, myisamchk also
162           reads the [myisamchk_other] group.
163
164           For additional information about this and other option-file
165           options, see Section 4.2.2.3, “Command-Line Options that Affect
166           Option-File Handling”.
167
168--no-defaults Do not read any option files. If program startup
169           fails due to reading unknown options from an option file,
170           --no-defaults can be used to prevent them from being read.
171
172           The exception is that the .mylogin.cnf file is read in all cases,
173           if it exists. This permits passwords to be specified in a safer way
174           than on the command line even when --no-defaults is used. To create
175           .mylogin.cnf, use the mysql_config_editor utility. See
176           mysql_config_editor(1).
177
178           For additional information about this and other option-file
179           options, see Section 4.2.2.3, “Command-Line Options that Affect
180           Option-File Handling”.
181
182--print-defaults Print the program name and all options that it
183           gets from option files.
184
185           For additional information about this and other option-file
186           options, see Section 4.2.2.3, “Command-Line Options that Affect
187           Option-File Handling”.
188
189--silent, -s Silent mode. Write output only when errors occur. You
190           can use -s twice (-ss) to make myisamchk very silent.
191
192--verbose, -v Verbose mode. Print more information about what the
193           program does. This can be used with -d and -e. Use -v multiple
194           times (-vv, -vvv) for even more output.
195
196--version, -V Display version information and exit.
197
198--wait, -w Instead of terminating with an error if the table is
199           locked, wait until the table is unlocked before continuing. If you
200           are running mysqld with external locking disabled, the table can be
201           locked only by another myisamchk command.
202
203       You can also set the following variables by using --var_name=value
204       syntax:
205
206       ┌───────────────────────┬───────────────────┐
207Variable               Default Value     
208       ├───────────────────────┼───────────────────┤
209       │decode_bits            │ 9                 │
210       ├───────────────────────┼───────────────────┤
211       │ft_max_word_len        │ version-dependent │
212       ├───────────────────────┼───────────────────┤
213       │ft_min_word_len        │ 4                 │
214       ├───────────────────────┼───────────────────┤
215       │ft_stopword_file       │ built-in list     │
216       ├───────────────────────┼───────────────────┤
217       │key_buffer_size        │ 523264            │
218       ├───────────────────────┼───────────────────┤
219       │myisam_block_size      │ 1024              │
220       ├───────────────────────┼───────────────────┤
221       │myisam_sort_key_blocks │ 16                │
222       ├───────────────────────┼───────────────────┤
223       │read_buffer_size       │ 262136            │
224       ├───────────────────────┼───────────────────┤
225       │sort_buffer_size       │ 2097144           │
226       ├───────────────────────┼───────────────────┤
227       │sort_key_blocks        │ 16                │
228       ├───────────────────────┼───────────────────┤
229       │stats_method           │ nulls_unequal     │
230       ├───────────────────────┼───────────────────┤
231       │write_buffer_size      │ 262136            │
232       └───────────────────────┴───────────────────┘
233
234       The possible myisamchk variables and their default values can be
235       examined with myisamchk --help:
236
237       myisam_sort_buffer_size is used when the keys are repaired by sorting
238       keys, which is the normal case when you use --recover.
239       sort_buffer_size is a deprecated synonym for myisam_sort_buffer_size.
240
241       key_buffer_size is used when you are checking the table with
242       --extend-check or when the keys are repaired by inserting keys row by
243       row into the table (like when doing normal inserts). Repairing through
244       the key buffer is used in the following cases:
245
246       •   You use --safe-recover.
247
248       •   The temporary files needed to sort the keys would be more than
249           twice as big as when creating the key file directly. This is often
250           the case when you have large key values for CHAR, VARCHAR, or TEXT
251           columns, because the sort operation needs to store the complete key
252           values as it proceeds. If you have lots of temporary space and you
253           can force myisamchk to repair by sorting, you can use the
254           --sort-recover option.
255
256       Repairing through the key buffer takes much less disk space than using
257       sorting, but is also much slower.
258
259       If you want a faster repair, set the key_buffer_size and
260       myisam_sort_buffer_size variables to about 25% of your available
261       memory. You can set both variables to large values, because only one of
262       them is used at a time.
263
264       myisam_block_size is the size used for index blocks.
265
266       stats_method influences how NULL values are treated for index
267       statistics collection when the --analyze option is given. It acts like
268       the myisam_stats_method system variable. For more information, see the
269       description of myisam_stats_method in Section 5.1.8, “Server System
270       Variables”, and Section 8.3.8, “InnoDB and MyISAM Index Statistics
271       Collection”.
272
273       ft_min_word_len and ft_max_word_len indicate the minimum and maximum
274       word length for FULLTEXT indexes on MyISAM tables.  ft_stopword_file
275       names the stopword file. These need to be set under the following
276       circumstances.
277
278       If you use myisamchk to perform an operation that modifies table
279       indexes (such as repair or analyze), the FULLTEXT indexes are rebuilt
280       using the default full-text parameter values for minimum and maximum
281       word length and the stopword file unless you specify otherwise. This
282       can result in queries failing.
283
284       The problem occurs because these parameters are known only by the
285       server. They are not stored in MyISAM index files. To avoid the problem
286       if you have modified the minimum or maximum word length or the stopword
287       file in the server, specify the same ft_min_word_len, ft_max_word_len,
288       and ft_stopword_file values to myisamchk that you use for mysqld. For
289       example, if you have set the minimum word length to 3, you can repair a
290       table with myisamchk like this:
291
292           myisamchk --recover --ft_min_word_len=3 tbl_name.MYI
293
294       To ensure that myisamchk and the server use the same values for
295       full-text parameters, you can place each one in both the [mysqld] and
296       [myisamchk] sections of an option file:
297
298           [mysqld]
299           ft_min_word_len=3
300           [myisamchk]
301           ft_min_word_len=3
302
303       An alternative to using myisamchk is to use the REPAIR TABLE, ANALYZE
304       TABLE, OPTIMIZE TABLE, or ALTER TABLE. These statements are performed
305       by the server, which knows the proper full-text parameter values to
306       use.
307

MYISAMCHK CHECK OPTIONS

309       myisamchk supports the following options for table checking operations:
310
311--check, -c Check the table for errors. This is the default
312           operation if you specify no option that selects an operation type
313           explicitly.
314
315--check-only-changed, -C Check only tables that have changed since
316           the last check.
317
318--extend-check, -e Check the table very thoroughly. This is quite
319           slow if the table has many indexes. This option should only be used
320           in extreme cases. Normally, myisamchk or myisamchk --medium-check
321           should be able to determine whether there are any errors in the
322           table.
323
324           If you are using --extend-check and have plenty of memory, setting
325           the key_buffer_size variable to a large value helps the repair
326           operation run faster.
327
328           See also the description of this option under table repair options.
329
330           For a description of the output format, see the section called
331           “OBTAINING TABLE INFORMATION WITH MYISAMCHK”.
332
333--fast, -F Check only tables that haven't been closed properly.
334
335--force, -f Do a repair operation automatically if myisamchk finds
336           any errors in the table. The repair type is the same as that
337           specified with the --recover or -r option.
338
339--information, -i Print informational statistics about the table
340           that is checked.
341
342--medium-check, -m Do a check that is faster than an --extend-check
343           operation. This finds only 99.99% of all errors, which should be
344           good enough in most cases.
345
346--read-only, -T Do not mark the table as checked. This is useful if
347           you use myisamchk to check a table that is in use by some other
348           application that does not use locking, such as mysqld when run with
349           external locking disabled.
350
351--update-state, -U Store information in the .MYI file to indicate
352           when the table was checked and whether the table crashed. This
353           should be used to get full benefit of the --check-only-changed
354           option, but you shouldn't use this option if the mysqld server is
355           using the table and you are running it with external locking
356           disabled.
357

MYISAMCHK REPAIR OPTIONS

359       myisamchk supports the following options for table repair operations
360       (operations performed when an option such as --recover or
361       --safe-recover is given):
362
363--backup, -B Make a backup of the .MYD file as file_name-time.BAK
364
365--character-sets-dir=dir_name The directory where character sets
366           are installed. See Section 10.15, “Character Set Configuration”.
367
368--correct-checksum Correct the checksum information for the table.
369
370--data-file-length=len, -D len The maximum length of the data file
371           (when re-creating data file when it is “full”).
372
373--extend-check, -e
374
375           Do a repair that tries to recover every possible row from the data
376           file. Normally, this also finds a lot of garbage rows. Do not use
377           this option unless you are desperate.
378
379           See also the description of this option under table checking
380           options.
381
382           For a description of the output format, see the section called
383           “OBTAINING TABLE INFORMATION WITH MYISAMCHK”.
384
385--force, -f
386
387           Overwrite old intermediate files (files with names like
388           tbl_name.TMD) instead of aborting.
389
390--keys-used=val, -k val For myisamchk, the option value is a bit
391           value that indicates which indexes to update. Each binary bit of
392           the option value corresponds to a table index, where the first
393           index is bit 0. An option value of 0 disables updates to all
394           indexes, which can be used to get faster inserts. Deactivated
395           indexes can be reactivated by using myisamchk -r.
396
397--no-symlinks, -l Do not follow symbolic links. Normally myisamchk
398           repairs the table that a symlink points to. This option does not
399           exist as of MySQL 4.0 because versions from 4.0 on do not remove
400           symlinks during repair operations.
401
402--max-record-length=len Skip rows larger than the given length if
403           myisamchk cannot allocate memory to hold them.
404
405--parallel-recover, -p Use the same technique as -r and -n, but
406           create all the keys in parallel, using different threads.  This is
407           beta-quality code. Use at your own risk!
408
409--quick, -q Achieve a faster repair by modifying only the index
410           file, not the data file. You can specify this option twice to force
411           myisamchk to modify the original data file in case of duplicate
412           keys.
413
414--recover, -r Do a repair that can fix almost any problem except
415           unique keys that are not unique (which is an extremely unlikely
416           error with MyISAM tables). If you want to recover a table, this is
417           the option to try first. You should try --safe-recover only if
418           myisamchk reports that the table cannot be recovered using
419           --recover. (In the unlikely case that --recover fails, the data
420           file remains intact.)
421
422           If you have lots of memory, you should increase the value of
423           myisam_sort_buffer_size.
424
425--safe-recover, -o Do a repair using an old recovery method that
426           reads through all rows in order and updates all index trees based
427           on the rows found. This is an order of magnitude slower than
428           --recover, but can handle a couple of very unlikely cases that
429           --recover cannot. This recovery method also uses much less disk
430           space than --recover. Normally, you should repair first using
431           --recover, and then with --safe-recover only if --recover fails.
432
433           If you have lots of memory, you should increase the value of
434           key_buffer_size.
435
436--set-collation=name Specify the collation to use for sorting table
437           indexes. The character set name is implied by the first part of the
438           collation name.
439
440--sort-recover, -n Force myisamchk to use sorting to resolve the
441           keys even if the temporary files would be very large.
442
443--tmpdir=dir_name, -t dir_name The path of the directory to be used
444           for storing temporary files. If this is not set, myisamchk uses the
445           value of the TMPDIR environment variable.  --tmpdir can be set to a
446           list of directory paths that are used successively in round-robin
447           fashion for creating temporary files. The separator character
448           between directory names is the colon (:) on Unix and the semicolon
449           (;) on Windows.
450
451--unpack, -u Unpack a table that was packed with myisampack.
452

OTHER MYISAMCHK OPTIONS

454       myisamchk supports the following options for actions other than table
455       checks and repairs:
456
457--analyze, -a Analyze the distribution of key values. This improves
458           join performance by enabling the join optimizer to better choose
459           the order in which to join the tables and which indexes it should
460           use. To obtain information about the key distribution, use a
461           myisamchk --description --verbose tbl_name command or the SHOW
462           INDEX FROM tbl_name statement.
463
464--block-search=offset, -b offset Find the record that a block at
465           the given offset belongs to.
466
467--description, -d Print some descriptive information about the
468           table. Specifying the --verbose option once or twice produces
469           additional information. See the section called “OBTAINING TABLE
470           INFORMATION WITH MYISAMCHK”.
471
472--set-auto-increment[=value], -A[value] Force AUTO_INCREMENT
473           numbering for new records to start at the given value (or higher,
474           if there are existing records with AUTO_INCREMENT values this
475           large). If value is not specified, AUTO_INCREMENT numbers for new
476           records begin with the largest value currently in the table, plus
477           one.
478
479--sort-index, -S Sort the index tree blocks in high-low order. This
480           optimizes seeks and makes table scans that use indexes faster.
481
482--sort-records=N, -R N Sort records according to a particular
483           index. This makes your data much more localized and may speed up
484           range-based SELECT and ORDER BY operations that use this index.
485           (The first time you use this option to sort a table, it may be very
486           slow.) To determine a table's index numbers, use SHOW INDEX, which
487           displays a table's indexes in the same order that myisamchk sees
488           them. Indexes are numbered beginning with 1.
489
490           If keys are not packed (PACK_KEYS=0), they have the same length, so
491           when myisamchk sorts and moves records, it just overwrites record
492           offsets in the index. If keys are packed (PACK_KEYS=1), myisamchk
493           must unpack key blocks first, then re-create indexes and pack the
494           key blocks again. (In this case, re-creating indexes is faster than
495           updating offsets for each index.)
496

OBTAINING TABLE INFORMATION WITH MYISAMCHK

498       To obtain a description of a MyISAM table or statistics about it, use
499       the commands shown here. The output from these commands is explained
500       later in this section.
501
502myisamchk -d tbl_name
503
504           Runs myisamchk in “describe mode” to produce a description of your
505           table. If you start the MySQL server with external locking
506           disabled, myisamchk may report an error for a table that is updated
507           while it runs. However, because myisamchk does not change the table
508           in describe mode, there is no risk of destroying data.
509
510myisamchk -dv tbl_name
511
512           Adding -v runs myisamchk in verbose mode so that it produces more
513           information about the table. Adding -v a second time produces even
514           more information.
515
516myisamchk -eis tbl_name
517
518           Shows only the most important information from a table. This
519           operation is slow because it must read the entire table.
520
521myisamchk -eiv tbl_name
522
523           This is like -eis, but tells you what is being done.
524
525       The tbl_name argument can be either the name of a MyISAM table or the
526       name of its index file, as described in myisamchk(1). Multiple tbl_name
527       arguments can be given.
528
529       Suppose that a table named person has the following structure. (The
530       MAX_ROWS table option is included so that in the example output from
531       myisamchk shown later, some values are smaller and fit the output
532       format more easily.)
533
534           CREATE TABLE person
535           (
536             id         INT NOT NULL AUTO_INCREMENT,
537             last_name  VARCHAR(20) NOT NULL,
538             first_name VARCHAR(20) NOT NULL,
539             birth      DATE,
540             death      DATE,
541             PRIMARY KEY (id),
542             INDEX (last_name, first_name),
543             INDEX (birth)
544           ) MAX_ROWS = 1000000 ENGINE=MYISAM;
545
546       Suppose also that the table has these data and index file sizes:
547
548           -rw-rw----  1 mysql  mysql  9347072 Aug 19 11:47 person.MYD
549           -rw-rw----  1 mysql  mysql  6066176 Aug 19 11:47 person.MYI
550
551       Example of myisamchk -dvv output:
552
553           MyISAM file:         person
554           Record format:       Packed
555           Character set:       utf8mb4_0900_ai_ci (255)
556           File-version:        1
557           Creation time:       2017-03-30 21:21:30
558           Status:              checked,analyzed,optimized keys,sorted index pages
559           Auto increment key:              1  Last value:                306688
560           Data records:               306688  Deleted blocks:                 0
561           Datafile parts:             306688  Deleted data:                   0
562           Datafile pointer (bytes):        4  Keyfile pointer (bytes):        3
563           Datafile length:           9347072  Keyfile length:           6066176
564           Max datafile length:    4294967294  Max keyfile length:   17179868159
565           Recordlength:                   54
566           table description:
567           Key Start Len Index   Type                     Rec/key         Root  Blocksize
568           1   2     4   unique  long                           1                    1024
569           2   6     80  multip. varchar prefix                 0                    1024
570               87    80          varchar                        0
571           3   168   3   multip. uint24 NULL                    0                    1024
572           Field Start Length Nullpos Nullbit Type
573           1     1     1
574           2     2     4                      no zeros
575           3     6     81                     varchar
576           4     87    81                     varchar
577           5     168   3      1       1       no zeros
578           6     171   3      1       2       no zeros
579
580       Explanations for the types of information myisamchk produces are given
581       here.  “Keyfile” refers to the index file.  “Record” and “row” are
582       synonymous, as are “field” and “column.”
583
584       The initial part of the table description contains these values:
585
586       •   MyISAM file
587
588           Name of the MyISAM (index) file.
589
590       •   Record format
591
592           The format used to store table rows. The preceding examples use
593           Fixed length. Other possible values are Compressed and Packed.
594           (Packed corresponds to what SHOW TABLE STATUS reports as Dynamic.)
595
596       •   Chararacter set
597
598           The table default character set.
599
600       •   File-version
601
602           Version of MyISAM format. Always 1.
603
604       •   Creation time
605
606           When the data file was created.
607
608       •   Recover time
609
610           When the index/data file was last reconstructed.
611
612       •   Status
613
614           Table status flags. Possible values are crashed, open, changed,
615           analyzed, optimized keys, and sorted index pages.
616
617       •   Auto increment key, Last value
618
619           The key number associated the table's AUTO_INCREMENT column, and
620           the most recently generated value for this column. These fields do
621           not appear if there is no such column.
622
623       •   Data records
624
625           The number of rows in the table.
626
627       •   Deleted blocks
628
629           How many deleted blocks still have reserved space. You can optimize
630           your table to minimize this space. See Section 7.6.4, “MyISAM Table
631           Optimization”.
632
633       •   Datafile parts
634
635           For dynamic-row format, this indicates how many data blocks there
636           are. For an optimized table without fragmented rows, this is the
637           same as Data records.
638
639       •   Deleted data
640
641           How many bytes of unreclaimed deleted data there are. You can
642           optimize your table to minimize this space. See Section 7.6.4,
643           “MyISAM Table Optimization”.
644
645       •   Datafile pointer
646
647           The size of the data file pointer, in bytes. It is usually 2, 3, 4,
648           or 5 bytes. Most tables manage with 2 bytes, but this cannot be
649           controlled from MySQL yet. For fixed tables, this is a row address.
650           For dynamic tables, this is a byte address.
651
652       •   Keyfile pointer
653
654           The size of the index file pointer, in bytes. It is usually 1, 2,
655           or 3 bytes. Most tables manage with 2 bytes, but this is calculated
656           automatically by MySQL. It is always a block address.
657
658       •   Max datafile length
659
660           How long the table data file can become, in bytes.
661
662       •   Max keyfile length
663
664           How long the table index file can become, in bytes.
665
666       •   Recordlength
667
668           How much space each row takes, in bytes.
669
670       The table description part of the output includes a list of all keys in
671       the table. For each key, myisamchk displays some low-level information:
672
673       •   Key
674
675           This key's number. This value is shown only for the first column of
676           the key. If this value is missing, the line corresponds to the
677           second or later column of a multiple-column key. For the table
678           shown in the example, there are two table description lines for the
679           second index. This indicates that it is a multiple-part index with
680           two parts.
681
682       •   Start
683
684           Where in the row this portion of the index starts.
685
686       •   Len
687
688           How long this portion of the index is. For packed numbers, this
689           should always be the full length of the column. For strings, it may
690           be shorter than the full length of the indexed column, because you
691           can index a prefix of a string column. The total length of a
692           multiple-part key is the sum of the Len values for all key parts.
693
694       •   Index
695
696           Whether a key value can exist multiple times in the index. Possible
697           values are unique or multip.  (multiple).
698
699       •   Type
700
701           What data type this portion of the index has. This is a MyISAM data
702           type with the possible values packed, stripped, or empty.
703
704       •   Root
705
706           Address of the root index block.
707
708       •   Blocksize
709
710           The size of each index block. By default this is 1024, but the
711           value may be changed at compile time when MySQL is built from
712           source.
713
714       •   Rec/key
715
716           This is a statistical value used by the optimizer. It tells how
717           many rows there are per value for this index. A unique index always
718           has a value of 1. This may be updated after a table is loaded (or
719           greatly changed) with myisamchk -a. If this is not updated at all,
720           a default value of 30 is given.
721
722       The last part of the output provides information about each column:
723
724       •   Field
725
726           The column number.
727
728       •   Start
729
730           The byte position of the column within table rows.
731
732       •   Length
733
734           The length of the column in bytes.
735
736       •   Nullpos, Nullbit
737
738           For columns that can be NULL, MyISAM stores NULL values as a flag
739           in a byte. Depending on how many nullable columns there are, there
740           can be one or more bytes used for this purpose. The Nullpos and
741           Nullbit values, if nonempty, indicate which byte and bit contains
742           that flag indicating whether the column is NULL.
743
744           The position and number of bytes used to store NULL flags is shown
745           in the line for field 1. This is why there are six Field lines for
746           the person table even though it has only five columns.
747
748       •   Type
749
750           The data type. The value may contain any of the following
751           descriptors:
752
753           •   constant
754
755               All rows have the same value.
756
757           •   no endspace
758
759               Do not store endspace.
760
761           •   no endspace, not_always
762
763               Do not store endspace and do not do endspace compression for
764               all values.
765
766           •   no endspace, no empty
767
768               Do not store endspace. Do not store empty values.
769
770           •   table-lookup
771
772               The column was converted to an ENUM.
773
774           •   zerofill(N)
775
776               The most significant N bytes in the value are always 0 and are
777               not stored.
778
779           •   no zeros
780
781               Do not store zeros.
782
783           •   always zero
784
785               Zero values are stored using one bit.
786
787       •   Huff tree
788
789           The number of the Huffman tree associated with the column.
790
791       •   Bits
792
793           The number of bits used in the Huffman tree.
794
795       The Huff tree and Bits fields are displayed if the table has been
796       compressed with myisampack. See myisampack(1), for an example of this
797       information.
798
799       Example of myisamchk -eiv output:
800
801           Checking MyISAM file: person
802           Data records:  306688   Deleted blocks:       0
803           - check file-size
804           - check record delete-chain
805           No recordlinks
806           - check key delete-chain
807           block_size 1024:
808           - check index reference
809           - check data record references index: 1
810           Key:  1:  Keyblocks used:  98%  Packed:    0%  Max levels:  3
811           - check data record references index: 2
812           Key:  2:  Keyblocks used:  99%  Packed:   97%  Max levels:  3
813           - check data record references index: 3
814           Key:  3:  Keyblocks used:  98%  Packed:  -14%  Max levels:  3
815           Total:    Keyblocks used:  98%  Packed:   89%
816           - check records and index references
817           *** LOTS OF ROW NUMBERS DELETED ***
818           Records:            306688  M.recordlength:       25  Packed:            83%
819           Recordspace used:       97% Empty space:           2% Blocks/Record:   1.00
820           Record blocks:      306688  Delete blocks:         0
821           Record data:       7934464  Deleted data:          0
822           Lost space:         256512  Linkdata:        1156096
823           User time 43.08, System time 1.68
824           Maximum resident set size 0, Integral resident set size 0
825           Non-physical pagefaults 0, Physical pagefaults 0, Swaps 0
826           Blocks in 0 out 7, Messages in 0 out 0, Signals 0
827           Voluntary context switches 0, Involuntary context switches 0
828           Maximum memory usage: 1046926 bytes (1023k)
829
830       myisamchk -eiv output includes the following information:
831
832       •   Data records
833
834           The number of rows in the table.
835
836       •   Deleted blocks
837
838           How many deleted blocks still have reserved space. You can optimize
839           your table to minimize this space. See Section 7.6.4, “MyISAM Table
840           Optimization”.
841
842       •   Key
843
844           The key number.
845
846       •   Keyblocks used
847
848           What percentage of the keyblocks are used. When a table has just
849           been reorganized with myisamchk, the values are very high (very
850           near theoretical maximum).
851
852       •   Packed
853
854           MySQL tries to pack key values that have a common suffix. This can
855           only be used for indexes on CHAR and VARCHAR columns. For long
856           indexed strings that have similar leftmost parts, this can
857           significantly reduce the space used. In the preceding example, the
858           second key is 40 bytes long and a 97% reduction in space is
859           achieved.
860
861       •   Max levels
862
863           How deep the B-tree for this key is. Large tables with long key
864           values get high values.
865
866       •   Records
867
868           How many rows are in the table.
869
870       •   M.recordlength
871
872           The average row length. This is the exact row length for tables
873           with fixed-length rows, because all rows have the same length.
874
875       •   Packed
876
877           MySQL strips spaces from the end of strings. The Packed value
878           indicates the percentage of savings achieved by doing this.
879
880       •   Recordspace used
881
882           What percentage of the data file is used.
883
884       •   Empty space
885
886           What percentage of the data file is unused.
887
888       •   Blocks/Record
889
890           Average number of blocks per row (that is, how many links a
891           fragmented row is composed of). This is always 1.0 for fixed-format
892           tables. This value should stay as close to 1.0 as possible. If it
893           gets too large, you can reorganize the table. See Section 7.6.4,
894           “MyISAM Table Optimization”.
895
896       •   Recordblocks
897
898           How many blocks (links) are used. For fixed-format tables, this is
899           the same as the number of rows.
900
901       •   Deleteblocks
902
903           How many blocks (links) are deleted.
904
905       •   Recorddata
906
907           How many bytes in the data file are used.
908
909       •   Deleted data
910
911           How many bytes in the data file are deleted (unused).
912
913       •   Lost space
914
915           If a row is updated to a shorter length, some space is lost. This
916           is the sum of all such losses, in bytes.
917
918       •   Linkdata
919
920           When the dynamic table format is used, row fragments are linked
921           with pointers (4 to 7 bytes each).  Linkdata is the sum of the
922           amount of storage used by all such pointers.
923

MYISAMCHK MEMORY USAGE

925       Memory allocation is important when you run myisamchk.  myisamchk uses
926       no more memory than its memory-related variables are set to. If you are
927       going to use myisamchk on very large tables, you should first decide
928       how much memory you want it to use. The default is to use only about
929       3MB to perform repairs. By using larger values, you can get myisamchk
930       to operate faster. For example, if you have more than 512MB RAM
931       available, you could use options such as these (in addition to any
932       other options you might specify):
933
934           myisamchk --myisam_sort_buffer_size=256M \
935                      --key_buffer_size=512M \
936                      --read_buffer_size=64M \
937                      --write_buffer_size=64M ...
938
939       Using --myisam_sort_buffer_size=16M is probably enough for most cases.
940
941       Be aware that myisamchk uses temporary files in TMPDIR. If TMPDIR
942       points to a memory file system, out of memory errors can easily occur.
943       If this happens, run myisamchk with the --tmpdir=dir_name option to
944       specify a directory located on a file system that has more space.
945
946       When performing repair operations, myisamchk also needs a lot of disk
947       space:
948
949       •   Twice the size of the data file (the original file and a copy).
950           This space is not needed if you do a repair with --quick; in this
951           case, only the index file is re-created.  This space must be
952           available on the same file system as the original data file, as the
953           copy is created in the same directory as the original.
954
955       •   Space for the new index file that replaces the old one. The old
956           index file is truncated at the start of the repair operation, so
957           you usually ignore this space. This space must be available on the
958           same file system as the original data file.
959
960       •   When using --recover or --sort-recover (but not when using
961           --safe-recover), you need space on disk for sorting. This space is
962           allocated in the temporary directory (specified by TMPDIR or
963           --tmpdir=dir_name). The following formula yields the amount of
964           space required:
965
966               (largest_key + row_pointer_length) * number_of_rows * 2
967
968           You can check the length of the keys and the row_pointer_length
969           with myisamchk -dv tbl_name (see the section called “OBTAINING
970           TABLE INFORMATION WITH MYISAMCHK”). The row_pointer_length and
971           number_of_rows values are the Datafile pointer and Data records
972           values in the table description. To determine the largest_key
973           value, check the Key lines in the table description. The Len column
974           indicates the number of bytes for each key part. For a
975           multiple-column index, the key size is the sum of the Len values
976           for all key parts.
977
978       If you have a problem with disk space during repair, you can try
979       --safe-recover instead of --recover.
980
982       Copyright © 1997, 2021, Oracle and/or its affiliates.
983
984       This documentation is free software; you can redistribute it and/or
985       modify it only under the terms of the GNU General Public License as
986       published by the Free Software Foundation; version 2 of the License.
987
988       This documentation is distributed in the hope that it will be useful,
989       but WITHOUT ANY WARRANTY; without even the implied warranty of
990       MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the GNU
991       General Public License for more details.
992
993       You should have received a copy of the GNU General Public License along
994       with the program; if not, write to the Free Software Foundation, Inc.,
995       51 Franklin Street, Fifth Floor, Boston, MA 02110-1301 USA or see
996       http://www.gnu.org/licenses/.
997
998

SEE ALSO

1000       For more information, please refer to the MySQL Reference Manual, which
1001       may already be installed locally and which is also available online at
1002       http://dev.mysql.com/doc/.
1003

AUTHOR

1005       Oracle Corporation (http://dev.mysql.com/).
1006
1007
1008
1009MySQL 8.0                         11/26/2021                      MYISAMCHK(1)
Impressum