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 Syntax”,
18 and Section 13.7.3.5, “REPAIR TABLE Syntax”.
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 shell> 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 shell> 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 shell> 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 shell> myisamchk /path/to/datadir/*/*.MYI
68
69 The recommended way to quickly check all MyISAM tables is:
70
71 shell> 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 shell> 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 Syntax”.
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, -?
126
127 Display a help message and exit. Options are grouped by type of
128 operation.
129
130 · --HELP, -H
131
132 Display a help message and exit. Options are presented in a single
133 list.
134
135 · --debug=debug_options, -# debug_options
136
137 Write a debugging log. A typical debug_options string is
138 d:t:o,file_name. The default is d:t:o,/tmp/myisamchk.trace.
139
140 · --defaults-extra-file=file_name
141
142 Read this option file after the global option file but (on Unix)
143 before the user option file. If the file does not exist or is
144 otherwise inaccessible, an error occurs. file_name is interpreted
145 relative to the current directory if given as a relative path name
146 rather than a full path name.
147
148 For additional information about this and other option-file
149 options, see Section 4.2.2.3, “Command-Line Options that Affect
150 Option-File Handling”.
151
152 · --defaults-file=file_name
153
154 Use only the given option file. If the file does not exist or is
155 otherwise inaccessible, an error occurs. file_name is interpreted
156 relative to the current directory if given as a relative path name
157 rather than a full path name.
158
159 For additional information about this and other option-file
160 options, see Section 4.2.2.3, “Command-Line Options that Affect
161 Option-File Handling”.
162
163 · --defaults-group-suffix=str
164
165 Read not only the usual option groups, but also groups with the
166 usual names and a suffix of str. For example, myisamchk normally
167 reads the [myisamchk] group. If the --defaults-group-suffix=_other
168 option is given, myisamchk also reads the [myisamchk_other] group.
169
170 For additional information about this and other option-file
171 options, see Section 4.2.2.3, “Command-Line Options that Affect
172 Option-File Handling”.
173
174 · --no-defaults
175
176 Do not read any option files. If program startup fails due to
177 reading unknown options from an option file, --no-defaults can be
178 used to prevent them from being read.
179
180 The exception is that the .mylogin.cnf file, if it exists, is read
181 in all cases. This permits passwords to be specified in a safer way
182 than on the command line even when --no-defaults is used.
183 (.mylogin.cnf is created by the mysql_config_editor utility. See
184 mysql_config_editor(1).)
185
186 For additional information about this and other option-file
187 options, see Section 4.2.2.3, “Command-Line Options that Affect
188 Option-File Handling”.
189
190 · --print-defaults
191
192 Print the program name and all options that it gets from option
193 files.
194
195 For additional information about this and other option-file
196 options, see Section 4.2.2.3, “Command-Line Options that Affect
197 Option-File Handling”.
198
199 · --silent, -s
200
201 Silent mode. Write output only when errors occur. You can use -s
202 twice (-ss) to make myisamchk very silent.
203
204 · --verbose, -v
205
206 Verbose mode. Print more information about what the program does.
207 This can be used with -d and -e. Use -v multiple times (-vv, -vvv)
208 for even more output.
209
210 · --version, -V
211
212 Display version information and exit.
213
214 · --wait, -w
215
216 Instead of terminating with an error if the table is locked, wait
217 until the table is unlocked before continuing. If you are running
218 mysqld with external locking disabled, the table can be locked only
219 by another myisamchk command.
220
221 You can also set the following variables by using --var_name=value
222 syntax:
223
224 ┌───────────────────────┬───────────────────┐
225 │Variable │ Default Value │
226 ├───────────────────────┼───────────────────┤
227 │decode_bits │ 9 │
228 ├───────────────────────┼───────────────────┤
229 │ft_max_word_len │ version-dependent │
230 ├───────────────────────┼───────────────────┤
231 │ft_min_word_len │ 4 │
232 ├───────────────────────┼───────────────────┤
233 │ft_stopword_file │ built-in list │
234 ├───────────────────────┼───────────────────┤
235 │key_buffer_size │ 523264 │
236 ├───────────────────────┼───────────────────┤
237 │myisam_block_size │ 1024 │
238 ├───────────────────────┼───────────────────┤
239 │myisam_sort_key_blocks │ 16 │
240 ├───────────────────────┼───────────────────┤
241 │read_buffer_size │ 262136 │
242 ├───────────────────────┼───────────────────┤
243 │sort_buffer_size │ 2097144 │
244 ├───────────────────────┼───────────────────┤
245 │sort_key_blocks │ 16 │
246 ├───────────────────────┼───────────────────┤
247 │stats_method │ nulls_unequal │
248 ├───────────────────────┼───────────────────┤
249 │write_buffer_size │ 262136 │
250 └───────────────────────┴───────────────────┘
251
252 The possible myisamchk variables and their default values can be
253 examined with myisamchk --help:
254
255 myisam_sort_buffer_size is used when the keys are repaired by sorting
256 keys, which is the normal case when you use --recover.
257 sort_buffer_size is a deprecated synonym for myisam_sort_buffer_size.
258
259 key_buffer_size is used when you are checking the table with
260 --extend-check or when the keys are repaired by inserting keys row by
261 row into the table (like when doing normal inserts). Repairing through
262 the key buffer is used in the following cases:
263
264 · You use --safe-recover.
265
266 · The temporary files needed to sort the keys would be more than
267 twice as big as when creating the key file directly. This is often
268 the case when you have large key values for CHAR, VARCHAR, or TEXT
269 columns, because the sort operation needs to store the complete key
270 values as it proceeds. If you have lots of temporary space and you
271 can force myisamchk to repair by sorting, you can use the
272 --sort-recover option.
273
274 Repairing through the key buffer takes much less disk space than using
275 sorting, but is also much slower.
276
277 If you want a faster repair, set the key_buffer_size and
278 myisam_sort_buffer_size variables to about 25% of your available
279 memory. You can set both variables to large values, because only one of
280 them is used at a time.
281
282 myisam_block_size is the size used for index blocks.
283
284 stats_method influences how NULL values are treated for index
285 statistics collection when the --analyze option is given. It acts like
286 the myisam_stats_method system variable. For more information, see the
287 description of myisam_stats_method in Section 5.1.8, “Server System
288 Variables”, and Section 8.3.8, “InnoDB and MyISAM Index Statistics
289 Collection”.
290
291 ft_min_word_len and ft_max_word_len indicate the minimum and maximum
292 word length for FULLTEXT indexes on MyISAM tables. ft_stopword_file
293 names the stopword file. These need to be set under the following
294 circumstances.
295
296 If you use myisamchk to perform an operation that modifies table
297 indexes (such as repair or analyze), the FULLTEXT indexes are rebuilt
298 using the default full-text parameter values for minimum and maximum
299 word length and the stopword file unless you specify otherwise. This
300 can result in queries failing.
301
302 The problem occurs because these parameters are known only by the
303 server. They are not stored in MyISAM index files. To avoid the problem
304 if you have modified the minimum or maximum word length or the stopword
305 file in the server, specify the same ft_min_word_len, ft_max_word_len,
306 and ft_stopword_file values to myisamchk that you use for mysqld. For
307 example, if you have set the minimum word length to 3, you can repair a
308 table with myisamchk like this:
309
310 shell> myisamchk --recover --ft_min_word_len=3 tbl_name.MYI
311
312 To ensure that myisamchk and the server use the same values for
313 full-text parameters, you can place each one in both the [mysqld] and
314 [myisamchk] sections of an option file:
315
316 [mysqld]
317 ft_min_word_len=3
318 [myisamchk]
319 ft_min_word_len=3
320
321 An alternative to using myisamchk is to use the REPAIR TABLE, ANALYZE
322 TABLE, OPTIMIZE TABLE, or ALTER TABLE. These statements are performed
323 by the server, which knows the proper full-text parameter values to
324 use.
325
327 myisamchk supports the following options for table checking operations:
328
329 · --check, -c
330
331 Check the table for errors. This is the default operation if you
332 specify no option that selects an operation type explicitly.
333
334 · --check-only-changed, -C
335
336 Check only tables that have changed since the last check.
337
338 · --extend-check, -e
339
340 Check the table very thoroughly. This is quite slow if the table
341 has many indexes. This option should only be used in extreme cases.
342 Normally, myisamchk or myisamchk --medium-check should be able to
343 determine whether there are any errors in the table.
344
345 If you are using --extend-check and have plenty of memory, setting
346 the key_buffer_size variable to a large value helps the repair
347 operation run faster.
348
349 See also the description of this option under table repair options.
350
351 For a description of the output format, see the section called
352 “OBTAINING TABLE INFORMATION WITH MYISAMCHK”.
353
354 · --fast, -F
355
356 Check only tables that haven't been closed properly.
357
358 · --force, -f
359
360 Do a repair operation automatically if myisamchk finds any errors
361 in the table. The repair type is the same as that specified with
362 the --recover or -r option.
363
364 · --information, -i
365
366 Print informational statistics about the table that is checked.
367
368 · --medium-check, -m
369
370 Do a check that is faster than an --extend-check operation. This
371 finds only 99.99% of all errors, which should be good enough in
372 most cases.
373
374 · --read-only, -T
375
376 Do not mark the table as checked. This is useful if you use
377 myisamchk to check a table that is in use by some other application
378 that does not use locking, such as mysqld when run with external
379 locking disabled.
380
381 · --update-state, -U
382
383 Store information in the .MYI file to indicate when the table was
384 checked and whether the table crashed. This should be used to get
385 full benefit of the --check-only-changed option, but you shouldn't
386 use this option if the mysqld server is using the table and you are
387 running it with external locking disabled.
388
390 myisamchk supports the following options for table repair operations
391 (operations performed when an option such as --recover or
392 --safe-recover is given):
393
394 · --backup, -B
395
396 Make a backup of the .MYD file as file_name-time.BAK
397
398 · --character-sets-dir=dir_name
399
400 The directory where character sets are installed. See
401 Section 10.15, “Character Set Configuration”.
402
403 · --correct-checksum
404
405 Correct the checksum information for the table.
406
407 · --data-file-length=len, -D len
408
409 The maximum length of the data file (when re-creating data file
410 when it is “full”).
411
412 · --extend-check, -e
413
414 Do a repair that tries to recover every possible row from the data
415 file. Normally, this also finds a lot of garbage rows. Do not use
416 this option unless you are desperate.
417
418 See also the description of this option under table checking
419 options.
420
421 For a description of the output format, see the section called
422 “OBTAINING TABLE INFORMATION WITH MYISAMCHK”.
423
424 · --force, -f
425
426 Overwrite old intermediate files (files with names like
427 tbl_name.TMD) instead of aborting.
428
429 · --keys-used=val, -k val
430
431 For myisamchk, the option value is a bit value that indicates which
432 indexes to update. Each binary bit of the option value corresponds
433 to a table index, where the first index is bit 0. An option value
434 of 0 disables updates to all indexes, which can be used to get
435 faster inserts. Deactivated indexes can be reactivated by using
436 myisamchk -r.
437
438 · --no-symlinks, -l
439
440 Do not follow symbolic links. Normally myisamchk repairs the table
441 that a symlink points to. This option does not exist as of MySQL
442 4.0 because versions from 4.0 on do not remove symlinks during
443 repair operations.
444
445 · --max-record-length=len
446
447 Skip rows larger than the given length if myisamchk cannot allocate
448 memory to hold them.
449
450 · --parallel-recover, -p
451
452 Use the same technique as -r and -n, but create all the keys in
453 parallel, using different threads. This is beta-quality code. Use
454 at your own risk!
455
456 · --quick, -q
457
458 Achieve a faster repair by modifying only the index file, not the
459 data file. You can specify this option twice to force myisamchk to
460 modify the original data file in case of duplicate keys.
461
462 · --recover, -r
463
464 Do a repair that can fix almost any problem except unique keys that
465 are not unique (which is an extremely unlikely error with MyISAM
466 tables). If you want to recover a table, this is the option to try
467 first. You should try --safe-recover only if myisamchk reports that
468 the table cannot be recovered using --recover. (In the unlikely
469 case that --recover fails, the data file remains intact.)
470
471 If you have lots of memory, you should increase the value of
472 myisam_sort_buffer_size.
473
474 · --safe-recover, -o
475
476 Do a repair using an old recovery method that reads through all
477 rows in order and updates all index trees based on the rows found.
478 This is an order of magnitude slower than --recover, but can handle
479 a couple of very unlikely cases that --recover cannot. This
480 recovery method also uses much less disk space than --recover.
481 Normally, you should repair first using --recover, and then with
482 --safe-recover only if --recover fails.
483
484 If you have lots of memory, you should increase the value of
485 key_buffer_size.
486
487 · --set-collation=name
488
489 Specify the collation to use for sorting table indexes. The
490 character set name is implied by the first part of the collation
491 name.
492
493 · --sort-recover, -n
494
495 Force myisamchk to use sorting to resolve the keys even if the
496 temporary files would be very large.
497
498 · --tmpdir=dir_name, -t dir_name
499
500 The path of the directory to be used for storing temporary files.
501 If this is not set, myisamchk uses the value of the TMPDIR
502 environment variable. --tmpdir can be set to a list of directory
503 paths that are used successively in round-robin fashion for
504 creating temporary files. The separator character between directory
505 names is the colon (:) on Unix and the semicolon (;) on Windows.
506
507 · --unpack, -u
508
509 Unpack a table that was packed with myisampack.
510
512 myisamchk supports the following options for actions other than table
513 checks and repairs:
514
515 · --analyze, -a
516
517 Analyze the distribution of key values. This improves join
518 performance by enabling the join optimizer to better choose the
519 order in which to join the tables and which indexes it should use.
520 To obtain information about the key distribution, use a myisamchk
521 --description --verbose tbl_name command or the SHOW INDEX FROM
522 tbl_name statement.
523
524 · --block-search=offset, -b offset
525
526 Find the record that a block at the given offset belongs to.
527
528 · --description, -d
529
530 Print some descriptive information about the table. Specifying the
531 --verbose option once or twice produces additional information. See
532 the section called “OBTAINING TABLE INFORMATION WITH MYISAMCHK”.
533
534 · --set-auto-increment[=value], -A[value]
535
536 Force AUTO_INCREMENT numbering for new records to start at the
537 given value (or higher, if there are existing records with
538 AUTO_INCREMENT values this large). If value is not specified,
539 AUTO_INCREMENT numbers for new records begin with the largest value
540 currently in the table, plus one.
541
542 · --sort-index, -S
543
544 Sort the index tree blocks in high-low order. This optimizes seeks
545 and makes table scans that use indexes faster.
546
547 · --sort-records=N, -R N
548
549 Sort records according to a particular index. This makes your data
550 much more localized and may speed up range-based SELECT and ORDER
551 BY operations that use this index. (The first time you use this
552 option to sort a table, it may be very slow.) To determine a
553 table's index numbers, use SHOW INDEX, which displays a table's
554 indexes in the same order that myisamchk sees them. Indexes are
555 numbered beginning with 1.
556
557 If keys are not packed (PACK_KEYS=0), they have the same length, so
558 when myisamchk sorts and moves records, it just overwrites record
559 offsets in the index. If keys are packed (PACK_KEYS=1), myisamchk
560 must unpack key blocks first, then re-create indexes and pack the
561 key blocks again. (In this case, re-creating indexes is faster than
562 updating offsets for each index.)
563
565 To obtain a description of a MyISAM table or statistics about it, use
566 the commands shown here. The output from these commands is explained
567 later in this section.
568
569 · myisamchk -d tbl_name
570
571 Runs myisamchk in “describe mode” to produce a description of your
572 table. If you start the MySQL server with external locking
573 disabled, myisamchk may report an error for a table that is updated
574 while it runs. However, because myisamchk does not change the table
575 in describe mode, there is no risk of destroying data.
576
577 · myisamchk -dv tbl_name
578
579 Adding -v runs myisamchk in verbose mode so that it produces more
580 information about the table. Adding -v a second time produces even
581 more information.
582
583 · myisamchk -eis tbl_name
584
585 Shows only the most important information from a table. This
586 operation is slow because it must read the entire table.
587
588 · myisamchk -eiv tbl_name
589
590 This is like -eis, but tells you what is being done.
591
592 The tbl_name argument can be either the name of a MyISAM table or the
593 name of its index file, as described in myisamchk(1). Multiple tbl_name
594 arguments can be given.
595
596 Suppose that a table named person has the following structure. (The
597 MAX_ROWS table option is included so that in the example output from
598 myisamchk shown later, some values are smaller and fit the output
599 format more easily.)
600
601 CREATE TABLE person
602 (
603 id INT NOT NULL AUTO_INCREMENT,
604 last_name VARCHAR(20) NOT NULL,
605 first_name VARCHAR(20) NOT NULL,
606 birth DATE,
607 death DATE,
608 PRIMARY KEY (id),
609 INDEX (last_name, first_name),
610 INDEX (birth)
611 ) MAX_ROWS = 1000000 ENGINE=MYISAM;
612
613 Suppose also that the table has these data and index file sizes:
614
615 -rw-rw---- 1 mysql mysql 9347072 Aug 19 11:47 person.MYD
616 -rw-rw---- 1 mysql mysql 6066176 Aug 19 11:47 person.MYI
617
618 Example of myisamchk -dvv output:
619
620 MyISAM file: person
621 Record format: Packed
622 Character set: utf8mb4_0900_ai_ci (255)
623 File-version: 1
624 Creation time: 2017-03-30 21:21:30
625 Status: checked,analyzed,optimized keys,sorted index pages
626 Auto increment key: 1 Last value: 306688
627 Data records: 306688 Deleted blocks: 0
628 Datafile parts: 306688 Deleted data: 0
629 Datafile pointer (bytes): 4 Keyfile pointer (bytes): 3
630 Datafile length: 9347072 Keyfile length: 6066176
631 Max datafile length: 4294967294 Max keyfile length: 17179868159
632 Recordlength: 54
633 table description:
634 Key Start Len Index Type Rec/key Root Blocksize
635 1 2 4 unique long 1 1024
636 2 6 80 multip. varchar prefix 0 1024
637 87 80 varchar 0
638 3 168 3 multip. uint24 NULL 0 1024
639 Field Start Length Nullpos Nullbit Type
640 1 1 1
641 2 2 4 no zeros
642 3 6 81 varchar
643 4 87 81 varchar
644 5 168 3 1 1 no zeros
645 6 171 3 1 2 no zeros
646
647 Explanations for the types of information myisamchk produces are given
648 here. “Keyfile” refers to the index file. “Record” and “row” are
649 synonymous, as are “field” and “column.”
650
651 The initial part of the table description contains these values:
652
653 · MyISAM file
654
655 Name of the MyISAM (index) file.
656
657 · Record format
658
659 The format used to store table rows. The preceding examples use
660 Fixed length. Other possible values are Compressed and Packed.
661 (Packed corresponds to what SHOW TABLE STATUS reports as Dynamic.)
662
663 · Chararacter set
664
665 The table default character set.
666
667 · File-version
668
669 Version of MyISAM format. Always 1.
670
671 · Creation time
672
673 When the data file was created.
674
675 · Recover time
676
677 When the index/data file was last reconstructed.
678
679 · Status
680
681 Table status flags. Possible values are crashed, open, changed,
682 analyzed, optimized keys, and sorted index pages.
683
684 · Auto increment key, Last value
685
686 The key number associated the table's AUTO_INCREMENT column, and
687 the most recently generated value for this column. These fields do
688 not appear if there is no such column.
689
690 · Data records
691
692 The number of rows in the table.
693
694 · Deleted blocks
695
696 How many deleted blocks still have reserved space. You can optimize
697 your table to minimize this space. See Section 7.6.4, “MyISAM Table
698 Optimization”.
699
700 · Datafile parts
701
702 For dynamic-row format, this indicates how many data blocks there
703 are. For an optimized table without fragmented rows, this is the
704 same as Data records.
705
706 · Deleted data
707
708 How many bytes of unreclaimed deleted data there are. You can
709 optimize your table to minimize this space. See Section 7.6.4,
710 “MyISAM Table Optimization”.
711
712 · Datafile pointer
713
714 The size of the data file pointer, in bytes. It is usually 2, 3, 4,
715 or 5 bytes. Most tables manage with 2 bytes, but this cannot be
716 controlled from MySQL yet. For fixed tables, this is a row address.
717 For dynamic tables, this is a byte address.
718
719 · Keyfile pointer
720
721 The size of the index file pointer, in bytes. It is usually 1, 2,
722 or 3 bytes. Most tables manage with 2 bytes, but this is calculated
723 automatically by MySQL. It is always a block address.
724
725 · Max datafile length
726
727 How long the table data file can become, in bytes.
728
729 · Max keyfile length
730
731 How long the table index file can become, in bytes.
732
733 · Recordlength
734
735 How much space each row takes, in bytes.
736
737 The table description part of the output includes a list of all keys in
738 the table. For each key, myisamchk displays some low-level information:
739
740 · Key
741
742 This key's number. This value is shown only for the first column of
743 the key. If this value is missing, the line corresponds to the
744 second or later column of a multiple-column key. For the table
745 shown in the example, there are two table description lines for the
746 second index. This indicates that it is a multiple-part index with
747 two parts.
748
749 · Start
750
751 Where in the row this portion of the index starts.
752
753 · Len
754
755 How long this portion of the index is. For packed numbers, this
756 should always be the full length of the column. For strings, it may
757 be shorter than the full length of the indexed column, because you
758 can index a prefix of a string column. The total length of a
759 multiple-part key is the sum of the Len values for all key parts.
760
761 · Index
762
763 Whether a key value can exist multiple times in the index. Possible
764 values are unique or multip. (multiple).
765
766 · Type
767
768 What data type this portion of the index has. This is a MyISAM data
769 type with the possible values packed, stripped, or empty.
770
771 · Root
772
773 Address of the root index block.
774
775 · Blocksize
776
777 The size of each index block. By default this is 1024, but the
778 value may be changed at compile time when MySQL is built from
779 source.
780
781 · Rec/key
782
783 This is a statistical value used by the optimizer. It tells how
784 many rows there are per value for this index. A unique index always
785 has a value of 1. This may be updated after a table is loaded (or
786 greatly changed) with myisamchk -a. If this is not updated at all,
787 a default value of 30 is given.
788
789 The last part of the output provides information about each column:
790
791 · Field
792
793 The column number.
794
795 · Start
796
797 The byte position of the column within table rows.
798
799 · Length
800
801 The length of the column in bytes.
802
803 · Nullpos, Nullbit
804
805 For columns that can be NULL, MyISAM stores NULL values as a flag
806 in a byte. Depending on how many nullable columns there are, there
807 can be one or more bytes used for this purpose. The Nullpos and
808 Nullbit values, if nonempty, indicate which byte and bit contains
809 that flag indicating whether the column is NULL.
810
811 The position and number of bytes used to store NULL flags is shown
812 in the line for field 1. This is why there are six Field lines for
813 the person table even though it has only five columns.
814
815 · Type
816
817 The data type. The value may contain any of the following
818 descriptors:
819
820 · constant
821
822 All rows have the same value.
823
824 · no endspace
825
826 Do not store endspace.
827
828 · no endspace, not_always
829
830 Do not store endspace and do not do endspace compression for
831 all values.
832
833 · no endspace, no empty
834
835 Do not store endspace. Do not store empty values.
836
837 · table-lookup
838
839 The column was converted to an ENUM.
840
841 · zerofill(N)
842
843 The most significant N bytes in the value are always 0 and are
844 not stored.
845
846 · no zeros
847
848 Do not store zeros.
849
850 · always zero
851
852 Zero values are stored using one bit.
853
854 · Huff tree
855
856 The number of the Huffman tree associated with the column.
857
858 · Bits
859
860 The number of bits used in the Huffman tree.
861
862 The Huff tree and Bits fields are displayed if the table has been
863 compressed with myisampack. See myisampack(1), for an example of this
864 information.
865
866 Example of myisamchk -eiv output:
867
868 Checking MyISAM file: person
869 Data records: 306688 Deleted blocks: 0
870 - check file-size
871 - check record delete-chain
872 No recordlinks
873 - check key delete-chain
874 block_size 1024:
875 - check index reference
876 - check data record references index: 1
877 Key: 1: Keyblocks used: 98% Packed: 0% Max levels: 3
878 - check data record references index: 2
879 Key: 2: Keyblocks used: 99% Packed: 97% Max levels: 3
880 - check data record references index: 3
881 Key: 3: Keyblocks used: 98% Packed: -14% Max levels: 3
882 Total: Keyblocks used: 98% Packed: 89%
883 - check records and index references
884 *** LOTS OF ROW NUMBERS DELETED ***
885 Records: 306688 M.recordlength: 25 Packed: 83%
886 Recordspace used: 97% Empty space: 2% Blocks/Record: 1.00
887 Record blocks: 306688 Delete blocks: 0
888 Record data: 7934464 Deleted data: 0
889 Lost space: 256512 Linkdata: 1156096
890 User time 43.08, System time 1.68
891 Maximum resident set size 0, Integral resident set size 0
892 Non-physical pagefaults 0, Physical pagefaults 0, Swaps 0
893 Blocks in 0 out 7, Messages in 0 out 0, Signals 0
894 Voluntary context switches 0, Involuntary context switches 0
895 Maximum memory usage: 1046926 bytes (1023k)
896
897 myisamchk -eiv output includes the following information:
898
899 · Data records
900
901 The number of rows in the table.
902
903 · Deleted blocks
904
905 How many deleted blocks still have reserved space. You can optimize
906 your table to minimize this space. See Section 7.6.4, “MyISAM Table
907 Optimization”.
908
909 · Key
910
911 The key number.
912
913 · Keyblocks used
914
915 What percentage of the keyblocks are used. When a table has just
916 been reorganized with myisamchk, the values are very high (very
917 near theoretical maximum).
918
919 · Packed
920
921 MySQL tries to pack key values that have a common suffix. This can
922 only be used for indexes on CHAR and VARCHAR columns. For long
923 indexed strings that have similar leftmost parts, this can
924 significantly reduce the space used. In the preceding example, the
925 second key is 40 bytes long and a 97% reduction in space is
926 achieved.
927
928 · Max levels
929
930 How deep the B-tree for this key is. Large tables with long key
931 values get high values.
932
933 · Records
934
935 How many rows are in the table.
936
937 · M.recordlength
938
939 The average row length. This is the exact row length for tables
940 with fixed-length rows, because all rows have the same length.
941
942 · Packed
943
944 MySQL strips spaces from the end of strings. The Packed value
945 indicates the percentage of savings achieved by doing this.
946
947 · Recordspace used
948
949 What percentage of the data file is used.
950
951 · Empty space
952
953 What percentage of the data file is unused.
954
955 · Blocks/Record
956
957 Average number of blocks per row (that is, how many links a
958 fragmented row is composed of). This is always 1.0 for fixed-format
959 tables. This value should stay as close to 1.0 as possible. If it
960 gets too large, you can reorganize the table. See Section 7.6.4,
961 “MyISAM Table Optimization”.
962
963 · Recordblocks
964
965 How many blocks (links) are used. For fixed-format tables, this is
966 the same as the number of rows.
967
968 · Deleteblocks
969
970 How many blocks (links) are deleted.
971
972 · Recorddata
973
974 How many bytes in the data file are used.
975
976 · Deleted data
977
978 How many bytes in the data file are deleted (unused).
979
980 · Lost space
981
982 If a row is updated to a shorter length, some space is lost. This
983 is the sum of all such losses, in bytes.
984
985 · Linkdata
986
987 When the dynamic table format is used, row fragments are linked
988 with pointers (4 to 7 bytes each). Linkdata is the sum of the
989 amount of storage used by all such pointers.
990
992 Memory allocation is important when you run myisamchk. myisamchk uses
993 no more memory than its memory-related variables are set to. If you are
994 going to use myisamchk on very large tables, you should first decide
995 how much memory you want it to use. The default is to use only about
996 3MB to perform repairs. By using larger values, you can get myisamchk
997 to operate faster. For example, if you have more than 512MB RAM
998 available, you could use options such as these (in addition to any
999 other options you might specify):
1000
1001 shell> myisamchk --myisam_sort_buffer_size=256M \
1002 --key_buffer_size=512M \
1003 --read_buffer_size=64M \
1004 --write_buffer_size=64M ...
1005
1006 Using --myisam_sort_buffer_size=16M is probably enough for most cases.
1007
1008 Be aware that myisamchk uses temporary files in TMPDIR. If TMPDIR
1009 points to a memory file system, out of memory errors can easily occur.
1010 If this happens, run myisamchk with the --tmpdir=dir_name option to
1011 specify a directory located on a file system that has more space.
1012
1013 When performing repair operations, myisamchk also needs a lot of disk
1014 space:
1015
1016 · Twice the size of the data file (the original file and a copy).
1017 This space is not needed if you do a repair with --quick; in this
1018 case, only the index file is re-created. This space must be
1019 available on the same file system as the original data file, as the
1020 copy is created in the same directory as the original.
1021
1022 · Space for the new index file that replaces the old one. The old
1023 index file is truncated at the start of the repair operation, so
1024 you usually ignore this space. This space must be available on the
1025 same file system as the original data file.
1026
1027 · When using --recover or --sort-recover (but not when using
1028 --safe-recover), you need space on disk for sorting. This space is
1029 allocated in the temporary directory (specified by TMPDIR or
1030 --tmpdir=dir_name). The following formula yields the amount of
1031 space required:
1032
1033 (largest_key + row_pointer_length) * number_of_rows * 2
1034
1035 You can check the length of the keys and the row_pointer_length
1036 with myisamchk -dv tbl_name (see the section called “OBTAINING
1037 TABLE INFORMATION WITH MYISAMCHK”). The row_pointer_length and
1038 number_of_rows values are the Datafile pointer and Data records
1039 values in the table description. To determine the largest_key
1040 value, check the Key lines in the table description. The Len column
1041 indicates the number of bytes for each key part. For a
1042 multiple-column index, the key size is the sum of the Len values
1043 for all key parts.
1044
1045 If you have a problem with disk space during repair, you can try
1046 --safe-recover instead of --recover.
1047
1049 Copyright © 1997, 2019, Oracle and/or its affiliates. All rights
1050 reserved.
1051
1052 This documentation is free software; you can redistribute it and/or
1053 modify it only under the terms of the GNU General Public License as
1054 published by the Free Software Foundation; version 2 of the License.
1055
1056 This documentation is distributed in the hope that it will be useful,
1057 but WITHOUT ANY WARRANTY; without even the implied warranty of
1058 MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the GNU
1059 General Public License for more details.
1060
1061 You should have received a copy of the GNU General Public License along
1062 with the program; if not, write to the Free Software Foundation, Inc.,
1063 51 Franklin Street, Fifth Floor, Boston, MA 02110-1301 USA or see
1064 http://www.gnu.org/licenses/.
1065
1066
1068 For more information, please refer to the MySQL Reference Manual, which
1069 may already be installed locally and which is also available online at
1070 http://dev.mysql.com/doc/.
1071
1073 Oracle Corporation (http://dev.mysql.com/).
1074
1075
1076
1077MySQL 8.0 09/06/2019 MYISAMCHK(1)