High CPU Usage
-
@george1421 said in High CPU Usage:
STRICT_TRANS_TABLES
Interesting find. Hmmm, just did a quick test. This is not the case on Debian 9 (MariaDB 10.1.44). But Ubuntu (20.04 - pre release testing) with MySQL 8.0.19 does have the same
sql_mode
that as we see from the OP’s Ubuntu 18.04 install. I will see if I can figure out why they have it in Ubuntu. -
@Sebastian-Roth said in High CPU Usage:
I will see if I can figure out why they have it in Ubuntu.
It looks like its the defaults compiled into the sql server because the OP doesn’t have that value specifically set. So now we need to come up with the correct line to exclude that value from the sql server options. Once we get that turned off we can then convert the rest of the tables to innodb format. I do think it is a great find too because that value would have stopped the creation of the fog tables if we defaulted to the innodb engine.
-
@george1421 said in High CPU Usage:
So now we need to come up with the correct line to exclude that value from the sql server options.
Definitely worth a try though I am not sure how we will handle this “for the mass”. Sure we can mess with DB settings but I am afraid of doing this and causing a lot more issues than we had before. But we’ll see. Probably we’ll find a god solution to that somehow.
-
@Sebastian-Roth I had some more time to look into this and I admit, “I couldn’t see the forest because of the trees”.
This is what the OP posted as the global configuration.
mysql> SELECT @@GLOBAL.sql_mode global, @@SESSION.sql_mode session; +-------------------------------------------------------------------------------------------------------------------------------------------+-------------------------------------------------------------------------------------------------------------------------------------------+ | global | session | +-------------------------------------------------------------------------------------------------------------------------------------------+-------------------------------------------------------------------------------------------------------------------------------------------+ | ONLY_FULL_GROUP_BY,STRICT_TRANS_TABLES,NO_ZERO_IN_DATE,NO_ZERO_DATE,ERROR_FOR_DIVISION_BY_ZERO,NO_AUTO_CREATE_USER,NO_ENGINE_SUBSTITUTION | ONLY_FULL_GROUP_BY,STRICT_TRANS_TABLES,NO_ZERO_IN_DATE,NO_ZERO_DATE,ERROR_FOR_DIVISION_BY_ZERO,NO_AUTO_CREATE_USER,NO_ENGINE_SUBSTITUTION | +-------------------------------------------------------------------------------------------------------------------------------------------+-------------------------------------------------------------------------------------------------------------------------------------------+ 1 row in set (0.01 sec)
This is the error he received when he tried to alter the table.
mysql> ALTER TABLE hosts ENGINE=InnoDB; ERROR 1067 (42000): Invalid default value for 'hostSecTime'
If we describe table hosts this is what we see.
MariaDB [fog]> describe hosts; +------------------+---------------+------+-----+---------------------+----------------+ | Field | Type | Null | Key | Default | Extra | +------------------+---------------+------+-----+---------------------+----------------+ | hostID | int(11) | NO | PRI | NULL | auto_increment | | hostName | varchar(16) | NO | UNI | NULL | | | hostDesc | longtext | NO | | NULL | | | hostIP | varchar(25) | NO | MUL | NULL | | | hostImage | int(11) | NO | | NULL | | | hostBuilding | int(11) | NO | | NULL | | | hostCreateDate | timestamp | NO | | CURRENT_TIMESTAMP | | | hostLastDeploy | datetime | NO | | NULL | | | hostCreateBy | varchar(50) | NO | | NULL | | | hostUseAD | char(1) | NO | MUL | NULL | | | hostADDomain | varchar(250) | NO | | NULL | | | hostADOU | longtext | NO | | NULL | | | hostADUser | varchar(250) | NO | | NULL | | | hostADPass | varchar(250) | NO | | NULL | | | hostADPassLegacy | longtext | NO | | NULL | | | hostProductKey | longtext | YES | | NULL | | | hostPrinterLevel | varchar(2) | NO | | NULL | | | hostKernelArgs | varchar(250) | NO | | NULL | | | hostKernel | varchar(250) | NO | | NULL | | | hostDevice | varchar(250) | NO | | NULL | | | hostInit | longtext | YES | | NULL | | | hostPending | enum('0','1') | NO | | NULL | | | hostPubKey | longtext | NO | | NULL | | | hostSecToken | longtext | NO | | NULL | | | hostSecTime | timestamp | NO | | 0000-00-00 00:00:00 | | | hostPingCode | varchar(20) | YES | | NULL | | | hostExitBios | longtext | YES | | NULL | | | hostExitEfi | longtext | YES | | NULL | | | hostEnforce | enum('0','1') | NO | | 1 | | +------------------+---------------+------+-----+---------------------+----------------+ 29 rows in set (0.02 sec)
So the issue is (maybe) not the STRICT_TRANS_TABLES like I originally thought, but the two values just after those of NO_ZERO_IN_DATE,NO_ZERO_DATE
With that in mind we might consider changing the default values for the tables from
0000-00-00 00:00:00
to something more memorable such as1980-01-01 00:00:00
I don’t know the impact on FOG’s internal program if it uses
0000-00-00 00:00:00
as anything significant or its just a value other than NULL. This seems to be an issue with mysql it doesn’t look like mariadb has these value but does introduce strict_trans_table in 10.2.4 and later. ref: https://mariadb.com/kb/en/sql-mode/ -
@george1421 Hi George, let me know if you need me to do anything further
-
@Arrowtron ok i will follow up in about 30 minutes with a test we can try.
-
@Arrowtron Our goal with this step is to remove 2 settings from the compiled in default values for the db server.
To do that we need to add a configuration file into /etc/mysql/conf.d/ called sqlmode.cnf. Into that file add in the following:
[mysqld] sql-mode="ONLY_FULL_GROUP_BY,STRICT_TRANS_TABLES,ERROR_FOR_DIVISION_BY_ZERO,NO_AUTO_CREATE_USER,NO_ENGINE_SUBSTITUTION"
Save that file and then restart the sql server with
sudo systemctl restart mariadb
You might have to adjust for your linux OS.Once the sql server comes back online login with the mysql cli too and key in
SELECT @@GLOBAL.sql_mode global, @@SESSION.sql_mode session;
With any luck the following settings will be gone.
+-------------------------------------------------------------------------------------------------------------------------------------------+-------------------------------------------------------------------------------------------------------------------------------------------+ | global | session | +-------------------------------------------------------------------------------------------------------------------------------------------+-------------------------------------------------------------------------------------------------------------------------------------------+ | ONLY_FULL_GROUP_BY,STRICT_TRANS_TABLES,>>NO_ZERO_IN_DATE<<,>>NO_ZERO_DATE<<,ERROR_FOR_DIVISION_BY_ZERO,NO_AUTO_CREATE_USER,NO_ENGINE_SUBSTITUTION | ONLY_FULL_GROUP_BY,STRICT_TRANS_TABLES,NO_ZERO_IN_DATE,NO_ZERO_DATE,ERROR_FOR_DIVISION_BY_ZERO,NO_AUTO_CREATE_USER,NO_ENGINE_SUBSTITUTION | +-------------------------------------------------------------------------------------------------------------------------------------------+-------------------------------------------------------------------------------------------------------------------------------------------+
If only those values are missing then lets continue with the alter database commands.
ALTER TABLE hosts ENGINE=InnoDB; ALTER TABLE imagingLog ENGINE=InnoDB; ALTER TABLE inventory ENGINE=InnoDB; ALTER TABLE snapinTasks ENGINE=InnoDB; SELECT TABLE_NAME,ENGINE FROM information_schema.TABLES WHERE TABLE_SCHEMA = 'fog' and ENGINE = 'MyISAM';
-
Added the configuration file
sudo systemctl restart mariadb Failed to restart mariadb.service: Unit mariadb.service not found.
Ran systemctl restart mysql (also restarted the server)
Entered in your mysql command, result below:
SELECT @@GLOBAL.sql_mode global, @@SESSION.sql_mode session; +--------------------------------------------------------------------------------------------------------------+--------------------------------------------------------------------------------------------------------------+ | global | session | +--------------------------------------------------------------------------------------------------------------+--------------------------------------------------------------------------------------------------------------+ | ONLY_FULL_GROUP_BY,STRICT_TRANS_TABLES,ERROR_FOR_DIVISION_BY_ZERO,NO_AUTO_CREATE_USER,NO_ENGINE_SUBSTITUTION | ONLY_FULL_GROUP_BY,STRICT_TRANS_TABLES,ERROR_FOR_DIVISION_BY_ZERO,NO_AUTO_CREATE_USER,NO_ENGINE_SUBSTITUTION | +--------------------------------------------------------------------------------------------------------------+--------------------------------------------------------------------------------------------------------------+ 1 row in set (0.00 sec) mysql> ALTER TABLE hosts ENGINE=InnoDB; ERROR 1046 (3D000): No database selected mysql> ALTER TABLE imagingLog ENGINE=InnoDB; ERROR 1046 (3D000): No database selected mysql> ALTER TABLE inventory ENGINE=InnoDB; ERROR 1046 (3D000): No database selected mysql> ALTER TABLE snapinTasks ENGINE=InnoDB; ERROR 1046 (3D000): No database selected
Something I’m doing wrong?
-
@Arrowtron ok well 50% (and the most important bits worked). We were able to remove the date requirements from the default values for mysql. Good catch on the mariadb vs mysql.
The only thing missing is this command before the
ALTER TABLE
command.USE fog
to tell mysql cli which database we are working on.USE fog; ALTER TABLE hosts ENGINE=InnoDB; ALTER TABLE imagingLog ENGINE=InnoDB; ALTER TABLE inventory ENGINE=InnoDB; ALTER TABLE snapinTasks ENGINE=InnoDB; SELECT TABLE_NAME,ENGINE FROM information_schema.TABLES WHERE TABLE_SCHEMA = 'fog' and ENGINE = 'MyISAM';
-
Ah that’s done it!
mysql> ALTER TABLE hosts ENGINE=InnoDB; Query OK, 1116 rows affected (0.34 sec) Records: 1116 Duplicates: 0 Warnings: 0 mysql> ALTER TABLE imagingLog ENGINE=InnoDB; Query OK, 1216 rows affected (0.06 sec) Records: 1216 Duplicates: 0 Warnings: 0 mysql> ALTER TABLE inventory ENGINE=InnoDB; Query OK, 907 rows affected (0.16 sec) Records: 907 Duplicates: 0 Warnings: 0 mysql> ALTER TABLE snapinTasks ENGINE=InnoDB; Query OK, 231 rows affected (0.11 sec) Records: 231 Duplicates: 0 Warnings: 0 mysql> ALTER TABLE tasks ENGINE=InnoDB; Query OK, 87 rows affected (0.06 sec) Records: 87 Duplicates: 0 Warnings: 0 mysql> SELECT TABLE_NAME,ENGINE -> FROM information_schema.TABLES -> WHERE TABLE_SCHEMA = 'fog' and ENGINE = 'MyISAM'; Empty set (0.00 sec)
I’ve reset the client polling time to 60 seconds. Let it run for 4 hrs with the newly converted tables. About ~580 PC’s online with FOG installed at the time. It fluctuates a fair bit in terms of load average. Pictures below; I’ll change client polling to 180. CPU usage is quite acceptable at 180, unless you want it to remain at 60 for the testing purpose? I’ll report back in a week with mysqltuner results
-
I’ve looked over all of the posts in this particular topic. Perhaps I’ve missed it, but I don’t see FOG Server specs. How many cores? Core speed? Type of disk, like SAS2 or SAS3, SATA3, etc. Disk speed? Disk spinner or solid state? Amount of RAM? Size of Swap Space? Is this server a dedicated server? These things are important to know.
-
@Wayne-Workman
Fair point, some of the specs are in the screenshots in htop, however I’ll document the othersVMware Environment
2 Cores for Virtual Machine
Intel Xeon Silver 4214 @ 2.2Ghz per core
3PAR iSCSI Disk | HDD | 10K SAS
RAM 4GB
SWAP 4GB -
@Arrowtron In addition to increasing your fog client checking time as was suggested by @Sebastian-Roth, and in addition to moving the database to InnoDB as suggested by @george1421 I’d recommend you go to 4 CPU cores.
-
@Wayne-Workman Yes i’ll be changing the client check in time after posting the required information from MySQLtuner for @george1421.
Yes 4 Cores would be nice, however due to fog not a being a critical server on our production environment it’s best not to take away resources from other servers. This might change in future though@george1421 Let me know if this is good info for you, I’m looking to update fog in the next couple of weeks. Maybe to the latest development version
Server has been up for ~8 Days
>> MySQLTuner 1.7.19 - Major Hayden <major@mhtx.net> >> Bug reports, feature requests, and downloads at http://mysqltuner.com/ >> Run with '--help' for additional options and output filtering [--] Skipped version check for MySQLTuner script Please enter your MySQL administrative login: root [OK] Currently running supported MySQL version 5.7.28-0ubuntu0.19.04.2 [OK] Operating on 64-bit architecture -------- Log file Recommendations ------------------------------------------------------------------ [OK] Log file /var/log/mysql/error.log exists [--] Log file: /var/log/mysql/error.log(106B) [OK] Log file /var/log/mysql/error.log is readable. [OK] Log file /var/log/mysql/error.log is not empty [OK] Log file /var/log/mysql/error.log is smaller than 32 Mb [OK] /var/log/mysql/error.log doesn't contain any warning. [OK] /var/log/mysql/error.log doesn't contain any error. [--] 0 start(s) detected in /var/log/mysql/error.log [--] 0 shutdown(s) detected in /var/log/mysql/error.log -------- Storage Engine Statistics ----------------------------------------------------------------- [--] Status: +ARCHIVE +BLACKHOLE +CSV -FEDERATED +InnoDB +MEMORY +MRG_MYISAM +MyISAM +PERFORMANCE_SCHEMA [--] Data in InnoDB tables: 17.3M (Tables: 55) [OK] Total fragmented tables: 0 -------- Analysis Performance Metrics -------------------------------------------------------------- [--] innodb_stats_on_metadata: OFF [OK] No stat updates during querying INFORMATION_SCHEMA. -------- CVE Security Recommendations -------------------------------------------------------------- [--] Skipped due to --cvefile option undefined -------- Performance Metrics ----------------------------------------------------------------------- [--] Up for: 8d 2h 27m 17s (521M q [744.370 qps], 11M conn, TX: 468G, RX: 112G) [--] Reads / Writes: 98% / 2% [--] Binary logging is disabled [--] Physical Memory : 3.8G [--] Max MySQL memory : 2.7G [--] Other process memory: 0B [--] Total buffers: 192.0M global + 17.1M per thread (151 max threads) [--] P_S Max memory usage: 72B [--] Galera GCache Max memory usage: 0B [OK] Maximum reached memory usage: 1.1G (29.54% of installed RAM) [OK] Maximum possible memory usage: 2.7G (70.22% of installed RAM) [OK] Overall possible memory usage with other process is compatible with memory available [OK] Slow queries: 0% (0/521M) [OK] Highest usage of available connections: 37% (57/151) [OK] Aborted connections: 0.00% (117/11896308) [!!] name resolution is active : a reverse name resolution is made for each new connection and can reduce performance [!!] Query cache may be disabled by default due to mutex contention. [!!] Query cache efficiency: 0.0% (0 cached / 477M selects) [OK] Query cache prunes per day: 0 [OK] Sorts requiring temporary tables: 0% (15 temp sorts / 146M sorts) [OK] No joins without indexes [!!] Temporary tables created on disk: 97% (11M on disk / 12M total) [OK] Thread cache hit rate: 98% (210K created / 11M connections) [OK] Table cache hit rate: 96% (1K open / 1K opened) [OK] table_definition_cache(1400) is upper than number of tables(334) [OK] Open file limit used: 0% (6/5K) [OK] Table locks acquired immediately: 100% (102 immediate / 102 locks) -------- Performance schema ------------------------------------------------------------------------ [--] Memory used by P_S: 72B [--] Sys schema is installed. -------- ThreadPool Metrics ------------------------------------------------------------------------ [--] ThreadPool stat is disabled. -------- MyISAM Metrics ---------------------------------------------------------------------------- [!!] Key buffer used: 18.2% (3M used / 16M cache) [OK] Key buffer size / total MyISAM indexes: 16.0M/43.0K [!!] Read Key buffer hit rate: 50.0% (6 cached / 3 reads) -------- InnoDB Metrics ---------------------------------------------------------------------------- [--] InnoDB is enabled. [--] InnoDB Thread Concurrency: 0 [OK] InnoDB File per table is activated [OK] InnoDB buffer pool / data size: 128.0M/17.3M [!!] Ratio InnoDB log file size / InnoDB Buffer pool size (75 %): 48.0M * 2/128.0M should be equal to 25% [OK] InnoDB buffer pool instances: 1 [--] Number of InnoDB Buffer Pool Chunk : 1 for 1 Buffer Pool Instance(s) [OK] Innodb_buffer_pool_size aligned with Innodb_buffer_pool_chunk_size & Innodb_buffer_pool_instances [OK] InnoDB Read buffer efficiency: 100.00% (12493296749 hits/ 12493297691 total) [!!] InnoDB Write Log efficiency: 44.2% (2737439 hits/ 6192657 total) [OK] InnoDB log waits: 0.00% (0 waits / 3455218 writes) -------- AriaDB Metrics ---------------------------------------------------------------------------- [--] AriaDB is disabled. -------- TokuDB Metrics ---------------------------------------------------------------------------- [--] TokuDB is disabled. -------- XtraDB Metrics ---------------------------------------------------------------------------- [--] XtraDB is disabled. -------- Galera Metrics ---------------------------------------------------------------------------- [--] Galera is disabled. -------- Replication Metrics ----------------------------------------------------------------------- [--] Galera Synchronous replication: NO [--] No replication slave(s) for this server. [--] Binlog format: ROW [--] XA support enabled: ON [--] Semi synchronous replication Master: Not Activated [--] Semi synchronous replication Slave: Not Activated [--] This is a standalone server -------- Recommendations --------------------------------------------------------------------------- General recommendations: Restrict Host for 'fogstorage'@% to fogstorage@SpecificDNSorIp UPDATE mysql.user SET host ='SpecificDNSorIp' WHERE user='fogstorage' AND host ='%'; FLUSH PRIVILEGES; Configure your accounts with ip or subnets only, then update your configuration with skip-name-resolve=1 When making adjustments, make tmp_table_size/max_heap_table_size equal Reduce your SELECT DISTINCT queries which have no LIMIT clause Before changing innodb_log_file_size and/or innodb_log_files_in_group read this: https://bit.ly/2TcGgtU Variables to adjust: query_cache_size (=0) query_cache_type (=0) query_cache_limit (> 1M, or use smaller result sets) tmp_table_size (> 16M) max_heap_table_size (> 16M) innodb_log_file_size should be (=16M) if possible, so InnoDB total log files size equals to 25% of buffer pool size.