From 53de628a9cff4f3a666eb00188421ac9de48705c Mon Sep 17 00:00:00 2001 From: Christoph Pirkl <4711730+kaklakariada@users.noreply.github.com> Date: Tue, 24 Sep 2024 13:53:14 +0200 Subject: [PATCH] #134 MySql table charset (#141) MIME-Version: 1.0 Content-Type: text/plain; charset=UTF-8 Content-Transfer-Encoding: 8bit Co-authored-by: Sebastian Bär --- doc/changes/changes_3.6.0.md | 3 +- doc/user_guide/user_guide.md | 15 ++- .../dbbuilder/dialects/AbstractSchema.java | 2 +- .../com/exasol/dbbuilder/dialects/Table.java | 4 +- .../MySqlImmediateDatabaseObjectWriter.java | 24 +++- .../dbbuilder/dialects/mysql/MySqlSchema.java | 5 + .../dbbuilder/dialects/mysql/MySqlTable.java | 87 +++++++++++++++ .../dialects/AbstractObjectFactoryTest.java | 4 +- ...QLDatabaseObjectCreationAndDeletionIT.java | 103 ++++++++++++++---- .../dialects/mysql/MySqlTableTest.java | 33 ++++++ 10 files changed, 251 insertions(+), 29 deletions(-) create mode 100644 src/main/java/com/exasol/dbbuilder/dialects/mysql/MySqlTable.java create mode 100644 src/test/java/com/exasol/dbbuilder/dialects/mysql/MySqlTableTest.java diff --git a/doc/changes/changes_3.6.0.md b/doc/changes/changes_3.6.0.md index 78e2a75..11e73f9 100644 --- a/doc/changes/changes_3.6.0.md +++ b/doc/changes/changes_3.6.0.md @@ -6,7 +6,7 @@ Code name: Fix CVE-2024-7254 in test dependency `com.google.protobuf:protobuf-ja This release fixes CVE-2024-7254 in test dependency `com.google.protobuf:protobuf-java:3.25.1`. -The release also speeds up inserting rows into a table by using batch insert. +The release also speeds up inserting rows into a table by using batch insert and allows specifying a charset when creating MySQL tables, see the [user guide](../user_guide/user_guide.md#mysql-specific-database-objects) for details. ## Security @@ -15,6 +15,7 @@ The release also speeds up inserting rows into a table by using batch insert. ## Features * #137: Updated `AbstractImmediateDatabaseObjectWriter#write()` to use batching for inserting rows +* #134: Allowed specifying charset for MySQL tables ## Dependency Updates diff --git a/doc/user_guide/user_guide.md b/doc/user_guide/user_guide.md index 5b5c403..ea6f7fc 100644 --- a/doc/user_guide/user_guide.md +++ b/doc/user_guide/user_guide.md @@ -62,7 +62,7 @@ final Table table = schema.createTable("DAYS","DAY_NAME","VARCHAR(9), "SHORT_NAM In case you want to create more complex tables, you can also use a builder. ```java -final Table table=schema.createTableBuilder("DAYS") +final Table table = schema.createTableBuilder("DAYS") .column("DAY_NAME","VARCHAR(9)" .column("SHORT_NAME","VARCHAR(3)" .column("DAY_IN_WEEK","DECIMAL(1,0)" @@ -390,6 +390,17 @@ Given that a script of that name exists, you can then [execute the script](#exec ## MySQL-Specific Database Objects -So far there are no MySQL Specific Database Objects that are not described in [Dialect-Agnostic Database Objects](#dialect-agnostic-database-objects) section. +In addition to [Dialect-Agnostic Database Objects](#dialect-agnostic-database-objects), MySQL allows specifying a charset when creating a new table using the table builder of a `MySqlSchema`. When no charset is specified, MySql uses UTF8 as default. + +```java +final MySqlSchema schema = (MySqlSchema) factory.createSchema("TEST")); +final MySqlTable table = schema.createTableBuilder("ASCII_DAYS") + .charset("ASCII") + .column("DAY_NAME","VARCHAR(9)" + .column("SHORT_NAME","VARCHAR(3)" + .column("DAY_IN_WEEK","DECIMAL(1,0)" + // ... + .build() +``` Please keep in mind that Schema object represents a database in MySQL as a schema is a [synonym](https://dev.mysql.com/doc/refman/8.0/en/create-database.html) for a database in MySQL syntax. diff --git a/src/main/java/com/exasol/dbbuilder/dialects/AbstractSchema.java b/src/main/java/com/exasol/dbbuilder/dialects/AbstractSchema.java index 87c1224..b6b06d1 100644 --- a/src/main/java/com/exasol/dbbuilder/dialects/AbstractSchema.java +++ b/src/main/java/com/exasol/dbbuilder/dialects/AbstractSchema.java @@ -63,7 +63,7 @@ public Table.Builder createTableBuilder(final String name) { public Table createTable(final String name, final List columnNames, final List columnTypes) { verifyNotDeleted(); if (columnNames.size() == columnTypes.size()) { - final Table.Builder builder = Table.builder(getWriter(), this, getIdentifier(name)); + final Table.Builder builder = createTableBuilder(name); passColumnsToTableBuilder(columnNames, columnTypes, builder); final Table table = builder.build(); this.tables.add(table); diff --git a/src/main/java/com/exasol/dbbuilder/dialects/Table.java b/src/main/java/com/exasol/dbbuilder/dialects/Table.java index 0637511..41e0491 100644 --- a/src/main/java/com/exasol/dbbuilder/dialects/Table.java +++ b/src/main/java/com/exasol/dbbuilder/dialects/Table.java @@ -30,7 +30,7 @@ protected Table(final Builder builder) { * @param writer database object writer * @param schema parent schema * @param tableName name of the database table - * @return new {@link Table} instance + * @return new {@link Builder} instance */ // [impl->dsn~creating-tables~1] public static Builder builder(final DatabaseObjectWriter writer, final Schema schema, final Identifier tableName) { @@ -151,4 +151,4 @@ public Table build() { return table; } } -} \ No newline at end of file +} diff --git a/src/main/java/com/exasol/dbbuilder/dialects/mysql/MySqlImmediateDatabaseObjectWriter.java b/src/main/java/com/exasol/dbbuilder/dialects/mysql/MySqlImmediateDatabaseObjectWriter.java index 5767210..29ec636 100644 --- a/src/main/java/com/exasol/dbbuilder/dialects/mysql/MySqlImmediateDatabaseObjectWriter.java +++ b/src/main/java/com/exasol/dbbuilder/dialects/mysql/MySqlImmediateDatabaseObjectWriter.java @@ -46,9 +46,31 @@ public void write(final User user, final DatabaseObject object, final ObjectPriv } } + @Override + public void write(final Table table) { + final MySqlTable mySqlTable = (MySqlTable) table; + final StringBuilder builder = new StringBuilder("CREATE TABLE "); + builder.append(mySqlTable.getFullyQualifiedName()).append(" ("); + int i = 0; + for (final Column column : mySqlTable.getColumns()) { + if (i++ > 0) { + builder.append(", "); + } + builder.append(getQuotedColumnName(column.getName())) // + .append(" ") // + .append(column.getType()); + } + builder.append(")"); + if (mySqlTable.getCharset() != null) { + builder.append(" CHARACTER SET ") // + .append(mySqlTable.getCharset()); + } + writeToObject(mySqlTable, builder.toString()); + } + @Override // [impl->dsn~dropping-schemas~2] public void drop(final Schema schema) { writeToObject(schema, "DROP SCHEMA " + schema.getFullyQualifiedName()); } -} \ No newline at end of file +} diff --git a/src/main/java/com/exasol/dbbuilder/dialects/mysql/MySqlSchema.java b/src/main/java/com/exasol/dbbuilder/dialects/mysql/MySqlSchema.java index bb31781..835bcd1 100644 --- a/src/main/java/com/exasol/dbbuilder/dialects/mysql/MySqlSchema.java +++ b/src/main/java/com/exasol/dbbuilder/dialects/mysql/MySqlSchema.java @@ -31,4 +31,9 @@ public DatabaseObjectWriter getWriter() { protected Identifier getIdentifier(final String name) { return MySQLIdentifier.of(name); } + + @Override + public MySqlTable.Builder createTableBuilder(final String name) { + return MySqlTable.builder(getWriter(), this, getIdentifier(name)); + } } diff --git a/src/main/java/com/exasol/dbbuilder/dialects/mysql/MySqlTable.java b/src/main/java/com/exasol/dbbuilder/dialects/mysql/MySqlTable.java new file mode 100644 index 0000000..52990c7 --- /dev/null +++ b/src/main/java/com/exasol/dbbuilder/dialects/mysql/MySqlTable.java @@ -0,0 +1,87 @@ +package com.exasol.dbbuilder.dialects.mysql; + +import com.exasol.db.Identifier; +import com.exasol.dbbuilder.dialects.*; + +/** + * A MySql table that allows specifying a character set. + */ +public class MySqlTable extends Table { + private final String charset; + + /** + * Create a new MySql table based on a given builder. + * + * @param builder builder from which to copy the values + */ + protected MySqlTable(final Builder builder) { + super(builder); + this.charset = builder.charset; + } + + /** + * Get the table's character set. + * + * @return charset or {@code null} for the default charset + */ + public String getCharset() { + return charset; + } + + /** + * Create a builder for a {@link MySqlTable}. + * + * @param writer database object writer + * @param parentSchema parent schema + * @param tableName name of the database table + * @return new {@link Builder} instance + */ + public static Builder builder(final DatabaseObjectWriter writer, final Schema parentSchema, + final Identifier tableName) { + return new Builder(writer, parentSchema, tableName); + } + + /** + * Builder for {@link MySqlTable}s. + */ + public static class Builder extends Table.Builder { + private String charset; + + private Builder(final DatabaseObjectWriter writer, final Schema parentSchema, final Identifier tableName) { + super(writer, parentSchema, tableName); + } + + @Override + // Overriding this so that returned builder has the right type and users don't need to cast. + public Builder column(final String columnName, final String columnType) { + return (Builder) super.column(columnName, columnType); + } + + /** + * Set a custom character set for the new table. Defaults to UTF-8. + *

+ * This character set is then used for the whole table down to the columns. Additionally the standard collation + * rules for this dataset are applied. + *

+ * + * @param charset custom charset, e.g. {@code ascii} + * @return {@code this} for fluent programming + */ + public Builder charset(final String charset) { + this.charset = charset; + return this; + } + + /** + * Build a new {@link MySqlTable} instance. + * + * @return new {@link MySqlTable} instance + */ + @Override + public MySqlTable build() { + final MySqlTable table = new MySqlTable(this); + this.writer.write(table); + return table; + } + } +} diff --git a/src/test/java/com/exasol/dbbuilder/dialects/AbstractObjectFactoryTest.java b/src/test/java/com/exasol/dbbuilder/dialects/AbstractObjectFactoryTest.java index 7e1c8bb..d5e93f0 100644 --- a/src/test/java/com/exasol/dbbuilder/dialects/AbstractObjectFactoryTest.java +++ b/src/test/java/com/exasol/dbbuilder/dialects/AbstractObjectFactoryTest.java @@ -7,9 +7,9 @@ public abstract class AbstractObjectFactoryTest { - abstract protected AbstractImmediateDatabaseObjectWriter getWriterMock(); + protected abstract AbstractImmediateDatabaseObjectWriter getWriterMock(); - abstract protected DatabaseObjectFactory testee(); + protected abstract DatabaseObjectFactory testee(); @Test void createSchemaWritesObject() { diff --git a/src/test/java/com/exasol/dbbuilder/dialects/mysql/MySQLDatabaseObjectCreationAndDeletionIT.java b/src/test/java/com/exasol/dbbuilder/dialects/mysql/MySQLDatabaseObjectCreationAndDeletionIT.java index a6aaf1b..730528c 100644 --- a/src/test/java/com/exasol/dbbuilder/dialects/mysql/MySQLDatabaseObjectCreationAndDeletionIT.java +++ b/src/test/java/com/exasol/dbbuilder/dialects/mysql/MySQLDatabaseObjectCreationAndDeletionIT.java @@ -9,12 +9,14 @@ import static org.hamcrest.Matchers.containsString; import static org.hamcrest.Matchers.equalTo; import static org.junit.jupiter.api.Assertions.assertAll; +import static org.junit.jupiter.api.Assertions.assertTrue; import java.sql.*; import org.hamcrest.Matcher; import org.junit.jupiter.api.Tag; import org.junit.jupiter.api.Test; +import org.testcontainers.containers.JdbcDatabaseContainer.NoDriverFoundException; import org.testcontainers.containers.MySQLContainer; import org.testcontainers.junit.jupiter.Container; import org.testcontainers.junit.jupiter.Testcontainers; @@ -81,19 +83,21 @@ private void assertUserHasSchemaPrivilege(final String username, final String ob @Test void testGrantSchemaPrivilegeToUser() { - final Schema schema = this.factory.createSchema("OBJPRIVSCHEMA"); - final User user = this.factory.createUser("OBJPRIVUSER").grant(schema, SELECT, DELETE); - assertAll(() -> assertUserHasSchemaPrivilege(user.getName(), schema.getName(), "Select_priv"), - () -> assertUserHasSchemaPrivilege(user.getName(), schema.getName(), "Delete_priv")); + try (final Schema schema = this.factory.createSchema("OBJPRIVSCHEMA")) { + final User user = this.factory.createUser("OBJPRIVUSER").grant(schema, SELECT, DELETE); + assertAll(() -> assertUserHasSchemaPrivilege(user.getName(), schema.getName(), "Select_priv"), + () -> assertUserHasSchemaPrivilege(user.getName(), schema.getName(), "Delete_priv")); + } } @Test void testGrantTablePrivilegeToUser() { - final Schema schema = this.factory.createSchema("TABPRIVSCHEMA"); - final Table table = schema.createTable("TABPRIVTABLE", "COL1", "DATE", "COL2", "INT"); - final User user = this.factory.createUser("TABPRIVUSER").grant(table, SELECT, DELETE); - assertAll(() -> assertUserHasTablePrivilege(user.getName(), table.getName(), "Select"), - () -> assertUserHasTablePrivilege(user.getName(), table.getName(), "Delete")); + try (final Schema schema = this.factory.createSchema("TABPRIVSCHEMA")) { + final Table table = schema.createTable("TABPRIVTABLE", "COL1", "DATE", "COL2", "INT"); + final User user = this.factory.createUser("TABPRIVUSER").grant(table, SELECT, DELETE); + assertAll(() -> assertUserHasTablePrivilege(user.getName(), table.getName(), "Select"), + () -> assertUserHasTablePrivilege(user.getName(), table.getName(), "Delete")); + } } private void assertUserHasTablePrivilege(final String username, final String objectName, @@ -114,17 +118,76 @@ private void assertUserHasTablePrivilege(final String username, final String obj @Test void testInsertIntoTable() { - final Schema schema = this.factory.createSchema("INSERTSCHEMA"); - final Table table = schema.createTable("INSERTTABLE", "ID", "INT", "NAME", "VARCHAR(10)"); - table.insert(1, "FOO").insert(2, "BAR"); - try { - final ResultSet result = this.adminConnection.createStatement() - .executeQuery("SELECT ID, NAME FROM " + table.getFullyQualifiedName() + "ORDER BY ID ASC"); - assertThat(result, table().row(1, "FOO").row(2, "BAR").matches()); - } catch (final SQLException exception) { - throw new AssertionError(ExaError.messageBuilder("E-TDBJ-25") - .message("Unable to validate contents of table {{table}}", table.getFullyQualifiedName()) - .toString(), exception); + try (final Schema schema = this.factory.createSchema("INSERTSCHEMA")) { + final Table table = schema.createTable("INSERTTABLE", "ID", "INT", "NAME", "VARCHAR(10)"); + table.insert(1, "FOO").insert(2, "BAR"); + try { + final ResultSet result = this.adminConnection.createStatement() + .executeQuery("SELECT ID, NAME FROM " + table.getFullyQualifiedName() + "ORDER BY ID ASC"); + assertThat(result, table().row(1, "FOO").row(2, "BAR").matches()); + } catch (final SQLException exception) { + throw new AssertionError(ExaError.messageBuilder("E-TDBJ-25") + .message("Unable to validate contents of table {{table}}", table.getFullyQualifiedName()) + .toString(), exception); + } + } + } + + @Test + void testCreateTableWithDefaultCharsetUsesUtf8() { + try (final MySqlSchema schema = (MySqlSchema) this.factory.createSchema("CHARSET_SCHEMA_DEFAULT")) { + final MySqlTable table = schema.createTableBuilder("TABLE_WITH_CHARSET").column("ID", "INT") + .column("NAME", "VARCHAR(10)").build(); + assertAll( + () -> assertThat("column charset", + getColumnCharset("def", schema.getName(), table.getName(), "NAME"), equalTo("utf8mb4")), + () -> assertThat("table collation", getTableCollation("def", schema.getName(), table.getName()), + equalTo("utf8mb4_0900_ai_ci"))); + } + } + + @Test + void testCreateTableWithCharset() { + try (final MySqlSchema schema = (MySqlSchema) this.factory.createSchema("CHARSET_SCHEMA_ASCII")) { + final MySqlTable table = schema.createTableBuilder("TABLE_WITH_CHARSET").charset("ASCII") + .column("ID", "INT").column("NAME", "VARCHAR(10)").build(); + assertAll( + () -> assertThat("column charset", + getColumnCharset("def", schema.getName(), table.getName(), "NAME"), equalTo("ascii")), + () -> assertThat("table collation", getTableCollation("def", schema.getName(), table.getName()), + equalTo("ascii_general_ci"))); + } + } + + private String getColumnCharset(final String catalog, final String schema, final String table, + final String column) { + final String query = "select CHARACTER_SET_NAME from information_schema.COLUMNS " + + "where TABLE_CATALOG=? AND TABLE_SCHEMA=? AND TABLE_NAME=? AND COLUMN_NAME=?"; + try (Connection con = container.createConnection(""); PreparedStatement stmt = con.prepareStatement(query)) { + stmt.setString(1, catalog); + stmt.setString(2, schema); + stmt.setString(3, table); + stmt.setString(4, column); + final ResultSet rs = stmt.executeQuery(); + assertTrue(rs.next()); + return rs.getString("CHARACTER_SET_NAME"); + } catch (NoDriverFoundException | SQLException exception) { + throw new IllegalStateException("Query '" + query + "' failed: " + exception.getMessage(), exception); + } + } + + private String getTableCollation(final String catalog, final String schema, final String table) { + final String query = "select TABLE_COLLATION from information_schema.TABLES " + + "where TABLE_CATALOG=? AND TABLE_SCHEMA=? AND TABLE_NAME=?"; + try (Connection con = container.createConnection(""); PreparedStatement stmt = con.prepareStatement(query)) { + stmt.setString(1, catalog); + stmt.setString(2, schema); + stmt.setString(3, table); + final ResultSet rs = stmt.executeQuery(); + assertTrue(rs.next()); + return rs.getString("TABLE_COLLATION"); + } catch (NoDriverFoundException | SQLException exception) { + throw new IllegalStateException("Query '" + query + "' failed: " + exception.getMessage(), exception); } } diff --git a/src/test/java/com/exasol/dbbuilder/dialects/mysql/MySqlTableTest.java b/src/test/java/com/exasol/dbbuilder/dialects/mysql/MySqlTableTest.java new file mode 100644 index 0000000..d8e1675 --- /dev/null +++ b/src/test/java/com/exasol/dbbuilder/dialects/mysql/MySqlTableTest.java @@ -0,0 +1,33 @@ +package com.exasol.dbbuilder.dialects.mysql; + +import static org.hamcrest.MatcherAssert.assertThat; +import static org.hamcrest.Matchers.*; + +import org.junit.jupiter.api.Test; +import org.junit.jupiter.api.extension.ExtendWith; +import org.mockito.Mock; +import org.mockito.junit.jupiter.MockitoExtension; + +import com.exasol.dbbuilder.dialects.DatabaseObjectWriter; +import com.exasol.dbbuilder.dialects.Schema; + +@ExtendWith(MockitoExtension.class) +class MySqlTableTest { + @Mock + DatabaseObjectWriter writerMock; + @Mock + Schema schemaMock; + + @Test + void createWithoutCharset() { + final MySqlTable table = MySqlTable.builder(writerMock, schemaMock, MySQLIdentifier.of("tableName")).build(); + assertThat(table.getCharset(), is(nullValue())); + } + + @Test + void createWithCharset() { + final MySqlTable table = MySqlTable.builder(writerMock, schemaMock, MySQLIdentifier.of("tableName")) + .charset("myCharset").build(); + assertThat(table.getCharset(), equalTo("myCharset")); + } +}