1MYISAMCHK(1) MySQL Database System MYISAMCHK(1)
2
3
4
6 myisamchk - MyISAM table-maintenance utility
7
9 myisamchk [options] tbl_name ...
10
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
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 ┌───────────────────────┬───────────────────┐
207 │Variable │ 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
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
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
406
407 Note
408 This option is deprecated in MySQL 8.0.28 and removed in MySQL
409 8.0.30.
410 Use the same technique as -r and -n, but create all the keys in
411 parallel, using different threads. This is beta-quality code. Use
412 at your own risk!
413
414 • --quick, -q Achieve a faster repair by modifying only the index
415 file, not the data file. You can specify this option twice to force
416 myisamchk to modify the original data file in case of duplicate
417 keys.
418
419 • --recover, -r Do a repair that can fix almost any problem except
420 unique keys that are not unique (which is an extremely unlikely
421 error with MyISAM tables). If you want to recover a table, this is
422 the option to try first. You should try --safe-recover only if
423 myisamchk reports that the table cannot be recovered using
424 --recover. (In the unlikely case that --recover fails, the data
425 file remains intact.)
426
427 If you have lots of memory, you should increase the value of
428 myisam_sort_buffer_size.
429
430 • --safe-recover, -o Do a repair using an old recovery method that
431 reads through all rows in order and updates all index trees based
432 on the rows found. This is an order of magnitude slower than
433 --recover, but can handle a couple of very unlikely cases that
434 --recover cannot. This recovery method also uses much less disk
435 space than --recover. Normally, you should repair first using
436 --recover, and then with --safe-recover only if --recover fails.
437
438 If you have lots of memory, you should increase the value of
439 key_buffer_size.
440
441 • --set-collation=name Specify the collation to use for sorting table
442 indexes. The character set name is implied by the first part of the
443 collation name.
444
445 • --sort-recover, -n Force myisamchk to use sorting to resolve the
446 keys even if the temporary files would be very large.
447
448 • --tmpdir=dir_name, -t dir_name The path of the directory to be used
449 for storing temporary files. If this is not set, myisamchk uses the
450 value of the TMPDIR environment variable. --tmpdir can be set to a
451 list of directory paths that are used successively in round-robin
452 fashion for creating temporary files. The separator character
453 between directory names is the colon (:) on Unix and the semicolon
454 (;) on Windows.
455
456 • --unpack, -u Unpack a table that was packed with myisampack.
457
459 myisamchk supports the following options for actions other than table
460 checks and repairs:
461
462 • --analyze, -a Analyze the distribution of key values. This improves
463 join performance by enabling the join optimizer to better choose
464 the order in which to join the tables and which indexes it should
465 use. To obtain information about the key distribution, use a
466 myisamchk --description --verbose tbl_name command or the SHOW
467 INDEX FROM tbl_name statement.
468
469 • --block-search=offset, -b offset Find the record that a block at
470 the given offset belongs to.
471
472 • --description, -d Print some descriptive information about the
473 table. Specifying the --verbose option once or twice produces
474 additional information. See the section called “OBTAINING TABLE
475 INFORMATION WITH MYISAMCHK”.
476
477 • --set-auto-increment[=value], -A[value] Force AUTO_INCREMENT
478 numbering for new records to start at the given value (or higher,
479 if there are existing records with AUTO_INCREMENT values this
480 large). If value is not specified, AUTO_INCREMENT numbers for new
481 records begin with the largest value currently in the table, plus
482 one.
483
484 • --sort-index, -S Sort the index tree blocks in high-low order. This
485 optimizes seeks and makes table scans that use indexes faster.
486
487 • --sort-records=N, -R N Sort records according to a particular
488 index. This makes your data much more localized and may speed up
489 range-based SELECT and ORDER BY operations that use this index.
490 (The first time you use this option to sort a table, it may be very
491 slow.) To determine a table's index numbers, use SHOW INDEX, which
492 displays a table's indexes in the same order that myisamchk sees
493 them. Indexes are numbered beginning with 1.
494
495 If keys are not packed (PACK_KEYS=0), they have the same length, so
496 when myisamchk sorts and moves records, it just overwrites record
497 offsets in the index. If keys are packed (PACK_KEYS=1), myisamchk
498 must unpack key blocks first, then re-create indexes and pack the
499 key blocks again. (In this case, re-creating indexes is faster than
500 updating offsets for each index.)
501
503 To obtain a description of a MyISAM table or statistics about it, use
504 the commands shown here. The output from these commands is explained
505 later in this section.
506
507 • myisamchk -d tbl_name
508
509 Runs myisamchk in “describe mode” to produce a description of your
510 table. If you start the MySQL server with external locking
511 disabled, myisamchk may report an error for a table that is updated
512 while it runs. However, because myisamchk does not change the table
513 in describe mode, there is no risk of destroying data.
514
515 • myisamchk -dv tbl_name
516
517 Adding -v runs myisamchk in verbose mode so that it produces more
518 information about the table. Adding -v a second time produces even
519 more information.
520
521 • myisamchk -eis tbl_name
522
523 Shows only the most important information from a table. This
524 operation is slow because it must read the entire table.
525
526 • myisamchk -eiv tbl_name
527
528 This is like -eis, but tells you what is being done.
529
530 The tbl_name argument can be either the name of a MyISAM table or the
531 name of its index file, as described in myisamchk(1). Multiple tbl_name
532 arguments can be given.
533
534 Suppose that a table named person has the following structure. (The
535 MAX_ROWS table option is included so that in the example output from
536 myisamchk shown later, some values are smaller and fit the output
537 format more easily.)
538
539 CREATE TABLE person
540 (
541 id INT NOT NULL AUTO_INCREMENT,
542 last_name VARCHAR(20) NOT NULL,
543 first_name VARCHAR(20) NOT NULL,
544 birth DATE,
545 death DATE,
546 PRIMARY KEY (id),
547 INDEX (last_name, first_name),
548 INDEX (birth)
549 ) MAX_ROWS = 1000000 ENGINE=MYISAM;
550
551 Suppose also that the table has these data and index file sizes:
552
553 -rw-rw---- 1 mysql mysql 9347072 Aug 19 11:47 person.MYD
554 -rw-rw---- 1 mysql mysql 6066176 Aug 19 11:47 person.MYI
555
556 Example of myisamchk -dvv output:
557
558 MyISAM file: person
559 Record format: Packed
560 Character set: utf8mb4_0900_ai_ci (255)
561 File-version: 1
562 Creation time: 2017-03-30 21:21:30
563 Status: checked,analyzed,optimized keys,sorted index pages
564 Auto increment key: 1 Last value: 306688
565 Data records: 306688 Deleted blocks: 0
566 Datafile parts: 306688 Deleted data: 0
567 Datafile pointer (bytes): 4 Keyfile pointer (bytes): 3
568 Datafile length: 9347072 Keyfile length: 6066176
569 Max datafile length: 4294967294 Max keyfile length: 17179868159
570 Recordlength: 54
571 table description:
572 Key Start Len Index Type Rec/key Root Blocksize
573 1 2 4 unique long 1 1024
574 2 6 80 multip. varchar prefix 0 1024
575 87 80 varchar 0
576 3 168 3 multip. uint24 NULL 0 1024
577 Field Start Length Nullpos Nullbit Type
578 1 1 1
579 2 2 4 no zeros
580 3 6 81 varchar
581 4 87 81 varchar
582 5 168 3 1 1 no zeros
583 6 171 3 1 2 no zeros
584
585 Explanations for the types of information myisamchk produces are given
586 here. “Keyfile” refers to the index file. “Record” and “row” are
587 synonymous, as are “field” and “column.”
588
589 The initial part of the table description contains these values:
590
591 • MyISAM file
592
593 Name of the MyISAM (index) file.
594
595 • Record format
596
597 The format used to store table rows. The preceding examples use
598 Fixed length. Other possible values are Compressed and Packed.
599 (Packed corresponds to what SHOW TABLE STATUS reports as Dynamic.)
600
601 • Chararacter set
602
603 The table default character set.
604
605 • File-version
606
607 Version of MyISAM format. Always 1.
608
609 • Creation time
610
611 When the data file was created.
612
613 • Recover time
614
615 When the index/data file was last reconstructed.
616
617 • Status
618
619 Table status flags. Possible values are crashed, open, changed,
620 analyzed, optimized keys, and sorted index pages.
621
622 • Auto increment key, Last value
623
624 The key number associated the table's AUTO_INCREMENT column, and
625 the most recently generated value for this column. These fields do
626 not appear if there is no such column.
627
628 • Data records
629
630 The number of rows in the table.
631
632 • Deleted blocks
633
634 How many deleted blocks still have reserved space. You can optimize
635 your table to minimize this space. See Section 7.6.4, “MyISAM Table
636 Optimization”.
637
638 • Datafile parts
639
640 For dynamic-row format, this indicates how many data blocks there
641 are. For an optimized table without fragmented rows, this is the
642 same as Data records.
643
644 • Deleted data
645
646 How many bytes of unreclaimed deleted data there are. You can
647 optimize your table to minimize this space. See Section 7.6.4,
648 “MyISAM Table Optimization”.
649
650 • Datafile pointer
651
652 The size of the data file pointer, in bytes. It is usually 2, 3, 4,
653 or 5 bytes. Most tables manage with 2 bytes, but this cannot be
654 controlled from MySQL yet. For fixed tables, this is a row address.
655 For dynamic tables, this is a byte address.
656
657 • Keyfile pointer
658
659 The size of the index file pointer, in bytes. It is usually 1, 2,
660 or 3 bytes. Most tables manage with 2 bytes, but this is calculated
661 automatically by MySQL. It is always a block address.
662
663 • Max datafile length
664
665 How long the table data file can become, in bytes.
666
667 • Max keyfile length
668
669 How long the table index file can become, in bytes.
670
671 • Recordlength
672
673 How much space each row takes, in bytes.
674
675 The table description part of the output includes a list of all keys in
676 the table. For each key, myisamchk displays some low-level information:
677
678 • Key
679
680 This key's number. This value is shown only for the first column of
681 the key. If this value is missing, the line corresponds to the
682 second or later column of a multiple-column key. For the table
683 shown in the example, there are two table description lines for the
684 second index. This indicates that it is a multiple-part index with
685 two parts.
686
687 • Start
688
689 Where in the row this portion of the index starts.
690
691 • Len
692
693 How long this portion of the index is. For packed numbers, this
694 should always be the full length of the column. For strings, it may
695 be shorter than the full length of the indexed column, because you
696 can index a prefix of a string column. The total length of a
697 multiple-part key is the sum of the Len values for all key parts.
698
699 • Index
700
701 Whether a key value can exist multiple times in the index. Possible
702 values are unique or multip. (multiple).
703
704 • Type
705
706 What data type this portion of the index has. This is a MyISAM data
707 type with the possible values packed, stripped, or empty.
708
709 • Root
710
711 Address of the root index block.
712
713 • Blocksize
714
715 The size of each index block. By default this is 1024, but the
716 value may be changed at compile time when MySQL is built from
717 source.
718
719 • Rec/key
720
721 This is a statistical value used by the optimizer. It tells how
722 many rows there are per value for this index. A unique index always
723 has a value of 1. This may be updated after a table is loaded (or
724 greatly changed) with myisamchk -a. If this is not updated at all,
725 a default value of 30 is given.
726
727 The last part of the output provides information about each column:
728
729 • Field
730
731 The column number.
732
733 • Start
734
735 The byte position of the column within table rows.
736
737 • Length
738
739 The length of the column in bytes.
740
741 • Nullpos, Nullbit
742
743 For columns that can be NULL, MyISAM stores NULL values as a flag
744 in a byte. Depending on how many nullable columns there are, there
745 can be one or more bytes used for this purpose. The Nullpos and
746 Nullbit values, if nonempty, indicate which byte and bit contains
747 that flag indicating whether the column is NULL.
748
749 The position and number of bytes used to store NULL flags is shown
750 in the line for field 1. This is why there are six Field lines for
751 the person table even though it has only five columns.
752
753 • Type
754
755 The data type. The value may contain any of the following
756 descriptors:
757
758 • constant
759
760 All rows have the same value.
761
762 • no endspace
763
764 Do not store endspace.
765
766 • no endspace, not_always
767
768 Do not store endspace and do not do endspace compression for
769 all values.
770
771 • no endspace, no empty
772
773 Do not store endspace. Do not store empty values.
774
775 • table-lookup
776
777 The column was converted to an ENUM.
778
779 • zerofill(N)
780
781 The most significant N bytes in the value are always 0 and are
782 not stored.
783
784 • no zeros
785
786 Do not store zeros.
787
788 • always zero
789
790 Zero values are stored using one bit.
791
792 • Huff tree
793
794 The number of the Huffman tree associated with the column.
795
796 • Bits
797
798 The number of bits used in the Huffman tree.
799
800 The Huff tree and Bits fields are displayed if the table has been
801 compressed with myisampack. See myisampack(1), for an example of this
802 information.
803
804 Example of myisamchk -eiv output:
805
806 Checking MyISAM file: person
807 Data records: 306688 Deleted blocks: 0
808 - check file-size
809 - check record delete-chain
810 No recordlinks
811 - check key delete-chain
812 block_size 1024:
813 - check index reference
814 - check data record references index: 1
815 Key: 1: Keyblocks used: 98% Packed: 0% Max levels: 3
816 - check data record references index: 2
817 Key: 2: Keyblocks used: 99% Packed: 97% Max levels: 3
818 - check data record references index: 3
819 Key: 3: Keyblocks used: 98% Packed: -14% Max levels: 3
820 Total: Keyblocks used: 98% Packed: 89%
821 - check records and index references
822 *** LOTS OF ROW NUMBERS DELETED ***
823 Records: 306688 M.recordlength: 25 Packed: 83%
824 Recordspace used: 97% Empty space: 2% Blocks/Record: 1.00
825 Record blocks: 306688 Delete blocks: 0
826 Record data: 7934464 Deleted data: 0
827 Lost space: 256512 Linkdata: 1156096
828 User time 43.08, System time 1.68
829 Maximum resident set size 0, Integral resident set size 0
830 Non-physical pagefaults 0, Physical pagefaults 0, Swaps 0
831 Blocks in 0 out 7, Messages in 0 out 0, Signals 0
832 Voluntary context switches 0, Involuntary context switches 0
833 Maximum memory usage: 1046926 bytes (1023k)
834
835 myisamchk -eiv output includes the following information:
836
837 • Data records
838
839 The number of rows in the table.
840
841 • Deleted blocks
842
843 How many deleted blocks still have reserved space. You can optimize
844 your table to minimize this space. See Section 7.6.4, “MyISAM Table
845 Optimization”.
846
847 • Key
848
849 The key number.
850
851 • Keyblocks used
852
853 What percentage of the keyblocks are used. When a table has just
854 been reorganized with myisamchk, the values are very high (very
855 near theoretical maximum).
856
857 • Packed
858
859 MySQL tries to pack key values that have a common suffix. This can
860 only be used for indexes on CHAR and VARCHAR columns. For long
861 indexed strings that have similar leftmost parts, this can
862 significantly reduce the space used. In the preceding example, the
863 second key is 40 bytes long and a 97% reduction in space is
864 achieved.
865
866 • Max levels
867
868 How deep the B-tree for this key is. Large tables with long key
869 values get high values.
870
871 • Records
872
873 How many rows are in the table.
874
875 • M.recordlength
876
877 The average row length. This is the exact row length for tables
878 with fixed-length rows, because all rows have the same length.
879
880 • Packed
881
882 MySQL strips spaces from the end of strings. The Packed value
883 indicates the percentage of savings achieved by doing this.
884
885 • Recordspace used
886
887 What percentage of the data file is used.
888
889 • Empty space
890
891 What percentage of the data file is unused.
892
893 • Blocks/Record
894
895 Average number of blocks per row (that is, how many links a
896 fragmented row is composed of). This is always 1.0 for fixed-format
897 tables. This value should stay as close to 1.0 as possible. If it
898 gets too large, you can reorganize the table. See Section 7.6.4,
899 “MyISAM Table Optimization”.
900
901 • Recordblocks
902
903 How many blocks (links) are used. For fixed-format tables, this is
904 the same as the number of rows.
905
906 • Deleteblocks
907
908 How many blocks (links) are deleted.
909
910 • Recorddata
911
912 How many bytes in the data file are used.
913
914 • Deleted data
915
916 How many bytes in the data file are deleted (unused).
917
918 • Lost space
919
920 If a row is updated to a shorter length, some space is lost. This
921 is the sum of all such losses, in bytes.
922
923 • Linkdata
924
925 When the dynamic table format is used, row fragments are linked
926 with pointers (4 to 7 bytes each). Linkdata is the sum of the
927 amount of storage used by all such pointers.
928
930 Memory allocation is important when you run myisamchk. myisamchk uses
931 no more memory than its memory-related variables are set to. If you are
932 going to use myisamchk on very large tables, you should first decide
933 how much memory you want it to use. The default is to use only about
934 3MB to perform repairs. By using larger values, you can get myisamchk
935 to operate faster. For example, if you have more than 512MB RAM
936 available, you could use options such as these (in addition to any
937 other options you might specify):
938
939 myisamchk --myisam_sort_buffer_size=256M \
940 --key_buffer_size=512M \
941 --read_buffer_size=64M \
942 --write_buffer_size=64M ...
943
944 Using --myisam_sort_buffer_size=16M is probably enough for most cases.
945
946 Be aware that myisamchk uses temporary files in TMPDIR. If TMPDIR
947 points to a memory file system, out of memory errors can easily occur.
948 If this happens, run myisamchk with the --tmpdir=dir_name option to
949 specify a directory located on a file system that has more space.
950
951 When performing repair operations, myisamchk also needs a lot of disk
952 space:
953
954 • Twice the size of the data file (the original file and a copy).
955 This space is not needed if you do a repair with --quick; in this
956 case, only the index file is re-created. This space must be
957 available on the same file system as the original data file, as the
958 copy is created in the same directory as the original.
959
960 • Space for the new index file that replaces the old one. The old
961 index file is truncated at the start of the repair operation, so
962 you usually ignore this space. This space must be available on the
963 same file system as the original data file.
964
965 • When using --recover or --sort-recover (but not when using
966 --safe-recover), you need space on disk for sorting. This space is
967 allocated in the temporary directory (specified by TMPDIR or
968 --tmpdir=dir_name). The following formula yields the amount of
969 space required:
970
971 (largest_key + row_pointer_length) * number_of_rows * 2
972
973 You can check the length of the keys and the row_pointer_length
974 with myisamchk -dv tbl_name (see the section called “OBTAINING
975 TABLE INFORMATION WITH MYISAMCHK”). The row_pointer_length and
976 number_of_rows values are the Datafile pointer and Data records
977 values in the table description. To determine the largest_key
978 value, check the Key lines in the table description. The Len column
979 indicates the number of bytes for each key part. For a
980 multiple-column index, the key size is the sum of the Len values
981 for all key parts.
982
983 If you have a problem with disk space during repair, you can try
984 --safe-recover instead of --recover.
985
987 Copyright © 1997, 2022, Oracle and/or its affiliates.
988
989 This documentation is free software; you can redistribute it and/or
990 modify it only under the terms of the GNU General Public License as
991 published by the Free Software Foundation; version 2 of the License.
992
993 This documentation is distributed in the hope that it will be useful,
994 but WITHOUT ANY WARRANTY; without even the implied warranty of
995 MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the GNU
996 General Public License for more details.
997
998 You should have received a copy of the GNU General Public License along
999 with the program; if not, write to the Free Software Foundation, Inc.,
1000 51 Franklin Street, Fifth Floor, Boston, MA 02110-1301 USA or see
1001 http://www.gnu.org/licenses/.
1002
1003
1005 For more information, please refer to the MySQL Reference Manual, which
1006 may already be installed locally and which is also available online at
1007 http://dev.mysql.com/doc/.
1008
1010 Oracle Corporation (http://dev.mysql.com/).
1011
1012
1013
1014MySQL 8.0 08/29/2022 MYISAMCHK(1)