diff --git a/.idea/sqldialects.xml b/.idea/sqldialects.xml index f3005944..ebfee56c 100644 --- a/.idea/sqldialects.xml +++ b/.idea/sqldialects.xml @@ -7,5 +7,7 @@ + + \ No newline at end of file diff --git a/docs/datetime.md b/docs/datetime.md index 7a008138..7082124f 100644 --- a/docs/datetime.md +++ b/docs/datetime.md @@ -16,6 +16,7 @@ The following table presents a matrix of available DB date-time types: | MySQL | `datetime` | `timestamp` | - | | Postgres | `timestamp` | `timestamptz` | - | | SQL Server | `datetime`, `datetime2` | - | `datetimeoffset` | +| Sqlite | - | - | - - **no timezone handling**: database stores the time-stamp and does not do any modification to it; this is the easiest solution, but brings a disadvantage: database cannot exactly diff two time-stamps, i.e. it may produce wrong results because day-light saving shift is needed but db does not know which zone to use for the calculation; - **timezone conversion**: database stores the time-stamp unified in UTC and reads it in connection's timezone; @@ -90,3 +91,25 @@ This will make Dbal fully functional, although some SQL queries and expressions |------|-------------|-------- | local datetime | `datetime` | value is converted into application timezone | datetime | `datetimeoffset` | value is read with timezone offset and no further modification is done - i.e. no application timezone conversion happens + +-------------------------- + +### Sqlite + +Sqlite does not have a dedicated type for date time at all. However, Sqlite provides a function that helps to transform unix time to a local time zone. + +Use `datetime(your_column, 'unixepoch', 'localtime')` to convert stored timestamp to your local time-zone. Read more in the [official documentation](https://sqlite.org/lang_datefunc.html#modifiers). + +##### Writing + +| Type | Modifier | Comment +|------|----------|-------- +| local datetime | `%ldt` | the timezone offset is removed and value is formatter as ISO string without the timezone offset +| datetime | `%dt` | no timezone conversion is done and value is formatted as ISO string with timezone offset + +##### Reading + +| Type | Column Type | Comment +|--------------------|-------------|-------- +| local datetime | ❌ | cannot be auto-detected +| datetime | ❌ | cannot be auto-detected diff --git a/docs/default.md b/docs/default.md index 3ead54a5..128514df 100644 --- a/docs/default.md +++ b/docs/default.md @@ -6,15 +6,16 @@ Supported platforms: - **MySQL** via `mysqli` or `pdo_mysql` extension, - **Postgres** via `pgsql` or `pdo_pgsql` extension, -- **MS SQL Server** via `sqlsrv` or `pdo_sqlsrv` extension. +- **MS SQL Server** via `sqlsrv` or `pdo_sqlsrv` extension, +- **Sqlite** via `pdo_sqlite` extension. ### Connection The Connection instance is the main access point to the database. Connection's constructor accepts a configuration array. The possible keys depend on the specific driver; some configuration keys are shared for all drivers. To actual list of supported keys are enumerated in PhpDoc comment in driver's source code. -| Key | Description -| --- | --- | -| `driver` | driver name, use `mysqli`, `pgsql`, `sqlsrv`, `pdo_mysql`, `pdo_pgsql`, `pdo_sqlsrv` +| Key | Description +| --- | --- | +| `driver` | driver name, use `mysqli`, `pgsql`, `sqlsrv`, `pdo_mysql`, `pdo_pgsql`, `pdo_sqlsrv`, `pdo_sqlite` | `host` | database server name | `username` | username for authentication | `password` | password for authentication diff --git a/readme.md b/readme.md index 08e521f8..7a5e8c9e 100644 --- a/readme.md +++ b/readme.md @@ -12,6 +12,7 @@ Supported platforms: - **MySQL** via `mysqli` or `pdo_mysql` extension, - **PostgreSQL** via `pgsql` or `pdo_pgsql` extension, - **MS SQL Server** via `sqlsrv` or `pdo_sqlsrv` extension. +- **Sqlite** via `pdo_sqlite` extension. Integrations: - Symfony Bundle diff --git a/src/Drivers/PdoSqlite/PdoSqliteDriver.php b/src/Drivers/PdoSqlite/PdoSqliteDriver.php new file mode 100644 index 00000000..715d7168 --- /dev/null +++ b/src/Drivers/PdoSqlite/PdoSqliteDriver.php @@ -0,0 +1,112 @@ +connectPdo($dsn, '', '', [], $logger); + $this->resultNormalizerFactory = new PdoSqliteResultNormalizerFactory(); + + $this->connectionTz = new DateTimeZone('UTC'); + $this->loggedQuery('PRAGMA foreign_keys = 1'); + } + + + public function createPlatform(IConnection $connection): IPlatform + { + return new SqlitePlatform($connection); + } + + + public function getLastInsertedId(?string $sequenceName = null) + { + return $this->query('SELECT last_insert_rowid()')->fetchField(); + } + + + public function setTransactionIsolationLevel(int $level): void + { + static $levels = [ + Connection::TRANSACTION_READ_UNCOMMITTED => 'READ UNCOMMITTED', + Connection::TRANSACTION_READ_COMMITTED => 'READ COMMITTED', + Connection::TRANSACTION_REPEATABLE_READ => 'REPEATABLE READ', + Connection::TRANSACTION_SERIALIZABLE => 'SERIALIZABLE', + ]; + if (!isset($levels[$level])) { + throw new NotSupportedException("Unsupported transaction level $level"); + } + $this->loggedQuery("SET SESSION TRANSACTION ISOLATION LEVEL {$levels[$level]}"); + } + + + protected function createResultAdapter(PDOStatement $statement): IResultAdapter + { + return (new PdoSqliteResultAdapter($statement, $this->resultNormalizerFactory))->toBuffered(); + } + + + protected function convertIdentifierToSql(string $identifier): string + { + return '[' . strtr($identifier, '[]', ' ') . ']'; + } + + + protected function createException(string $error, int $errorNo, string $sqlState, ?string $query = null): Exception + { + if (stripos($error, 'FOREIGN KEY constraint failed') !== false) { + return new ForeignKeyConstraintViolationException($error, $errorNo, '', null, $query); + } elseif ( + strpos($error, 'must be unique') !== false + || strpos($error, 'is not unique') !== false + || strpos($error, 'are not unique') !== false + || strpos($error, 'UNIQUE constraint failed') !== false + ) { + return new UniqueConstraintViolationException($error, $errorNo, '', null, $query); + } elseif ( + strpos($error, 'may not be NULL') !== false + || strpos($error, 'NOT NULL constraint failed') !== false + ) { + return new NotNullConstraintViolationException($error, $errorNo, '', null, $query); + } elseif (stripos($error, 'unable to open database') !== false) { + return new ConnectionException($error, $errorNo, ''); + } elseif ($query !== null) { + return new QueryException($error, $errorNo, '', null, $query); + } else { + return new DriverException($error, $errorNo, ''); + } + } +} diff --git a/src/Drivers/PdoSqlite/PdoSqliteResultAdapter.php b/src/Drivers/PdoSqlite/PdoSqliteResultAdapter.php new file mode 100644 index 00000000..3bbcdd59 --- /dev/null +++ b/src/Drivers/PdoSqlite/PdoSqliteResultAdapter.php @@ -0,0 +1,100 @@ + */ + private $statement; + + /** @var bool */ + private $beforeFirstFetch = true; + + /** @var PdoSqliteResultNormalizerFactory */ + private $normalizerFactory; + + + /** + * @param PDOStatement $statement + */ + public function __construct(PDOStatement $statement, PdoSqliteResultNormalizerFactory $normalizerFactory) + { + $this->statement = $statement; + $this->normalizerFactory = $normalizerFactory; + } + + + public function toBuffered(): IResultAdapter + { + return new FullyBufferedResultAdapter($this); + } + + + public function toUnbuffered(): IResultAdapter + { + return $this; + } + + + public function seek(int $index): void + { + if ($index === 0 && $this->beforeFirstFetch) { + return; + } + + throw new NotSupportedException("PDO does not support rewinding or seeking. Use Result::buffered() before first consume of the result."); + } + + + public function fetch(): ?array + { + $this->beforeFirstFetch = false; + $fetched = $this->statement->fetch(PDO::FETCH_ASSOC); + return $fetched !== false ? $fetched : null; + } + + + public function getRowsCount(): int + { + return $this->statement->rowCount(); + } + + + public function getTypes(): array + { + $types = []; + $count = $this->statement->columnCount(); + + for ($i = 0; $i < $count; $i++) { + $field = $this->statement->getColumnMeta($i); + if ($field === false) { // @phpstan-ignore-line + // Sqlite does not return meta for special queries (PRAGMA, etc.) + continue; + } + + $type = strtolower($field['sqlite:decl_type'] ?? $field['native_type'] ?? ''); + $types[(string) $field['name']] = $type; + } + + return $types; + } + + + public function getNormalizers(): array + { + return $this->normalizerFactory->resolve($this->getTypes()); + } +} diff --git a/src/Drivers/PdoSqlite/PdoSqliteResultNormalizerFactory.php b/src/Drivers/PdoSqlite/PdoSqliteResultNormalizerFactory.php new file mode 100644 index 00000000..5bd87856 --- /dev/null +++ b/src/Drivers/PdoSqlite/PdoSqliteResultNormalizerFactory.php @@ -0,0 +1,78 @@ +intNormalizer = static function ($value): ?int { + if ($value === null) return null; + return (int) $value; + }; + + $this->floatNormalizer = static function ($value): ?float { + if ($value === null) return null; + return (float) $value; + }; + } + + + /** + * @param array $types + * @return array + */ + public function resolve(array $types): array + { + static $ints = [ + 'int' => true, + 'integer' => true, + 'tinyint' => true, + 'smallint' => true, + 'mediumint' => true, + 'bigint' => true, + 'unsigned big int' => true, + 'int2' => true, + 'int8' => true, + ]; + + static $floats = [ + 'real' => self::TYPE_FLOAT, + 'double' => self::TYPE_FLOAT, + 'double precision' => self::TYPE_FLOAT, + 'float' => self::TYPE_FLOAT, + 'numeric' => self::TYPE_FLOAT, + 'decimal' => self::TYPE_FLOAT, + ]; + + $normalizers = []; + foreach ($types as $column => $type) { + if ($type === 'text' || $type === 'varchar') { + continue; // optimization + } elseif ($type === 'integer') { + $normalizers[$column] = $this->intNormalizer; + } elseif ($type === 'real') { + $normalizers[$column] = $this->floatNormalizer; + } + } + return $normalizers; + } +} diff --git a/src/Platforms/IPlatform.php b/src/Platforms/IPlatform.php index 293530cc..0ecc5960 100644 --- a/src/Platforms/IPlatform.php +++ b/src/Platforms/IPlatform.php @@ -15,6 +15,7 @@ interface IPlatform public const SUPPORT_MULTI_COLUMN_IN = 1; public const SUPPORT_QUERY_EXPLAIN = 2; public const SUPPORT_WHITESPACE_EXPLAIN = 3; + public const SUPPORT_INSERT_DEFAULT_KEYWORD = 4; /** diff --git a/src/Platforms/SqlitePlatform.php b/src/Platforms/SqlitePlatform.php new file mode 100644 index 00000000..7daf47f3 --- /dev/null +++ b/src/Platforms/SqlitePlatform.php @@ -0,0 +1,208 @@ +connection = $connection; + $this->driver = $connection->getDriver(); + } + + + public function getName(): string + { + return self::NAME; + } + + + public function getTables(?string $schema = null): array + { + $result = $this->connection->query(/** @lang SQLite */ " + SELECT name, type FROM sqlite_master WHERE type IN ('table', 'view') AND name NOT LIKE 'sqlite_%' + UNION ALL + SELECT name, type FROM sqlite_temp_master WHERE type IN ('table', 'view') AND name NOT LIKE 'sqlite_%' + "); + + $tables = []; + foreach ($result as $row) { + $table = new Table(); + $table->name = $row->name; + $table->schema = ''; + $table->isView = $row->type === 'view'; + $tables[$table->getNameFqn()] = $table; + } + return $tables; + } + + + public function getColumns(string $table): array + { + $raw = $this->connection->query(/** @lang SQLite */ " + SELECT sql FROM sqlite_master WHERE type = 'table' AND name = %s + UNION ALL + SELECT sql FROM sqlite_temp_master WHERE type = 'table' AND name = %s + ", $table, $table)->fetchField(); + + $result = $this->connection->query(/** @lang SQLite */ " + PRAGMA table_info(%table) + ", $table); + + $columns = []; + foreach ($result as $row) { + $column = $row->name; + $pattern = "~(\"$column\"|`$column`|\\[$column\\]|$column)\\s+[^,]+\\s+PRIMARY\\s+KEY\\s+AUTOINCREMENT~Ui"; + + $type = explode('(', $row->type); + $column = new Column(); + $column->name = (string) $row->name; + $column->type = $type[0]; + $column->size = (int) ($type[1] ?? 0); + $column->default = $row->dflt_value; + $column->isPrimary = $row->pk === 1; + $column->isAutoincrement = preg_match($pattern, (string) $raw) === 1; + $column->isUnsigned = false; + $column->isNullable = $row->notnull === 0; + $columns[$column->name] = $column; + } + return $columns; + } + + + public function getForeignKeys(string $table): array + { + $result = $this->connection->query(/** @lang SQLite */ " + PRAGMA foreign_key_list(%table) + ", $table); + + $foreignKeys = []; + foreach ($result as $row) { + $foreignKey = new ForeignKey(); + $foreignKey->name = (string) $row->id; + $foreignKey->schema = ''; + $foreignKey->column = $row->from; + $foreignKey->refTable = $row->table; + $foreignKey->refTableSchema = ''; + $foreignKey->refColumn = $row->to; + $foreignKeys[$foreignKey->getNameFqn()] = $foreignKey; + } + return $foreignKeys; + } + + + public function getPrimarySequenceName(string $table): ?string + { + return null; + } + + + public function formatString(string $value): string + { + return $this->driver->convertStringToSql($value); + } + + + public function formatStringLike(string $value, int $mode) + { + $value = addcslashes($this->formatString($value), '\\%_'); + return ($mode <= 0 ? "'%" : "'") . $value . ($mode >= 0 ? "%'" : "'") . " ESCAPE '\\'"; + } + + + public function formatJson($value): string + { + $encoded = JsonHelper::safeEncode($value); + return $this->formatString($encoded); + } + + + public function formatBool(bool $value): string + { + return $value ? '1' : '0'; + } + + + public function formatIdentifier(string $value): string + { + return '[' . strtr($value, '[]', ' ') . ']'; + } + + + public function formatDateTime(DateTimeInterface $value): string + { + $value = DateTimeHelper::convertToTimezone($value, $this->driver->getConnectionTimeZone()); + return strval($value->format('U') * 1000 + intval($value->format('u'))); + } + + + public function formatLocalDateTime(DateTimeInterface $value): string + { + return "'" . $value->format('Y-m-d H:i:s.u') . "'"; + } + + + public function formatDateInterval(DateInterval $value): string + { + return $value->format('P%yY%mM%dDT%hH%iM%sS'); + } + + + public function formatBlob(string $value): string + { + return "X'" . bin2hex($value) . "'"; + } + + + public function formatLimitOffset(?int $limit, ?int $offset): string + { + if ($limit === null && $offset === null) { + return ''; + } elseif ($limit === null && $offset !== null) { + return 'LIMIT -1 OFFSET ' . $offset; + } elseif ($limit !== null && $offset === null) { + return "LIMIT $limit"; + } else { + return "LIMIT $limit OFFSET $offset"; + } + } + + + public function isSupported(int $feature): bool + { + static $supported = [ + self::SUPPORT_QUERY_EXPLAIN => true, + ]; + return isset($supported[$feature]); + } +} diff --git a/src/Result/FullyBufferedResultAdapter.php b/src/Result/FullyBufferedResultAdapter.php new file mode 100644 index 00000000..6af38225 --- /dev/null +++ b/src/Result/FullyBufferedResultAdapter.php @@ -0,0 +1,43 @@ +|null */ + protected $types = null; + + + public function getTypes(): array + { + $this->getData(); + assert($this->types !== null); + return $this->types; + } + + + public function getRowsCount(): int + { + return $this->getData()->count(); + } + + + protected function fetchData(): ArrayIterator + { + $rows = []; + while (($row = $this->adapter->fetch()) !== null) { + if ($this->types === null) { + $this->types = $this->adapter->getTypes(); + } + $rows[] = $row; + } + return new ArrayIterator($rows); + } +} diff --git a/tests/cases/integration/connection.sqlite.phpt b/tests/cases/integration/connection.sqlite.phpt new file mode 100644 index 00000000..0d542ae4 --- /dev/null +++ b/tests/cases/integration/connection.sqlite.phpt @@ -0,0 +1,54 @@ +connection->query('CREATE TEMP TABLE %table (id INT PRIMARY KEY)', $tableName); + Assert::same( + 1, + $this->connection->query( + "SELECT COUNT(*) FROM sqlite_temp_master WHERE type = 'table' AND name = %s", + $tableName + )->fetchField() + ); + + $this->connection->reconnect(); + + Assert::same( + 0, + $this->connection->query( + "SELECT COUNT(*) FROM sqlite_temp_master WHERE type = 'table' AND name = %s", + $tableName + )->fetchField() + ); + } + + + public function testLastInsertId() + { + $this->initData($this->connection); + + $this->connection->query('INSERT INTO publishers %values', ['name' => 'FOO']); + Assert::same(2, $this->connection->getLastInsertedId()); + } +} + + +$test = new ConnectionSqliteTest(); +$test->run(); diff --git a/tests/cases/integration/datetime.sqlite.phpt b/tests/cases/integration/datetime.sqlite.phpt new file mode 100644 index 00000000..678baac9 --- /dev/null +++ b/tests/cases/integration/datetime.sqlite.phpt @@ -0,0 +1,119 @@ +createConnection(); + $this->lockConnection($connection); + + $connection->query(/** @lang GenericSQL */ ' + CREATE TEMP TABLE dates_write ( + a varchar, + b numeric + ); + '); + + $connection->query('INSERT INTO dates_write VALUES (%ldt, %dt)', + new DateTime('2015-01-01 12:00:00'), // local + new DateTime('2015-01-01 12:00:00') // 11:00 UTC + ); + + $result = $connection->query('SELECT * FROM dates_write'); + $result->setValueNormalization(false); + + $row = $result->fetch(); + Assert::same('2015-01-01 12:00:00.000000', $row->a); + Assert::same(strtotime('2015-01-01T11:00:00Z') * 1000, $row->b * 1); + + $connection->query('DELETE FROM dates_write'); + $connection->query('INSERT INTO dates_write VALUES (%ldt, %dt)', + new DateTime('2015-01-01 12:00:00'), // local + new DateTime('2015-01-01 12:00:00 Europe/Kiev') // 10:00 UTC, + ); + + $result = $connection->query('SELECT * FROM dates_write'); + $result->setValueNormalization(false); + + $row = $result->fetch(); + Assert::same('2015-01-01 12:00:00.000000', $row->a); + Assert::same(strtotime('2015-01-01T10:00:00Z') * 1000, $row->b * 1); + } + + + public function testReadStorage() + { + $connection = $this->createConnection(); + $this->lockConnection($connection); + + $connection->query('DROP TABLE IF EXISTS dates_read'); + $connection->query(' + CREATE TABLE dates_read ( + a datetime, + b timestamp + ); + '); + + $connection->query('INSERT INTO dates_read VALUES (%s, %s)', + '2015-01-01 12:00:00', // local + '2015-01-01 12:00:00' // 11:00 UTC + ); + + $result = $connection->query('SELECT * FROM dates_read'); + $result->setColumnType('a', Result::TYPE_LOCAL_DATETIME); + $result->setColumnType('b', Result::TYPE_DATETIME); + + $row = $result->fetch(); + Assert::type(DateTimeImmutable::class, $row->a); + Assert::type(DateTimeImmutable::class, $row->b); + Assert::same('2015-01-01T12:00:00+01:00', $row->a->format('c')); + Assert::same('2015-01-01T12:00:00+01:00', $row->b->format('c')); + } + + + public function testMicroseconds() + { + $connection = $this->createConnection(); + $this->lockConnection($connection); + + $connection->query('DROP TABLE IF EXISTS dates_micro'); + $connection->query(' + CREATE TABLE dates_micro ( + a datetime(6), + b timestamp(6) + ); + '); + + $now = new DateTime(); + $connection->query('INSERT INTO dates_micro %values', [ + 'a%ldt' => $now, + 'b%dt' => $now, + ]); + + $row = $connection->query('SELECT * FROM dates_micro')->fetch(); + Assert::same($now->format('u'), $row->a->format('u')); + Assert::same($now->format('u'), $row->b->format('u')); + } +} + + +$test = new DateTimeSqliteTest(); +$test->run(); diff --git a/tests/cases/integration/exceptions.phpt b/tests/cases/integration/exceptions.phpt index f547d246..b8ae7554 100644 --- a/tests/cases/integration/exceptions.phpt +++ b/tests/cases/integration/exceptions.phpt @@ -7,12 +7,16 @@ namespace NextrasTests\Dbal; + use Nextras\Dbal\Drivers\Exception\ConnectionException; use Nextras\Dbal\Drivers\Exception\ForeignKeyConstraintViolationException; use Nextras\Dbal\Drivers\Exception\NotNullConstraintViolationException; use Nextras\Dbal\Drivers\Exception\QueryException; use Nextras\Dbal\Drivers\Exception\UniqueConstraintViolationException; +use Nextras\Dbal\Drivers\PdoSqlite\PdoSqliteDriver; use Tester\Assert; +use Tester\Environment; + require_once __DIR__ . '/../../bootstrap.php'; @@ -22,6 +26,10 @@ class ExceptionsTest extends IntegrationTestCase public function testConnection() { + if ($this->connection->getDriver() instanceof PdoSqliteDriver) { + Environment::skip('Connection cannot fail because wrong configuration.'); + } + Assert::exception(function () { $connection = $this->createConnection(['database' => 'unknown']); $connection->connect(); diff --git a/tests/cases/integration/platform.format.sqlite.phpt b/tests/cases/integration/platform.format.sqlite.phpt new file mode 100644 index 00000000..fa00faa5 --- /dev/null +++ b/tests/cases/integration/platform.format.sqlite.phpt @@ -0,0 +1,69 @@ +connection->getPlatform(); + $this->connection->connect(); + + Assert::same('[foo]', $platform->formatIdentifier('foo')); + Assert::same('[foo].[bar]', $platform->formatIdentifier('foo.bar')); + Assert::same('[foo].[bar].[baz]', $platform->formatIdentifier('foo.bar.baz')); + } + + + public function testDateInterval() + { + Assert::exception(function () { + $interval1 = (new DateTime('2015-01-03 12:01:01'))->diff(new DateTime('2015-01-01 09:00:00')); + $this->connection->getPlatform()->formatDateInterval($interval1); + }, NotSupportedException::class); + } + + + public function testLike() + { + $c = $this->connection; + Assert::same(0, $c->query("SELECT CASE WHEN 'AAxBB' LIKE %_like_ THEN 1 ELSE 0 END", "A'B")->fetchField()); + Assert::same(1, $c->query("SELECT CASE WHEN 'AA''BB' LIKE %_like_ THEN 1 ELSE 0 END", "A'B")->fetchField()); + + Assert::same(0, $c->query("SELECT CASE WHEN 'AAxBB' LIKE %_like_ THEN 1 ELSE 0 END", "A\\B")->fetchField()); + Assert::same(1, $c->query("SELECT CASE WHEN 'AA\\BB' LIKE %_like_ THEN 1 ELSE 0 END", "A\\B")->fetchField()); + + Assert::same(0, $c->query("SELECT CASE WHEN 'AAxBB' LIKE %_like_ THEN 1 ELSE 0 END", "A%B")->fetchField()); + Assert::same(1, $c->query("SELECT CASE WHEN %raw LIKE %_like_ THEN 1 ELSE 0 END", "'AA%BB'", "A%B") + ->fetchField()); + + Assert::same(0, $c->query("SELECT CASE WHEN 'AAxBB' LIKE %_like_ THEN 1 ELSE 0 END", "A_B")->fetchField()); + Assert::same(1, $c->query("SELECT CASE WHEN 'AA_BB' LIKE %_like_ THEN 1 ELSE 0 END", "A_B")->fetchField()); + + Assert::same(0, $c->query("SELECT CASE WHEN 'AAxBB' LIKE %_like THEN 1 ELSE 0 END", "AAAxBB")->fetchField()); + Assert::same(0, $c->query("SELECT CASE WHEN 'AAxBB' LIKE %_like THEN 1 ELSE 0 END", "AxB")->fetchField()); + Assert::same(1, $c->query("SELECT CASE WHEN 'AAxBB' LIKE %_like THEN 1 ELSE 0 END", "AxBB")->fetchField()); + + Assert::same(0, $c->query("SELECT CASE WHEN 'AAxBB' LIKE %like_ THEN 1 ELSE 0 END", "AAxBBB")->fetchField()); + Assert::same(0, $c->query("SELECT CASE WHEN 'AAxBB' LIKE %like_ THEN 1 ELSE 0 END", "AxB")->fetchField()); + Assert::same(1, $c->query("SELECT CASE WHEN 'AAxBB' LIKE %like_ THEN 1 ELSE 0 END", "AAxB")->fetchField()); + } +} + + +$test = new PlatformFormatSqlServerTest(); +$test->run(); diff --git a/tests/cases/integration/platform.sqlite.phpt b/tests/cases/integration/platform.sqlite.phpt new file mode 100644 index 00000000..c32046cd --- /dev/null +++ b/tests/cases/integration/platform.sqlite.phpt @@ -0,0 +1,220 @@ +connection->getPlatform()->getTables(); + + Assert::true(isset($tables["books"])); + Assert::same('books', $tables["books"]->name); + Assert::same(false, $tables["books"]->isView); + } + + + public function testColumns() + { + $columns = $this->connection->getPlatform()->getColumns('books'); + $columns = array_map(function ($column) { + return (array) $column; + }, $columns); + + Assert::same([ + 'id' => [ + 'name' => 'id', + 'type' => 'INTEGER', + 'size' => 0, + 'default' => null, + 'isPrimary' => true, + 'isAutoincrement' => true, + 'isUnsigned' => false, + 'isNullable' => false, + 'meta' => [], + ], + 'author_id' => [ + 'name' => 'author_id', + 'type' => 'int', + 'size' => 0, + 'default' => null, + 'isPrimary' => false, + 'isAutoincrement' => false, + 'isUnsigned' => false, + 'isNullable' => false, + 'meta' => [], + ], + 'translator_id' => [ + 'name' => 'translator_id', + 'type' => 'int', + 'size' => 0, + 'default' => null, + 'isPrimary' => false, + 'isAutoincrement' => false, + 'isUnsigned' => false, + 'isNullable' => true, + 'meta' => [], + ], + 'title' => [ + 'name' => 'title', + 'type' => 'varchar', + 'size' => 50, + 'default' => null, + 'isPrimary' => false, + 'isAutoincrement' => false, + 'isUnsigned' => false, + 'isNullable' => false, + 'meta' => [], + ], + 'publisher_id' => [ + 'name' => 'publisher_id', + 'type' => 'int', + 'size' => 0, + 'default' => null, + 'isPrimary' => false, + 'isAutoincrement' => false, + 'isUnsigned' => false, + 'isNullable' => false, + 'meta' => [], + ], + 'ean_id' => [ + 'name' => 'ean_id', + 'type' => 'int', + 'size' => 0, + 'default' => null, + 'isPrimary' => false, + 'isAutoincrement' => false, + 'isUnsigned' => false, + 'isNullable' => true, + 'meta' => [], + ], + ], $columns); + + $schemaColumns = $this->connection->getPlatform()->getColumns('authors'); + $schemaColumns = array_map(function ($column) { + return (array) $column; + }, $schemaColumns); + + Assert::same([ + 'id' => [ + 'name' => 'id', + 'type' => 'INTEGER', + 'size' => 0, + 'default' => null, + 'isPrimary' => true, + 'isAutoincrement' => true, + 'isUnsigned' => false, + 'isNullable' => false, + 'meta' => [], + ], + 'name' => [ + 'name' => 'name', + 'type' => 'varchar', + 'size' => 50, + 'default' => null, + 'isPrimary' => false, + 'isAutoincrement' => false, + 'isUnsigned' => false, + 'isNullable' => false, + 'meta' => [], + ], + 'web' => [ + 'name' => 'web', + 'type' => 'varchar', + 'size' => 100, + 'default' => null, + 'isPrimary' => false, + 'isAutoincrement' => false, + 'isUnsigned' => false, + 'isNullable' => false, + 'meta' => [], + ], + 'born' => [ + 'name' => 'born', + 'type' => 'date', + 'size' => 0, + 'default' => 'NULL', + 'isPrimary' => false, + 'isAutoincrement' => false, + 'isUnsigned' => false, + 'isNullable' => true, + 'meta' => [], + ], + ], $schemaColumns); + } + + + public function testForeignKeys() + { + $this->lockConnection($this->connection); + + $keys = $this->connection->getPlatform()->getForeignKeys('books'); + $keys = array_map(function ($key) { + return (array) $key; + }, $keys); + + Assert::same([ + [ + 'name' => '0', + 'schema' => '', + 'column' => 'ean_id', + 'refTable' => 'eans', + 'refTableSchema' => '', + 'refColumn' => 'id', + ], + [ + 'name' => '1', + 'schema' => '', + 'column' => 'publisher_id', + 'refTable' => 'publishers', + 'refTableSchema' => '', + 'refColumn' => 'id', + ], + [ + 'name' => '2', + 'schema' => '', + 'column' => 'translator_id', + 'refTable' => 'authors', + 'refTableSchema' => '', + 'refColumn' => 'id', + ], + [ + 'name' => '3', + 'schema' => '', + 'column' => 'author_id', + 'refTable' => 'authors', + 'refTableSchema' => '', + 'refColumn' => 'id', + ], + ], $keys); + } + + + public function testPrimarySequence() + { + Assert::same(null, $this->connection->getPlatform()->getPrimarySequenceName('books')); + } + + + public function testName() + { + Assert::same('sqlite', $this->connection->getPlatform()->getName()); + } +} + + +$test = new PlatformSqliteTest(); +$test->run(); diff --git a/tests/cases/integration/types.sqlite.phpt b/tests/cases/integration/types.sqlite.phpt new file mode 100644 index 00000000..ded22623 --- /dev/null +++ b/tests/cases/integration/types.sqlite.phpt @@ -0,0 +1,112 @@ +connection->query(" + SELECT + -- datetimes + CAST('2017-02-22' AS date) as dt1, + CAST('2017-02-22 16:40:00' AS datetime) as dt2, + CAST('2017-02-22 16:40:00.003' AS datetime2) as dt3, + CAST('2017-02-22 16:40:00' AS datetimeoffset) as dt4, + CAST('2017-02-22 16:40:00' AS smalldatetime) as dt5, + CAST('16:40' AS time) as dt6, + + -- int + CAST('1' AS tinyint) AS integer1, + CAST('1' AS smallint) AS integer2, + CAST('1' AS int) AS integer3, + CAST('1' AS bigint) AS integer4, + + -- float + CAST('12' as float(2)) AS float1, + CAST('12' as real) AS real1, + + CAST('12.04' as numeric(5,2)) AS numeric1, + CAST('12' as numeric(5,2)) AS numeric2, + CAST('12' as numeric) AS numeric3, + + CAST('12.04' as decimal(5,2)) AS decimal1, + CAST('12' as decimal(5,2)) AS decimal2, + CAST('12' as decimal) AS decimal3, + + CAST('12' as money) AS money1, + CAST('12' as smallmoney) AS smallmoney1, + + -- boolean + CAST(1 as bit) as boolean + "); + + $row = $result->fetch(); + Assert::type(DateTimeImmutable::class, $row->dt1); + Assert::type(DateTimeImmutable::class, $row->dt2); + Assert::type(DateTimeImmutable::class, $row->dt3); + Assert::type(DateTimeImmutable::class, $row->dt4); + Assert::type(DateTimeImmutable::class, $row->dt5); + Assert::type(DateTimeImmutable::class, $row->dt6); + + Assert::same(1, $row->integer1); + Assert::same(1, $row->integer2); + Assert::same(1, $row->integer3); + Assert::same(1, $row->integer4); + + Assert::same(12.0, $row->float1); + Assert::same(12.0, $row->real1); + + Assert::same(12.04, $row->numeric1); + Assert::same(12.00, $row->numeric2); + Assert::same(12, $row->numeric3); + + Assert::same(12.00, $row->money1); + Assert::same(12.00, $row->smallmoney1); + + Assert::same(true, $row->boolean); + } + +// +// public function testWrite() +// { +// $this->lockConnection($this->connection); +// +// $this->connection->query('DROP TABLE IF EXISTS [types_write]'); +// $this->connection->query(" +// CREATE TABLE [types_write] ( +// [blob] varbinary(1000), +// [json] varchar(500), +// [bool] bit +// ); +// "); +// +// $file = file_get_contents(__DIR__ . '/nextras.png'); +// $this->connection->query('INSERT INTO [types_write] %values', +// [ +// 'blob%blob' => $file, +// 'json%json' => [1, '2', true, null], +// 'bool%b' => true, +// ]); +// $row = $this->connection->query('SELECT * FROM [types_write]')->fetch(); +// Assert::same($file, $row->blob); +// Assert::same('[1,"2",true,null]', $row->json); +// Assert::same(true, $row->bool); +// } +} + + +$test = new TypesSqliteTest(); +$test->run(); diff --git a/tests/data/sqlite-data.sql b/tests/data/sqlite-data.sql new file mode 100644 index 00000000..c1dc97c7 --- /dev/null +++ b/tests/data/sqlite-data.sql @@ -0,0 +1,32 @@ +-- SET FOREIGN_KEY_CHECKS = 0; +DELETE FROM books_x_tags; +DELETE FROM books; +DELETE FROM tags; +DELETE FROM authors; +DELETE FROM publishers; +DELETE FROM tag_followers; +-- SET FOREIGN_KEY_CHECKS = 1; + +INSERT INTO authors (id, name, web, born) VALUES (1, 'Writer 1', 'http://example.com/1', NULL); +INSERT INTO authors (id, name, web, born) VALUES (2, 'Writer 2', 'http://example.com/2', NULL); + +INSERT INTO publishers (id, name) VALUES (1, 'Nextras publisher'); + +INSERT INTO tags (id, name) VALUES (1, 'Tag 1'); +INSERT INTO tags (id, name) VALUES (2, 'Tag 2'); +INSERT INTO tags (id, name) VALUES (3, 'Tag 3'); + +INSERT INTO books (id, author_id, translator_id, title, publisher_id) VALUES (1, 1, 1, 'Book 1', 1); +INSERT INTO books (id, author_id, translator_id, title, publisher_id) VALUES (2, 1, NULL, 'Book 2', 1); +INSERT INTO books (id, author_id, translator_id, title, publisher_id) VALUES (3, 2, 2, 'Book 3', 1); +INSERT INTO books (id, author_id, translator_id, title, publisher_id) VALUES (4, 2, 2, 'Book 4', 1); + +INSERT INTO books_x_tags (book_id, tag_id) VALUES (1, 1); +INSERT INTO books_x_tags (book_id, tag_id) VALUES (1, 2); +INSERT INTO books_x_tags (book_id, tag_id) VALUES (2, 2); +INSERT INTO books_x_tags (book_id, tag_id) VALUES (2, 3); +INSERT INTO books_x_tags (book_id, tag_id) VALUES (3, 3); + +INSERT INTO tag_followers (tag_id, author_id, created_at) VALUES (1, 1, '2014-01-01 00:10:00'); +INSERT INTO tag_followers (tag_id, author_id, created_at) VALUES (3, 1, '2014-01-01 00:10:00'); +INSERT INTO tag_followers (tag_id, author_id, created_at) VALUES (2, 2, '2014-01-01 00:10:00'); diff --git a/tests/data/sqlite-init.sql b/tests/data/sqlite-init.sql new file mode 100644 index 00000000..57ae3e8b --- /dev/null +++ b/tests/data/sqlite-init.sql @@ -0,0 +1,62 @@ +CREATE TABLE authors ( + id INTEGER NOT NULL PRIMARY KEY AUTOINCREMENT, + name varchar(50) NOT NULL, + web varchar(100) NOT NULL, + born date DEFAULT NULL +); + + +CREATE TABLE publishers ( + id INTEGER NOT NULL PRIMARY KEY AUTOINCREMENT, + name varchar(50) NOT NULL +); + +CREATE UNIQUE INDEX publishes_name ON publishers (name); + +CREATE TABLE tags ( + id INTEGER NOT NULL PRIMARY KEY AUTOINCREMENT, + name varchar(50) NOT NULL +); + +CREATE TABLE eans ( + id INTEGER NOT NULL PRIMARY KEY AUTOINCREMENT, + code varchar(50) NOT NULL +); + +CREATE TABLE books ( + id INTEGER NOT NULL PRIMARY KEY AUTOINCREMENT, + author_id int NOT NULL, + translator_id int, + title varchar(50) NOT NULL, + publisher_id int NOT NULL, + ean_id int, + CONSTRAINT books_authors FOREIGN KEY (author_id) REFERENCES authors (id), + CONSTRAINT books_translator FOREIGN KEY (translator_id) REFERENCES authors (id), + CONSTRAINT books_publisher FOREIGN KEY (publisher_id) REFERENCES publishers (id), + CONSTRAINT books_ean FOREIGN KEY (ean_id) REFERENCES eans (id) +); + +CREATE INDEX book_title ON books (title); + +CREATE VIEW my_books AS SELECT * FROM books WHERE author_id = 1; + +CREATE TABLE books_x_tags ( + book_id int NOT NULL, + tag_id int NOT NULL, + PRIMARY KEY (book_id, tag_id), + CONSTRAINT books_x_tags_tag FOREIGN KEY (tag_id) REFERENCES tags (id), + CONSTRAINT books_x_tags_book FOREIGN KEY (book_id) REFERENCES books (id) ON DELETE CASCADE +); + +CREATE TABLE tag_followers ( + tag_id int NOT NULL, + author_id int NOT NULL, + created_at datetime NOT NULL, + PRIMARY KEY (tag_id, author_id), + CONSTRAINT tag_followers_tag FOREIGN KEY (tag_id) REFERENCES tags (id) ON DELETE CASCADE ON UPDATE CASCADE, + CONSTRAINT tag_followers_author FOREIGN KEY (author_id) REFERENCES authors (id) ON DELETE CASCADE ON UPDATE CASCADE +); + +CREATE TABLE table_with_defaults ( + name VARCHAR(255) DEFAULT 'Jon Snow' +); diff --git a/tests/data/sqlite-reset.php b/tests/data/sqlite-reset.php new file mode 100644 index 00000000..d43914a1 --- /dev/null +++ b/tests/data/sqlite-reset.php @@ -0,0 +1,11 @@ +disconnect(); + @unlink($config['filename']); + $connection->connect(); +}; diff --git a/tests/databases.sample.ini b/tests/databases.sample.ini index de32dbeb..ffed5511 100644 --- a/tests/databases.sample.ini +++ b/tests/databases.sample.ini @@ -21,3 +21,7 @@ database = nextras_dbal_test username = postgres password = postgres port = 5432 + +[sqlite] +driver = pdo_sqlite +filename = ":memory:" diff --git a/tests/inc/IntegrationTestCase.php b/tests/inc/IntegrationTestCase.php index a08c9e0a..6b1bd433 100644 --- a/tests/inc/IntegrationTestCase.php +++ b/tests/inc/IntegrationTestCase.php @@ -39,6 +39,11 @@ protected function createConnection($params = []) 'password' => NULL, 'searchPath' => ['public'], ], Environment::loadData(), $params); + + if (isset($options['filename']) && $options['filename'] !== ':memory:') { + $options['filename'] = __DIR__ . '/../temp/' . $options['filename']; + } + return new Connection($options); } diff --git a/tests/inc/setup.php b/tests/inc/setup.php index 944257ea..0ef2a07f 100644 --- a/tests/inc/setup.php +++ b/tests/inc/setup.php @@ -27,6 +27,10 @@ $processed[$key] = true; echo "[setup] Bootstrapping '{$name}' structure.\n"; + if (isset($configDatabase['filename']) && $configDatabase['filename'] !== ':memory:') { + $configDatabase['filename'] = __DIR__ . '/../temp/' . $configDatabase['filename']; + } + $connection = new Connection($configDatabase); $platform = $connection->getPlatform()->getName(); $resetFunction = require __DIR__ . "/../data/{$platform}-reset.php";