diff --git a/CHANGELOG.md b/CHANGELOG.md index 27c4307..99b0a1a 100644 --- a/CHANGELOG.md +++ b/CHANGELOG.md @@ -8,6 +8,9 @@ Types of changes: `Added`, `Changed`, `Deprecate`, `Removed`, `Fixed`, `Secruity ## [Unreleased] +### Added +- Added class `CreateTableBlueprint` to create statements for generating tables in MySQL/MariaDB and SQLite + ## v2.5.0 - 17.03.2024 - Added statistic for amount and price development ### Added diff --git a/framework/Database/BlueprintInterface.php b/framework/Database/BlueprintInterface.php new file mode 100644 index 0000000..d2da9a6 --- /dev/null +++ b/framework/Database/BlueprintInterface.php @@ -0,0 +1,8 @@ +sql[] = 'id INT auto_increment'; + $this->sql[] = 'PRIMARY KEY (id)'; + break; + + case 'sqlite': + $this->sql[] = 'id INTEGER PRIMARY KEY'; + break; + + default: + throw new RuntimeException('The database connection "' . Config::env('DB_CONNECTION') . '" is not supported'); + } + } + + public function bool(string $column, bool $nullable = false, bool $default = false): void + { + switch (Config::env('DB_CONNECTION')) { + case 'mysql': + case 'sqlite': + $this->sql[] = $column . ' TINYINT(1) ' . ($nullable ? '' : 'NOT ') . 'NULL DEFAULT ' . Convert::boolToInt($default); + break; + + default: + throw new RuntimeException('The database connection "' . Config::env('DB_CONNECTION') . '" is not supported'); + } + } + + public function int(string $column, bool $nullable = false): void + { + switch (Config::env('DB_CONNECTION')) { + case 'mysql': + $this->sql[] = $column . ' INT ' . ($nullable ? '' : 'NOT ') . 'NULL'; + break; + + case 'sqlite': + $this->sql[] = $column . ' INTEGER ' . ($nullable ? '' : 'NOT ') . 'NULL'; + break; + + default: + throw new RuntimeException('The database connection "' . Config::env('DB_CONNECTION') . '" is not supported'); + } + } + + public function string(string $column, string $length, bool $nullable = false): void + { + switch (Config::env('DB_CONNECTION')) { + case 'mysql': + case 'sqlite': + $this->sql[] = $column . ' VARCHAR(' . $length . ') ' . ($nullable ? '' : 'NOT ') . 'NULL'; + break; + + default: + throw new RuntimeException('The database connection "' . Config::env('DB_CONNECTION') . '" is not supported'); + } + } + + public function timestamps(): void + { + switch (Config::env('DB_CONNECTION')) { + case 'mysql': + $this->sql[] = 'createdAt TIMESTAMP DEFAULT CURRENT_TIMESTAMP'; + $this->sql[] = 'updatedAt TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP'; + break; + + case 'sqlite': + $this->sql[] = 'createdAt TIMESTAMP DEFAULT CURRENT_TIMESTAMP'; + $this->sql[] = 'updatedAt TIMESTAMP DEFAULT CURRENT_TIMESTAMP'; + // Add "on update" trigger + $this->afterSql[] = 'CREATE TRIGGER ' . $this->table . '_updateAt AFTER UPDATE ON `' . $this->table . '` BEGIN UPDATE ' . $this->table . ' SET updatedAt=CURRENT_TIMESTAMP WHERE id = NEW.id; END;'; + break; + + default: + throw new RuntimeException('The database connection "' . Config::env('DB_CONNECTION') . '" is not supported'); + } + } + + public function build(): array + { + switch (Config::env('DB_CONNECTION')) { + case 'mysql': + return ['CREATE TABLE `' . $this->table . '` (' . implode(',', $this->sql) . ') ENGINE=InnoDB DEFAULT CHARSET=utf8mb4;']; + + case 'sqlite': + return ['CREATE TABLE `' . $this->table . '` (' . implode(',', $this->sql) . ');', ...$this->afterSql]; + + default: + throw new RuntimeException('The database connection "' . Config::env('DB_CONNECTION') . '" is not supported'); + } + } +} \ No newline at end of file diff --git a/framework/tests/Unit/Database/TestCreateTableBlueprint.php b/framework/tests/Unit/Database/TestCreateTableBlueprint.php new file mode 100644 index 0000000..13dd5d0 --- /dev/null +++ b/framework/tests/Unit/Database/TestCreateTableBlueprint.php @@ -0,0 +1,187 @@ +id(); + $this->assertEquals(['CREATE TABLE `user` (id INT auto_increment,PRIMARY KEY (id)) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4;'], $blueprint->build()); + + // SQLite + + Config::setTestValues('DB_CONNECTION', 'sqlite'); + + $blueprint = new CreateTableBlueprint('user'); + $blueprint->id(); + $this->assertEquals(['CREATE TABLE `user` (id INTEGER PRIMARY KEY);'], $blueprint->build()); + } + + public function testBool(): void + { + Config::useTestMode(); + + // MySQL + + Config::setTestValues('DB_CONNECTION', 'mysql'); + + $blueprint = new CreateTableBlueprint('user'); + $blueprint->bool('isLocked'); + $this->assertEquals(['CREATE TABLE `user` (isLocked TINYINT(1) NOT NULL DEFAULT 0) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4;'], $blueprint->build()); + + $blueprint = new CreateTableBlueprint('user'); + $blueprint->bool('isLocked', nullable: true); + $this->assertEquals(['CREATE TABLE `user` (isLocked TINYINT(1) NULL DEFAULT 0) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4;'], $blueprint->build()); + + $blueprint = new CreateTableBlueprint('user'); + $blueprint->bool('isLocked', default: true); + $this->assertEquals(['CREATE TABLE `user` (isLocked TINYINT(1) NOT NULL DEFAULT 1) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4;'], $blueprint->build()); + + // SQLite + + Config::setTestValues('DB_CONNECTION', 'sqlite'); + + $blueprint = new CreateTableBlueprint('user'); + $blueprint->bool('isLocked'); + $this->assertEquals(['CREATE TABLE `user` (isLocked TINYINT(1) NOT NULL DEFAULT 0);'], $blueprint->build()); + + $blueprint = new CreateTableBlueprint('user'); + $blueprint->bool('isLocked', nullable: true); + $this->assertEquals(['CREATE TABLE `user` (isLocked TINYINT(1) NULL DEFAULT 0);'], $blueprint->build()); + + $blueprint = new CreateTableBlueprint('user'); + $blueprint->bool('isLocked', default: true); + $this->assertEquals(['CREATE TABLE `user` (isLocked TINYINT(1) NOT NULL DEFAULT 1);'], $blueprint->build()); + } + + public function testInt(): void + { + Config::useTestMode(); + + // MySQL + + Config::setTestValues('DB_CONNECTION', 'mysql'); + + $blueprint = new CreateTableBlueprint('user'); + $blueprint->int('age'); + $this->assertEquals(['CREATE TABLE `user` (age INT NOT NULL) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4;'], $blueprint->build()); + + $blueprint = new CreateTableBlueprint('user'); + $blueprint->int('age', true); + $this->assertEquals(['CREATE TABLE `user` (age INT NULL) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4;'], $blueprint->build()); + + // SQLite + + Config::setTestValues('DB_CONNECTION', 'sqlite'); + + $blueprint = new CreateTableBlueprint('user'); + $blueprint->int('age'); + $this->assertEquals(['CREATE TABLE `user` (age INTEGER NOT NULL);'], $blueprint->build()); + + $blueprint = new CreateTableBlueprint('user'); + $blueprint->int('age', true); + $this->assertEquals(['CREATE TABLE `user` (age INTEGER NULL);'], $blueprint->build()); + } + + public function testString(): void + { + Config::useTestMode(); + + // MySQL + + Config::setTestValues('DB_CONNECTION', 'mysql'); + + $blueprint = new CreateTableBlueprint('user'); + $blueprint->string('firstname', 30); + $this->assertEquals(['CREATE TABLE `user` (firstname VARCHAR(30) NOT NULL) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4;'], $blueprint->build()); + + $blueprint = new CreateTableBlueprint('user'); + $blueprint->string('firstname', 30, true); + $this->assertEquals(['CREATE TABLE `user` (firstname VARCHAR(30) NULL) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4;'], $blueprint->build()); + + // SQLite + + Config::setTestValues('DB_CONNECTION', 'sqlite'); + + $blueprint = new CreateTableBlueprint('user'); + $blueprint->string('firstname', 30); + $this->assertEquals(['CREATE TABLE `user` (firstname VARCHAR(30) NOT NULL);'], $blueprint->build()); + + $blueprint = new CreateTableBlueprint('user'); + $blueprint->string('firstname', 30, true); + $this->assertEquals(['CREATE TABLE `user` (firstname VARCHAR(30) NULL);'], $blueprint->build()); + } + + public function testTimestamps(): void + { + Config::useTestMode(); + + // MySQL + + Config::setTestValues('DB_CONNECTION', 'mysql'); + + $blueprint = new CreateTableBlueprint('user'); + $blueprint->timestamps(); + $this->assertEquals(['CREATE TABLE `user` (createdAt TIMESTAMP DEFAULT CURRENT_TIMESTAMP,updatedAt TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4;'], $blueprint->build()); + + // SQLite + + Config::setTestValues('DB_CONNECTION', 'sqlite'); + + $blueprint = new CreateTableBlueprint('user'); + $blueprint->timestamps(); + $this->assertEquals( + [ + 'CREATE TABLE `user` (createdAt TIMESTAMP DEFAULT CURRENT_TIMESTAMP,updatedAt TIMESTAMP DEFAULT CURRENT_TIMESTAMP);', + 'CREATE TRIGGER user_updateAt AFTER UPDATE ON `user` BEGIN UPDATE user SET updatedAt=CURRENT_TIMESTAMP WHERE id = NEW.id; END;' + ], + $blueprint->build() + ); + } + + public function testCombined(): void + { + Config::useTestMode(); + + // MySQL + + Config::setTestValues('DB_CONNECTION', 'mysql'); + + $blueprint = new CreateTableBlueprint('user'); + $blueprint->id(); + $blueprint->string('firstname', 30); + $blueprint->int('age', true); + $blueprint->bool('isLocked', default: true); + $blueprint->timestamps(); + $this->assertEquals(['CREATE TABLE `user` (id INT auto_increment,PRIMARY KEY (id),firstname VARCHAR(30) NOT NULL,age INT NULL,isLocked TINYINT(1) NOT NULL DEFAULT 1,createdAt TIMESTAMP DEFAULT CURRENT_TIMESTAMP,updatedAt TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4;'], $blueprint->build()); + + // SQLite + + Config::setTestValues('DB_CONNECTION', 'sqlite'); + + $blueprint = new CreateTableBlueprint('user'); + $blueprint->id(); + $blueprint->string('firstname', 30); + $blueprint->int('age', true); + $blueprint->bool('isLocked', default: true); + $blueprint->timestamps(); + $this->assertEquals( + [ + 'CREATE TABLE `user` (id INTEGER PRIMARY KEY,firstname VARCHAR(30) NOT NULL,age INTEGER NULL,isLocked TINYINT(1) NOT NULL DEFAULT 1,createdAt TIMESTAMP DEFAULT CURRENT_TIMESTAMP,updatedAt TIMESTAMP DEFAULT CURRENT_TIMESTAMP);', + 'CREATE TRIGGER user_updateAt AFTER UPDATE ON `user` BEGIN UPDATE user SET updatedAt=CURRENT_TIMESTAMP WHERE id = NEW.id; END;' + ], + $blueprint->build() + ); + } + +} \ No newline at end of file