diff --git a/src/components/gui/tabs/relational-diagram-tab/index.tsx b/src/components/gui/tabs/relational-diagram-tab/index.tsx index e664b322..0b7875ff 100644 --- a/src/components/gui/tabs/relational-diagram-tab/index.tsx +++ b/src/components/gui/tabs/relational-diagram-tab/index.tsx @@ -95,10 +95,10 @@ function mapSchema( height: 14, }, id: `${item.name}-${column.constraint.foreignKey.foreignTableName}`, - source: item.name, - target: column.constraint.foreignKey.foreignTableName || "", - sourceHandle: column.name, - targetHandle: column.constraint.foreignKey.foreignColumns + target: item.name, + source: column.constraint.foreignKey.foreignTableName || "", + targetHandle: column.name, + sourceHandle: column.constraint.foreignKey.foreignColumns ? column.constraint.foreignKey.foreignColumns[0] : "", animated: true, @@ -135,10 +135,10 @@ function mapSchema( height: 14, }, id: `${item.name}-${constraint.foreignKey.foreignTableName}`, - source: item.name, - target: constraint.foreignKey.foreignTableName || "", - sourceHandle: columnName, - targetHandle: constraint.foreignKey.foreignColumns + target: item.name, + source: constraint.foreignKey.foreignTableName || "", + targetHandle: columnName, + sourceHandle: constraint.foreignKey.foreignColumns ? constraint.foreignKey.foreignColumns[0] : "", animated: true, @@ -203,13 +203,12 @@ function mapSchema( // Rearrange the nodes with relationship // We need to find the position const relationshipRightPosition = - Math.max(...layoutRelationship.nodes.map((x) => x.position.x)) + + (Math.max(...layoutRelationship.nodes.map((x) => x.position.x)) ?? 0) + NODE_MARGIN + MAX_NODE_WIDTH; - const relationshipTopPosition = Math.min( - ...layoutRelationship.nodes.map((x) => x.position.y) - ); + const relationshipTopPosition = + Math.min(...layoutRelationship.nodes.map((x) => x.position.y)) ?? 0; // Calculate estimate area of the nodes without relationship const area = diff --git a/src/drivers/mysql/mysql-driver.ts b/src/drivers/mysql/mysql-driver.ts index 363cb413..9225c1b5 100644 --- a/src/drivers/mysql/mysql-driver.ts +++ b/src/drivers/mysql/mysql-driver.ts @@ -8,6 +8,7 @@ import { TableColumnDataType, DatabaseTableSchemaChange, ColumnTypeSelector, + DatabaseTableColumnConstraint, } from "../base-driver"; import CommonSQLImplement from "../common-sql-imp"; import { escapeSqlValue } from "../sqlite/sql-helper"; @@ -30,7 +31,7 @@ interface MySqlColumn { CHARACTER_MAXIMUM_LENGTH: number; NUMERIC_PRECISION: number; NUMERIC_SCALE: number; - COLUMN_DEFAULT: string; + COLUMN_DEFAULT: string | null; COLUMN_TYPE: string; } @@ -40,6 +41,59 @@ interface MySqlTable { TABLE_TYPE: string; } +interface MySQLConstraintResult { + TABLE_SCHEMA: string; + TABLE_NAME: string; + CONSTRAINT_NAME: string; + CONSTRAINT_TYPE: string; +} + +export interface MySQLConstraintColumnResult { + TABLE_SCHEMA: string; + TABLE_NAME: string; + COLUMN_NAME: string; + CONSTRAINT_NAME: string; + REFERENCED_TABLE_SCHEMA: string; + REFERENCED_TABLE_NAME: string; + REFERENCED_COLUMN_NAME: string; +} + +function mapColumn(column: MySqlColumn): DatabaseTableColumn { + const result: DatabaseTableColumn = { + name: column.COLUMN_NAME, + type: column.COLUMN_TYPE, + constraint: undefined, + }; + + if (column.IS_NULLABLE === "NO") { + result.constraint = { + ...result.constraint, + notNull: true, + }; + } + + if (column.COLUMN_KEY === "PRI") { + result.constraint = { + ...result.constraint, + primaryKey: true, + }; + } + + if (column.COLUMN_DEFAULT === null && column.IS_NULLABLE === "YES") { + result.constraint = { + ...result.constraint, + defaultExpression: "NULL", + }; + } else if (column.COLUMN_DEFAULT !== null) { + result.constraint = { + ...result.constraint, + defaultValue: column.COLUMN_DEFAULT, + }; + } + + return result; +} + export default abstract class MySQLLikeDriver extends CommonSQLImplement { columnTypeSelector: ColumnTypeSelector = MYSQL_DATA_TYPE_SUGGESTION; @@ -88,10 +142,19 @@ export default abstract class MySQLLikeDriver extends CommonSQLImplement { .rows as unknown as MySqlTable[]; const columnSql = - "SELECT TABLE_SCHEMA, TABLE_NAME, COLUMN_NAME, COLUMN_TYPE, DATA_TYPE, EXTRA FROM information_schema.columns WHERE TABLE_SCHEMA NOT IN ('mysql', 'information_schema', 'performance_schema', 'sys')"; + "SELECT TABLE_SCHEMA, TABLE_NAME, COLUMN_NAME, COLUMN_TYPE, DATA_TYPE, EXTRA, COLUMN_KEY, IS_NULLABLE, COLUMN_DEFAULT FROM information_schema.columns WHERE TABLE_SCHEMA NOT IN ('mysql', 'information_schema', 'performance_schema', 'sys')"; const columnResult = (await this.query(columnSql)) .rows as unknown as MySqlColumn[]; + const constraintSql = + "SELECT TABLE_SCHEMA, TABLE_NAME, CONSTRAINT_NAME, CONSTRAINT_TYPE FROM information_schema.table_constraints WHERE TABLE_SCHEMA NOT IN ('mysql', 'information_schema', 'performance_schema', 'sys') AND CONSTRAINT_TYPE IN ('PRIMARY KEY', 'UNIQUE', 'FOREIGN KEY')"; + const constraintResult = (await this.query(constraintSql)) + .rows as unknown as MySQLConstraintResult[]; + + const constraintColumnsSql = `SELECT CONSTRAINT_NAME, TABLE_SCHEMA, TABLE_NAME, COLUMN_NAME, REFERENCED_TABLE_SCHEMA, REFERENCED_TABLE_NAME, REFERENCED_COLUMN_NAME FROM information_schema.key_column_usage WHERE TABLE_SCHEMA NOT IN ('mysql', 'information_schema', 'performance_schema', 'sys')`; + const constraintColumnsResult = (await this.query(constraintColumnsSql)) + .rows as unknown as MySQLConstraintColumnResult[]; + // Hash table of schema const schemaRecord: Record = {}; for (const s of schemaResult) { @@ -123,12 +186,7 @@ export default abstract class MySQLLikeDriver extends CommonSQLImplement { } for (const c of columnResult) { - const column: DatabaseTableColumn = { - name: c.COLUMN_NAME, - type: c.COLUMN_TYPE, - constraint: undefined, - }; - + const column: DatabaseTableColumn = mapColumn(c); const tableKey = c.TABLE_SCHEMA + "." + c.TABLE_NAME; const tableSchema = tableRecord[tableKey].tableSchema; if (tableSchema) { @@ -136,6 +194,81 @@ export default abstract class MySQLLikeDriver extends CommonSQLImplement { } } + // Add constraint + const constraintRecords: Record = {}; + + for (const c of constraintResult) { + const constraintKey = + c.TABLE_SCHEMA + "." + c.TABLE_NAME + "." + c.CONSTRAINT_NAME; + + const tableKey = c.TABLE_SCHEMA + "." + c.TABLE_NAME; + const table = tableRecord[tableKey]; + + if (table && table.tableSchema) { + const constraint: DatabaseTableColumnConstraint = { + name: c.CONSTRAINT_NAME, + }; + + if (c.CONSTRAINT_TYPE === "PRIMARY KEY") { + constraint.primaryKey = true; + constraint.primaryColumns = []; + } + + if (c.CONSTRAINT_TYPE === "UNIQUE") { + constraint.unique = true; + constraint.uniqueColumns = []; + } + + if (c.CONSTRAINT_TYPE === "FOREIGN KEY") { + constraint.foreignKey = { + columns: [], + foreignColumns: [], + foreignSchemaName: "", + foreignTableName: "", + }; + } + + table.tableSchema.constraints = [ + ...(table.tableSchema?.constraints ?? []), + constraint, + ]; + + constraintRecords[constraintKey] = constraint; + } + } + + // Add columns to constraint + for (const c of constraintColumnsResult) { + const constraintKey = + c.TABLE_SCHEMA + "." + c.TABLE_NAME + "." + c.CONSTRAINT_NAME; + + const tableKey = c.TABLE_SCHEMA + "." + c.TABLE_NAME; + const tableSchema = tableRecord[tableKey]?.tableSchema; + + const constraint = constraintRecords[constraintKey]; + + if (constraint && tableSchema) { + if (constraint.primaryKey) { + constraint.primaryColumns?.push(c.COLUMN_NAME); + const column = tableSchema.columns.find( + (col) => col.name === c.COLUMN_NAME + ); + if (column) column.pk = true; + } + + if (constraint.unique) { + constraint.uniqueColumns?.push(c.COLUMN_NAME); + } + + if (constraint.foreignKey) { + constraint.foreignKey.columns?.push(c.COLUMN_NAME); + constraint.foreignKey.foreignColumns?.push(c.REFERENCED_COLUMN_NAME); + constraint.foreignKey.foreignSchemaName = c.REFERENCED_TABLE_SCHEMA; + constraint.foreignKey.foreignTableName = c.REFERENCED_TABLE_NAME; + } + } + } + return schemaRecord; } @@ -143,28 +276,78 @@ export default abstract class MySQLLikeDriver extends CommonSQLImplement { schemaName: string, tableName: string ): Promise { - const columnSql = `SELECT TABLE_SCHEMA, TABLE_NAME, COLUMN_NAME, COLUMN_TYPE, DATA_TYPE, EXTRA, COLUMN_KEY FROM information_schema.columns WHERE TABLE_NAME=${escapeSqlValue(tableName)} AND TABLE_SCHEMA=${escapeSqlValue(schemaName)} ORDER BY ORDINAL_POSITION`; + const columnSql = `SELECT TABLE_SCHEMA, TABLE_NAME, COLUMN_NAME, COLUMN_TYPE, DATA_TYPE, EXTRA, COLUMN_KEY, IS_NULLABLE, COLUMN_DEFAULT FROM information_schema.columns WHERE TABLE_NAME=${escapeSqlValue(tableName)} AND TABLE_SCHEMA=${escapeSqlValue(schemaName)} ORDER BY ORDINAL_POSITION`; const columnResult = (await this.query(columnSql)) .rows as unknown as MySqlColumn[]; - const pk = columnResult - .filter((c) => c.COLUMN_KEY === "PRI") - .map((c) => c.COLUMN_NAME); - const autoIncrement = columnResult.some( (c) => c.EXTRA === "auto_increment" ); + const constraintSql = `SELECT TABLE_SCHEMA, TABLE_NAME, CONSTRAINT_NAME, CONSTRAINT_TYPE FROM information_schema.table_constraints WHERE TABLE_SCHEMA = ${this.escapeValue(schemaName)} AND TABLE_NAME = ${this.escapeValue(tableName)} AND CONSTRAINT_TYPE IN ('PRIMARY KEY', 'UNIQUE', 'FOREIGN KEY')`; + const constraintResult = (await this.query(constraintSql)) + .rows as unknown as MySQLConstraintResult[]; + + const constraintColumnsSql = `SELECT CONSTRAINT_NAME, TABLE_SCHEMA, TABLE_NAME, COLUMN_NAME, REFERENCED_TABLE_SCHEMA, REFERENCED_TABLE_NAME, REFERENCED_COLUMN_NAME FROM information_schema.key_column_usage WHERE TABLE_SCHEMA = ${this.escapeValue(schemaName)} AND TABLE_NAME = ${this.escapeValue(tableName)}`; + const constraintColumnsResult = (await this.query(constraintColumnsSql)) + .rows as unknown as MySQLConstraintColumnResult[]; + + const columns: DatabaseTableColumn[] = columnResult.map(mapColumn); + + const constraints: DatabaseTableColumnConstraint[] = constraintResult.map( + (constraint) => { + const columnList = constraintColumnsResult.filter( + (column) => column.CONSTRAINT_NAME === constraint.CONSTRAINT_NAME + ); + + if (constraint.CONSTRAINT_TYPE === "PRIMARY KEY") { + // Marking column as pk + const primaryColumns = columnList.map((c) => c.COLUMN_NAME); + const primarySet = new Set(primaryColumns); + + columns.forEach((col) => { + if (primarySet.has(col.name)) { + col.pk = true; + } + }); + + return { + name: constraint.CONSTRAINT_NAME, + primaryKey: true, + primaryColumns: columnList.map((c) => c.COLUMN_NAME), + } as DatabaseTableColumnConstraint; + } + + return { + name: constraint.CONSTRAINT_NAME, + primaryKey: constraint.CONSTRAINT_TYPE === "PRIMARY KEY", + unique: constraint.CONSTRAINT_TYPE === "UNIQUE", + foreignKey: + constraint.CONSTRAINT_TYPE === "FOREIGN KEY" + ? { + columns: columnList.map((c) => c.COLUMN_NAME), + foreignColumns: columnList.map( + (c) => c.REFERENCED_COLUMN_NAME + ), + foreignSchemaName: columnList[0].REFERENCED_TABLE_SCHEMA, + foreignTableName: columnList[0].REFERENCED_TABLE_NAME, + } + : undefined, + }; + } + ); + + const pk = columnResult + .filter((c) => c.COLUMN_KEY === "PRI") + .map((c) => c.COLUMN_NAME); + return { autoIncrement, pk, tableName, schemaName, - columns: columnResult.map((c) => ({ - name: c.COLUMN_NAME, - type: c.COLUMN_TYPE, - constraint: undefined, - })), + constraints, + columns, }; }