If it's a general and growing problem, it might be time to consider generalising your idea about an intermediary table or two,, optimised for queries to developing an OLAP version of your DB, with summary tables optimised for your dozens or hundreds of queries.
If you're not sure the problem is general enough for that, you might want to start with ...
(a) a detailed optimisation of a few of the biggest and slowest queries, that might turn up some patterns that'll be helpful in OLAP design. To get started, you could post here a query, its Explain and Explain Analyze results, and Show Create Table results for each referenced table, all inside BBCode code tags for human readability
(b) an overall analysis of the DB and its resource demands & usage, starting with
MySQL version, innodb_buffer_pool_size,, machine RAM, how much RAM is used by other processes, and ...
(i) the result of ...
select engine,data,indexes,total
from (
select
ifnull(engine,'TOTALS') as engine,
concat(data,' GB') as data,
concat(indexes,' GB') as indexes,
concat(tot,' GB') as total,
if(engine is null,-1,tot) as ord
from (
select
engine,
round( sum(data_length)/1024/1024/1024, 2 ) as data,
round( sum(index_length)/1024/1024/1024, 2 ) as indexes,
round( sum(data_length+index_length)/1024/1024/1024, 2 ) as tot
from information_schema.tables
where engine is not null and engine not in('information_schema','performance_schema')
group by engine with rollup
) sums
) list
order by list.ord desc;
(ii) results of running these queries in the mysql client program ...
show variables;
show global status;
If MySQL 5.7 or later ...
select * from sys.memory_global_total;
select
substring_index(event_name,'/',2) as code_area,
sys.format_bytes( sum(current_alloc) ) as current_alloc
from sys.x$memory_global_by_current_bytes
group by substring_index(event_name,'/',2)
order by sum(current_alloc) desc;
select
concat(format(a.num * 100.0 / b.num,2),"%") bufferpoolfullpct
from
(select variable_value num from performance_schema.global_status
where variable_name = 'innodb_buffer_pool_pages_data') a,
(select variable_value num from performance_schema.global_status
where variable_name = 'innodb_buffer_pool_pages_total') b;
... and look for runaway mem use in the results of ...
select *
from performance_schema.memory_summary_global_by_event_name
where event_name like 'memory/performance_schema/%';
(iii) post the result of ...
free -m
Edited 1 time(s). Last edit at 10/21/2019 11:38AM by Peter Brawley.