From 6af3b7cf9818b7ae0f70d98f546cecc19bc84618 Mon Sep 17 00:00:00 2001 From: Muhammad Aaqil Date: Sun, 13 Oct 2024 23:17:13 +0500 Subject: [PATCH 1/2] 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; From f705836e0fc0edc45e471b8613f11eb28b28ad30 Mon Sep 17 00:00:00 2001 From: Muhammad Aaqil Date: Sun, 20 Oct 2024 19:48:24 +0500 Subject: [PATCH 2/2] feat: fetch index info into the model Signed-off-by: Muhammad Aaqil --- lib/discovery.js | 140 ++++++++++++++++++------------------ test/mysql.discover.test.js | 17 +++++ test/schema.sql | 15 ++++ 3 files changed, 102 insertions(+), 70 deletions(-) diff --git a/lib/discovery.js b/lib/discovery.js index 6b764ef3..fc4bbfeb 100644 --- a/lib/discovery.js +++ b/lib/discovery.js @@ -158,89 +158,89 @@ function mixinDiscovery(MySQL, mysql) { let sql = null; if (schema) { 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) : ''} + `SELECT + cols.table_schema AS "owner", + cols.table_name AS "tableName", + cols.column_name AS "columnName", + cols.data_type AS "dataType", + cols.character_maximum_length AS "dataLength", + cols.numeric_precision AS "dataPrecision", + cols.numeric_scale AS "dataScale", + cols.column_type AS "columnType", + cols.is_nullable = 'YES' AS "nullable", + CASE WHEN cols.extra LIKE '%auto_increment%' THEN 1 ELSE 0 END AS "generated", + indexes.index_name AS "indexName", + indexes.non_unique AS "nonUnique", + indexes.seq_in_index AS "seqInIndex", + indexes.cardinality AS "cardinality", + indexes.index_type AS "indexType", + CASE WHEN fk.column_name IS NOT NULL THEN 1 ELSE 0 END AS "isForeignKey" + FROM + information_schema.columns cols + LEFT JOIN + information_schema.statistics indexes + ON + cols.table_schema = indexes.table_schema + AND cols.table_name = indexes.table_name + AND cols.column_name = indexes.column_name + LEFT JOIN + information_schema.KEY_COLUMN_USAGE fk + ON + cols.table_schema = fk.table_schema + AND cols.table_name = fk.table_name + AND cols.column_name = fk.column_name + AND fk.referenced_table_name IS NOT NULL + WHERE + cols.table_schema = ${mysql.escape(schema)} + ${table ? ' AND cols.table_name = ' + mysql.escape(table) : ''} `, - 'c.table_name, c.ordinal_position', + 'cols.table_name, cols.ordinal_position', {}, ); } else { 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", + `SELECT + cols.table_schema AS "owner", + cols.table_name AS "tableName", + cols.column_name AS "columnName", + cols.data_type AS "dataType", + cols.character_maximum_length AS "dataLength", + cols.numeric_precision AS "dataPrecision", + cols.numeric_scale AS "dataScale", + cols.column_type AS "columnType", + cols.is_nullable = 'YES' AS "nullable", + CASE WHEN cols.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) : ''} + indexes.cardinality AS "cardinality", + indexes.index_type AS "indexType", + CASE WHEN fk.column_name IS NOT NULL THEN 1 ELSE 0 END AS "isForeignKey" + FROM + information_schema.columns AS cols + LEFT JOIN + information_schema.statistics AS indexes + ON + cols.table_schema = indexes.table_schema + AND cols.table_name = indexes.table_name + AND cols.column_name = indexes.column_name + LEFT JOIN + information_schema.KEY_COLUMN_USAGE AS fk + ON + cols.table_schema = fk.table_schema + AND cols.table_name = fk.table_name + AND cols.column_name = fk.column_name + AND fk.referenced_table_name IS NOT NULL + WHERE + cols.table_schema = ${mysql.escape(schema)} + ${table ? ' AND cols.table_name = ' + mysql.escape(table) : ''} `, - 'columns.table_name, columns.ordinal_position', + 'cols.table_name, cols.ordinal_position', {}, ); } if (options.orderBy) { - sql += ' ORDER BY ' + options.orderBy; + sql += ' ORDER BY ' + 'cols.' + options.orderBy; } return sql; }; diff --git a/test/mysql.discover.test.js b/test/mysql.discover.test.js index b6d9c9c2..ed60abba 100644 --- a/test/mysql.discover.test.js +++ b/test/mysql.discover.test.js @@ -199,6 +199,23 @@ describe('Discover model primary keys', function() { }); }); +describe('Discover user model with index', function() { + it('should return user with index', function(done) { + db.discoverModelProperties('user', function(err, models) { + if (err) { + console.error(err); + done(err); + } else { + models.forEach(function(m) { + assert(m.tableName.toLowerCase() === 'user'); + assert(m.properties.email.index); + }); + done(null, models); + } + }); + }); +}); + describe('Discover model foreign keys', function() { it('should return an array of foreign keys for INVENTORY', function(done) { db.discoverForeignKeys('INVENTORY', function(err, models) { diff --git a/test/schema.sql b/test/schema.sql index 62d3acad..7c09b1f7 100644 --- a/test/schema.sql +++ b/test/schema.sql @@ -208,6 +208,21 @@ LOCK TABLES `RESERVATION` WRITE; /*!40000 ALTER TABLE `RESERVATION` ENABLE KEYS */; UNLOCK TABLES; +DROP TABLE IF EXISTS `USER`; +/*!40101 SET @saved_cs_client = @@character_set_client */; +/*!40101 SET character_set_client = utf8 */; + +CREATE TABLE `USER` ( + `ID` VARCHAR(20) NOT NULL, + `NAME` VARCHAR(100) NOT NULL, + `EMAIL` VARCHAR(255) NOT NULL, + `PASSWORD` VARCHAR(255) NOT NULL, + `CREATED_AT` TIMESTAMP DEFAULT CURRENT_TIMESTAMP, + `UPDATED_AT` TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP, + PRIMARY KEY (`ID`), + UNIQUE KEY `USER_EMAIL_UNIQUE` (`EMAIL`) +) ENGINE=MyISAM DEFAULT CHARSET=utf8; + -- -- Table structure for table `TESTGEN` --