From 6af3b7cf9818b7ae0f70d98f546cecc19bc84618 Mon Sep 17 00:00:00 2001 From: Muhammad Aaqil Date: Sun, 13 Oct 2024 23:17:13 +0500 Subject: [PATCH] feat: fetch index information for columns Signed-off-by: Muhammad Aaqil --- lib/discovery.js | 107 +++++++++++++++++++++++++++++++++++------------ 1 file changed, 80 insertions(+), 27 deletions(-) diff --git a/lib/discovery.js b/lib/discovery.js index 615c54da..6b764ef3 100644 --- a/lib/discovery.js +++ b/lib/discovery.js @@ -157,34 +157,87 @@ function mixinDiscovery(MySQL, mysql) { MySQL.prototype.buildQueryColumns = function(schema, table, options = {}) { let sql = null; if (schema) { - sql = paginateSQL('SELECT table_schema AS "owner",' + - ' table_name AS "tableName",' + - ' column_name AS "columnName",' + - ' data_type AS "dataType",' + - ' character_maximum_length AS "dataLength",' + - ' numeric_precision AS "dataPrecision",' + - ' numeric_scale AS "dataScale",' + - ' column_type AS "columnType",' + - ' is_nullable = \'YES\' AS "nullable",' + - ' CASE WHEN extra LIKE \'%auto_increment%\' THEN 1 ELSE 0 END AS "generated"' + - ' FROM information_schema.columns' + - ' WHERE table_schema=' + mysql.escape(schema) + - (table ? ' AND table_name=' + mysql.escape(table) : ''), - 'table_name, ordinal_position', {}); + sql = paginateSQL( + `SELECT + c.table_schema AS "owner", + c.table_name AS "tableName", + c.column_name AS "columnName", + c.data_type AS "dataType", + c.character_maximum_length AS "dataLength", + c.numeric_precision AS "dataPrecision", + c.numeric_scale AS "dataScale", + c.column_type AS "columnType", + c.is_nullable = 'YES' AS "nullable", + CASE WHEN c.extra LIKE '%auto_increment%' THEN 1 ELSE 0 END AS "generated", + s.index_name AS "indexName", + s.non_unique AS "nonUnique", + s.seq_in_index AS "seqInIndex", + s.cardinality AS "cardinality", + s.index_type AS "indexType", + CASE WHEN fk.column_name IS NOT NULL THEN 1 ELSE 0 END AS "isForeignKey" -- Flag for foreign key + FROM + information_schema.columns c + LEFT JOIN + information_schema.statistics s + ON + c.table_schema = s.table_schema + AND c.table_name = s.table_name + AND c.column_name = s.column_name + LEFT JOIN + information_schema.KEY_COLUMN_USAGE fk + ON + c.table_schema = fk.table_schema + AND c.table_name = fk.table_name + AND c.column_name = fk.column_name + AND fk.referenced_table_name IS NOT NULL -- Ensure it's a foreign key + WHERE + c.table_schema = ${mysql.escape(schema)} + ${table ? ' AND c.table_name = ' + mysql.escape(table) : ''} + `, + 'c.table_name, c.ordinal_position', + {}, + ); } else { - sql = paginateSQL('SELECT table_schema AS "owner",' + - ' table_name AS "tableName",' + - ' column_name AS "columnName",' + - ' data_type AS "dataType",' + - ' character_maximum_length AS "dataLength",' + - ' numeric_precision AS "dataPrecision",' + - ' numeric_scale AS "dataScale",' + - ' column_type AS "columnType",' + - ' is_nullable = \'YES\' AS "nullable",' + - ' CASE WHEN extra LIKE \'%auto_increment%\' THEN 1 ELSE 0 END AS "generated"' + - ' FROM information_schema.columns' + - (table ? ' WHERE table_name=' + mysql.escape(table) : ''), - 'table_name, ordinal_position', {}); + sql = paginateSQL( + `SELECT + columns.table_schema AS "owner", + columns.table_name AS "tableName", + columns.column_name AS "columnName", + columns.data_type AS "dataType", + columns.character_maximum_length AS "dataLength", + columns.numeric_precision AS "dataPrecision", + columns.numeric_scale AS "dataScale", + columns.column_type AS "columnType", + columns.is_nullable = 'YES' AS "nullable", + CASE WHEN columns.extra LIKE '%auto_increment%' THEN 1 ELSE 0 END AS "generated", + indexes.index_name AS "indexName", + indexes.seq_in_index AS "indexColumnOrder", + indexes.non_unique AS "nonUnique", + indexes.cardinality AS "cardinality", -- Cardinality of the index + indexes.index_type AS "indexType", -- Type of the index + CASE WHEN fk.column_name IS NOT NULL THEN 1 ELSE 0 END AS "isForeignKey" -- Flag for foreign key + FROM + information_schema.columns AS columns + LEFT JOIN + information_schema.statistics AS indexes + ON + columns.table_schema = indexes.table_schema + AND columns.table_name = indexes.table_name + AND columns.column_name = indexes.column_name + LEFT JOIN + information_schema.KEY_COLUMN_USAGE AS fk + ON + columns.table_schema = fk.table_schema + AND columns.table_name = fk.table_name + AND columns.column_name = fk.column_name + AND fk.referenced_table_name IS NOT NULL -- Ensure it's a foreign key + WHERE + columns.table_schema = ${mysql.escape(schema)} + ${table ? ' AND columns.table_name = ' + mysql.escape(table) : ''} + `, + 'columns.table_name, columns.ordinal_position', + {}, + ); } if (options.orderBy) { sql += ' ORDER BY ' + options.orderBy;