Browse code

put mysql on a memory diet

We propose several MySQL configuration parameter changes (with
explanations) to reduce the memory footprint of MySQL. A demonstration
of the improvement is provided in
https://etherpad.openstack.org/p/change-438668.

As Clint provided some of the descriptions that I've used, I have
listed him as a co-author (thanks Clint). Let this serve as a warning
to all that commetors may be enlisted :)

Change-Id: Icb2d6ea91d3d45a68ce99c817a746b10039479cc
Co-Authored-By: Clint 'SpamapS' Byrum <clint@fewbar.com>

Amrith Kumar authored on 2017/02/28 03:29:03
Showing 1 changed files
... ...
@@ -96,10 +96,191 @@ function configure_database_mysql {
96 96
     iniset -sudo $my_conf mysqld bind-address "$SERVICE_LISTEN_ADDRESS"
97 97
     iniset -sudo $my_conf mysqld sql_mode TRADITIONAL
98 98
     iniset -sudo $my_conf mysqld default-storage-engine InnoDB
99
-    iniset -sudo $my_conf mysqld max_connections 1024
99
+
100
+    # the number of connections has been throttled to 256. In the
101
+    # event that the gate jobs report "Too many connections" it is
102
+    # indicative of a problem that could be the result of one of many
103
+    # things. For more details about debugging this error, refer
104
+    # https://dev.mysql.com/doc/refman/5.5/en/too-many-connections.html.
105
+    # Note that the problem may not ONLY be an issue with MySQL
106
+    # connections. If the number of fd's at the OS is too low, you
107
+    # could see errors manifest as MySQL "too many connections".
108
+    iniset -sudo $my_conf mysqld max_connections 256
100 109
     iniset -sudo $my_conf mysqld query_cache_type OFF
101 110
     iniset -sudo $my_conf mysqld query_cache_size 0
102 111
 
112
+    # Additional settings to put MySQL on a memory diet. These
113
+    # settings are used in conjunction with the cap on max_connections
114
+    # as the total memory used by MySQL can be simply viewed as
115
+    # fixed-allocations + max_connections * variable-allocations. A
116
+    # nifty tool to help with this is
117
+    # http://www.mysqlcalculator.com/. A short description of each of
118
+    # the settings follows.
119
+
120
+    # binlog_cache_size, determines the size of cache to hold changes
121
+    # to the binary log during a transaction, for each connection. For
122
+    # more details, refer
123
+    # https://dev.mysql.com/doc/refman/5.6/en/replication-options-binary-log.html#sysvar_binlog_cache_size
124
+    # When binary logging is enabled, a smaller binlog cache could
125
+    # result in more frequent flushes to the disk and a larger value
126
+    # would result in less flushes to the disk but higher memory
127
+    # usage. This however only has to do with large transactions; if
128
+    # you have a small transaction the binlog cache is necessarily
129
+    # flushed on a transaction commit. This is a per-connection cache.
130
+    iniset -sudo $my_conf mysqld binlog_cache_size 4K
131
+
132
+    # binlog_stmt_cache_size determines the size of cache to hold non
133
+    # transactional statements in the binary log. For more details,
134
+    # refer
135
+    # https://dev.mysql.com/doc/refman/5.6/en/replication-options-binary-log.html#sysvar_binlog_stmt_cache_size
136
+    # This cache holds changes to non-transactional tables (read:
137
+    # MyISAM) or any non-transactional statements which cause
138
+    # modifications to data (truncate is an example). These are
139
+    # written to disk immediately on completion of the statement or
140
+    # when the cache is full. If the cache is too small, you get
141
+    # frequent writes to the disk (flush) and if the cache is too
142
+    # large, it takes up more memory. This is a per-connection cache.
143
+    iniset -sudo $my_conf mysqld binlog_stmt_cache_size 4K
144
+
145
+    # bulk_insert_buffer_size for MyISAM tables that use a special
146
+    # cache for insert statements and load statements, this cache is
147
+    # used to optimize writes to the disk. If the value is set to 0,
148
+    # the optimization is disabled. For more details refer
149
+    # https://dev.mysql.com/doc/refman/5.7/en/server-system-variables.html#sysvar_bulk_insert_buffer_size
150
+    # We set this to 0 which could result in higher disk I/O (I/O on
151
+    # each insert block completion).
152
+    iniset -sudo $my_conf mysqld bulk_insert_buffer_size 0
153
+
154
+    # host_cache_size controls a DNS lookup optimization. For more
155
+    # details refer
156
+    # https://dev.mysql.com/doc/refman/5.6/en/host-cache.html
157
+    iniset -sudo $my_conf mysqld host_cache_size 0
158
+
159
+    # innodb_buffer_pool_size This is the size of the server wide
160
+    # buffer pool. It is the cache for all data blocks being used by
161
+    # the server and is managed as a LRU chain. Dirty blocks either
162
+    # age off the list or are forced off when the list is
163
+    # full. Setting this to 5MB (default 128MB) reduces the amount of
164
+    # memory used by the server and this will result in more disk I/O
165
+    # in cases where (a) there is considerable write activity that
166
+    # overwhelms the allocated cache, or (b) there is considerable
167
+    # read activity on a data set that exceeds the allocated
168
+    # cache. For more details, refer
169
+    # https://dev.mysql.com/doc/refman/5.6/en/innodb-parameters.html#sysvar_innodb_buffer_pool_size
170
+    iniset -sudo $my_conf mysqld innodb_buffer_pool_size 5M
171
+
172
+    # innodb_ft_cache_size and innodb_ft_total_cache_size control the
173
+    # per-connection full text search cache and the server wide
174
+    # maximum full text search cache. We should not be using full text
175
+    # search and the value is set to the minimum allowable. The former
176
+    # is a per-connection cache size and the latter is server
177
+    # wide. For more details, refer
178
+    # https://dev.mysql.com/doc/refman/5.7/en/innodb-parameters.html#sysvar_innodb_ft_cache_size
179
+    # and
180
+    # https://dev.mysql.com/doc/refman/5.7/en/innodb-parameters.html#sysvar_innodb_ft_total_cache_size
181
+    iniset -sudo $my_conf mysqld innodb_ft_cache_size 1600000
182
+    iniset -sudo $my_conf mysqld innodb_ft_total_cache_size 32000000
183
+
184
+    # innodb_log_buffer_size This buffer is used to buffer
185
+    # transactions in-memory before writing them to the innodb
186
+    # internal transaction log. Large transactions, or high amounts of
187
+    # concurrency, will cause the system to fill this faster and thus
188
+    # make the system more disk-bound. For more details, refer
189
+    # https://dev.mysql.com/doc/refman/5.7/en/innodb-parameters.html#sysvar_innodb_log_buffer_size
190
+    iniset -sudo $my_conf mysqld innodb_log_buffer_size 256K
191
+
192
+    # innodb_sort_buffer_size, This buffer is used for sorting when
193
+    # InnoDB is creating indexes. Could cause that to be slower, but
194
+    # only if tables are large. This is a per-connection setting. For
195
+    # more details, refer
196
+    # https://dev.mysql.com/doc/refman/5.7/en/innodb-parameters.html#sysvar_innodb_sort_buffer_size
197
+    iniset -sudo $my_conf mysqld innodb_sort_buffer_size 64K
198
+
199
+    # join_buffer_size, This buffer makes table and index scans
200
+    # faster. So this setting could make some queries more disk
201
+    # bound. This is a per-connection setting. For more details refer
202
+    # https://dev.mysql.com/doc/refman/5.7/en/server-system-variables.html#sysvar_join_buffer_size.
203
+    iniset -sudo $my_conf mysqld join_buffer_size 128
204
+
205
+    # key_buffer_size defines the index blocks used for MyISAM tables
206
+    # and shared between threads. This is a server wide setting. For
207
+    # more details see
208
+    # https://dev.mysql.com/doc/refman/5.7/en/server-system-variables.html#sysvar_key_buffer_size
209
+    iniset -sudo $my_conf mysqld key_buffer_size 8
210
+
211
+    # max_heap_table_size sets the maximum amount of memory for MEMORY
212
+    # tables (which we don't use). The value is set to 16k, the
213
+    # minimum allowed. For more details, see
214
+    # https://dev.mysql.com/doc/refman/5.7/en/server-system-variables.html#sysvar_max_heap_table_size
215
+    iniset -sudo $my_conf mysqld max_heap_table_size 16K
216
+
217
+    # net_buffer_length Each client has a buffer for incoming and
218
+    # outgoing data, both start with a size of net_buffer_length and
219
+    # can grow (in steps of 2x) upto a size of max_allowed_packet. For
220
+    # more details see
221
+    # https://dev.mysql.com/doc/refman/5.7/en/server-system-variables.html#sysvar_net_buffer_length
222
+    iniset -sudo $my_conf mysqld net_buffer_length 1K
223
+
224
+    # read_buffer_size, read_rnd_buffer_size are per-thread buffer
225
+    # used for scans on MyISAM tables. It is a per-connection setting
226
+    # and so we set it to the minimum value allowable. Same for
227
+    # read_rnd_buffer_size. For more details refer
228
+    # https://dev.mysql.com/doc/refman/5.6/en/server-system-variables.html#sysvar_read_buffer_size
229
+    # and
230
+    # https://dev.mysql.com/doc/refman/5.6/en/server-system-variables.html#sysvar_read_rnd_buffer_size
231
+    iniset -sudo $my_conf mysqld read_buffer_size 8200
232
+    iniset -sudo $my_conf mysqld read_rnd_buffer_size 8200
233
+
234
+    # sort_buffer_size when a sort is requested, it will be performed
235
+    # in memory in a buffer of this size (allocated per connection)
236
+    # and if the data exceeds this size it will spill to disk. The
237
+    # innodb and myisam variables are used in computing indices for
238
+    # tables using the specified storage engine. Since we don't
239
+    # dynamically reindex (except during upgrade) these values should
240
+    # never be material. Obviously performance of disk based sorts is
241
+    # worse than in memory sorts and therefore a high value here will
242
+    # improve sort performance for large data. For more details,
243
+    # refer:
244
+    # https://dev.mysql.com/doc/refman/5.7/en/server-system-variables.html#sysvar_sort_buffer_size
245
+    # and
246
+    # https://dev.mysql.com/doc/refman/5.7/en/innodb-parameters.html#sysvar_innodb_sort_buffer_size
247
+    # and
248
+    # https://dev.mysql.com/doc/refman/5.7/en/server-system-variables.html#sysvar_myisam_sort_buffer_size
249
+    iniset -sudo $my_conf mysqld sort_buffer_size 32K
250
+    iniset -sudo $my_conf mysqld innodb_sort_buffer_size 64K
251
+    iniset -sudo $my_conf mysqld myisam_sort_buffer_size 4K
252
+
253
+    # thread_cache_size specifies how many internal threads to cache
254
+    # for use with incoming connections. We set this to 0 whic means
255
+    # that each connection will cause a new thread to be created. This
256
+    # could cause connections to take marginally longer on os'es with
257
+    # slow pthread_create calls. For more details, refer
258
+    # https://dev.mysql.com/doc/refman/5.7/en/server-system-variables.html#sysvar_thread_cache_size
259
+    iniset -sudo $my_conf mysqld thread_cache_size 0
260
+
261
+    # thread_stack is the per connection stack size, the minimum is
262
+    # 128k and the default is 192k on 32bit and 256k on 64bit
263
+    # systems. We set this to 192k. Complex queries which require
264
+    # recursion, stored procedures or other memory intensive
265
+    # operations could exhaust this and generate a very characteristic
266
+    # failure ("stack overflow") which is cleanly detected and the
267
+    # query is killed. For more details see
268
+    # https://dev.mysql.com/doc/refman/5.6/en/server-system-variables.html#sysvar_thread_stack
269
+    iniset -sudo $my_conf mysqld thread_stack 196608
270
+
271
+    # tmp_table_size is the maximum size of an in-memory temporary
272
+    # table. Temporary tables are created by MySQL as part of a
273
+    # multi-step query plan. The actual size of the temp table will be
274
+    # the lesser of tmp_table_size and max_heap_table_size. If a
275
+    # temporary table exceeds this size, it will be spooled to disk
276
+    # using the internal_tmp_disk_storage_engine (default
277
+    # MyISAM). Queries that often generate in-memory temporary tables
278
+    # include queries that have sorts, distinct, or group by
279
+    # operations, also queries that perform IN joins. For more details
280
+    # see
281
+    # https://dev.mysql.com/doc/refman/5.7/en/server-system-variables.html#sysvar_tmp_table_size
282
+    iniset -sudo $my_conf mysqld tmp_table_size 1K
283
+
103 284
     if [[ "$DATABASE_QUERY_LOGGING" == "True" ]]; then
104 285
         echo_summary "Enabling MySQL query logging"
105 286
         if is_fedora; then