1-- Copyright (c) 2014, 2015, Oracle and/or its affiliates. All rights reserved.
2--
3-- This program is free software; you can redistribute it and/or modify
4-- it under the terms of the GNU General Public License as published by
5-- the Free Software Foundation; version 2 of the License.
6--
7-- This program is distributed in the hope that it will be useful,
8-- but WITHOUT ANY WARRANTY; without even the implied warranty of
9-- MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE.  See the
10-- GNU General Public License for more details.
11--
12-- You should have received a copy of the GNU General Public License
13-- along with this program; if not, write to the Free Software
14-- Foundation, Inc., 51 Franklin St, Fifth Floor, Boston, MA 02110-1301 USA
15
16--
17-- View: innodb_buffer_stats_by_table
18--
19-- Summarizes the output of the INFORMATION_SCHEMA.INNODB_BUFFER_PAGE
20-- table, aggregating by schema and table name
21--
22-- mysql> select * from innodb_buffer_stats_by_table;
23-- +--------------------------+------------------------------------+------------+-----------+-------+--------------+-----------+-------------+
24-- | object_schema            | object_name                        | allocated  | data      | pages | pages_hashed | pages_old | rows_cached |
25-- +--------------------------+------------------------------------+------------+-----------+-------+--------------+-----------+-------------+
26-- | InnoDB System            | SYS_COLUMNS                        | 128.00 KiB | 98.97 KiB |     8 |            8 |         8 |        1532 |
27-- | InnoDB System            | SYS_FOREIGN                        | 128.00 KiB | 55.48 KiB |     8 |            8 |         8 |         172 |
28-- | InnoDB System            | SYS_TABLES                         | 128.00 KiB | 56.18 KiB |     8 |            8 |         8 |         365 |
29-- | InnoDB System            | SYS_INDEXES                        | 112.00 KiB | 76.16 KiB |     7 |            7 |         7 |        1046 |
30-- | mem30_trunk__instruments | agentlatencytime                   | 96.00 KiB  | 28.83 KiB |     6 |            6 |         6 |         252 |
31-- | mem30_trunk__instruments | binlogspaceusagedata               | 96.00 KiB  | 22.54 KiB |     6 |            6 |         6 |         196 |
32-- | mem30_trunk__instruments | connectionsdata                    | 96.00 KiB  | 36.68 KiB |     6 |            6 |         6 |         276 |
33-- ...
34-- +--------------------------+------------------------------------+------------+-----------+-------+--------------+-----------+-------------+
35--
36
37CREATE OR REPLACE
38  ALGORITHM = TEMPTABLE
39  DEFINER = 'root'@'localhost'
40  SQL SECURITY INVOKER
41VIEW innodb_buffer_stats_by_table (
42  object_schema,
43  object_name,
44  allocated,
45  data,
46  pages,
47  pages_hashed,
48  pages_old,
49  rows_cached
50) AS
51SELECT IF(LOCATE('.', ibp.table_name) = 0, 'InnoDB System', REPLACE(SUBSTRING_INDEX(ibp.table_name, '.', 1), '`', '')) AS object_schema,
52       REPLACE(SUBSTRING_INDEX(ibp.table_name, '.', -1), '`', '') AS object_name,
53       sys.format_bytes(SUM(IF(ibp.compressed_size = 0, 16384, compressed_size))) AS allocated,
54       sys.format_bytes(SUM(ibp.data_size)) AS data,
55       COUNT(ibp.page_number) AS pages,
56       COUNT(IF(ibp.is_hashed = 'YES', 1, 0)) AS pages_hashed,
57       COUNT(IF(ibp.is_old = 'YES', 1, 0)) AS pages_old,
58       ROUND(SUM(ibp.number_records)/COUNT(DISTINCT ibp.index_name)) AS rows_cached
59  FROM information_schema.innodb_buffer_page ibp
60 WHERE table_name IS NOT NULL
61 GROUP BY object_schema, object_name
62 ORDER BY SUM(IF(ibp.compressed_size = 0, 16384, compressed_size)) DESC;
63