[Maria-developers] MariaDB config for Akonadi - suggestions?
Hi, Daniel Vratil from Akonadi (a PIM manager for KDE) has asked me at FOSDEM about optimal MariaDB configuration for Akonadi. Some specific questions: * innodb_flush_log_at_trx_commit. Currently, Akonadi uses innodb_flush_log_at_trx_commit=2 which as far as I understand can cause up to 1 second of changes to be lost. Using value of 1 (always flush on commit) should be safer, but maybe it would put an unnecessary load on the system? Akonadi's use case has a bit different idea of what load is - there is only one person making changes, but the system is likely to be a laptop where one cares about battery life, etc. * innodb_buffer_pool_size=80M. The dataset size can vary from very small to up to 1-1.5Gb. Some users have very little data and complain that 80M is too much. Does anybody have an experience with using very small innodb_buffer_pool_size? Please find the full config file below: === Akonadi configuration file === # These settings can be adjusted using $HOME/.config/akonadi/mysql-local.conf # # Based on advice by Kris Köhntopp <kris@mysql.com> # [mysqld] # strict query parsing/interpretation # TODO: make Akonadi work with those settings enabled # sql_mode=strict_trans_tables,strict_all_tables,strict_error_for_division_by_zero,no_auto_create_user,no_auto_value_on_zero,no_engine_substitution,no_zero_date,no_zero_in_date,only_full_group_by,pipes_as_concat # sql_mode=strict_trans_tables # DEBUGGING: # log all queries, useful for debugging but generates an enormous amount of data # log=mysql.full # log queries slower than n seconds, log file name relative to datadir (for debugging only) # log_slow_queries=mysql.slow # long_query_time=1 # log queries not using indices, debug only, disable for production use # log_queries_not_using_indexes=1 # # mesure database size and adjust innodb_buffer_pool_size # SELECT sum(data_length) as bla, sum(index_length) as blub FROM information_schema.tables WHERE table_schema not in ("mysql", "information_schema"); # NOTES: # Keep Innob_log_waits and keep Innodb_buffer_pool_wait_free small (see show global status like "inno%", show global variables) #expire_logs_days=3 #sync_bin_log=0 # Use UTF-8 encoding for tables character_set_server=utf8 collation_server=utf8_general_ci # use InnoDB for transactions and better crash recovery default_storage_engine=innodb # memory pool InnoDB uses to store data dictionary information and other internal data structures (default:1M) # Deprecated in MySQL >= 5.6.3 innodb_additional_mem_pool_size=1M # memory buffer InnoDB uses to cache data and indexes of its tables (default:128M) # Larger values means less I/O innodb_buffer_pool_size=80M # Create a .ibd file for each table (default:0) innodb_file_per_table=1 # Write out the log buffer to the log file at each commit (default:1) innodb_flush_log_at_trx_commit=2 # Buffer size used to write to the log files on disk (default:1M for builtin, 8M for plugin) # larger values means less I/O innodb_log_buffer_size=1M # Size of each log file in a log group (default:5M) larger means less I/O but more time for recovery. innodb_log_file_size=64M # # error log file name, relative to datadir (default:hostname.err) log_error=mysql.err # print warnings and connection errors (default:1) log_warnings=2 # Convert table named to lowercase lower_case_table_names=1 # Maximum size of one packet or any generated/intermediate string. (default:1M) max_allowed_packet=32M # Maximum simultaneous connections allowed (default:100) max_connections=256 # The two options below make no sense with prepared statements and/or transactions # (make sense when having the same query multiple times) # Memory allocated for caching query results (default:0 (disabled)) query_cache_size=0 # Do not cache results (default:1) query_cache_type=0 # Do not use the privileges mechanisms skip_grant_tables # Do not listen for TCP/IP connections at all skip_networking # The number of open tables for all threads. (default:64) table_open_cache=200 # How many threads the server should cache for reuse (default:0) thread_cache_size=3 # wait 365d before dropping the DB connection (default:8h) wait_timeout=31536000 # We use InnoDB, so don't let MyISAM eat up memory key_buffer_size=16K [client] default-character-set=utf8 BR Sergei -- Sergei Petrunia, Software Developer MariaDB | Skype: sergefp | Blog: http://s.petrunia.net/blog
Sergey Petrunia <sergey@mariadb.com> writes:
* innodb_flush_log_at_trx_commit. Currently, Akonadi uses innodb_flush_log_at_trx_commit=2 which as far as I understand can cause up to 1 second of changes to be lost. Using value of 1 (always flush on commit) should be safer, but maybe it would put an unnecessary load on the system? Akonadi's use case has a bit different idea of what load is - there is only one person making changes, but the system is likely to be a laptop where one cares about battery life, etc.
innodb_flush_log_at_trx_commit=2 can lose up to 1 seconds of changes, yes, but this only happens if the kernel crashes (kernel bug or power failure). If mysqld crashes, there is no data loss. Presumably power failure is less likely on a laptop due to the battery. But note that this is probably irrelevant for laptop usage. On a laptop, the disk will almost invariably be configured with cache enabled. This means that the disk will lie to the operating system about fsync(), claiming that data is synced durably to disk when it is not. This will invalidate any durability guarantees that InnoDB tries to make. In fact, it even destroys crash-safety of InnoDB, meaning that a power failure can corrupt InnoDB data to the point where recovery is not possible except by complete restore from backup. - Kristian.
participants (2)
-
Kristian Nielsen
-
Sergey Petrunia