diff --git a/.github/workflows/test-unit.yml b/.github/workflows/test-unit.yml
index 4b1d8de0f..1792bb047 100644
--- a/.github/workflows/test-unit.yml
+++ b/.github/workflows/test-unit.yml
@@ -156,14 +156,12 @@ jobs:
           php -r '(new PDO("pgsql:host=postgres;dbname=atk4_test", "atk4_test", "atk4_pass"))->exec("ALTER ROLE atk4_test CONNECTION LIMIT 1");'
           if [ -n "$LOG_COVERAGE" ]; then mkdir coverage; fi
 
-      - name: "Run tests: SQLite (only for Phpunit)"
-        if: startsWith(matrix.type, 'Phpunit')
+      - name: "Run tests: SQLite"
         run: |
           php -d opcache.enable_cli=1 vendor/bin/phpunit --exclude-group none $(if [ -n "$LOG_COVERAGE" ]; then echo --coverage-text; else echo --no-coverage; fi) -v
           if [ -n "$LOG_COVERAGE" ]; then mv coverage/phpunit.cov coverage/phpunit-sqlite.cov; fi
 
-      - name: "Run tests: MySQL (only for Phpunit)"
-        if: startsWith(matrix.type, 'Phpunit')
+      - name: "Run tests: MySQL"
         env:
           DB_DSN: "mysql:host=mysql;dbname=atk4_test"
           DB_USER: atk4_test
@@ -172,8 +170,7 @@ jobs:
           php -d opcache.enable_cli=1 vendor/bin/phpunit --exclude-group none $(if [ -n "$LOG_COVERAGE" ]; then echo --coverage-text; else echo --no-coverage; fi) -v
           if [ -n "$LOG_COVERAGE" ]; then mv coverage/phpunit.cov coverage/phpunit-mysql.cov; fi
 
-      - name: "Run tests: MariaDB (only for Phpunit)"
-        if: startsWith(matrix.type, 'Phpunit')
+      - name: "Run tests: MariaDB"
         env:
           DB_DSN: "mysql:host=mariadb;dbname=atk4_test"
           DB_USER: atk4_test
@@ -182,8 +179,7 @@ jobs:
           php -d opcache.enable_cli=1 vendor/bin/phpunit --exclude-group none $(if [ -n "$LOG_COVERAGE" ]; then echo --coverage-text; else echo --no-coverage; fi) -v
           if [ -n "$LOG_COVERAGE" ]; then mv coverage/phpunit.cov coverage/phpunit-mariadb.cov; fi
 
-      - name: "Run tests: PostgreSQL (only for Phpunit)"
-        if: startsWith(matrix.type, 'Phpunit')
+      - name: "Run tests: PostgreSQL"
         env:
           DB_DSN: "pgsql:host=postgres;dbname=atk4_test"
           DB_USER: atk4_test
@@ -192,8 +188,7 @@ jobs:
           php -d opcache.enable_cli=1 vendor/bin/phpunit --exclude-group none $(if [ -n "$LOG_COVERAGE" ]; then echo --coverage-text; else echo --no-coverage; fi) -v
           if [ -n "$LOG_COVERAGE" ]; then mv coverage/phpunit.cov coverage/phpunit-postgres.cov; fi
 
-      - name: "Run tests: MSSQL (only for Phpunit)"
-        if: startsWith(matrix.type, 'Phpunit')
+      - name: "Run tests: MSSQL"
         env:
           DB_DSN: "sqlsrv:Server=mssql;Database=master"
           DB_USER: sa
@@ -202,8 +197,7 @@ jobs:
           php -d opcache.enable_cli=1 vendor/bin/phpunit --exclude-group none $(if [ -n "$LOG_COVERAGE" ]; then echo --coverage-text; else echo --no-coverage; fi) -v
           if [ -n "$LOG_COVERAGE" ]; then mv coverage/phpunit.cov coverage/phpunit-mssql.cov; fi
 
-      - name: "Run tests: Oracle (only for Phpunit)"
-        if: startsWith(matrix.type, 'Phpunit')
+      - name: "Run tests: Oracle"
         env:
           DB_DSN: "oci:dbname=oracle/xe;charset=UTF8"
           DB_USER: system
diff --git a/phpstan.neon.dist b/phpstan.neon.dist
index d3c67f8d7..9019d98ea 100644
--- a/phpstan.neon.dist
+++ b/phpstan.neon.dist
@@ -34,7 +34,7 @@ parameters:
             message: '~^(Call to an undefined method Doctrine\\DBAL\\Driver\\Connection::getWrappedConnection\(\)\.|Caught class Doctrine\\DBAL\\DBALException not found\.|Call to static method notSupported\(\) on an unknown class Doctrine\\DBAL\\DBALException\.|Access to an undefined property Doctrine\\DBAL\\Driver\\PDO\\Connection::\$connection\.|Method Atk4\\Data\\Persistence\\Sql\\Expression::execute\(\) should return Doctrine\\DBAL\\Result\|PDOStatement but returns bool\.|Class Doctrine\\DBAL\\Platforms\\MySqlPlatform referenced with incorrect case: Doctrine\\DBAL\\Platforms\\MySQLPlatform\.)$~'
             path: '*'
             # count for DBAL 3.x matched in "src/Persistence/GenericPlatform.php" file
-            count: 11
+            count: 10
 
         # TODO these rules are generated, this ignores should be fixed in the code
         # for src/Schema/TestCase.php
@@ -52,7 +52,6 @@ parameters:
         # for src/Model/ReferencesTrait.php (in context of class Atk4\Data\Model)
         - '~^Call to an undefined method Atk4\\Data\\Reference::refLink\(\)\.$~'
         # for src/Persistence/Sql.php
-        - '~^Call to an undefined method Atk4\\Data\\Persistence\\Sql\\Query::sequence\(\)\.$~'
         - '~^Call to an undefined method Atk4\\Data\\Persistence::expr\(\)\.$~'
         - '~^Call to an undefined method Atk4\\Data\\Persistence::exprNow\(\)\.$~'
         # for src/Persistence/Sql/Join.php
diff --git a/src/Model.php b/src/Model.php
index f1d86e550..c7fefecea 100644
--- a/src/Model.php
+++ b/src/Model.php
@@ -147,13 +147,6 @@ class Model implements \IteratorAggregate
      */
     public $table_alias;
 
-    /**
-     * Sequence name. Some DB engines use sequence for generating auto_increment IDs.
-     *
-     * @var string
-     */
-    public $sequence;
-
     /**
      * Persistence driver inherited from Atk4\Data\Persistence.
      *
diff --git a/src/Persistence.php b/src/Persistence.php
index a25fe6751..4d856ec04 100644
--- a/src/Persistence.php
+++ b/src/Persistence.php
@@ -90,6 +90,9 @@ public function add(Model $m, array $defaults = []): Model
         $m->persistence = $this;
         $m->persistence_data = [];
         $this->initPersistence($m);
+
+        // invokes Model::init()
+        // model is not added to elements as it does not implement TrackableTrait trait
         $m = $this->_add($m);
 
         $this->hook(self::HOOK_AFTER_ADD, [$m]);
diff --git a/src/Persistence/Array_/Action.php b/src/Persistence/Array_/Action.php
index 223a77160..d38b3eec7 100644
--- a/src/Persistence/Array_/Action.php
+++ b/src/Persistence/Array_/Action.php
@@ -51,7 +51,7 @@ public function filter(Model\Scope\AbstractScope $condition)
     }
 
     /**
-     * Calculates SUM|AVG|MIN|MAX aggragate values for $field.
+     * Calculates SUM|AVG|MIN|MAX aggregate values for $field.
      *
      * @param string $fx
      * @param string $field
diff --git a/src/Persistence/GenericPlatform.php b/src/Persistence/GenericPlatform.php
index 409d76ae7..2ba533d7d 100644
--- a/src/Persistence/GenericPlatform.php
+++ b/src/Persistence/GenericPlatform.php
@@ -20,7 +20,6 @@ private function createNotSupportedException(): \Exception // DbalException once
                 \Doctrine\DBAL\DBALException::notSupported('SQL');
                 \Doctrine\DBAL\DBALException::notSupported('SQL');
                 \Doctrine\DBAL\DBALException::notSupported('SQL');
-                \Doctrine\DBAL\DBALException::notSupported('SQL');
             }
 
             return \Doctrine\DBAL\DBALException::notSupported('SQL');
diff --git a/src/Persistence/Sql.php b/src/Persistence/Sql.php
index 5ec630776..8d473aa97 100644
--- a/src/Persistence/Sql.php
+++ b/src/Persistence/Sql.php
@@ -13,8 +13,9 @@
 use Atk4\Data\Persistence\Sql\Exception as DsqlException;
 use Atk4\Data\Persistence\Sql\Expression;
 use Atk4\Data\Persistence\Sql\Query;
-use Doctrine\DBAL\Platforms;
+use Doctrine\DBAL\Platforms\AbstractPlatform;
 use Doctrine\DBAL\Platforms\OraclePlatform;
+use Doctrine\DBAL\Platforms\PostgreSQL94Platform;
 use Doctrine\DBAL\Platforms\SQLServer2012Platform;
 
 class Sql extends Persistence
@@ -134,7 +135,7 @@ public function atomic(\Closure $fx)
         return $this->connection->atomic($fx);
     }
 
-    public function getDatabasePlatform(): Platforms\AbstractPlatform
+    public function getDatabasePlatform(): AbstractPlatform
     {
         return $this->connection->getDatabasePlatform();
     }
@@ -170,11 +171,6 @@ public function add(Model $model, array $defaults = []): Model
             //$m->getField($m->id_field)->type = 'integer';
         }
 
-        // Sequence support
-        if ($model->sequence && $model->hasField($model->id_field)) {
-            $model->getField($model->id_field)->default = $this->dsql()->mode('seq_nextval')->sequence($model->sequence);
-        }
-
         return $model;
     }
 
@@ -565,8 +561,6 @@ public function insert(Model $model, array $data): string
 
         if ($model->id_field && !isset($data[$model->id_field])) {
             unset($data[$model->id_field]);
-
-            $this->syncIdSequence($model);
         }
 
         $insert->set($this->typecastSaveRow($model, $data));
@@ -585,8 +579,6 @@ public function insert(Model $model, array $data): string
 
         if ($model->id_field && isset($data[$model->id_field])) {
             $id = (string) $data[$model->id_field];
-
-            $this->syncIdSequence($model);
         } else {
             $id = $this->lastInsertId($model);
         }
@@ -732,47 +724,20 @@ public function getFieldSqlExpression(Field $field, Expression $expression): Exp
         return $expression->expr($mask, $prop);
     }
 
-    private function getIdSequenceName(Model $model): ?string
-    {
-        $sequenceName = $model->sequence ?: null;
-
-        if ($sequenceName === null) {
-            // PostgreSQL uses sequence internally for PK autoincrement,
-            // use default name if not set explicitly
-            if ($this->connection instanceof \Atk4\Data\Persistence\Sql\Postgresql\Connection) {
-                $sequenceName = $model->table . '_' . $model->getField($model->id_field)->getPersistenceName() . '_seq';
-            }
-        }
-
-        return $sequenceName;
-    }
-
     public function lastInsertId(Model $model): string
     {
-        // TODO: Oracle does not support lastInsertId(), only for testing
-        // as this does not support concurrent inserts
-        if ($this->connection instanceof \Atk4\Data\Persistence\Sql\Oracle\Connection) {
-            if (!$model->id_field) {
-                return ''; // TODO code should never call lastInsertId() if id field is not defined
-            }
-
-            $query = $this->connection->dsql()->table($model->table);
-            $query->field($query->expr('max({id_col})', ['id_col' => $model->getField($model->id_field)->getPersistenceName()]), 'max_id');
-
-            return $query->getOne();
-        }
-
-        return $this->connection->lastInsertId($this->getIdSequenceName($model));
-    }
-
-    protected function syncIdSequence(Model $model): void
-    {
-        // PostgreSQL sequence must be manually synchronized if a row with explicit ID was inserted
-        if ($this->connection instanceof \Atk4\Data\Persistence\Sql\Postgresql\Connection) {
-            $this->connection->expr(
-                'select setval([], coalesce(max({}), 0) + 1, false) from {}',
-                [$this->getIdSequenceName($model), $model->getField($model->id_field)->getPersistenceName(), $model->table]
-            )->execute();
-        }
+        // PostgreSQL and Oracle DBAL platforms use sequence internally for PK autoincrement,
+        // use default name if not set explicitly
+        $sequenceName = null;
+        if ($this->connection->getDatabasePlatform() instanceof PostgreSQL94Platform) {
+            $sequenceName = $this->connection->getDatabasePlatform()->getIdentitySequenceName(
+                $model->table,
+                $model->getField($model->id_field)->getPersistenceName()
+            );
+        } elseif ($this->connection->getDatabasePlatform() instanceof OraclePlatform) {
+            $sequenceName = $model->table . '_SEQ';
+        }
+
+        return $this->connection->lastInsertId($sequenceName);
     }
 }
diff --git a/src/Persistence/Sql/Connection.php b/src/Persistence/Sql/Connection.php
index 41e5620ad..a095adb5e 100644
--- a/src/Persistence/Sql/Connection.php
+++ b/src/Persistence/Sql/Connection.php
@@ -273,199 +273,26 @@ protected static function connectDbalConnection(array $dsn)
             }, null, DbalConnection::class)();
         }
 
-        // SQL Server DBAL platform has buggy identifier escaping, fix until fixed officially, see:
-        // https://github.com/doctrine/dbal/pull/4360
+        if ($dbalConnection->getDatabasePlatform() instanceof PostgreSQL94Platform) {
+            \Closure::bind(function () use ($dbalConnection) {
+                $dbalConnection->platform = new class() extends PostgreSQL94Platform {
+                    use Postgresql\PlatformTrait;
+                };
+            }, null, DbalConnection::class)();
+        }
+
         if ($dbalConnection->getDatabasePlatform() instanceof SQLServer2012Platform) {
             \Closure::bind(function () use ($dbalConnection) {
                 $dbalConnection->platform = new class() extends SQLServer2012Platform {
-                    protected function getCreateColumnCommentSQL($tableName, $columnName, $comment)
-                    {
-                        if (strpos($tableName, '.') !== false) {
-                            [$schemaName, $tableName] = explode('.', $tableName, 2);
-                        } else {
-                            $schemaName = $this->getDefaultSchemaName();
-                        }
-
-                        return $this->getAddExtendedPropertySQL(
-                            'MS_Description',
-                            (string) $comment,
-                            'SCHEMA',
-                            $schemaName,
-                            'TABLE',
-                            $tableName,
-                            'COLUMN',
-                            $columnName
-                        );
-                    }
-
-                    protected function getAlterColumnCommentSQL($tableName, $columnName, $comment)
-                    {
-                        if (strpos($tableName, '.') !== false) {
-                            [$schemaName, $tableName] = explode('.', $tableName, 2);
-                        } else {
-                            $schemaName = $this->getDefaultSchemaName();
-                        }
-
-                        return $this->getUpdateExtendedPropertySQL(
-                            'MS_Description',
-                            (string) $comment,
-                            'SCHEMA',
-                            $schemaName,
-                            'TABLE',
-                            $tableName,
-                            'COLUMN',
-                            $columnName
-                        );
-                    }
-
-                    protected function getDropColumnCommentSQL($tableName, $columnName)
-                    {
-                        if (strpos($tableName, '.') !== false) {
-                            [$schemaName, $tableName] = explode('.', $tableName, 2);
-                        } else {
-                            $schemaName = $this->getDefaultSchemaName();
-                        }
-
-                        return $this->getDropExtendedPropertySQL(
-                            'MS_Description',
-                            'SCHEMA',
-                            $schemaName,
-                            'TABLE',
-                            $tableName,
-                            'COLUMN',
-                            $columnName
-                        );
-                    }
-
-                    private function quoteSingleIdentifierAsStringLiteral(string $levelName): string
-                    {
-                        return $this->quoteStringLiteral(preg_replace('~^\[|\]$~s', '', $levelName));
-                    }
-
-                    public function getAddExtendedPropertySQL(
-                        $name,
-                        $value = null,
-                        $level0Type = null,
-                        $level0Name = null,
-                        $level1Type = null,
-                        $level1Name = null,
-                        $level2Type = null,
-                        $level2Name = null
-                    ) {
-                        return 'EXEC sp_addextendedproperty'
-                            . ' N' . $this->quoteStringLiteral($name) . ', N' . $this->quoteStringLiteral((string) $value)
-                            . ', N' . $this->quoteStringLiteral((string) $level0Type)
-                            . ', ' . $this->quoteSingleIdentifierAsStringLiteral((string) $level0Name)
-                            . ', N' . $this->quoteStringLiteral((string) $level1Type)
-                            . ', ' . $this->quoteSingleIdentifierAsStringLiteral((string) $level1Name)
-                            . (
-                                $level2Type !== null || $level2Name !== null
-                                ? ', N' . $this->quoteStringLiteral((string) $level2Type)
-                                  . ', ' . $this->quoteSingleIdentifierAsStringLiteral((string) $level2Name)
-                                : ''
-                            );
-                    }
-
-                    public function getDropExtendedPropertySQL(
-                        $name,
-                        $level0Type = null,
-                        $level0Name = null,
-                        $level1Type = null,
-                        $level1Name = null,
-                        $level2Type = null,
-                        $level2Name = null
-                    ) {
-                        return 'EXEC sp_dropextendedproperty'
-                            . ' N' . $this->quoteStringLiteral($name)
-                            . ', N' . $this->quoteStringLiteral((string) $level0Type)
-                            . ', ' . $this->quoteSingleIdentifierAsStringLiteral((string) $level0Name)
-                            . ', N' . $this->quoteStringLiteral((string) $level1Type)
-                            . ', ' . $this->quoteSingleIdentifierAsStringLiteral((string) $level1Name)
-                            . (
-                                $level2Type !== null || $level2Name !== null
-                                ? ', N' . $this->quoteStringLiteral((string) $level2Type)
-                                  . ', ' . $this->quoteSingleIdentifierAsStringLiteral((string) $level2Name)
-                                : ''
-                            );
-                    }
-
-                    public function getUpdateExtendedPropertySQL(
-                        $name,
-                        $value = null,
-                        $level0Type = null,
-                        $level0Name = null,
-                        $level1Type = null,
-                        $level1Name = null,
-                        $level2Type = null,
-                        $level2Name = null
-                    ) {
-                        return 'EXEC sp_updateextendedproperty'
-                            . ' N' . $this->quoteStringLiteral($name) . ', N' . $this->quoteStringLiteral((string) $value)
-                            . ', N' . $this->quoteStringLiteral((string) $level0Type)
-                            . ', ' . $this->quoteSingleIdentifierAsStringLiteral((string) $level0Name)
-                            . ', N' . $this->quoteStringLiteral((string) $level1Type)
-                            . ', ' . $this->quoteSingleIdentifierAsStringLiteral((string) $level1Name)
-                            . (
-                                $level2Type !== null || $level2Name !== null
-                                ? ', N' . $this->quoteStringLiteral((string) $level2Type)
-                                  . ', ' . $this->quoteSingleIdentifierAsStringLiteral((string) $level2Name)
-                                : ''
-                            );
-                    }
-
-                    protected function getCommentOnTableSQL(string $tableName, ?string $comment): string
-                    {
-                        if (strpos($tableName, '.') !== false) {
-                            [$schemaName, $tableName] = explode('.', $tableName, 2);
-                        } else {
-                            $schemaName = $this->getDefaultSchemaName();
-                        }
-
-                        return $this->getAddExtendedPropertySQL(
-                            'MS_Description',
-                            (string) $comment,
-                            'SCHEMA',
-                            $schemaName,
-                            'TABLE',
-                            $tableName
-                        );
-                    }
+                    use Mssql\PlatformTrait;
                 };
             }, null, DbalConnection::class)();
         }
 
-        // Oracle CLOB/BLOB has limited SQL support, see:
-        // https://stackoverflow.com/questions/12980038/ora-00932-inconsistent-datatypes-expected-got-clob#12980560
-        // fix this Oracle inconsistency by using VARCHAR/VARBINARY instead (but limited to 4000 bytes)
         if ($dbalConnection->getDatabasePlatform() instanceof OraclePlatform) {
             \Closure::bind(function () use ($dbalConnection) {
                 $dbalConnection->platform = new class() extends OraclePlatform {
-                    private function forwardTypeDeclarationSQL(string $targetMethodName, array $column): string
-                    {
-                        $backtrace = debug_backtrace(\DEBUG_BACKTRACE_PROVIDE_OBJECT | \DEBUG_BACKTRACE_IGNORE_ARGS);
-                        foreach ($backtrace as $frame) {
-                            if ($this === ($frame['object'] ?? null)
-                                && $targetMethodName === ($frame['function'] ?? null)) {
-                                throw new Exception('Long CLOB/TEXT (4000+ bytes) is not supported for Oracle');
-                            }
-                        }
-
-                        return $this->{$targetMethodName}($column);
-                    }
-
-                    public function getClobTypeDeclarationSQL(array $column)
-                    {
-                        $column['length'] = $this->getVarcharMaxLength();
-
-                        return $this->forwardTypeDeclarationSQL('getVarcharTypeDeclarationSQL', $column);
-                    }
-
-                    public function getBlobTypeDeclarationSQL(array $column)
-                    {
-                        $column['length'] = $this->getBinaryMaxLength();
-
-                        return $this->forwardTypeDeclarationSQL('getBinaryTypeDeclarationSQL', $column);
-                    }
+                    use Oracle\PlatformTrait;
                 };
             }, null, DbalConnection::class)();
         }
diff --git a/src/Persistence/Sql/Mssql/PlatformTrait.php b/src/Persistence/Sql/Mssql/PlatformTrait.php
new file mode 100644
index 000000000..1cf35c62c
--- /dev/null
+++ b/src/Persistence/Sql/Mssql/PlatformTrait.php
@@ -0,0 +1,164 @@
+<?php
+
+declare(strict_types=1);
+
+namespace Atk4\Data\Persistence\Sql\Mssql;
+
+trait PlatformTrait
+{
+    // SQL Server DBAL platform has buggy identifier escaping, fix until fixed officially, see:
+    // https://github.com/doctrine/dbal/pull/4360
+
+    protected function getCreateColumnCommentSQL($tableName, $columnName, $comment)
+    {
+        if (strpos($tableName, '.') !== false) {
+            [$schemaName, $tableName] = explode('.', $tableName, 2);
+        } else {
+            $schemaName = $this->getDefaultSchemaName();
+        }
+
+        return $this->getAddExtendedPropertySQL(
+            'MS_Description',
+            (string) $comment,
+            'SCHEMA',
+            $schemaName,
+            'TABLE',
+            $tableName,
+            'COLUMN',
+            $columnName
+        );
+    }
+
+    protected function getAlterColumnCommentSQL($tableName, $columnName, $comment)
+    {
+        if (strpos($tableName, '.') !== false) {
+            [$schemaName, $tableName] = explode('.', $tableName, 2);
+        } else {
+            $schemaName = $this->getDefaultSchemaName();
+        }
+
+        return $this->getUpdateExtendedPropertySQL(
+            'MS_Description',
+            (string) $comment,
+            'SCHEMA',
+            $schemaName,
+            'TABLE',
+            $tableName,
+            'COLUMN',
+            $columnName
+        );
+    }
+
+    protected function getDropColumnCommentSQL($tableName, $columnName)
+    {
+        if (strpos($tableName, '.') !== false) {
+            [$schemaName, $tableName] = explode('.', $tableName, 2);
+        } else {
+            $schemaName = $this->getDefaultSchemaName();
+        }
+
+        return $this->getDropExtendedPropertySQL(
+            'MS_Description',
+            'SCHEMA',
+            $schemaName,
+            'TABLE',
+            $tableName,
+            'COLUMN',
+            $columnName
+        );
+    }
+
+    private function quoteSingleIdentifierAsStringLiteral(string $levelName): string
+    {
+        return $this->quoteStringLiteral(preg_replace('~^\[|\]$~s', '', $levelName));
+    }
+
+    public function getAddExtendedPropertySQL(
+        $name,
+        $value = null,
+        $level0Type = null,
+        $level0Name = null,
+        $level1Type = null,
+        $level1Name = null,
+        $level2Type = null,
+        $level2Name = null
+    ) {
+        return 'EXEC sp_addextendedproperty'
+            . ' N' . $this->quoteStringLiteral($name) . ', N' . $this->quoteStringLiteral((string) $value)
+            . ', N' . $this->quoteStringLiteral((string) $level0Type)
+            . ', ' . $this->quoteSingleIdentifierAsStringLiteral((string) $level0Name)
+            . ', N' . $this->quoteStringLiteral((string) $level1Type)
+            . ', ' . $this->quoteSingleIdentifierAsStringLiteral((string) $level1Name)
+            . (
+                $level2Type !== null || $level2Name !== null
+                ? ', N' . $this->quoteStringLiteral((string) $level2Type)
+                  . ', ' . $this->quoteSingleIdentifierAsStringLiteral((string) $level2Name)
+                : ''
+            );
+    }
+
+    public function getDropExtendedPropertySQL(
+        $name,
+        $level0Type = null,
+        $level0Name = null,
+        $level1Type = null,
+        $level1Name = null,
+        $level2Type = null,
+        $level2Name = null
+    ) {
+        return 'EXEC sp_dropextendedproperty'
+            . ' N' . $this->quoteStringLiteral($name)
+            . ', N' . $this->quoteStringLiteral((string) $level0Type)
+            . ', ' . $this->quoteSingleIdentifierAsStringLiteral((string) $level0Name)
+            . ', N' . $this->quoteStringLiteral((string) $level1Type)
+            . ', ' . $this->quoteSingleIdentifierAsStringLiteral((string) $level1Name)
+            . (
+                $level2Type !== null || $level2Name !== null
+                ? ', N' . $this->quoteStringLiteral((string) $level2Type)
+                  . ', ' . $this->quoteSingleIdentifierAsStringLiteral((string) $level2Name)
+                : ''
+            );
+    }
+
+    public function getUpdateExtendedPropertySQL(
+        $name,
+        $value = null,
+        $level0Type = null,
+        $level0Name = null,
+        $level1Type = null,
+        $level1Name = null,
+        $level2Type = null,
+        $level2Name = null
+    ) {
+        return 'EXEC sp_updateextendedproperty'
+            . ' N' . $this->quoteStringLiteral($name) . ', N' . $this->quoteStringLiteral((string) $value)
+            . ', N' . $this->quoteStringLiteral((string) $level0Type)
+            . ', ' . $this->quoteSingleIdentifierAsStringLiteral((string) $level0Name)
+            . ', N' . $this->quoteStringLiteral((string) $level1Type)
+            . ', ' . $this->quoteSingleIdentifierAsStringLiteral((string) $level1Name)
+            . (
+                $level2Type !== null || $level2Name !== null
+                ? ', N' . $this->quoteStringLiteral((string) $level2Type)
+                  . ', ' . $this->quoteSingleIdentifierAsStringLiteral((string) $level2Name)
+                : ''
+            );
+    }
+
+    protected function getCommentOnTableSQL(string $tableName, ?string $comment): string
+    {
+        if (strpos($tableName, '.') !== false) {
+            [$schemaName, $tableName] = explode('.', $tableName, 2);
+        } else {
+            $schemaName = $this->getDefaultSchemaName();
+        }
+
+        return $this->getAddExtendedPropertySQL(
+            'MS_Description',
+            (string) $comment,
+            'SCHEMA',
+            $schemaName,
+            'TABLE',
+            $tableName
+        );
+    }
+}
diff --git a/src/Persistence/Sql/Oracle/AbstractQuery.php b/src/Persistence/Sql/Oracle/AbstractQuery.php
index a1d9da93f..12ea6f0c2 100644
--- a/src/Persistence/Sql/Oracle/AbstractQuery.php
+++ b/src/Persistence/Sql/Oracle/AbstractQuery.php
@@ -8,11 +8,6 @@
 
 abstract class AbstractQuery extends BaseQuery
 {
-    /** @var string */
-    protected $template_seq_currval = 'select [sequence].CURRVAL from dual';
-    /** @var string */
-    protected $template_seq_nextval = '[sequence].NEXTVAL';
-
     public function render(): string
     {
         if ($this->mode === 'select' && $this->main_table === null) {
@@ -22,25 +17,6 @@ public function render(): string
         return parent::render();
     }
 
-    /**
-     * Set sequence.
-     *
-     * @param string $sequence
-     *
-     * @return $this
-     */
-    public function sequence($sequence)
-    {
-        $this->args['sequence'] = $sequence;
-
-        return $this;
-    }
-
-    public function _render_sequence(): ?string
-    {
-        return $this->args['sequence'];
-    }
-
     public function groupConcat($field, string $delimiter = ',')
     {
         return $this->expr('listagg({field}, []) within group (order by {field})', ['field' => $field, $delimiter]);
diff --git a/src/Persistence/Sql/Oracle/Connection.php b/src/Persistence/Sql/Oracle/Connection.php
index db1febace..62f93ab1b 100644
--- a/src/Persistence/Sql/Oracle/Connection.php
+++ b/src/Persistence/Sql/Oracle/Connection.php
@@ -91,21 +91,12 @@ protected static function connectDbalConnection(array $dsn)
 
     /// }}}
 
-    /**
-     * Return last inserted ID value.
-     *
-     * Drivers like PostgreSQL need to receive sequence name to get ID because PDO doesn't support this method.
-     */
     public function lastInsertId(string $sequence = null): string
     {
         if ($sequence) {
-            /** @var AbstractQuery */
-            $query = $this->dsql()->mode('seq_currval');
-
-            return $query->sequence($sequence)->getOne();
+            return $this->dsql()->field($this->expr('{}.CURRVAL', [$sequence]))->getOne();
         }
 
-        // fallback
         return parent::lastInsertId($sequence);
     }
 }
diff --git a/src/Persistence/Sql/Oracle/PlatformTrait.php b/src/Persistence/Sql/Oracle/PlatformTrait.php
new file mode 100644
index 000000000..d83863aa5
--- /dev/null
+++ b/src/Persistence/Sql/Oracle/PlatformTrait.php
@@ -0,0 +1,98 @@
+<?php
+
+declare(strict_types=1);
+
+namespace Atk4\Data\Persistence\Sql\Oracle;
+
+use Atk4\Data\Exception;
+use Doctrine\DBAL\Platforms\OraclePlatform;
+use Doctrine\DBAL\Schema\Sequence;
+
+trait PlatformTrait
+{
+    // Oracle CLOB/BLOB has limited SQL support, see:
+    // https://stackoverflow.com/questions/12980038/ora-00932-inconsistent-datatypes-expected-got-clob#12980560
+    // fix this Oracle inconsistency by using VARCHAR/VARBINARY instead (but limited to 4000 bytes)
+
+    private function forwardTypeDeclarationSQL(string $targetMethodName, array $column): string
+    {
+        $backtrace = debug_backtrace(\DEBUG_BACKTRACE_PROVIDE_OBJECT | \DEBUG_BACKTRACE_IGNORE_ARGS);
+        foreach ($backtrace as $frame) {
+            if ($this === ($frame['object'] ?? null)
+                && $targetMethodName === ($frame['function'] ?? null)) {
+                throw new Exception('Long CLOB/TEXT (4000+ bytes) is not supported for Oracle');
+            }
+        }
+
+        return $this->{$targetMethodName}($column);
+    }
+
+    public function getClobTypeDeclarationSQL(array $column)
+    {
+        $column['length'] = $this->getVarcharMaxLength();
+
+        return $this->forwardTypeDeclarationSQL('getVarcharTypeDeclarationSQL', $column);
+    }
+
+    public function getBlobTypeDeclarationSQL(array $column)
+    {
+        $column['length'] = $this->getBinaryMaxLength();
+
+        return $this->forwardTypeDeclarationSQL('getBinaryTypeDeclarationSQL', $column);
+    }
+
+    // Oracle DBAL platform autoincrement implementation does not increment like
+    // Sqlite or MySQL does, unify the behaviour
+
+    public function getCreateSequenceSQL(Sequence $sequence)
+    {
+        $sequence->setCache(1);
+
+        return parent::getCreateSequenceSQL($sequence);
+    }
+
+    public function getCreateAutoincrementSql($name, $table, $start = 1)
+    {
+        $sqls = parent::getCreateAutoincrementSql($name, $table, $start);
+
+        // replace trigger from https://github.com/doctrine/dbal/blob/3.1.3/src/Platforms/OraclePlatform.php#L526-L546
+        $tableIdentifier = \Closure::bind(fn () => $this->normalizeIdentifier($table), $this, OraclePlatform::class)();
+        $nameIdentifier = \Closure::bind(fn () => $this->normalizeIdentifier($name), $this, OraclePlatform::class)();
+        $aiTriggerName = \Closure::bind(fn () => $this->getAutoincrementIdentifierName($tableIdentifier), $this, OraclePlatform::class)();
+        $aiSequenceName = $this->getIdentitySequenceName($tableIdentifier->getQuotedName($this), $nameIdentifier->getQuotedName($this));
+        assert(str_starts_with($sqls[count($sqls) - 1], 'CREATE TRIGGER ' . $aiTriggerName . "\n"));
+
+        $conn = new Connection();
+        $pkSeq = \Closure::bind(fn () => $this->normalizeIdentifier($aiSequenceName), $this, OraclePlatform::class)()->getName();
+        $sqls[count($sqls) - 1] = $conn->expr(
+            // else branch should be maybe (because of concurrency) put into after update trigger
+            str_replace('[pk_seq]', '\'' . $pkSeq . '\'', <<<'EOT'
+                CREATE TRIGGER {trigger}
+                    BEFORE INSERT OR UPDATE
+                    ON {table}
+                    FOR EACH ROW
+                DECLARE
+                    atk4__pk_seq_last__ {table}.{pk}%TYPE;
+                BEGIN
+                    IF (:NEW.{pk} IS NULL) THEN
+                        SELECT {pk_seq}.NEXTVAL INTO :NEW.{pk} FROM DUAL;
+                    ELSE
+                        SELECT LAST_NUMBER INTO atk4__pk_seq_last__ FROM USER_SEQUENCES WHERE SEQUENCE_NAME = [pk_seq];
+                        WHILE atk4__pk_seq_last__ <= :NEW.{pk}
+                        LOOP
+                            SELECT {pk_seq}.NEXTVAL + 1 INTO atk4__pk_seq_last__ FROM DUAL;
+                        END LOOP;
+                    END IF;
+                END;
+                EOT),
+            [
+                'trigger' => \Closure::bind(fn () => $this->normalizeIdentifier($aiTriggerName), $this, OraclePlatform::class)()->getName(),
+                'table' => $tableIdentifier->getName(),
+                'pk' => $nameIdentifier->getName(),
+                'pk_seq' => $pkSeq,
+            ]
+        )->render();
+
+        return $sqls;
+    }
+}
diff --git a/src/Persistence/Sql/Postgresql/PlatformTrait.php b/src/Persistence/Sql/Postgresql/PlatformTrait.php
new file mode 100644
index 000000000..8ad495910
--- /dev/null
+++ b/src/Persistence/Sql/Postgresql/PlatformTrait.php
@@ -0,0 +1,90 @@
+<?php
+
+declare(strict_types=1);
+
+namespace Atk4\Data\Persistence\Sql\Postgresql;
+
+use Doctrine\DBAL\Schema\Column;
+use Doctrine\DBAL\Schema\Table;
+
+trait PlatformTrait
+{
+    // PostgreSQL DBAL platform uses SERIAL column type for autoincrement which does not increment
+    // when a row with a not-null PK is inserted like Sqlite or MySQL does, unify the behaviour
+
+    private function getPrimaryKeyColumn(Table $table): ?Column
+    {
+        if ($table->getPrimaryKey() === null) {
+            return null;
+        }
+
+        return $table->getColumn($table->getPrimaryKey()->getColumns()[0]);
+    }
+
+    protected function getCreateAutoincrementSql(Table $table, Column $pkColumn): array
+    {
+        $sqls = [];
+
+        $pkSeqName = $this->getIdentitySequenceName($table->getName(), $pkColumn->getName());
+
+        $conn = new Connection();
+
+        $sqls[] = $conn->expr(
+            // else branch should be maybe (because of concurrency) put into after update trigger
+            // with pure nextval instead of setval with a loop like in Oracle trigger
+            str_replace('[pk_seq]', '\'' . $pkSeqName . '\'', <<<'EOF'
+                CREATE OR REPLACE FUNCTION {trigger_func}()
+                RETURNS trigger AS $$
+                DECLARE
+                    atk4__pk_seq_last__ {table}.{pk}%TYPE;
+                BEGIN
+                    IF (NEW.{pk} IS NULL) THEN
+                        NEW.{pk} := nextval([pk_seq]);
+                    ELSE
+                        SELECT COALESCE(last_value, 0) INTO atk4__pk_seq_last__ FROM {pk_seq};
+                        IF (atk4__pk_seq_last__ <= NEW.{pk}) THEN
+                            atk4__pk_seq_last__  := setval([pk_seq], NEW.{pk}, true);
+                        END IF;
+                    END IF;
+                    RETURN NEW;
+                END;
+                $$ LANGUAGE plpgsql;
+                EOF),
+            [
+                'table' => $table->getName(),
+                'pk' => $pkColumn->getName(),
+                'pk_seq' => $pkSeqName,
+                'trigger_func' => $table->getName() . '_AI_FUNC',
+            ]
+        )->render();
+
+        $sqls[] = $conn->expr(
+            <<<'EOF'
+                CREATE TRIGGER {trigger}
+                    BEFORE INSERT OR UPDATE
+                    ON {table}
+                    FOR EACH ROW
+                EXECUTE PROCEDURE {trigger_func}();
+                EOF,
+            [
+                'table' => $table->getName(),
+                'trigger' => $table->getName() . '_AI_PK',
+                'trigger_func' => $table->getName() . '_AI_FUNC',
+            ]
+        )->render();
+
+        return $sqls;
+    }
+
+    public function getCreateTableSQL(Table $table, $createFlags = self::CREATE_INDEXES)
+    {
+        $sqls = parent::getCreateTableSQL($table, $createFlags);
+
+        $pkColumn = $this->getPrimaryKeyColumn($table);
+        if ($pkColumn !== null) {
+            $sqls = array_merge($sqls, $this->getCreateAutoincrementSql($table, $pkColumn));
+        }
+
+        return $sqls;
+    }
+}
diff --git a/src/Schema/Migration.php b/src/Schema/Migration.php
index 676df0d2c..12be422a7 100644
--- a/src/Schema/Migration.php
+++ b/src/Schema/Migration.php
@@ -15,7 +15,6 @@
 use Doctrine\DBAL\Platforms\OraclePlatform;
 use Doctrine\DBAL\Platforms\SqlitePlatform;
 use Doctrine\DBAL\Schema\AbstractSchemaManager;
-use Doctrine\DBAL\Schema\Column;
 use Doctrine\DBAL\Schema\Table;
 
 class Migration
@@ -74,81 +73,15 @@ public function table(string $tableName): self
         return $this;
     }
 
-    private function getPrimaryKeyColumn(): ?Column
-    {
-        if ($this->table->getPrimaryKey() === null) {
-            return null;
-        }
-
-        return $this->table->getColumn($this->table->getPrimaryKey()->getColumns()[0]);
-    }
-
     public function create(): self
     {
         $this->getSchemaManager()->createTable($this->table);
 
-        $pkColumn = $this->getPrimaryKeyColumn();
-        if ($this->getDatabasePlatform() instanceof OraclePlatform && $pkColumn !== null) {
-            $this->connection->expr(
-                <<<'EOT'
-                    begin
-                        execute immediate [];
-                    end;
-                    EOT,
-                [
-                    $this->connection->expr(
-                        <<<'EOT'
-                            create or replace trigger {table_ai_trigger_before}
-                                before insert on {table}
-                                for each row
-                                when (new.{id_column} is null)
-                            declare
-                                last_id {table}.{id_column}%type;
-                            begin
-                                select nvl(max({id_column}), 0) into last_id from {table};
-                                :new.{id_column} := last_id + 1;
-                            end;
-                            EOT,
-                        [
-                            'table' => $this->table->getName(),
-                            'table_ai_trigger_before' => $this->table->getName() . '__aitb',
-                            'id_column' => $pkColumn->getName(),
-                        ]
-                    )->render(),
-                ]
-            )->execute();
-        }
-
         return $this;
     }
 
     public function drop(): self
     {
-        if ($this->getDatabasePlatform() instanceof OraclePlatform) {
-            // drop trigger if exists
-            // see https://stackoverflow.com/questions/1799128/oracle-if-table-exists
-            $this->connection->expr(
-                <<<'EOT'
-                    begin
-                        execute immediate [];
-                    exception
-                        when others then
-                            if sqlcode != -4080 then
-                                raise;
-                            end if;
-                    end;
-                    EOT,
-                [
-                    $this->connection->expr(
-                        'drop trigger {table_ai_trigger_before}',
-                        [
-                            'table_ai_trigger_before' => $this->table->getName() . '__aitb',
-                        ]
-                    )->render(),
-                ]
-            )->execute();
-        }
-
         $this->getSchemaManager()->dropTable($this->getDatabasePlatform()->quoteSingleIdentifier($this->table->getName()));
 
         return $this;
@@ -191,9 +124,7 @@ public function field(string $fieldName, array $options = []): self
 
         if ($refType === self::REF_TYPE_PRIMARY) {
             $this->table->setPrimaryKey([$this->getDatabasePlatform()->quoteSingleIdentifier($fieldName)]);
-            if (!$this->getDatabasePlatform() instanceof OraclePlatform) {
-                $column->setAutoincrement(true);
-            }
+            $column->setAutoincrement(true);
         }
 
         return $this;
diff --git a/src/Schema/TestCase.php b/src/Schema/TestCase.php
index 4899c2736..9de595c60 100644
--- a/src/Schema/TestCase.php
+++ b/src/Schema/TestCase.php
@@ -9,7 +9,6 @@
 use Atk4\Data\Persistence;
 use Doctrine\DBAL\Logging\SQLLogger;
 use Doctrine\DBAL\Platforms\AbstractPlatform;
-use Doctrine\DBAL\Platforms\MySQLPlatform;
 use Doctrine\DBAL\Schema\AbstractSchemaManager;
 
 class TestCase extends BaseTestCase
@@ -32,11 +31,6 @@ protected function setUp(): void
 
         $this->db = Persistence::connect($_ENV['DB_DSN'], $_ENV['DB_USER'], $_ENV['DB_PASSWD']);
 
-        // reset DB autoincrement to 1, tests rely on it
-        if ($this->getDatabasePlatform() instanceof MySQLPlatform) {
-            $this->db->connection->expr('SET @@auto_increment_offset=1, @@auto_increment_increment=1')->execute();
-        }
-
         if ($this->debug) {
             $this->db->connection->connection()->getConfiguration()->setSQLLogger(
                 new class($this) implements SQLLogger {
@@ -107,8 +101,6 @@ public function createMigrator(Model $model = null): Migration
      */
     public function dropTableIfExists(string $tableName): self
     {
-        // we cannot use SchemaManager::dropTable directly because of
-        // our custom Oracle sequence for PK/AI
         $this->createMigrator()->table($tableName)->dropIfExists();
 
         return $this;
diff --git a/tests/JoinSqlTest.php b/tests/JoinSqlTest.php
index 103c7722d..af45021ac 100644
--- a/tests/JoinSqlTest.php
+++ b/tests/JoinSqlTest.php
@@ -139,10 +139,6 @@ public function testJoinSaving2(): void
 
         $this->db->connection->dsql()->table('contact')->where('id', 2)->delete();
 
-        if ($this->getDatabasePlatform() instanceof OraclePlatform) { // TODO
-            $this->markTestIncomplete('TODO - for some reasons, result below has one different key');
-        }
-
         $m_u2->unload();
         $m_u2 = $m_u->createEntity();
         $m_u2->set('name', 'Sue');
diff --git a/tests/Persistence/ArrayTest.php b/tests/Persistence/ArrayTest.php
index 21a48cc75..4f6eb0a4b 100644
--- a/tests/Persistence/ArrayTest.php
+++ b/tests/Persistence/ArrayTest.php
@@ -584,6 +584,7 @@ public function testOrder(): void
         // order by one field descending
         $p = new Persistence\Array_($dbData);
         $m = new Model($p);
+        $m->getField('id')->actual = 'myid';
         $m->addField('f1');
         $m->addField('f2');
         $m->addField('f3');
@@ -670,8 +671,12 @@ public function testImportAndAutoincrement(): void
 
         $m->import([
             ['f1' => 'K'],
+            ['f1' => 'L'],
         ]);
-        $this->assertSame(10, $m->action('count')->getOne());
+        $this->assertSame(11, $m->action('count')->getOne());
+
+        $m->delete(100);
+        $m->createEntity()->set('f1', 'M')->save();
 
         $this->assertSame([
             1 => ['id' => 1, 'f1' => 'A'],
@@ -683,7 +688,8 @@ public function testImportAndAutoincrement(): void
             9 => ['id' => 9, 'f1' => 'H'],
             99 => ['id' => 99, 'f1' => 'I'],
             20 => ['id' => 20, 'f1' => 'J'],
-            100 => ['id' => 100, 'f1' => 'K'],
+            101 => ['id' => 101, 'f1' => 'L'],
+            102 => ['id' => 102, 'f1' => 'M'],
         ], $m->export());
     }
 
diff --git a/tests/Persistence/Sql/WithDb/SelectTest.php b/tests/Persistence/Sql/WithDb/SelectTest.php
index 923471482..babd315bc 100644
--- a/tests/Persistence/Sql/WithDb/SelectTest.php
+++ b/tests/Persistence/Sql/WithDb/SelectTest.php
@@ -9,6 +9,7 @@
 use Atk4\Data\Persistence\Sql\Exception;
 use Atk4\Data\Persistence\Sql\Expression;
 use Atk4\Data\Persistence\Sql\Query;
+use Atk4\Data\Schema\Migration;
 use Doctrine\DBAL\Platforms\MySQLPlatform;
 use Doctrine\DBAL\Platforms\OraclePlatform;
 use Doctrine\DBAL\Platforms\PostgreSQL94Platform;
@@ -21,18 +22,7 @@ class SelectTest extends TestCase
 
     private function dropDbIfExists(): void
     {
-        if ($this->c->getDatabasePlatform() instanceof OraclePlatform) {
-            $this->c->connection()->executeQuery('begin
-                execute immediate \'drop table "employee"\';
-            exception
-                when others then
-                    if sqlcode != -942 then
-                        raise;
-                    end if;
-            end;');
-        } else {
-            $this->c->connection()->executeQuery('DROP TABLE IF EXISTS employee');
-        }
+        (new Migration($this->c))->table('employee')->dropIfExists();
     }
 
     protected function setUp(): void
@@ -313,4 +303,99 @@ public function testExecuteException(): void
             throw $e;
         }
     }
+
+    public function testImportAndAutoincrement(): void
+    {
+        $p = new \Atk4\Data\Persistence\Sql($this->c);
+        $m = new \Atk4\Data\Model($p, ['table' => 'test']);
+        $m->getField('id')->actual = 'myid';
+        $m->setOrder('id');
+        $m->addField('f1');
+        (new \Atk4\Data\Schema\Migration($m))->dropIfExists()->create();
+
+        $getLastAiFx = function (): int {
+            $table = 'test';
+            $pk = 'myid';
+            $maxIdExpr = $this->c->dsql()->table($table)->field($this->c->expr('max({})', [$pk]));
+            if ($this->c->getDatabasePlatform() instanceof MySQLPlatform) {
+                $query = $this->c->dsql()->table('INFORMATION_SCHEMA.TABLES')
+                    ->field($this->c->expr('greatest({} - 1, (' . $maxIdExpr->render() . '))', ['AUTO_INCREMENT']))
+                    ->where('TABLE_NAME', $table);
+            } elseif ($this->c->getDatabasePlatform() instanceof PostgreSQL94Platform) {
+                $query = $this->c->dsql()->field($this->c->expr('currval(pg_get_serial_sequence([], []))', [$table, $pk]));
+            } elseif ($this->c->getDatabasePlatform() instanceof SQLServer2012Platform) {
+                $query = $this->c->dsql()->field($this->c->expr('IDENT_CURRENT([])', [$table]));
+            } elseif ($this->c->getDatabasePlatform() instanceof OraclePlatform) {
+                $query = $this->c->dsql()->field($this->c->expr('{}.CURRVAL', [$table . '_SEQ']));
+            } else {
+                $query = $this->c->dsql()->table('sqlite_sequence')->field('seq')->where('name', $table);
+            }
+
+            return (int) $query->getOne();
+        };
+
+        $m->import([
+            ['id' => 1, 'f1' => 'A'],
+            ['id' => 2, 'f1' => 'B'],
+        ]);
+        $this->assertSame('2', $m->action('count')->getOne());
+        $this->assertSame(2, $getLastAiFx());
+
+        $m->import([
+            ['f1' => 'C'],
+            ['f1' => 'D'],
+        ]);
+        $this->assertSame('4', $m->action('count')->getOne());
+        $this->assertSame(4, $getLastAiFx());
+
+        $m->import([
+            ['id' => 6, 'f1' => 'E'],
+            ['id' => 7, 'f1' => 'F'],
+        ]);
+        $this->assertSame('6', $m->action('count')->getOne());
+        $this->assertSame(7, $getLastAiFx());
+
+        $m->delete(6);
+        $this->assertSame('5', $m->action('count')->getOne());
+        $this->assertSame(7, $getLastAiFx());
+
+        $m->import([
+            ['f1' => 'G'],
+            ['f1' => 'H'],
+        ]);
+        $this->assertSame('7', $m->action('count')->getOne());
+        $this->assertSame(9, $getLastAiFx());
+
+        $m->import([
+            ['id' => 99, 'f1' => 'I'],
+            ['id' => 20, 'f1' => 'J'],
+        ]);
+        $this->assertSame('9', $m->action('count')->getOne());
+        $this->assertSame(99, $getLastAiFx());
+
+        $m->import([
+            ['f1' => 'K'],
+            ['f1' => 'L'],
+        ]);
+        $this->assertSame('11', $m->action('count')->getOne());
+        $this->assertSame(101, $getLastAiFx());
+
+        $m->delete(100);
+        $m->createEntity()->set('f1', 'M')->save();
+        $this->assertSame(102, $getLastAiFx());
+
+        $this->assertSame([
+            ['id' => 1, 'f1' => 'A'],
+            ['id' => 2, 'f1' => 'B'],
+            ['id' => 3, 'f1' => 'C'],
+            ['id' => 4, 'f1' => 'D'],
+            ['id' => 7, 'f1' => 'F'],
+            ['id' => 8, 'f1' => 'G'],
+            ['id' => 9, 'f1' => 'H'],
+            ['id' => 20, 'f1' => 'J'],
+            ['id' => 99, 'f1' => 'I'],
+            ['id' => 101, 'f1' => 'L'],
+            ['id' => 102, 'f1' => 'M'],
+        ], $m->export());
+    }
 }
diff --git a/tests/Persistence/Sql/WithDb/TransactionTest.php b/tests/Persistence/Sql/WithDb/TransactionTest.php
index ce0d11604..5a0d9a384 100644
--- a/tests/Persistence/Sql/WithDb/TransactionTest.php
+++ b/tests/Persistence/Sql/WithDb/TransactionTest.php
@@ -9,6 +9,7 @@
 use Atk4\Data\Persistence\Sql\Exception;
 use Atk4\Data\Persistence\Sql\Expression;
 use Atk4\Data\Persistence\Sql\Query;
+use Atk4\Data\Schema\Migration;
 use Doctrine\DBAL\Platforms\MySQLPlatform;
 use Doctrine\DBAL\Platforms\OraclePlatform;
 use Doctrine\DBAL\Platforms\PostgreSQL94Platform;
@@ -21,18 +22,7 @@ class TransactionTest extends TestCase
 
     private function dropDbIfExists(): void
     {
-        if ($this->c->getDatabasePlatform() instanceof OraclePlatform) {
-            $this->c->connection()->executeQuery('begin
-                execute immediate \'drop table "employee"\';
-            exception
-                when others then
-                    if sqlcode != -942 then
-                        raise;
-                    end if;
-            end;');
-        } else {
-            $this->c->connection()->executeQuery('DROP TABLE IF EXISTS employee');
-        }
+        (new Migration($this->c))->table('employee')->dropIfExists();
     }
 
     protected function setUp(): void