Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

perf: Use Optimized Queries for MySQLQueryRunner.loadTables #6886

Merged
merged 1 commit into from
Oct 15, 2020
Merged
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
188 changes: 162 additions & 26 deletions src/driver/mysql/MysqlQueryRunner.ts
Original file line number Diff line number Diff line change
Expand Up @@ -1200,47 +1200,183 @@ export class MysqlQueryRunner extends BaseQueryRunner implements QueryRunner {
return [];

const currentDatabase = await this.getCurrentDatabase();
const tablesCondition = tableNames.map(tableName => {

// The following SQL brought to you by:
// A terrible understanding of https://dev.mysql.com/doc/refman/8.0/en/information-schema-optimization.html
//
// Short Version:
// INFORMATION_SCHEMA is a weird metadata virtual table and follows VERY FEW of the normal
// query optimization rules. Depending on the columns you query against & the columns you're SELECTing
// there can be a drastically different query performance - this is because the tables map to
// data on the disk and some pieces of data require a scan of the data directory, the database files, etc

// With most of these, you'll want to do an `EXPLAIN` when making changes to make sure
// the changes you're making aren't changing the query performance profile negatively
// When you do the explain you'll want to look at the `Extra` field -
// It will look something like: "Using where; {FILE_OPENING}; Scanned {DB_NUM} databases"
// FILE_OPENING will commonly be OPEN_FRM_ONLY or OPEN_FULL_TABLE - you want to aim to NOT do
// an OPEN_FULL_TABLE unless necessary. DB_NUM may be a number or "all" - you really want to
// keep this to 0 or 1. Ideally 0. "All" means you've scanned all databases - not good.
//
// For more info, see the above link to the MySQL docs.
//
// Something not noted in the docs is that complex `WHERE` clauses - such as `OR` expressions -
// will cause the query to not hit the optimizations & do full scans. This is why
// a number of queries below do `UNION`s of single `WHERE` clauses.

// Avoid data directory scan: TABLE_SCHEMA
// Avoid database directory scan: TABLE_NAME
// Full columns: CARDINALITY & INDEX_TYPE - everything else is FRM only
const statsSubquerySql = tableNames.map(tableName => {
let [database, name] = tableName.split(".");
if (!name) {
name = database;
database = this.driver.database || currentDatabase;
}
return `(\`TABLE_SCHEMA\` = '${database}' AND \`TABLE_NAME\` = '${name}')`;
}).join(" OR ");
const tablesSql = `SELECT * FROM \`INFORMATION_SCHEMA\`.\`TABLES\` WHERE ` + tablesCondition;

const columnsSql = `SELECT * FROM \`INFORMATION_SCHEMA\`.\`COLUMNS\` WHERE ` + tablesCondition;

const primaryKeySql = `SELECT * FROM \`INFORMATION_SCHEMA\`.\`KEY_COLUMN_USAGE\` WHERE \`CONSTRAINT_NAME\` = 'PRIMARY' AND (${tablesCondition})`;

const collationsSql = `SELECT \`SCHEMA_NAME\`, \`DEFAULT_CHARACTER_SET_NAME\` as \`CHARSET\`, \`DEFAULT_COLLATION_NAME\` AS \`COLLATION\` FROM \`INFORMATION_SCHEMA\`.\`SCHEMATA\``;

const indicesCondition = tableNames.map(tableName => {
return `
SELECT
*
FROM \`INFORMATION_SCHEMA\`.\`STATISTICS\`
WHERE
\`TABLE_SCHEMA\` = '${database}'
AND
\`TABLE_NAME\` = '${name}'
`;
}).join(" UNION ");

// Avoid data directory scan: TABLE_SCHEMA
// Avoid database directory scan: TABLE_NAME
// All columns will hit the full table.
const kcuSubquerySql = tableNames.map(tableName => {
let [database, name] = tableName.split(".");
if (!name) {
name = database;
database = this.driver.database || currentDatabase;
}
return `(\`s\`.\`TABLE_SCHEMA\` = '${database}' AND \`s\`.\`TABLE_NAME\` = '${name}')`;
}).join(" OR ");
const indicesSql = `SELECT \`s\`.* FROM \`INFORMATION_SCHEMA\`.\`STATISTICS\` \`s\` ` +
`LEFT JOIN \`INFORMATION_SCHEMA\`.\`REFERENTIAL_CONSTRAINTS\` \`rc\` ON \`s\`.\`INDEX_NAME\` = \`rc\`.\`CONSTRAINT_NAME\` AND \`s\`.\`TABLE_SCHEMA\` = \`rc\`.\`CONSTRAINT_SCHEMA\`` +
`WHERE (${indicesCondition}) AND \`s\`.\`INDEX_NAME\` != 'PRIMARY' AND \`rc\`.\`CONSTRAINT_NAME\` IS NULL`;

const foreignKeysCondition = tableNames.map(tableName => {
return `
SELECT
*
FROM \`INFORMATION_SCHEMA\`.\`KEY_COLUMN_USAGE\` \`kcu\`
WHERE
\`kcu\`.\`TABLE_SCHEMA\` = '${database}'
AND
\`kcu\`.\`TABLE_NAME\` = '${name}'
`;
}).join(" UNION ");

// Avoid data directory scan: CONSTRAINT_SCHEMA
// Avoid database directory scan: TABLE_NAME
// All columns will hit the full table.
const rcSubquerySql = tableNames.map(tableName => {
let [database, name] = tableName.split(".");
if (!name) {
name = database;
database = this.driver.database || currentDatabase;
}
return `(\`kcu\`.\`TABLE_SCHEMA\` = '${database}' AND \`kcu\`.\`TABLE_NAME\` = '${name}')`;
}).join(" OR ");
const foreignKeysSql = `SELECT \`kcu\`.\`TABLE_SCHEMA\`, \`kcu\`.\`TABLE_NAME\`, \`kcu\`.\`CONSTRAINT_NAME\`, \`kcu\`.\`COLUMN_NAME\`, \`kcu\`.\`REFERENCED_TABLE_SCHEMA\`, ` +
`\`kcu\`.\`REFERENCED_TABLE_NAME\`, \`kcu\`.\`REFERENCED_COLUMN_NAME\`, \`rc\`.\`DELETE_RULE\` \`ON_DELETE\`, \`rc\`.\`UPDATE_RULE\` \`ON_UPDATE\` ` +
`FROM \`INFORMATION_SCHEMA\`.\`KEY_COLUMN_USAGE\` \`kcu\` ` +
`INNER JOIN \`INFORMATION_SCHEMA\`.\`REFERENTIAL_CONSTRAINTS\` \`rc\` ON \`rc\`.\`constraint_name\` = \`kcu\`.\`constraint_name\` AND \`rc\`.\`CONSTRAINT_SCHEMA\` = \`kcu\`.\`CONSTRAINT_SCHEMA\` AND \`rc\`.\`TABLE_NAME\` = \`kcu\`.\`TABLE_NAME\` ` +
`WHERE ` + foreignKeysCondition;
return `
SELECT
*
FROM \`INFORMATION_SCHEMA\`.\`REFERENTIAL_CONSTRAINTS\`
WHERE
\`CONSTRAINT_SCHEMA\` = '${database}'
AND
\`TABLE_NAME\` = '${name}'
`;
}).join(" UNION ");

// Avoid data directory scan: TABLE_SCHEMA
// Avoid database directory scan: TABLE_NAME
// We only use `TABLE_SCHEMA` and `TABLE_NAME` which is `SKIP_OPEN_TABLE`
const tablesSql = tableNames.map(tableName => {
let [database, name] = tableName.split(".");
if (!name) {
name = database;
database = this.driver.database || currentDatabase;
}
return `
SELECT
\`TABLE_SCHEMA\`,
\`TABLE_NAME\`
FROM
\`INFORMATION_SCHEMA\`.\`TABLES\`
WHERE
\`TABLE_SCHEMA\` = '${database}'
AND
\`TABLE_NAME\` = '${name}'
`;
}).join(" UNION ");

// Avoid data directory scan: TABLE_SCHEMA
// Avoid database directory scan: TABLE_NAME
// OPEN_FRM_ONLY applies to all columns
const columnsSql = tableNames.map(tableName => {
let [database, name] = tableName.split(".");
if (!name) {
name = database;
database = this.driver.database || currentDatabase;
}
return `
SELECT
*
FROM
\`INFORMATION_SCHEMA\`.\`COLUMNS\`
WHERE
\`TABLE_SCHEMA\` = '${database}'
AND
\`TABLE_NAME\` = '${name}'
`;
}).join(" UNION ");

// No Optimizations are available for COLLATIONS
const collationsSql = `
SELECT
\`SCHEMA_NAME\`,
\`DEFAULT_CHARACTER_SET_NAME\` as \`CHARSET\`,
\`DEFAULT_COLLATION_NAME\` AS \`COLLATION\`
FROM \`INFORMATION_SCHEMA\`.\`SCHEMATA\`
`;

// Key Column Usage but only for PKs
const primaryKeySql = `SELECT * FROM (${kcuSubquerySql}) \`kcu\` WHERE \`CONSTRAINT_NAME\` = 'PRIMARY'`;

// Combine stats & referential constraints
const indicesSql = `
SELECT
\`s\`.*
FROM (${statsSubquerySql}) \`s\`
LEFT JOIN (${rcSubquerySql}) \`rc\`
ON
\`s\`.\`INDEX_NAME\` = \`rc\`.\`CONSTRAINT_NAME\`
AND
\`s\`.\`TABLE_SCHEMA\` = \`rc\`.\`CONSTRAINT_SCHEMA\`
WHERE
\`s\`.\`INDEX_NAME\` != 'PRIMARY'
AND
\`rc\`.\`CONSTRAINT_NAME\` IS NULL
`;

// Combine Key Column Usage & Referential Constraints
const foreignKeysSql = `
SELECT
\`kcu\`.\`TABLE_SCHEMA\`,
\`kcu\`.\`TABLE_NAME\`,
\`kcu\`.\`CONSTRAINT_NAME\`,
\`kcu\`.\`COLUMN_NAME\`,
\`kcu\`.\`REFERENCED_TABLE_SCHEMA\`,
\`kcu\`.\`REFERENCED_TABLE_NAME\`,
\`kcu\`.\`REFERENCED_COLUMN_NAME\`,
\`rc\`.\`DELETE_RULE\` \`ON_DELETE\`,
\`rc\`.\`UPDATE_RULE\` \`ON_UPDATE\`
FROM (${kcuSubquerySql}) \`kcu\`
INNER JOIN (${rcSubquerySql}) \`rc\`
ON
\`rc\`.\`CONSTRAINT_SCHEMA\` = \`kcu\`.\`CONSTRAINT_SCHEMA\`
AND
\`rc\`.\`TABLE_NAME\` = \`kcu\`.\`TABLE_NAME\`
AND
\`rc\`.\`CONSTRAINT_NAME\` = \`kcu\`.\`CONSTRAINT_NAME\`
`;

const [dbTables, dbColumns, dbPrimaryKeys, dbCollations, dbIndices, dbForeignKeys]: ObjectLiteral[][] = await Promise.all([
this.query(tablesSql),
this.query(columnsSql),
Expand Down