Skip to content

Instantly share code, notes, and snippets.

@utdrmac
Created August 19, 2014 15:31
Show Gist options
  • Star 0 You must be signed in to star a gist
  • Fork 1 You must be signed in to fork a gist
  • Save utdrmac/8fd63f4aae532ca6e507 to your computer and use it in GitHub Desktop.
Save utdrmac/8fd63f4aae532ca6e507 to your computer and use it in GitHub Desktop.
Find db.table.columns that are > 90% auto_increment capacity
SELECT TABLE_SCHEMA, TABLE_NAME, COLUMN_NAME, COLUMN_TYPE,
(CASE DATA_TYPE
WHEN 'tinyint' THEN 255
WHEN 'smallint' THEN 65535
WHEN 'mediumint' THEN 16777215
WHEN 'int' THEN 4294967295
WHEN 'bigint' THEN 18446744073709551615
END >> IF(LOCATE('unsigned', COLUMN_TYPE) > 0, 0, 1)
) AS MAX_VALUE,
AUTO_INCREMENT AS CURRENT_VALUE,
ROUND((AUTO_INCREMENT /
(CASE DATA_TYPE
WHEN 'tinyint' THEN 255
WHEN 'smallint' THEN 65535
WHEN 'mediumint' THEN 16777215
WHEN 'int' THEN 4294967295
WHEN 'bigint' THEN 18446744073709551615
END >> IF(LOCATE('unsigned', COLUMN_TYPE) > 0, 0, 1)
))*100, 2) AS AUTO_INCREMENT_RATIO
FROM
INFORMATION_SCHEMA.COLUMNS INNER JOIN INFORMATION_SCHEMA.TABLES USING (TABLE_SCHEMA, TABLE_NAME)
WHERE
TABLE_SCHEMA NOT IN ('mysql', 'INFORMATION_SCHEMA', 'performance_schema') AND EXTRA = 'auto_increment'
HAVING AUTO_INCREMENT_RATIO > 90;
Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment