From 9324a60aba5a5144d31a237ecf92a972066300f8 Mon Sep 17 00:00:00 2001 From: Tim203 Date: Tue, 24 Sep 2024 17:40:26 +0200 Subject: [PATCH] Add indexes for sql, add mssql support and enforce database type limits --- README.md | 33 +- .../processor/EntityManager.java | 14 +- .../processor/RepositoryProcessor.java | 21 +- .../processor/info/ColumnInfo.java | 17 +- .../processor/info/EntityInfo.java | 12 + .../processor/info/IndexInfo.java | 20 +- .../processor/type/LimitsEnforcer.java | 489 ++++++++++++++++++ .../type/mongo/MongoDatabaseGenerator.java | 4 + .../type/sql/SqlDatabaseGenerator.java | 49 +- .../type/sql/SqlRepositoryGenerator.java | 1 + .../util/InvalidRepositoryException.java | 33 +- .../test/advanced/SqlDatabaseGenerated.java | 51 +- .../resources/test/advanced/TestEntity.java | 5 +- .../test/basic/SqlDatabaseGenerated.java | 51 +- .../test/resources/test/basic/TestEntity.java | 5 +- .../geysermc/databaseutils/DatabaseType.java | 29 +- .../geysermc/databaseutils/meta/Length.java | 20 + .../sql/SqlTypeMappingRegistry.java | 35 +- .../geysermc/databaseutils/TestContext.java | 7 +- .../databaseutils/delete/DeleteTests.java | 16 +- .../databaseutils/entity/TestEntity.java | 4 +- 21 files changed, 779 insertions(+), 137 deletions(-) create mode 100644 ap/src/main/java/org/geysermc/databaseutils/processor/type/LimitsEnforcer.java create mode 100644 core/src/main/java/org/geysermc/databaseutils/meta/Length.java diff --git a/README.md b/README.md index c3fb592..8ba9b48 100644 --- a/README.md +++ b/README.md @@ -9,6 +9,7 @@ currently examples can be found in the tests of the AP module and the tests of t - support adding every variable of the entity as parameter - add `upsert` which either inserts the entity if it's not present or updates the already existing entity - adding migrations +- add null and non-null support - and plenty more # Supported types @@ -52,7 +53,8 @@ The current codebase is not flexible enough to do these wildly different behavio but will be supported in the future. #### any deleteFirst() and any deleteTop*() -Anything with a limit projection in delete currently doesn't work for Oracle Database, PostgreSQL and SQLite. +Anything with a limit projection in delete currently doesn't work for Oracle Database, PostgreSQL, SQLite and SQL Server. +For SQL Server it's TOP instead of LIMIT. For SQLite this is a flag that can be enabled during compile, but it's disabled by default. For Oracle and Postgres delete with a limit doesn't exist. We have to fetch a record first and then delete it (inside a transaction). @@ -74,25 +76,32 @@ These are the base type conversions: | Java Type | SQL type | Reason / remarks | |-----------|------------------|-----------------------------------------------------------------| | Boolean | boolean | More platforms support boolean than tinyint / bit | -| Byte | smallint | SQL Server's tinyint is unsigned and PostgresSQL has no tinyint | +| Byte | tinyint | SQL Server's tinyint is unsigned and PostgresSQL has no tinyint | | Short | smallint | - | -| Char | smallint | Basically the same as short | +| Char | int | Unlike short, char is unsigned | | Integer | int | - | | Long | bigint | - | -| Float | real | Some dialects map this as a double precision type | +| Float | real | MySQL and MariaDB map this as a double precision type | | Double | double precision | - | -| String | varchar | - | +| String | varchar | All dialects support varchar, but it's deprecated on OracleDB | | Byte[] | varbinary | Most dialects support varbinary | And these are the exceptions: -| Java Type | Dialect | SQL Type | -|-----------|------------|----------| -| Boolean | SQLite | int | -| Boolean | SQL Server | bit | -| Double | SQL Server | float | -| Byte[] | PostgreSQL | bytea | -| Byte[] | SQLite | varchar | +| Java Type | Dialect | SQL Type | +|-----------|------------|-------------------| +| Boolean | SQLite | int | +| Boolean | SQL Server | bit | +| Byte | PostgreSQL | smallint | +| Byte | SQL Server | smallint | +| Char | MariaDB | smallint unsigned | +| Char | MySQL | smallint unsigned | +| Char | OracleDB | number(5) | +| Double | SQL Server | float | +| String | OracleDB | varchar2 | +| Byte[] | OracleDB | raw | +| Byte[] | PostgreSQL | bytea | +| Byte[] | SQLite | blob | # Query syntax Assuming we have the following entity called TestEntity: diff --git a/ap/src/main/java/org/geysermc/databaseutils/processor/EntityManager.java b/ap/src/main/java/org/geysermc/databaseutils/processor/EntityManager.java index 41198e7..455b601 100644 --- a/ap/src/main/java/org/geysermc/databaseutils/processor/EntityManager.java +++ b/ap/src/main/java/org/geysermc/databaseutils/processor/EntityManager.java @@ -26,6 +26,8 @@ import org.geysermc.databaseutils.processor.info.ColumnInfo; import org.geysermc.databaseutils.processor.info.EntityInfo; import org.geysermc.databaseutils.processor.info.IndexInfo; +import org.geysermc.databaseutils.processor.info.IndexInfo.IndexType; +import org.geysermc.databaseutils.processor.type.LimitsEnforcer; import org.geysermc.databaseutils.processor.util.TypeUtils; final class EntityManager { @@ -41,6 +43,9 @@ Collection processedEntities() { } EntityInfo processEntity(TypeMirror typeMirror) { + // todo technically all those meta annotation classes can be moved a separate module you only need during + // compile time, instead of including the annotation definitions in runtime as well + var type = MoreTypes.asTypeElement(typeMirror); var cached = entityInfoByClassName.get(type.getQualifiedName()); @@ -64,7 +69,7 @@ EntityInfo processEntity(TypeMirror typeMirror) { var columns = new ArrayList(); Arrays.stream(type.getAnnotationsByType(Index.class)) - .map(index -> new IndexInfo(index.name(), index.columns(), index.unique())) + .map(index -> new IndexInfo(index.name(), index.columns(), index.unique(), index.direction())) .forEach(indexes::add); for (Element element : type.getEnclosedElements()) { @@ -84,7 +89,7 @@ EntityInfo processEntity(TypeMirror typeMirror) { continue; } - columns.add(new ColumnInfo(field.getSimpleName(), typeUtils.toBoxedTypeElement(field.asType()))); + columns.add(new ColumnInfo(field.getSimpleName(), typeUtils.toBoxedTypeElement(field.asType()), field)); if (hasAnnotation(field, Key.class)) { keys.add(field.getSimpleName()); @@ -119,13 +124,16 @@ EntityInfo processEntity(TypeMirror typeMirror) { } if (!keys.isEmpty()) { - indexes.add(new IndexInfo("", keys.toArray(new CharSequence[0]), true)); + indexes.add(new IndexInfo("", keys.toArray(new CharSequence[0]), IndexType.PRIMARY)); } else { // todo just make every column a key throw new IllegalStateException("Expected entity to have at least one field marked as key"); } var entityInfo = new EntityInfo(tableName, type, columns, indexes, keys); + + new LimitsEnforcer(entityInfo).enforce(); + entityInfoByClassName.put(type.getQualifiedName(), entityInfo); return entityInfo; } diff --git a/ap/src/main/java/org/geysermc/databaseutils/processor/RepositoryProcessor.java b/ap/src/main/java/org/geysermc/databaseutils/processor/RepositoryProcessor.java index cbd432f..df87519 100644 --- a/ap/src/main/java/org/geysermc/databaseutils/processor/RepositoryProcessor.java +++ b/ap/src/main/java/org/geysermc/databaseutils/processor/RepositoryProcessor.java @@ -10,6 +10,8 @@ import com.squareup.javapoet.JavaFile; import com.squareup.javapoet.TypeSpec; import java.io.IOException; +import java.io.PrintWriter; +import java.io.StringWriter; import java.util.ArrayList; import java.util.List; import java.util.Locale; @@ -206,21 +208,8 @@ private void error(Element cause, String message, Object... arguments) { } private void error(Element cause, Throwable exception) { - // trimming down the exception until the first trace of ourselves. - // This would be either a test class or our RepositoryProcessor. - // This makes the exception much easier to read - int lastOwnTrace = 0; - StringBuilder stackTrace = new StringBuilder(exception.toString()).append('\n'); - for (StackTraceElement traceElement : exception.getStackTrace()) { - stackTrace.append(traceElement.toString()).append('\n'); - if (traceElement.getClassName().startsWith("org.geysermc.databaseutils")) { - lastOwnTrace = stackTrace.length() - 1; - } - } - - if (lastOwnTrace != stackTrace.length() - 1) { - stackTrace.delete(lastOwnTrace, stackTrace.length()); - } - this.messager.printMessage(Diagnostic.Kind.ERROR, stackTrace, cause); + var writer = new StringWriter(); + exception.printStackTrace(new PrintWriter(writer)); + this.messager.printMessage(Diagnostic.Kind.ERROR, writer.toString(), cause); } } diff --git a/ap/src/main/java/org/geysermc/databaseutils/processor/info/ColumnInfo.java b/ap/src/main/java/org/geysermc/databaseutils/processor/info/ColumnInfo.java index 493490d..f34bce8 100644 --- a/ap/src/main/java/org/geysermc/databaseutils/processor/info/ColumnInfo.java +++ b/ap/src/main/java/org/geysermc/databaseutils/processor/info/ColumnInfo.java @@ -5,11 +5,14 @@ */ package org.geysermc.databaseutils.processor.info; +import java.lang.annotation.Annotation; import javax.lang.model.element.Name; import javax.lang.model.element.TypeElement; +import javax.lang.model.element.VariableElement; import javax.lang.model.type.TypeMirror; +import org.geysermc.databaseutils.meta.Length; -public record ColumnInfo(Name name, TypeElement type) { +public record ColumnInfo(Name name, TypeElement type, VariableElement variable) { public TypeMirror asType() { return type.asType(); } @@ -17,4 +20,16 @@ public TypeMirror asType() { public Name typeName() { return type.getQualifiedName(); } + + public T annotation(Class annotationClass) { + return variable.getAnnotation(annotationClass); + } + + /** + * Returns the max length as provided by {@link Length}, or -1 if no limit is provided + */ + public int maxLength() { + var length = annotation(Length.class); + return length != null ? length.max() : -1; + } } diff --git a/ap/src/main/java/org/geysermc/databaseutils/processor/info/EntityInfo.java b/ap/src/main/java/org/geysermc/databaseutils/processor/info/EntityInfo.java index 2198699..3c12e7f 100644 --- a/ap/src/main/java/org/geysermc/databaseutils/processor/info/EntityInfo.java +++ b/ap/src/main/java/org/geysermc/databaseutils/processor/info/EntityInfo.java @@ -27,6 +27,18 @@ public ColumnInfo columnFor(CharSequence columnName) { return null; } + public List columnsFor(CharSequence[] columnNames) { + var columns = new ArrayList(); + for (CharSequence columnName : columnNames) { + var column = columnFor(columnName); + if (column == null) { + throw new IllegalArgumentException("Column " + columnName + " not found"); + } + columns.add(column); + } + return columns; + } + public TypeMirror asType() { return type.asType(); } diff --git a/ap/src/main/java/org/geysermc/databaseutils/processor/info/IndexInfo.java b/ap/src/main/java/org/geysermc/databaseutils/processor/info/IndexInfo.java index 341e8f1..c22a466 100644 --- a/ap/src/main/java/org/geysermc/databaseutils/processor/info/IndexInfo.java +++ b/ap/src/main/java/org/geysermc/databaseutils/processor/info/IndexInfo.java @@ -7,8 +7,22 @@ import org.geysermc.databaseutils.meta.Index; -public record IndexInfo(String name, CharSequence[] columns, boolean unique, Index.IndexDirection direction) { - public IndexInfo(String name, CharSequence[] columns, boolean unique) { - this(name, columns, unique, Index.IndexDirection.ASCENDING); +public record IndexInfo(String name, CharSequence[] columns, IndexType type, Index.IndexDirection direction) { + public IndexInfo(String name, CharSequence[] columns, IndexType type) { + this(name, columns, type, Index.IndexDirection.ASCENDING); + } + + public IndexInfo(String name, CharSequence[] columns, boolean unique, Index.IndexDirection direction) { + this(name, columns, unique ? IndexType.UNIQUE : IndexType.NORMAL, direction); + } + + public boolean unique() { + return type == IndexType.UNIQUE || type == IndexType.PRIMARY; + } + + public enum IndexType { + PRIMARY, + UNIQUE, + NORMAL } } diff --git a/ap/src/main/java/org/geysermc/databaseutils/processor/type/LimitsEnforcer.java b/ap/src/main/java/org/geysermc/databaseutils/processor/type/LimitsEnforcer.java new file mode 100644 index 0000000..16de0de --- /dev/null +++ b/ap/src/main/java/org/geysermc/databaseutils/processor/type/LimitsEnforcer.java @@ -0,0 +1,489 @@ +/* + * Copyright (c) 2024 GeyserMC + * Licensed under the MIT license + * @link https://github.com/GeyserMC/DatabaseUtils + */ +package org.geysermc.databaseutils.processor.type; + +import static org.geysermc.databaseutils.processor.type.LimitsEnforcer.DialectTypeLimit.UNLIMITED; +import static org.geysermc.databaseutils.processor.util.CollectionUtils.join; + +import java.util.ArrayList; +import java.util.HashMap; +import java.util.List; +import java.util.Map; +import org.geysermc.databaseutils.DatabaseType; +import org.geysermc.databaseutils.meta.Length; +import org.geysermc.databaseutils.processor.info.ColumnInfo; +import org.geysermc.databaseutils.processor.info.EntityInfo; +import org.geysermc.databaseutils.processor.info.IndexInfo; +import org.geysermc.databaseutils.processor.util.InvalidRepositoryException; + +public class LimitsEnforcer { + private static final Map LIMITS = new HashMap<>(); + private final EntityInfo entity; + + public LimitsEnforcer(EntityInfo entity) { + this.entity = entity; + } + + public void enforce() { + var suppressed = new HashMap>(); + + for (DatabaseType type : DatabaseType.VALUES) { + var limits = LIMITS.get(type); + + // todo remove + if (limits == null) { + continue; + } + + var failures = enforceSingle(limits); + if (!failures.isEmpty()) { + suppressed.put(type, failures); + } + } + + if (!suppressed.isEmpty()) { + var exception = new InvalidRepositoryException( + "Entity %s failed validation for the following database types: %s", + entity.name(), join(suppressed.keySet())); + + suppressed.forEach((type, failures) -> { + var baseException = + InvalidRepositoryException.createWithoutStackTrace("Failures for database type " + type); + failures.forEach(baseException::addSuppressed); + exception.addSuppressed(baseException); + }); + + throw exception; + } + } + + private List enforceSingle(DialectLimits limits) { + var suppressed = new ArrayList(); + + if (limits.columnLimit() != -1 && entity.columns().size() > limits.columnLimit()) { + suppressed.add(InvalidRepositoryException.createWithoutStackTrace( + "Expected at most %s columns, got %s", limits.columnLimit(), entity.columns())); + } + + if (limits.maxIndexLength() != -1 && entity.indexes().size() > limits.maxIndexLength()) { + suppressed.add(InvalidRepositoryException.createWithoutStackTrace( + "Expected at most %s indexes, got %s", + limits.maxIndexLength(), entity.indexes().size())); + } + + if (limits.maxColumnsPerIndex() != -1) { + for (IndexInfo index : entity.indexes()) { + if (index.columns().length > limits.maxColumnsPerIndex()) { + suppressed.add(InvalidRepositoryException.createWithoutStackTrace( + "Expected at most %s columns per index, got %s", + limits.maxColumnsPerIndex(), index.columns().length)); + } + } + } + + if (limits.maxIdentifierLength() != -1 && entity.name().length() > limits.maxIdentifierLength()) { + suppressed.add(InvalidRepositoryException.createWithoutStackTrace( + "The entity name is longer than allowed. Expected at most %s and got %s", + limits.maxIdentifierLength(), entity.name().length())); + } + + // if there are no type limits, we also can't properly calculate the max row- and max index length + if (limits.noTypeLimits()) { + return suppressed; + } + + if (limits.maxRowLength() != -1) { + var rowLength = rowLengthFor(entity.columns(), limits); + if (rowLength > limits.maxRowLength()) { + suppressed.add(InvalidRepositoryException.createWithoutStackTrace( + "The total length of all columns (%s) exceeded the maximum of %s", + rowLength, limits.maxRowLength())); + } + } + + if (limits.maxIndexLength() != -1) { + for (IndexInfo index : entity.indexes()) { + var indexLength = rowLengthFor(entity.columnsFor(index.columns()), limits); + + if (index.type() == IndexInfo.IndexType.PRIMARY) { + if (indexLength > limits.maxClusteredIndexLength()) { + suppressed.add(InvalidRepositoryException.createWithoutStackTrace( + "The total length of all columns of a clustered index (%s) exceeded the maximum of %s", + indexLength, limits.maxClusteredIndexLength())); + } + continue; + } + + if (indexLength > limits.maxIndexLength()) { + suppressed.add(InvalidRepositoryException.createWithoutStackTrace( + "The total length of all columns of an index (%s) exceeded the maximum of %s", + indexLength, limits.maxIndexLength())); + } + } + } + + return suppressed; + } + + private int rowLengthFor(List columns, DialectLimits limits) { + return columns.stream() + .mapToInt(column -> { + var typeLimit = limits.limit(column.typeName()); + var length = column.annotation(Length.class); + // todo allow TypeCodecs to specify the max length, instead of having to specify + // it on the fields using the codecs + if (length != null) { + return typeLimit.validateAndReturnColumnLength(length.max(), column.name()); + } + return typeLimit.validateAndReturnColumnLength(null, column.name()); + }) + .sum(); + } + + static { + // https://www.mongodb.com/docs/manual/reference/limits/#bson-documents + // MongoDB doesn't support more than 100 levels of nesting. But we currently don't support nesting anyway + // https://www.mongodb.com/docs/manual/reference/limits/#mongodb-limit-Length-of-Database-Names + // https://www.mongodb.com/docs/manual/reference/limits/#namespaces + // namespace = .. Namespace length limit = 255, database can be at most 64 + // https://www.mongodb.com/docs/manual/reference/limits/#indexes + var mongoLimits = new DialectLimits() + .maxRowLength(-1) // technically it cannot be longer than 16mb + .maxIndexLength(-1) // unknown, supports at least 124,000 + .columnLimit(-1) // unknown - probably unlimited + .indexLimit(64) + .maxColumnsPerIndex(32) + .maxIdentifierLength(255 - 64) // What remains of namespace - database is max length for collection + .noTypeLimits(true); + LIMITS.put(DatabaseType.MONGODB, mongoLimits); + + // https://dev.mysql.com/doc/refman/8.4/en/innodb-limits.html + // https://dev.mysql.com/doc/refman/8.4/en/glossary.html#glos_index + // https://dev.mysql.com/doc/refman/8.4/en/innodb-index-types.html + // https://dev.mysql.com/doc/refman/8.4/en/identifier-length.html + // https://dev.mysql.com/doc/refman/8.4/en/numeric-type-syntax.html + // https://dev.mysql.com/doc/refman/8.4/en/integer-types.html + // https://dev.mysql.com/doc/refman/8.4/en/floating-point-types.html + // https://dev.mysql.com/doc/refman/8.4/en/storage-requirements.html#data-types-storage-reqs-strings + // also: the max row size (for all columns combined) is 65535. Have to change some to TEXT or BLOBs + var mysqlLimits = new DialectLimits() + .maxRowLength(65535) // MySQL/MariaDB imposed limit + .maxIndexLength(3072) // InnoDB limit for the default page size, 16KB + .columnLimit(1017) // InnoDB limit + .indexLimit(65) // 64 secondary indexes, this doesn't include the primary index + .maxColumnsPerIndex(16) // MySQL limit + .maxIdentifierLength(64) + .limit(Boolean.class, 1) // bool/boolean = synonym for tinyint(1) + .limit(Byte.class, 1) // bit + .limit(Short.class, 2) // smallint + .limit(Character.class, 2) // smallint unsigned + .limit(Integer.class, 4) // int + .limit(Long.class, 8) // bigint + .limit(Float.class, 8) // real - alias for double + .limit(Double.class, 8) // double - double precision + .limit(String.class, 2, UNLIMITED) // varchar - max in chars! 4 bytes per char (utf8mb4) + .limit(Byte[].class, 2, UNLIMITED); // 3 bytes for the length prefix + LIMITS.put(DatabaseType.MYSQL, mysqlLimits); + // MySQL to MariaDB are almost fully identical when it comes to limits + // https://mariadb.com/kb/en/innodb-limitations/ + // https://mariadb.com/kb/en/data-types/ + LIMITS.put(DatabaseType.MARIADB, mysqlLimits.copy().maxColumnsPerIndex(32)); + + // https://docs.oracle.com/en/database/oracle/oracle-database/23/refrn/logical-database-limits.html + // https://docs.oracle.com/en/database/oracle/oracle-database/23/sqlrf/CREATE-INDEX.html#GUID-1F89BBC0-825F-4215-AF71-7588E31D8BFE__BGECBJDG + // https://docs.oracle.com/en/database/oracle/oracle-database/23/refrn/DB_BLOCK_SIZE.html + // https://docs.oracle.com/en/error-help/db/ora-01450/?r=23ai + // https://docs.oracle.com/en/database/oracle/oracle-database/23/sqlrf/Oracle-Compliance-with-FIPS-127-2.html + // https://docs.oracle.com/en/database/oracle/oracle-database/23/gmswn/database-gateway-sqlserver-data-type-conversion.html + // https://docs.oracle.com/en/database/oracle/oracle-database/23/jjdbc/Oracle-extensions.html#GUID-FC9510C6-8FF2-41A7-864A-890B85A316BC + // https://docs.oracle.com/en/database/oracle/oracle-database/23/sqlrf/Data-Types.html + // https://docs.oracle.com/en/database/oracle/oracle-database/23/refrn/MAX_STRING_SIZE.html#REFRN10321 + // note that for varchar2 the limit is 4000 bytes (not characters) by default (unless extended), which for utf8 + // can vary between 1000 and 4000 depending on how many bytes every character takes. The base byte count + // is assumed. It was not found in the documentation + var oracleLimits = new DialectLimits() + .maxRowLength(2_000_000) + .maxIndexLength(6300) // docs mention ~6400 for 8k block size (default), so give it a bit of wiggle room + .columnLimit(1000) // by default + .indexLimit(-1) + .maxColumnsPerIndex(32) + .maxIdentifierLength(128 - 6) // -6 because of the special types (_table, and _row) + .limit(Boolean.class, 1) // boolean - unknown length, jdbc seems to indicate 4 + .limit(Byte.class, 3) // tinyint - number(3) / 2 + 1 + .limit(Short.class, 5) // smallint - number(5) / 2 + 1 + 1 + .limit(Character.class, 4) // number(5) / 2 + 1 + .limit(Integer.class, 7) // int - number(10) / 2 + 1 + 1 + .limit(Long.class, 12) // bigint - number(20) / 2 + 1 + 1 + .limit(Float.class, 4) // binary_float + .limit(Double.class, 8) // binary_double + .limit(String.class, 2, 4000) // varchar2, see comment above + .limit(Byte[].class, 2, 2000); // raw, default if not extended + LIMITS.put(DatabaseType.ORACLE_DATABASE, oracleLimits); + + // https://learn.microsoft.com/en-us/sql/relational-databases/indexes/clustered-and-nonclustered-indexes-described?view=sql-server-ver16 + // https://en.wikipedia.org/wiki/Database_index#Non-clustered + // https://learn.microsoft.com/en-us/sql/sql-server/maximum-capacity-specifications-for-sql-server?view=sql-server-ver16 + // https://learn.microsoft.com/en-us/sql/relational-databases/pages-and-extents-architecture-guide?view=sql-server-ver16#large-row-support + // https://learn.microsoft.com/en-us/sql/t-sql/statements/create-index-transact-sql?view=sql-server-ver16#nonclustered + // https://learn.microsoft.com/en-us/sql/t-sql/data-types/int-bigint-smallint-and-tinyint-transact-sql?view=sql-server-ver16 + // https://learn.microsoft.com/en-us/sql/t-sql/data-types/float-and-real-transact-sql?view=sql-server-ver16 + // https://learn.microsoft.com/en-us/sql/t-sql/data-types/char-and-varchar-transact-sql?view=sql-server-ver16 + // https://learn.microsoft.com/en-us/sql/t-sql/data-types/binary-and-varbinary-transact-sql?view=sql-server-ver16 + var mssqlLimits = new DialectLimits() + .maxRowLength(-1) // the soft-limit is 8060 bytes, at which point it uses Large Row Support + .maxClusteredIndexLength(900) + .maxIndexLength(1700) + .columnLimit(1024) // can technically be increased using sparse column sets + .indexLimit(999) + .maxColumnsPerIndex(32) + .maxIdentifierLength(128) + .limit(Boolean.class, 1) // tinyint + .limit(Byte.class, 2) // smallint, since tinyint is unsigned + .limit(Short.class, 2) // smallint + .limit(Character.class, 4) // int - since char is an unsigned short + .limit(Integer.class, 4) // int + .limit(Long.class, 8) // bigint + .limit(Float.class, 4) // real - float(24) + .limit(Double.class, 8) // double precision - float(53) + .limit(String.class, 2, 8000) // varchar, the max is 8000 unless 'max' is used + .limit(Byte[].class, 2, 8000); // same as varchar + LIMITS.put(DatabaseType.SQL_SERVER, mssqlLimits); + + // https://www.postgresql.org/docs/16/limits.html + // https://www.postgresql.org/docs/16/datatype-boolean.html + // https://www.postgresql.org/docs/16/datatype-numeric.html + // https://www.postgresql.org/docs/16/datatype-character.html + // https://www.postgresql.org/docs/16/datatype-binary.html + // for varchar and bytea: baseByteCount = 1 for small values (126 bytes or less) + // PostgreSQL uses B-Tree indexes by default, the limits are based of that + var postgresLimits = new DialectLimits() + .maxRowLength(-1) // unknown, supports at least 174,000 + .maxIndexLength(-1) // unknown, supports at least 120,000 + .columnLimit(1600) + .indexLimit(-1) + .maxColumnsPerIndex(32) + .maxIdentifierLength(-1) // unknown, at least 500 + .limit(Boolean.class, 1) // boolean + .limit(Byte.class, 2) // smallint + .limit(Short.class, 2) // smallint + .limit(Character.class, 4) // integer - smallint is signed + .limit(Integer.class, 4) // integer + .limit(Long.class, 8) // bigint + .limit(Float.class, 4) // real + .limit(Double.class, 8) // double precision + .limit(String.class, 4, 10485760) // varchar - max in chars, not bytes + .limit(Byte[].class, 4, UNLIMITED); // bytea - no known limit + LIMITS.put(DatabaseType.POSTGRESQL, postgresLimits); + + // https://h2database.com/html/advanced.html#limits_limitations + // http://h2database.com/html/datatypes.html + // no need to specify the other data types, since there is no max row- and no max index length. + // clob and blob should be used for large strings and binaries respectively + var h2Limits = new DialectLimits() + .maxRowLength(-1) // no limit + .maxIndexLength(-1) // no limit + .columnLimit(16384) + .indexLimit(-1) // no limit + .maxColumnsPerIndex(-1) // unknown, at least 45 - probably unlimited + .maxIdentifierLength(256) + .noTypeLimits(true); // technically there is a limit of 1,000,000,000 for varchar and varbinary + LIMITS.put(DatabaseType.H2, h2Limits); + + // https://www.sqlite.org/limits.html + // https://www.sqlite.org/lang_createindex.html + // https://www.sqlite.org/quirks.html + // https://www.sqlite.org/datatype3.html + var sqliteLimits = new DialectLimits() + .maxRowLength(-1) // technically, since one row = one blob, the limit is 1,000,000,000 + .maxIndexLength(-1) // unknown, probably the same as row length limit + .columnLimit(2000) + .indexLimit(-1) // no limit + .maxColumnsPerIndex(2000) + .maxIdentifierLength(-1) // unknown, at least 500 - probably unlimited + .noTypeLimits(true); // technically there is a limit of 1,000,000,000 for strings and blobs + LIMITS.put(DatabaseType.SQLITE, sqliteLimits); + } + + private static class DialectLimits { + private final Map typeLimits = new HashMap<>(); + private int maxRowLength; + private int maxClusteredIndexLength = Integer.MIN_VALUE; + private int maxIndexLength; + private int columnLimit; + private int indexLimit; + private int maxColumnsPerIndex; + private int maxIdentifierLength; + private boolean noTypeLimits = false; + + public DialectTypeLimit limit(Class clazz) { + return limit(clazz.getCanonicalName()); + } + + public DialectTypeLimit limit(String clazz) { + var limit = typeLimits.get(clazz); + if (limit == null) { + return limit(Byte[].class); + } + return limit; + } + + public DialectTypeLimit limit(CharSequence clazz) { + return limit(clazz.toString()); + } + + public DialectLimits limit(Class clazz, int byteCount) { + typeLimits.put(clazz.getCanonicalName(), new DialectTypeLimit(byteCount)); + return this; + } + + public DialectLimits limit(Class clazz, int baseByteCount, int maxVaryingLength) { + typeLimits.put(clazz.getCanonicalName(), new DialectTypeLimit(baseByteCount, maxVaryingLength)); + return this; + } + + public DialectLimits maxRowLength(int rowLimit) { + this.maxRowLength = rowLimit; + return this; + } + + /** + * Returns the max length of a single row, or -1 if there is no limit. + */ + public int maxRowLength() { + return maxRowLength; + } + + public int maxClusteredIndexLength() { + if (maxClusteredIndexLength == Integer.MIN_VALUE) { + return maxIndexLength; + } + return maxClusteredIndexLength; + } + + public DialectLimits maxClusteredIndexLength(int maxClusteredIndexLength) { + this.maxClusteredIndexLength = maxClusteredIndexLength; + return this; + } + + /** + * Returns the max length of a single index, or -1 if there is no limit. + */ + public int maxIndexLength() { + return maxIndexLength; + } + + public DialectLimits maxIndexLength(int maxIndexLength) { + this.maxIndexLength = maxIndexLength; + return this; + } + + /** + * Returns the max number of columns in a single table, or -1 if there is no limit. + */ + public int columnLimit() { + return columnLimit; + } + + public DialectLimits columnLimit(int columnLimit) { + this.columnLimit = columnLimit; + return this; + } + + /** + * Returns the max amount of indexes in a table, or -1 if there is no limit. + */ + public int indexLimit() { + return indexLimit; + } + + public DialectLimits indexLimit(int indexLimit) { + this.indexLimit = indexLimit; + return this; + } + + /** + * Returns the max amount of columns allowed per index, or -1 if there is no limit. + */ + public int maxColumnsPerIndex() { + return maxColumnsPerIndex; + } + + public DialectLimits maxColumnsPerIndex(int maxColumnsPerIndex) { + this.maxColumnsPerIndex = maxColumnsPerIndex; + return this; + } + + /** + * Returns the max length of an identifier, or -1 if there is no limit + */ + public int maxIdentifierLength() { + return maxIdentifierLength; + } + + public DialectLimits maxIdentifierLength(int maxIdentifierLength) { + this.maxIdentifierLength = maxIdentifierLength; + return this; + } + + public boolean noTypeLimits() { + return noTypeLimits; + } + + public DialectLimits noTypeLimits(boolean noTypeLimits) { + this.noTypeLimits = noTypeLimits; + return this; + } + + public DialectLimits copy() { + var copy = new DialectLimits(); + copy.typeLimits.putAll(typeLimits); + copy.maxRowLength = maxRowLength; + copy.maxClusteredIndexLength = maxClusteredIndexLength; + copy.maxIndexLength = maxIndexLength; + copy.columnLimit = columnLimit; + copy.indexLimit = indexLimit; + copy.maxColumnsPerIndex = maxColumnsPerIndex; + copy.maxIdentifierLength = maxIdentifierLength; + copy.noTypeLimits = noTypeLimits; + return copy; + } + } + + record DialectTypeLimit(int baseByteCount, int maxVaryingLength) { + static final int UNSET = -2; + static final int UNLIMITED = -1; + + private DialectTypeLimit(int base) { + this(base, UNSET); + } + + public boolean varying() { + return maxVaryingLength == UNLIMITED || maxVaryingLength > 0; + } + + @Override + public int maxVaryingLength() { + return maxVaryingLength == UNLIMITED ? Integer.MAX_VALUE : maxVaryingLength; + } + + public int validateAndReturnColumnLength(Integer selfDefinedLength, CharSequence columnName) { + if (selfDefinedLength == null && varying()) { + throw new InvalidRepositoryException( + "Expected %s to have a Length annotation specifying the max length", columnName); + } + if (!varying()) { + return baseByteCount; + } + + if (selfDefinedLength <= maxVaryingLength()) { + return baseByteCount + selfDefinedLength; + } + throw new InvalidRepositoryException( + "Expected %s to have a max length of at most %s bytes, got %s", + columnName, maxVaryingLength(), selfDefinedLength); + } + } +} diff --git a/ap/src/main/java/org/geysermc/databaseutils/processor/type/mongo/MongoDatabaseGenerator.java b/ap/src/main/java/org/geysermc/databaseutils/processor/type/mongo/MongoDatabaseGenerator.java index d9acfa4..b0512be 100644 --- a/ap/src/main/java/org/geysermc/databaseutils/processor/type/mongo/MongoDatabaseGenerator.java +++ b/ap/src/main/java/org/geysermc/databaseutils/processor/type/mongo/MongoDatabaseGenerator.java @@ -69,6 +69,10 @@ private void createEntityQuery(EntityInfo entity, MethodSpec.Builder method) { Document.class, entity.name()); + // todo make some magic to always use _id for a composite key, + // without adding additional fields for those columns. + // because the current approach breaks for MongoDB clusters. + entity.indexes().forEach(index -> method.addStatement("collection.createIndex($L)", createIndex(index))); method.endControlFlow(); diff --git a/ap/src/main/java/org/geysermc/databaseutils/processor/type/sql/SqlDatabaseGenerator.java b/ap/src/main/java/org/geysermc/databaseutils/processor/type/sql/SqlDatabaseGenerator.java index f4b18f9..a733bf0 100644 --- a/ap/src/main/java/org/geysermc/databaseutils/processor/type/sql/SqlDatabaseGenerator.java +++ b/ap/src/main/java/org/geysermc/databaseutils/processor/type/sql/SqlDatabaseGenerator.java @@ -15,6 +15,8 @@ import org.geysermc.databaseutils.DatabaseCategory; import org.geysermc.databaseutils.processor.info.ColumnInfo; import org.geysermc.databaseutils.processor.info.EntityInfo; +import org.geysermc.databaseutils.processor.info.IndexInfo; +import org.geysermc.databaseutils.processor.info.IndexInfo.IndexType; import org.geysermc.databaseutils.processor.type.DatabaseGenerator; import org.geysermc.databaseutils.sql.SqlDatabase; import org.geysermc.databaseutils.sql.SqlDialect; @@ -39,24 +41,54 @@ protected void addEntities(Collection entities, MethodSpec.Builder m method.beginControlFlow("try ($T statement = connection.createStatement())", Statement.class); for (EntityInfo entity : entities) { - method.addStatement("statement.executeUpdate($L)", createEntityQuery(entity)); + method.beginControlFlow("if (dialect == $T.$L)", SqlDialect.class, SqlDialect.SQL_SERVER); + method.addStatement( + "statement.executeUpdate($S + $L + $S)", + "IF OBJECT_ID(N'" + entity.name() + "', N'U') IS NULL BEGIN ", + createEntityQuery(entity, false), + " END"); + method.nextControlFlow("else"); + + method.addStatement("statement.executeUpdate($L)", createEntityQuery(entity, true)); method.beginControlFlow("if (dialect == $T.$L)", SqlDialect.class, SqlDialect.ORACLE_DATABASE); createRowTypes(entity, method); method.endControlFlow(); + + method.endControlFlow(); } method.endControlFlow(); method.endControlFlow(); } - private CodeBlock createEntityQuery(EntityInfo entity) { - // https://docs.oracle.com/en/database/oracle/oracle-database/23/sqlrf/Data-Types.html - // https://docs.oracle.com/en/database/oracle/oracle-database/23/gmswn/database-gateway-sqlserver-data-type-conversion.html + private CodeBlock createEntityQuery(EntityInfo entity, boolean ifNotExists) { + // todo primary keys don't allow null values (excluding SQLite due to a legacy bug) - check for null + // PRIMARY KEY & UNIQUE don't need an index name, INDEX does. + + // https://docs.oracle.com/en/database/oracle/oracle-database/23/sqlrf/CREATE-TABLE.html + // https://www.postgresql.org/docs/16/sql-createtable.html + // https://www.sqlite.org/lang_createtable.html + // https://dev.mysql.com/doc/refman/8.4/en/create-table.html + // https://mariadb.com/kb/en/create-table/ + // https://learn.microsoft.com/en-us/sql/t-sql/statements/create-table-transact-sql?view=sql-server-ver16 + // http://h2database.com/html/commands.html#create_table var builder = CodeBlock.builder(); - // todo indexes are not added atm - builder.add("\"CREATE TABLE IF NOT EXISTS $L (\" +\n", entity.name()); + builder.add("\"CREATE TABLE $L$L (\" +\n", ifNotExists ? "IF NOT EXISTS " : "", entity.name()); createEntityQueryBody(entity, builder); + + // todo normal (non-primary & non-unique) indexes aren't added atm + for (IndexInfo index : entity.indexes()) { + if (index.type() == IndexType.NORMAL) { + continue; + } + builder.add("+ ',' +\n"); + builder.add( + "\"$L ($L)\" ", + index.type() == IndexType.PRIMARY ? "PRIMARY KEY" : "UNIQUE", + String.join(", ", index.columns())); + } + builder.add("+\n\")\""); return builder.build(); } @@ -96,10 +128,11 @@ private void createEntityQueryBody(EntityInfo entity, CodeBlock.Builder builder) } builder.add( - "\"$L \" + $T.sqlTypeFor($T.class, dialect) ", + "\"$L \" + $T.sqlTypeFor($T.class, dialect, $L) ", column.name(), SqlTypeMappingRegistry.class, - column.asType()); + column.asType(), + column.maxLength()); } } } diff --git a/ap/src/main/java/org/geysermc/databaseutils/processor/type/sql/SqlRepositoryGenerator.java b/ap/src/main/java/org/geysermc/databaseutils/processor/type/sql/SqlRepositoryGenerator.java index f1c820c..f0c7d9f 100644 --- a/ap/src/main/java/org/geysermc/databaseutils/processor/type/sql/SqlRepositoryGenerator.java +++ b/ap/src/main/java/org/geysermc/databaseutils/processor/type/sql/SqlRepositoryGenerator.java @@ -185,6 +185,7 @@ public void addDelete(QueryContext context, MethodSpec.Builder spec) { if (context.hasProjection()) { var limit = context.projection().limit(); if (limit != -1) { + // todo is top for mssql query.addRaw("limit " + limit); } } diff --git a/ap/src/main/java/org/geysermc/databaseutils/processor/util/InvalidRepositoryException.java b/ap/src/main/java/org/geysermc/databaseutils/processor/util/InvalidRepositoryException.java index 2de7008..4f6a01a 100644 --- a/ap/src/main/java/org/geysermc/databaseutils/processor/util/InvalidRepositoryException.java +++ b/ap/src/main/java/org/geysermc/databaseutils/processor/util/InvalidRepositoryException.java @@ -1,25 +1,6 @@ /* - * Copyright (c) 2024 GeyserMC - * - * Permission is hereby granted, free of charge, to any person obtaining a copy - * of this software and associated documentation files (the "Software"), to deal - * in the Software without restriction, including without limitation the rights - * to use, copy, modify, merge, publish, distribute, sublicense, and/or sell - * copies of the Software, and to permit persons to whom the Software is - * furnished to do so, subject to the following conditions: - * - * The above copyright notice and this permission notice shall be included in - * all copies or substantial portions of the Software. - * - * THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, EXPRESS OR - * IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF MERCHANTABILITY, - * FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. IN NO EVENT SHALL THE - * AUTHORS OR COPYRIGHT HOLDERS BE LIABLE FOR ANY CLAIM, DAMAGES OR OTHER - * LIABILITY, WHETHER IN AN ACTION OF CONTRACT, TORT OR OTHERWISE, ARISING FROM, - * OUT OF OR IN CONNECTION WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN - * THE SOFTWARE. - * - * @author GeyserMC + * Copyright (c) 2024 GeyserMC + * Licensed under the MIT license * @link https://github.com/GeyserMC/DatabaseUtils */ package org.geysermc.databaseutils.processor.util; @@ -31,6 +12,14 @@ public final class InvalidRepositoryException extends RuntimeException { private static final long serialVersionUID = 3849728966061779304L; public InvalidRepositoryException(String message, Object... arguments) { - super(String.format(message, arguments), null, false, true); + super(String.format(message, arguments)); + } + + private InvalidRepositoryException(boolean disableOwnStackTrace, String message, Object... arguments) { + super(String.format(message, arguments), null, true, !disableOwnStackTrace); + } + + public static InvalidRepositoryException createWithoutStackTrace(String message, Object... arguments) { + return new InvalidRepositoryException(true, message, arguments); } } diff --git a/ap/src/test/resources/test/advanced/SqlDatabaseGenerated.java b/ap/src/test/resources/test/advanced/SqlDatabaseGenerated.java index f1bb7d0..2217a26 100644 --- a/ap/src/test/resources/test/advanced/SqlDatabaseGenerated.java +++ b/ap/src/test/resources/test/advanced/SqlDatabaseGenerated.java @@ -27,27 +27,38 @@ static void createEntities(SqlDatabase database) throws SQLException { SqlDialect dialect = database.dialect(); try (Connection connection = database.dataSource().getConnection()) { try (Statement statement = connection.createStatement()) { - statement.executeUpdate("CREATE TABLE IF NOT EXISTS hello (" + - "a " + SqlTypeMappingRegistry.sqlTypeFor(Integer.class, dialect) + ',' + - "b " + SqlTypeMappingRegistry.sqlTypeFor(String.class, dialect) + ',' + - "c " + SqlTypeMappingRegistry.sqlTypeFor(String.class, dialect) + ',' + - "d " + SqlTypeMappingRegistry.sqlTypeFor(UUID.class, dialect) + - ")"); - if (dialect == SqlDialect.ORACLE_DATABASE) { - boolean rowExists = false; - try (var rs = statement.executeQuery("SELECT COUNT(*) FROM USER_OBJECTS WHERE OBJECT_NAME = 'HELLO_ROW' AND STATUS = 'VALID'")) { - if (rs.next()) { - rowExists = rs.getInt(1) > 0; + if (dialect == SqlDialect.SQL_SERVER) { + statement.executeUpdate("IF OBJECT_ID(N'hello', N'U') IS NULL BEGIN " + "CREATE TABLE hello (" + + "a " + SqlTypeMappingRegistry.sqlTypeFor(Integer.class, dialect, -1) + ',' + + "b " + SqlTypeMappingRegistry.sqlTypeFor(String.class, dialect, 50) + ',' + + "c " + SqlTypeMappingRegistry.sqlTypeFor(String.class, dialect, 10) + ',' + + "d " + SqlTypeMappingRegistry.sqlTypeFor(UUID.class, dialect, 16) + ',' + + "PRIMARY KEY (a, b)" + + ")" + " END"); + } else { + statement.executeUpdate("CREATE TABLE IF NOT EXISTS hello (" + + "a " + SqlTypeMappingRegistry.sqlTypeFor(Integer.class, dialect, -1) + ',' + + "b " + SqlTypeMappingRegistry.sqlTypeFor(String.class, dialect, 50) + ',' + + "c " + SqlTypeMappingRegistry.sqlTypeFor(String.class, dialect, 10) + ',' + + "d " + SqlTypeMappingRegistry.sqlTypeFor(UUID.class, dialect, 16) + ',' + + "PRIMARY KEY (a, b)" + + ")"); + if (dialect == SqlDialect.ORACLE_DATABASE) { + boolean rowExists = false; + try (var rs = statement.executeQuery("SELECT COUNT(*) FROM USER_OBJECTS WHERE OBJECT_NAME = 'HELLO_ROW' AND STATUS = 'VALID'")) { + if (rs.next()) { + rowExists = rs.getInt(1) > 0; + } + } + if (!rowExists) { + statement.executeUpdate("CREATE TYPE hello_row AS OBJECT(" + + "a " + SqlTypeMappingRegistry.sqlTypeFor(Integer.class, dialect, -1) + ',' + + "b " + SqlTypeMappingRegistry.sqlTypeFor(String.class, dialect, 50) + ',' + + "c " + SqlTypeMappingRegistry.sqlTypeFor(String.class, dialect, 10) + ',' + + "d " + SqlTypeMappingRegistry.sqlTypeFor(UUID.class, dialect, 16) + + ")"); + statement.executeUpdate("CREATE TYPE hello_table AS TABLE OF hello_row"); } - } - if (!rowExists) { - statement.executeUpdate("CREATE TYPE hello_row AS OBJECT(" + - "a " + SqlTypeMappingRegistry.sqlTypeFor(Integer.class, dialect) + ',' + - "b " + SqlTypeMappingRegistry.sqlTypeFor(String.class, dialect) + ',' + - "c " + SqlTypeMappingRegistry.sqlTypeFor(String.class, dialect) + ',' + - "d " + SqlTypeMappingRegistry.sqlTypeFor(UUID.class, dialect) + - ")"); - statement.executeUpdate("CREATE TYPE hello_table AS TABLE OF hello_row"); } } } diff --git a/ap/src/test/resources/test/advanced/TestEntity.java b/ap/src/test/resources/test/advanced/TestEntity.java index 14e3cc1..18119ec 100644 --- a/ap/src/test/resources/test/advanced/TestEntity.java +++ b/ap/src/test/resources/test/advanced/TestEntity.java @@ -4,8 +4,9 @@ import org.geysermc.databaseutils.meta.Entity; import org.geysermc.databaseutils.meta.Index; import org.geysermc.databaseutils.meta.Key; +import org.geysermc.databaseutils.meta.Length; @Index(columns = {"c"}) @Entity("hello") -public record TestEntity(@Key int a, @Key String b, String c, UUID d) { -} \ No newline at end of file +public record TestEntity( + @Key int a, @Key @Length(max = 50) String b, @Length(max = 10) String c, @Length(max = 16) UUID d) {} \ No newline at end of file diff --git a/ap/src/test/resources/test/basic/SqlDatabaseGenerated.java b/ap/src/test/resources/test/basic/SqlDatabaseGenerated.java index 5c05320..8fa3d7c 100644 --- a/ap/src/test/resources/test/basic/SqlDatabaseGenerated.java +++ b/ap/src/test/resources/test/basic/SqlDatabaseGenerated.java @@ -27,27 +27,38 @@ static void createEntities(SqlDatabase database) throws SQLException { SqlDialect dialect = database.dialect(); try (Connection connection = database.dataSource().getConnection()) { try (Statement statement = connection.createStatement()) { - statement.executeUpdate("CREATE TABLE IF NOT EXISTS hello (" + - "a " + SqlTypeMappingRegistry.sqlTypeFor(Integer.class, dialect) + ',' + - "b " + SqlTypeMappingRegistry.sqlTypeFor(String.class, dialect) + ',' + - "c " + SqlTypeMappingRegistry.sqlTypeFor(String.class, dialect) + ',' + - "d " + SqlTypeMappingRegistry.sqlTypeFor(UUID.class, dialect) + - ")"); - if (dialect == SqlDialect.ORACLE_DATABASE) { - boolean rowExists = false; - try (var rs = statement.executeQuery("SELECT COUNT(*) FROM USER_OBJECTS WHERE OBJECT_NAME = 'HELLO_ROW' AND STATUS = 'VALID'")) { - if (rs.next()) { - rowExists = rs.getInt(1) > 0; + if (dialect == SqlDialect.SQL_SERVER) { + statement.executeUpdate("IF OBJECT_ID(N'hello', N'U') IS NULL BEGIN " + "CREATE TABLE hello (" + + "a " + SqlTypeMappingRegistry.sqlTypeFor(Integer.class, dialect, -1) + ',' + + "b " + SqlTypeMappingRegistry.sqlTypeFor(String.class, dialect, 50) + ',' + + "c " + SqlTypeMappingRegistry.sqlTypeFor(String.class, dialect, 10) + ',' + + "d " + SqlTypeMappingRegistry.sqlTypeFor(UUID.class, dialect, 16) + ',' + + "PRIMARY KEY (a, b)" + + ")" + " END"); + } else { + statement.executeUpdate("CREATE TABLE IF NOT EXISTS hello (" + + "a " + SqlTypeMappingRegistry.sqlTypeFor(Integer.class, dialect, -1) + ',' + + "b " + SqlTypeMappingRegistry.sqlTypeFor(String.class, dialect, 50) + ',' + + "c " + SqlTypeMappingRegistry.sqlTypeFor(String.class, dialect, 10) + ',' + + "d " + SqlTypeMappingRegistry.sqlTypeFor(UUID.class, dialect, 16) + ',' + + "PRIMARY KEY (a, b)" + + ")"); + if (dialect == SqlDialect.ORACLE_DATABASE) { + boolean rowExists = false; + try (var rs = statement.executeQuery("SELECT COUNT(*) FROM USER_OBJECTS WHERE OBJECT_NAME = 'HELLO_ROW' AND STATUS = 'VALID'")) { + if (rs.next()) { + rowExists = rs.getInt(1) > 0; + } + } + if (!rowExists) { + statement.executeUpdate("CREATE TYPE hello_row AS OBJECT(" + + "a " + SqlTypeMappingRegistry.sqlTypeFor(Integer.class, dialect, -1) + ',' + + "b " + SqlTypeMappingRegistry.sqlTypeFor(String.class, dialect, 50) + ',' + + "c " + SqlTypeMappingRegistry.sqlTypeFor(String.class, dialect, 10) + ',' + + "d " + SqlTypeMappingRegistry.sqlTypeFor(UUID.class, dialect, 16) + + ")"); + statement.executeUpdate("CREATE TYPE hello_table AS TABLE OF hello_row"); } - } - if (!rowExists) { - statement.executeUpdate("CREATE TYPE hello_row AS OBJECT(" + - "a " + SqlTypeMappingRegistry.sqlTypeFor(Integer.class, dialect) + ',' + - "b " + SqlTypeMappingRegistry.sqlTypeFor(String.class, dialect) + ',' + - "c " + SqlTypeMappingRegistry.sqlTypeFor(String.class, dialect) + ',' + - "d " + SqlTypeMappingRegistry.sqlTypeFor(UUID.class, dialect) + - ")"); - statement.executeUpdate("CREATE TYPE hello_table AS TABLE OF hello_row"); } } } diff --git a/ap/src/test/resources/test/basic/TestEntity.java b/ap/src/test/resources/test/basic/TestEntity.java index e0e3838..53718eb 100644 --- a/ap/src/test/resources/test/basic/TestEntity.java +++ b/ap/src/test/resources/test/basic/TestEntity.java @@ -4,8 +4,9 @@ import org.geysermc.databaseutils.meta.Entity; import org.geysermc.databaseutils.meta.Index; import org.geysermc.databaseutils.meta.Key; +import org.geysermc.databaseutils.meta.Length; @Index(columns = {"c"}) @Entity("hello") -public record TestEntity(@Key int a, @Key String b, String c, UUID d) { -} \ No newline at end of file +public record TestEntity( + @Key int a, @Key @Length(max = 50) String b, @Length(max = 10) String c, @Length(max = 16) UUID d) {} \ No newline at end of file diff --git a/core/src/main/java/org/geysermc/databaseutils/DatabaseType.java b/core/src/main/java/org/geysermc/databaseutils/DatabaseType.java index 19ac973..a82a5cb 100644 --- a/core/src/main/java/org/geysermc/databaseutils/DatabaseType.java +++ b/core/src/main/java/org/geysermc/databaseutils/DatabaseType.java @@ -12,23 +12,25 @@ import org.geysermc.databaseutils.sql.SqlDialect; public enum DatabaseType { - H2(DatabaseCategory.SQL, SqlDialect.H2), - SQL_SERVER(DatabaseCategory.SQL, SqlDialect.SQL_SERVER), - MYSQL(DatabaseCategory.SQL, SqlDialect.MYSQL), - MARIADB(DatabaseCategory.SQL, SqlDialect.MARIADB), - ORACLE_DATABASE(DatabaseCategory.SQL, SqlDialect.ORACLE_DATABASE), - POSTGRESQL(DatabaseCategory.SQL, SqlDialect.POSTGRESQL), - SQLITE(DatabaseCategory.SQL, SqlDialect.SQLITE), - MONGODB(DatabaseCategory.MONGODB, null); + H2(DatabaseCategory.SQL, SqlDialect.H2, "H2"), + SQL_SERVER(DatabaseCategory.SQL, SqlDialect.SQL_SERVER, "SQL Server"), + MYSQL(DatabaseCategory.SQL, SqlDialect.MYSQL, "MySQL"), + MARIADB(DatabaseCategory.SQL, SqlDialect.MARIADB, "MariaDB"), + ORACLE_DATABASE(DatabaseCategory.SQL, SqlDialect.ORACLE_DATABASE, "Oracle Database"), + POSTGRESQL(DatabaseCategory.SQL, SqlDialect.POSTGRESQL, "PostgreSQL"), + SQLITE(DatabaseCategory.SQL, SqlDialect.SQLITE, "SQLite"), + MONGODB(DatabaseCategory.MONGODB, null, "MongoDB"); public static final DatabaseType[] VALUES = values(); private final DatabaseCategory databaseCategory; private final SqlDialect dialect; + private final String friendlyName; - DatabaseType(@NonNull DatabaseCategory databaseCategory, @Nullable SqlDialect dialect) { + DatabaseType(@NonNull DatabaseCategory databaseCategory, @Nullable SqlDialect dialect, String friendlyName) { this.databaseCategory = Objects.requireNonNull(databaseCategory); this.dialect = dialect; + this.friendlyName = friendlyName; } public @NonNull DatabaseCategory databaseCategory() { @@ -39,6 +41,10 @@ public enum DatabaseType { return dialect; } + public @NonNull String friendlyName() { + return friendlyName; + } + public static @Nullable DatabaseType byName(@NonNull String name) { var normalized = name.replace('-', '_').replace(' ', '_').toUpperCase(Locale.ROOT); for (DatabaseType value : VALUES) { @@ -48,4 +54,9 @@ public enum DatabaseType { } return null; } + + @Override + public String toString() { + return friendlyName(); + } } diff --git a/core/src/main/java/org/geysermc/databaseutils/meta/Length.java b/core/src/main/java/org/geysermc/databaseutils/meta/Length.java new file mode 100644 index 0000000..c61b195 --- /dev/null +++ b/core/src/main/java/org/geysermc/databaseutils/meta/Length.java @@ -0,0 +1,20 @@ +/* + * Copyright (c) 2024 GeyserMC + * Licensed under the MIT license + * @link https://github.com/GeyserMC/DatabaseUtils + */ +package org.geysermc.databaseutils.meta; + +import java.lang.annotation.ElementType; +import java.lang.annotation.Target; +import org.checkerframework.checker.index.qual.Positive; + +@Target(ElementType.FIELD) +public @interface Length { + /** + * The maximum length (in bytes) that the given column can be. Note that for strings this mean that you have to + * keep the chosen charset (by default almost always UTF-8) into account. A single UTF-8 character can vary from 1 + * to 4 bytes per character. + */ + @Positive int max() default 0; +} diff --git a/core/src/main/java/org/geysermc/databaseutils/sql/SqlTypeMappingRegistry.java b/core/src/main/java/org/geysermc/databaseutils/sql/SqlTypeMappingRegistry.java index 16c696c..90b0574 100644 --- a/core/src/main/java/org/geysermc/databaseutils/sql/SqlTypeMappingRegistry.java +++ b/core/src/main/java/org/geysermc/databaseutils/sql/SqlTypeMappingRegistry.java @@ -14,11 +14,11 @@ public final class SqlTypeMappingRegistry { private SqlTypeMappingRegistry() {} - public static String sqlTypeFor(Class type, SqlDialect dialect) { + public static String sqlTypeFor(Class type, SqlDialect dialect, int maxLength) { var dialectMapping = DIALECT_MAPPINGS.getOrDefault(dialect, Collections.emptyMap()); var mapping = dialectMapping.getOrDefault(type, dialectMapping.get(Byte[].class)); if (mapping != null) { - return mapping; + return mapping.formatted(maxLength); } throw new IllegalStateException( String.format("Was not able to find mapping for %s with dialect %s", type.getName(), dialectMapping)); @@ -35,24 +35,37 @@ private static void addMapping(Class type, String mapping) { } static { - // see the README for more info + // see the README for more info, data is based off LimitsEnforcer addMapping(Boolean.class, "boolean"); addDialectMapping(SqlDialect.SQL_SERVER, Boolean.class, "bit"); addDialectMapping(SqlDialect.SQLITE, Boolean.class, "int"); - addMapping(Byte.class, "smallint"); + + addMapping(Byte.class, "tinyint"); + addDialectMapping(SqlDialect.POSTGRESQL, Byte.class, "smallint"); + addDialectMapping(SqlDialect.SQL_SERVER, Byte.class, "smallint"); + addMapping(Short.class, "smallint"); - addMapping(Character.class, "smallint"); + + addMapping(Character.class, "int"); + addDialectMapping(SqlDialect.MARIADB, Short.class, "smallint unsigned"); + addDialectMapping(SqlDialect.MYSQL, Short.class, "smallint unsigned"); + addDialectMapping(SqlDialect.ORACLE_DATABASE, Character.class, "number(5)"); + addMapping(Integer.class, "int"); addMapping(Long.class, "bigint"); + addMapping(Float.class, "real"); + addDialectMapping(SqlDialect.ORACLE_DATABASE, Float.class, "binary_float"); + addMapping(Double.class, "double precision"); + addDialectMapping(SqlDialect.ORACLE_DATABASE, Double.class, "binary_double"); addDialectMapping(SqlDialect.SQL_SERVER, Double.class, "float"); - // todo require all entities to specify the max length for specific types, to make sure we choose the most - // efficient type - // also: the max row size (for all columns combined) is 65535. Have to change some to TEXT or BLOBs - addMapping(String.class, "varchar(1000)"); // 16383 for utf8mb4, 21844 for utf8, 65535 for one byte char set - addMapping(Byte[].class, "varbinary(1000)"); // max = 65532, 3 byte prefix + + addMapping(String.class, "varchar(%s)"); + addDialectMapping(SqlDialect.ORACLE_DATABASE, String.class, "varchar2(%s)"); + + addMapping(Byte[].class, "varbinary(%s)"); addDialectMapping(SqlDialect.POSTGRESQL, Byte[].class, "bytea"); - addDialectMapping(SqlDialect.ORACLE_DATABASE, Byte[].class, "raw(1000)"); + addDialectMapping(SqlDialect.ORACLE_DATABASE, Byte[].class, "raw(%s)"); } } diff --git a/core/src/test/java/org/geysermc/databaseutils/TestContext.java b/core/src/test/java/org/geysermc/databaseutils/TestContext.java index 0a7b8fc..d140ba7 100644 --- a/core/src/test/java/org/geysermc/databaseutils/TestContext.java +++ b/core/src/test/java/org/geysermc/databaseutils/TestContext.java @@ -21,6 +21,7 @@ import org.junit.jupiter.api.DynamicTest; import org.testcontainers.containers.GenericContainer; import org.testcontainers.containers.JdbcDatabaseContainer; +import org.testcontainers.containers.MSSQLServerContainer; import org.testcontainers.containers.MariaDBContainer; import org.testcontainers.containers.MongoDBContainer; import org.testcontainers.containers.MySQLContainer; @@ -42,9 +43,9 @@ public final class TestContext { put(DatabaseType.MYSQL, new MySQLContainer<>("mysql:9.0.1")); put(DatabaseType.MONGODB, new MongoDBContainer("mongo:7.0.14")); put(DatabaseType.POSTGRESQL, new PostgreSQLContainer<>("postgres:16.4")); - // todo 'create table if not exists' is not a thing in mssqlserver - // put(DatabaseType.SQL_SERVER, new MSSQLServerContainer<>(MSSQLServerContainer.IMAGE + - // ":2022-latest").acceptLicense()); + put( + DatabaseType.SQL_SERVER, + new MSSQLServerContainer<>(MSSQLServerContainer.IMAGE + ":2022-latest").acceptLicense()); put(DatabaseType.ORACLE_DATABASE, new OracleContainer("gvenzl/oracle-free:23.5-slim-faststart")); } }; diff --git a/core/src/test/java/org/geysermc/databaseutils/delete/DeleteTests.java b/core/src/test/java/org/geysermc/databaseutils/delete/DeleteTests.java index cc8761a..3b08fb9 100644 --- a/core/src/test/java/org/geysermc/databaseutils/delete/DeleteTests.java +++ b/core/src/test/java/org/geysermc/databaseutils/delete/DeleteTests.java @@ -133,13 +133,20 @@ Stream deleteFirst() { repository.insert(new TestEntity(0, "hello", "world!", null)); assertEquals(1, repository.deleteFirstByB("hello")); - assertFalse(repository.existsByAAndB(1, "hello")); + + // depending on the dialect either the first inserted item is deleted or + // the one with the lowest index + if (repository.existsByAAndB(1, "hello")) { + assertFalse(repository.existsByAAndB(0, "hello")); + } else { + assertTrue(repository.existsByAAndB(0, "hello")); + } assertTrue(repository.existsByAAndB(2, "hello")); - assertTrue(repository.existsByAAndB(0, "hello")); }, DatabaseType.ORACLE_DATABASE, DatabaseType.POSTGRESQL, - DatabaseType.SQLITE); + DatabaseType.SQLITE, + DatabaseType.SQL_SERVER); // delete limit is a flag that needs to be enabled during compiling on sqlite, and on Oracle and Postgres it // doesn't exist. So we have to work around this in the future by doing a subquery } @@ -235,6 +242,7 @@ Stream deleteFirstWithOrderReturning() { DatabaseType.H2, DatabaseType.MYSQL, DatabaseType.MONGODB, - DatabaseType.MARIADB); + DatabaseType.MARIADB, + DatabaseType.SQL_SERVER); } } diff --git a/core/src/test/java/org/geysermc/databaseutils/entity/TestEntity.java b/core/src/test/java/org/geysermc/databaseutils/entity/TestEntity.java index 277fd92..e8b1d27 100644 --- a/core/src/test/java/org/geysermc/databaseutils/entity/TestEntity.java +++ b/core/src/test/java/org/geysermc/databaseutils/entity/TestEntity.java @@ -9,7 +9,9 @@ import org.geysermc.databaseutils.meta.Entity; import org.geysermc.databaseutils.meta.Index; import org.geysermc.databaseutils.meta.Key; +import org.geysermc.databaseutils.meta.Length; @Index(columns = {"c"}) @Entity("hello") -public record TestEntity(@Key int a, @Key String b, String c, UUID d) {} +public record TestEntity( + @Key int a, @Key @Length(max = 50) String b, @Length(max = 30) String c, @Length(max = 16) UUID d) {}