diff --git a/README.md b/README.md index 3c3deb3..316519b 100644 --- a/README.md +++ b/README.md @@ -18,8 +18,7 @@ Documentation is at [docs/guide/README.md](docs/guide/README.md). [![Latest Stable Version](https://poser.pugx.org/yiisoft/db-oracle/v/stable.png)](https://packagist.org/packages/yiisoft/db-oracle) [![Total Downloads](https://poser.pugx.org/yiisoft/db-oracle/downloads.png)](https://packagist.org/packages/yiisoft/db-oracle) [![Build status](https://github.com/yiisoft/db-oracle/workflows/build/badge.svg)](https://github.com/yiisoft/db-oracle/actions?query=workflow%3Abuild) -[![Scrutinizer Code Quality](https://scrutinizer-ci.com/g/yiisoft/db-oracle/badges/quality-score.png?b=master)](https://scrutinizer-ci.com/g/yiisoft/db-oracle/?branch=master) -[![Code Coverage](https://scrutinizer-ci.com/g/yiisoft/db-oracle/badges/coverage.png?b=master)](https://scrutinizer-ci.com/g/yiisoft/db-oracle/?branch=master) +[![codecov](https://codecov.io/gh/yiisoft/db-oracle/branch/master/graph/badge.svg?token=XGJAFXVHSH)](https://codecov.io/gh/yiisoft/db-oracle) [![Mutation testing badge](https://img.shields.io/endpoint?style=flat&url=https%3A%2F%2Fbadge-api.stryker-mutator.io%2Fgithub.com%2Fyiisoft%2Fdb-oracle%2Fmaster)](https://dashboard.stryker-mutator.io/reports/github.com/yiisoft/db-oracle/master) [![static analysis](https://github.com/yiisoft/db-oracle/workflows/static%20analysis/badge.svg)](https://github.com/yiisoft/db-oracle/actions?query=workflow%3A%22static+analysis%22) [![type-coverage](https://shepherd.dev/github/yiisoft/db-oracle/coverage.svg)](https://shepherd.dev/github/yiisoft/db-oracle) diff --git a/composer.json b/composer.json index abe8d6e..7633648 100644 --- a/composer.json +++ b/composer.json @@ -18,17 +18,15 @@ "minimum-stability": "dev", "require": { "ext-pdo": "*", - "php": "^7.4|^8.0", + "php": "^8.0", "yiisoft/arrays": "^2.0", "yiisoft/db": "dev-dev", "yiisoft/strings": "^2.0" }, "require-dev": { "phpunit/phpunit": "^9.5", - "roave/infection-static-analysis-plugin": "^1.16", - "spatie/phpunit-watcher": "^1.23", - "vimeo/psalm": "^4.18", - "yiisoft/active-record": "dev-master", + "roave/infection-static-analysis-plugin": "^1.6", + "vimeo/psalm": "^4.2", "yiisoft/aliases": "^1.1|^2.0", "yiisoft/cache": "^1.0", "yiisoft/log": "^1.0" @@ -49,11 +47,11 @@ } }, "config": { - "sort-packages": true + "sort-packages": true, + "allow-plugins": { + "composer/package-versions-deprecated": true, + "infection/extension-installer": true + } }, - "prefer-stable": true, - "scripts": { - "test": "phpunit --testdox --no-interaction", - "test-watch": "phpunit-watcher watch" - } + "prefer-stable": true } diff --git a/src/ColumnSchemaBuilder.php b/src/ColumnSchemaBuilder.php index a43888a..bf33f15 100644 --- a/src/ColumnSchemaBuilder.php +++ b/src/ColumnSchemaBuilder.php @@ -28,16 +28,11 @@ protected function buildUnsignedString(): string */ public function __toString(): string { - switch ($this->getTypeCategory()) { - case self::CATEGORY_PK: - $format = '{type}{length}{check}{append}'; - break; - case self::CATEGORY_NUMERIC: - $format = '{type}{length}{unsigned}{default}{notnull}{check}{append}'; - break; - default: - $format = '{type}{length}{default}{notnull}{check}{append}'; - } + $format = match ($this->getTypeCategory()) { + self::CATEGORY_PK => '{type}{length}{check}{append}', + self::CATEGORY_NUMERIC => '{type}{length}{unsigned}{default}{notnull}{check}{append}', + default => '{type}{length}{default}{notnull}{check}{append}', + }; return $this->buildCompleteString($format); } diff --git a/src/Conditions/InConditionBuilder.php b/src/Conditions/InConditionBuilder.php index 1e23707..1781c6b 100644 --- a/src/Conditions/InConditionBuilder.php +++ b/src/Conditions/InConditionBuilder.php @@ -7,9 +7,15 @@ use Yiisoft\Db\Expression\ExpressionInterface; use Yiisoft\Db\Query\Conditions\InCondition; use Yiisoft\Db\Query\Conditions\InConditionBuilder as AbstractInConditionBuilder; +use Yiisoft\Db\Query\QueryBuilderInterface; final class InConditionBuilder extends AbstractInConditionBuilder { + public function __construct(private QueryBuilderInterface $queryBuilder) + { + parent::__construct($queryBuilder); + } + /** * Method builds the raw SQL from the $expression that will not be additionally * escaped or quoted. @@ -23,6 +29,7 @@ public function build(ExpressionInterface $expression, array &$params = []): str { /** @var Incondition $expression */ $splitCondition = $this->splitCondition($expression, $params); + if ($splitCondition !== null) { return $splitCondition; } @@ -51,14 +58,17 @@ protected function splitCondition(InCondition $condition, &$params) $maxParameters = 1000; $count = count($values); + if ($count <= $maxParameters) { return null; } $slices = []; + for ($i = 0; $i < $count; $i += $maxParameters) { $slices[] = $this->queryBuilder->createConditionFromArray([$operator, $column, array_slice($values, $i, $maxParameters)]); } + array_unshift($slices, ($operator === 'IN') ? 'OR' : 'AND'); return $this->queryBuilder->buildCondition($slices, $params); diff --git a/src/Conditions/LikeConditionBuilder.php b/src/Conditions/LikeConditionBuilder.php index 5832a49..229a024 100644 --- a/src/Conditions/LikeConditionBuilder.php +++ b/src/Conditions/LikeConditionBuilder.php @@ -6,6 +6,7 @@ use Yiisoft\Db\Expression\ExpressionInterface; use Yiisoft\Db\Query\Conditions\LikeConditionBuilder as AbstractLikeConditionBuilder; +use Yiisoft\Db\Query\QueryBuilderInterface; final class LikeConditionBuilder extends AbstractLikeConditionBuilder { @@ -25,6 +26,11 @@ final class LikeConditionBuilder extends AbstractLikeConditionBuilder '!' => '!!', ]; + public function __construct(private QueryBuilderInterface $queryBuilder) + { + parent::__construct($queryBuilder); + } + public function build(ExpressionInterface $expression, array &$params = []): string { if (!isset($this->escapingReplacements['\\'])) { @@ -32,7 +38,7 @@ public function build(ExpressionInterface $expression, array &$params = []): str * Different pdo_oci8 versions may or may not implement PDO::quote(), so * Yiisoft\Db\Schema::quoteValue() may or may not quote \. */ - $this->escapingReplacements['\\'] = substr((string) $this->queryBuilder->getDb()->quoteValue('\\'), 1, -1); + $this->escapingReplacements['\\'] = substr((string) $this->queryBuilder->quoter()->quoteValue('\\'), 1, -1); } return parent::build($expression, $params); diff --git a/src/DDLQueryBuilder.php b/src/DDLQueryBuilder.php new file mode 100644 index 0000000..649c090 --- /dev/null +++ b/src/DDLQueryBuilder.php @@ -0,0 +1,30 @@ +queryBuilder->quoter()->quoteTableName($table) + . '.' + . $this->queryBuilder->quoter()->quoteColumnName($column) + . " IS ''"; + } + + public function dropCommentFromTable(string $table): string + { + return 'COMMENT ON TABLE ' . $this->queryBuilder->quoter()->quoteTableName($table) . " IS ''"; + } +} diff --git a/src/DMLQueryBuilder.php b/src/DMLQueryBuilder.php new file mode 100644 index 0000000..9b6bfb8 --- /dev/null +++ b/src/DMLQueryBuilder.php @@ -0,0 +1,125 @@ +queryBuilder->prepareUpsertColumns( + $table, + $insertColumns, + $updateColumns, + $constraints + ); + + if (empty($uniqueNames)) { + return $this->insert($table, $insertColumns, $params); + } + + if ($updateNames === []) { + /** there are no columns to update */ + $updateColumns = false; + } + + $onCondition = ['or']; + $quotedTableName = $this->queryBuilder->quoter()->quoteTableName($table); + + foreach ($constraints as $constraint) { + $constraintCondition = ['and']; + foreach ($constraint->getColumnNames() as $name) { + $quotedName = $this->queryBuilder->quoter()->quoteColumnName($name); + $constraintCondition[] = "$quotedTableName.$quotedName=\"EXCLUDED\".$quotedName"; + } + + $onCondition[] = $constraintCondition; + } + + $on = $this->queryBuilder->buildCondition($onCondition, $params); + [, $placeholders, $values, $params] = $this->queryBuilder->prepareInsertValues($table, $insertColumns, $params); + + if (!empty($placeholders)) { + $usingSelectValues = []; + foreach ($insertNames as $index => $name) { + $usingSelectValues[$name] = new Expression($placeholders[$index]); + } + + /** @psalm-suppress UndefinedInterfaceMethod */ + $usingSubQuery = $this->queryBuilder->query()->select($usingSelectValues)->from('DUAL'); + [$usingValues, $params] = $this->queryBuilder->build($usingSubQuery, $params); + } + + $insertValues = []; + $mergeSql = 'MERGE INTO ' + . $this->queryBuilder->quoter()->quoteTableName($table) + . ' ' + . 'USING (' . ($usingValues ?? ltrim($values, ' ')) + . ') "EXCLUDED" ' + . "ON ($on)"; + + foreach ($insertNames as $name) { + $quotedName = $this->queryBuilder->quoter()->quoteColumnName($name); + + if (strrpos($quotedName, '.') === false) { + $quotedName = '"EXCLUDED".' . $quotedName; + } + + $insertValues[] = $quotedName; + } + + $insertSql = 'INSERT (' . implode(', ', $insertNames) . ')' . ' VALUES (' . implode(', ', $insertValues) . ')'; + + if ($updateColumns === false) { + return "$mergeSql WHEN NOT MATCHED THEN $insertSql"; + } + + if ($updateColumns === true) { + $updateColumns = []; + foreach ($updateNames as $name) { + $quotedName = $this->queryBuilder->quoter()->quoteColumnName($name); + + if (strrpos($quotedName, '.') === false) { + $quotedName = '"EXCLUDED".' . $quotedName; + } + $updateColumns[$name] = new Expression($quotedName); + } + } + + [$updates, $params] = $this->queryBuilder->prepareUpdateSets($table, $updateColumns, $params); + $updateSql = 'UPDATE SET ' . implode(', ', $updates); + + return "$mergeSql WHEN MATCHED THEN $updateSql WHEN NOT MATCHED THEN $insertSql"; + } +} diff --git a/src/PDO/CommandPDOOracle.php b/src/PDO/CommandPDOOracle.php new file mode 100644 index 0000000..54d6fb5 --- /dev/null +++ b/src/PDO/CommandPDOOracle.php @@ -0,0 +1,125 @@ +db->getQueryBuilder(); + } + + public function prepare(?bool $forRead = null): void + { + if (isset($this->pdoStatement)) { + $this->bindPendingParams(); + + return; + } + + $sql = $this->getSql(); + + if ($this->db->getTransaction()) { + /** master is in a transaction. use the same connection. */ + $forRead = false; + } + + if ($forRead || ($forRead === null && $this->db->getSchema()->isReadQuery($sql))) { + $pdo = $this->db->getSlavePdo(); + } else { + $pdo = $this->db->getMasterPdo(); + } + + try { + $this->pdoStatement = $pdo->prepare($sql); + $this->bindPendingParams(); + } catch (PDOException $e) { + $message = $e->getMessage() . "\nFailed to prepare SQL: $sql"; + $errorInfo = $e->errorInfo ?? null; + + throw new Exception($message, $errorInfo, $e); + } + } + + protected function bindPendingParams(): void + { + $paramsPassedByReference = []; + + foreach ($this->pendingParams as $name => $value) { + if (PDO::PARAM_STR === $value[1]) { + $paramsPassedByReference[$name] = $value[0]; + $this->pdoStatement?->bindParam( + $name, + $paramsPassedByReference[$name], + $value[1], + strlen($value[0]) + ); + } else { + $this->pdoStatement?->bindValue($name, $value[0], $value[1]); + } + } + + $this->pendingParams = []; + } + + protected function getCacheKey(string $method, ?int $fetchMode, string $rawSql): array + { + return [ + __CLASS__, + $method, + $fetchMode, + $this->db->getDriver()->getDsn(), + $this->db->getDriver()->getUsername(), + $rawSql, + ]; + } + + protected function internalExecute(?string $rawSql): void + { + $attempt = 0; + + while (true) { + try { + if ( + ++$attempt === 1 + && $this->isolationLevel !== null + && $this->db->getTransaction() === null + ) { + $this->db->transaction(fn ($rawSql) => $this->internalExecute($rawSql), $this->isolationLevel); + } else { + $this->pdoStatement->execute(); + } + break; + } catch (PDOException $e) { + $rawSql = $rawSql ?: $this->getRawSql(); + $e = $this->db->getSchema()->convertException($e, $rawSql); + + if ($this->retryHandler === null || !($this->retryHandler)($e, $attempt)) { + throw $e; + } + } + } + } +} diff --git a/src/PDO/ConnectionPDOOracle.php b/src/PDO/ConnectionPDOOracle.php new file mode 100644 index 0000000..122ce4d --- /dev/null +++ b/src/PDO/ConnectionPDOOracle.php @@ -0,0 +1,288 @@ +master = null; + $this->slave = null; + $this->transaction = null; + + if (strncmp($this->driver->getDsn(), 'sqlite::memory:', 15) !== 0) { + /** reset PDO connection, unless its sqlite in-memory, which can only have one connection */ + $this->pdo = null; + } + } + + /** + * Close the connection before serializing. + * + * @return array + */ + public function __sleep(): array + { + $fields = (array) $this; + + unset( + $fields["\000" . __CLASS__ . "\000" . 'pdo'], + $fields["\000" . __CLASS__ . "\000" . 'master'], + $fields["\000" . __CLASS__ . "\000" . 'slave'], + $fields["\000" . __CLASS__ . "\000" . 'transaction'], + $fields["\000" . __CLASS__ . "\000" . 'schema'] + ); + + return array_keys($fields); + } + + public function createCommand(?string $sql = null, array $params = []): CommandPDOOracle + { + $command = new CommandPDOOracle($this, $this->queryCache); + + if ($sql !== null) { + $command->setSql($sql); + } + + if ($this->logger !== null) { + $command->setLogger($this->logger); + } + + if ($this->profiler !== null) { + $command->setProfiler($this->profiler); + } + + return $command->bindValues($params); + } + + public function createTransaction(): TransactionInterface + { + return new TransactionPDOOracle($this); + } + + public function close(): void + { + if (!empty($this->master)) { + /** @var ConnectionPDOOracle */ + $db = $this->master; + + if ($this->pdo === $db->getPDO()) { + $this->pdo = null; + } + + $db->close(); + $this->master = null; + } + + if ($this->pdo !== null) { + $this->logger?->log( + LogLevel::DEBUG, + 'Closing DB connection: ' . $this->driver->getDsn() . ' ' . __METHOD__, + ); + + $this->pdo = null; + $this->transaction = null; + } + + if (!empty($this->slave)) { + $this->slave->close(); + $this->slave = null; + } + } + + public function getDriver(): PDODriver + { + return $this->driver; + } + + public function getDriverName(): string + { + return 'oci'; + } + + public function getMasterPdo(): PDO|null + { + $this->open(); + return $this->pdo; + } + + public function getPDO(): ?PDO + { + return $this->pdo; + } + + public function getQuery(): Query + { + if ($this->query === null) { + $this->query = new Query($this); + } + + return $this->query; + } + + /** + * @throws Exception|InvalidConfigException + */ + public function getQueryBuilder(): QueryBuilderInterface + { + if ($this->queryBuilder === null) { + $this->queryBuilder = new QueryBuilderPDOOracle( + $this->createCommand(), + $this->getQuery(), + $this->getQuoter(), + $this->getSchema(), + ); + } + + return $this->queryBuilder; + } + + public function getQuoter(): QuoterInterface + { + if ($this->quoter === null) { + $this->quoter = new Quoter('"', '"', $this->getTablePrefix()); + } + + return $this->quoter; + } + + /** + * @throws Exception + */ + public function getServerVersion(): string + { + if ($this->serverVersion === '') { + /** @var mixed */ + $version = $this->getSlavePDO()?->getAttribute(PDO::ATTR_SERVER_VERSION); + $this->serverVersion = is_string($version) ? $version : 'Version could not be determined.'; + } + + return $this->serverVersion; + } + + public function getSchema(): SchemaInterface + { + if ($this->schema === null) { + $this->schema = new SchemaPDOOracle($this, $this->schemaCache); + } + + return $this->schema; + } + + public function getSlavePdo(bool $fallbackToMaster = true): ?PDO + { + /** @var ConnectionPDOOracle|null $db */ + $db = $this->getSlave(false); + + if ($db === null) { + return $fallbackToMaster ? $this->getMasterPdo() : null; + } + + return $db->getPDO(); + } + + public function isActive(): bool + { + return $this->pdo !== null; + } + + public function open(): void + { + if (!empty($this->pdo)) { + return; + } + + if (!empty($this->masters)) { + /** @var ConnectionPDOOracle|null */ + $db = $this->getMaster(); + + if ($db !== null) { + $this->pdo = $db->getPDO(); + return; + } + + throw new InvalidConfigException('None of the master DB servers is available.'); + } + + if (empty($this->driver->getDsn())) { + throw new InvalidConfigException('Connection::dsn cannot be empty.'); + } + + $token = 'Opening DB connection: ' . $this->driver->getDsn(); + + try { + $this->logger?->log(LogLevel::INFO, $token); + $this->profiler?->begin($token, [__METHOD__]); + $this->initConnection(); + $this->profiler?->end($token, [__METHOD__]); + } catch (PDOException $e) { + $this->profiler?->end($token, [__METHOD__]); + $this->logger?->log(LogLevel::ERROR, $token); + + throw new Exception($e->getMessage(), (array) $e->errorInfo, $e); + } + } + + /** + * Initializes the DB connection. + * + * This method is invoked right after the DB connection is established. + * + * The default implementation turns on `PDO::ATTR_EMULATE_PREPARES`. + * + * if {@see emulatePrepare} is true, and sets the database {@see charset} if it is not empty. + * + * It then triggers an {@see EVENT_AFTER_OPEN} event. + */ + protected function initConnection(): void + { + $this->pdo = $this->driver->createConnection(); + $this->pdo->setAttribute(PDO::ATTR_ERRMODE, PDO::ERRMODE_EXCEPTION); + + if ($this->getEmulatePrepare() !== null && constant('PDO::ATTR_EMULATE_PREPARES')) { + $this->pdo->setAttribute(PDO::ATTR_EMULATE_PREPARES, $this->getEmulatePrepare()); + } + } +} diff --git a/src/PDO/QueryBuilderPDOOracle.php b/src/PDO/QueryBuilderPDOOracle.php new file mode 100644 index 0000000..7756c9d --- /dev/null +++ b/src/PDO/QueryBuilderPDOOracle.php @@ -0,0 +1,368 @@ + 'NUMBER(10) NOT NULL PRIMARY KEY', + Schema::TYPE_UPK => 'NUMBER(10) UNSIGNED NOT NULL PRIMARY KEY', + Schema::TYPE_BIGPK => 'NUMBER(20) NOT NULL PRIMARY KEY', + Schema::TYPE_UBIGPK => 'NUMBER(20) UNSIGNED NOT NULL PRIMARY KEY', + Schema::TYPE_CHAR => 'CHAR(1)', + Schema::TYPE_STRING => 'VARCHAR2(255)', + Schema::TYPE_TEXT => 'CLOB', + Schema::TYPE_TINYINT => 'NUMBER(3)', + Schema::TYPE_SMALLINT => 'NUMBER(5)', + Schema::TYPE_INTEGER => 'NUMBER(10)', + Schema::TYPE_BIGINT => 'NUMBER(20)', + Schema::TYPE_FLOAT => 'NUMBER', + Schema::TYPE_DOUBLE => 'NUMBER', + Schema::TYPE_DECIMAL => 'NUMBER', + Schema::TYPE_DATETIME => 'TIMESTAMP', + Schema::TYPE_TIMESTAMP => 'TIMESTAMP', + Schema::TYPE_TIME => 'TIMESTAMP', + Schema::TYPE_DATE => 'DATE', + Schema::TYPE_BINARY => 'BLOB', + Schema::TYPE_BOOLEAN => 'NUMBER(1)', + Schema::TYPE_MONEY => 'NUMBER(19,4)', + ]; + + public function __construct( + private CommandInterface $command, + private Query $query, + private QuoterInterface $quoter, + private SchemaInterface $schema + ) { + $this->ddlBuilder = new DDLQueryBuilder($this); + $this->dmlBuilder = new DMLQueryBuilder($this); + parent::__construct($quoter, $schema); + } + + public function addForeignKey( + string $name, + string $table, + $columns, + string $refTable, + $refColumns, + ?string $delete = null, + ?string $update = null + ): string { + $sql = 'ALTER TABLE ' . $this->quoter->quoteTableName($table) + . ' ADD CONSTRAINT ' . $this->quoter->quoteColumnName($name) + . ' FOREIGN KEY (' . $this->buildColumns($columns) . ')' + . ' REFERENCES ' . $this->quoter->quoteTableName($refTable) + . ' (' . $this->buildColumns($refColumns) . ')'; + + if ($delete !== null) { + $sql .= ' ON DELETE ' . $delete; + } + + if ($update !== null) { + throw new Exception('Oracle does not support ON UPDATE clause.'); + } + + return $sql; + } + + /** + * Builds a SQL statement for changing the definition of a column. + * + * @param string $table the table whose column is to be changed. The table name will be properly quoted by the + * method. + * @param string $column the name of the column to be changed. The name will be properly quoted by the method. + * @param string $type the new column type. The [[getColumnType]] method will be invoked to convert abstract column + * type (if any) into the physical one. Anything that is not recognized as abstract type will be kept in the + * generated SQL. + * + * For example, 'string' will be turned into 'varchar(255)', while 'string not null' will become + * 'varchar(255) not null'. + * + * @return string the SQL statement for changing the definition of a column. + */ + public function alterColumn(string $table, string $column, string $type): string + { + $type = $this->getColumnType($type); + + return 'ALTER TABLE ' + . $this->quoter->quoteTableName($table) + . ' MODIFY ' + . $this->quoter->quoteColumnName($column) + . ' ' . $this->getColumnType($type); + } + + /** + * Generates a batch INSERT SQL statement. + * + * For example, + * + * ```php + * $sql = $queryBuilder->batchInsert('user', ['name', 'age'], [ + * ['Tom', 30], + * ['Jane', 20], + * ['Linda', 25], + * ]); + * ``` + * + * Note that the values in each row must match the corresponding column names. + * + * @param string $table the table that new rows will be inserted into. + * @param array $columns the column names. + * @param iterable|Generator $rows the rows to be batched inserted into the table. + * @param array $params + * + * @throws \Exception|InvalidArgumentException|InvalidConfigException|NotSupportedException + * + * @return string the batch INSERT SQL statement. + */ + public function batchInsert(string $table, array $columns, iterable|Generator $rows, array &$params = []): string + { + if (empty($rows)) { + return ''; + } + + $schema = $this->schema; + + if (($tableSchema = $schema->getTableSchema($table)) !== null) { + $columnSchemas = $tableSchema->getColumns(); + } else { + $columnSchemas = []; + } + + $values = []; + + foreach ($rows as $row) { + $vs = []; + foreach ($row as $i => $value) { + if (isset($columns[$i], $columnSchemas[$columns[$i]])) { + $value = $columnSchemas[$columns[$i]]->dbTypecast($value); + } + + if (is_string($value)) { + $value = $this->quoter->quoteValue($value); + } elseif (is_float($value)) { + /* ensure type cast always has . as decimal separator in all locales */ + $value = NumericHelper::normalize($value); + } elseif ($value === false) { + $value = 0; + } elseif ($value === null) { + $value = 'NULL'; + } elseif ($value instanceof ExpressionInterface) { + $value = $this->buildExpression($value, $params); + } + + $vs[] = $value; + } + + $values[] = '(' . implode(', ', $vs) . ')'; + } + + if (empty($values)) { + return ''; + } + + foreach ($columns as $i => $name) { + $columns[$i] = $this->quoter->quoteColumnName($name); + } + + $tableAndColumns = ' INTO ' . $this->quoter->quoteTableName($table) + . ' (' . implode(', ', $columns) . ') VALUES '; + + return 'INSERT ALL ' . $tableAndColumns . implode($tableAndColumns, $values) . ' SELECT 1 FROM SYS.DUAL'; + } + + public function buildOrderByAndLimit(string $sql, array $orderBy, $limit, $offset, array &$params = []): string + { + $orderBy = $this->buildOrderBy($orderBy, $params); + + if ($orderBy !== '') { + $sql .= $this->separator . $orderBy; + } + + $filters = []; + + if ($this->hasOffset($offset)) { + $filters[] = 'rowNumId > ' . $offset; + } + + if ($this->hasLimit($limit)) { + $filters[] = 'rownum <= ' . $limit; + } + + if (empty($filters)) { + return $sql; + } + + $filter = implode(' AND ', $filters); + return <<command; + } + + /** + * Builds a SQL statement for dropping an index. + * + * @param string $name the name of the index to be dropped. The name will be properly quoted by the method. + * @param string $table the table whose index is to be dropped. The name will be properly quoted by the method. + * + * @return string the SQL statement for dropping an index. + */ + public function dropIndex(string $name, string $table): string + { + return 'DROP INDEX ' . $this->quoter->quoteTableName($name); + } + + /** + * Creates a SQL statement for resetting the sequence value of a table's primary key. + * + * The sequence will be reset such that the primary key of the next new row inserted will have the specified value + * or 1. + * + * @param string $tableName the name of the table whose primary key sequence will be reset. + * @param array|int|string|null $value the value for the primary key of the next new row inserted. If this is not + * set, the next new row's primary key will have a value 1. + * + * @throws Exception|InvalidArgumentException|InvalidConfigException|Throwable + */ + public function executeResetSequence(string $tableName, array|int|string $value = null): void + { + $tableSchema = $this->schema->getTableSchema($tableName); + + if ($tableSchema === null) { + throw new InvalidArgumentException("Unknown table: $tableName"); + } + + if ($tableSchema->getSequenceName() === null) { + throw new InvalidArgumentException("There is no sequence associated with table: $tableName"); + } + + if ($value !== null) { + $value = (int) $value; + } else { + if (count($tableSchema->getPrimaryKey()) > 1) { + throw new InvalidArgumentException( + "Can't reset sequence for composite primary key in table: $tableName" + ); + } + $value = $this->command->setSql( + 'SELECT MAX("' . $tableSchema->getPrimaryKey()[0] . '") FROM "' . $tableSchema->getName() . '"' + )->queryScalar() + 1; + } + + /** + * Oracle needs at least two queries to reset sequence (see adding transactions and/or use alter method to + * avoid grants' issue?) + */ + $this->command->setSQl('DROP SEQUENCE "' . $tableSchema->getSequenceName() . '"')->execute(); + $this->command->setSql( + 'CREATE SEQUENCE "' . + $tableSchema->getSequenceName() . + '" START WITH ' . + $value . + ' INCREMENT BY 1 NOMAXVALUE NOCACHE' + )->execute(); + } + + public function prepareInsertValues(string $table, $columns, array $params = []): array + { + [$names, $placeholders, $values, $params] = parent::prepareInsertValues($table, $columns, $params); + + if (!$columns instanceof Query && empty($names)) { + $tableSchema = $this->schema->getTableSchema($table); + + if ($tableSchema !== null) { + $tableColumns = $tableSchema->getColumns(); + $columns = !empty($tableSchema->getPrimaryKey()) + ? $tableSchema->getPrimaryKey() : [reset($tableColumns)->getName()]; + foreach ($columns as $name) { + $names[] = $this->quoter->quoteColumnName($name); + $placeholders[] = 'DEFAULT'; + } + } + } + + return [$names, $placeholders, $values, $params]; + } + + public function query(): Query + { + return $this->query; + } + + public function quoter(): QuoterInterface + { + return $this->quoter; + } + + /** + * Builds a SQL statement for renaming a DB table. + * + * @param string $oldName + * @param string $newName the new table name. The name will be properly quoted by the method. + * + * @return string the SQL statement for renaming a DB table. + */ + public function renameTable(string $oldName, string $newName): string + { + return 'ALTER TABLE ' . $this->quoter->quoteTableName($oldName) . ' RENAME TO ' . + $this->quoter->quoteTableName($newName); + } + + public function selectExists(string $rawSql): string + { + return 'SELECT CASE WHEN EXISTS(' . $rawSql . ') THEN 1 ELSE 0 END FROM DUAL'; + } + + public function schema(): SchemaInterface + { + return $this->schema; + } + + protected function defaultExpressionBuilders(): array + { + return array_merge(parent::defaultExpressionBuilders(), [ + InCondition::class => InConditionBuilder::class, + LikeCondition::class => LikeConditionBuilder::class, + ]); + } +} diff --git a/src/PDO/SchemaPDOOracle.php b/src/PDO/SchemaPDOOracle.php new file mode 100644 index 0000000..b752bed --- /dev/null +++ b/src/PDO/SchemaPDOOracle.php @@ -0,0 +1,974 @@ + + */ +final class SchemaPDOOracle extends Schema +{ + /** + * @var array map of DB errors and corresponding exceptions. + * + * If left part is found in DB error message exception class from the right part is used. + */ + protected array $exceptionMap = [ + 'ORA-00001: unique constraint' => IntegrityException::class, + ]; + + public function __construct(private ConnectionPDOInterface $db, SchemaCache $schemaCache) + { + $this->defaultSchema = strtoupper($db->getDriver()->getUsername()); + parent::__construct($schemaCache); + } + + protected function resolveTableName(string $name): TableSchema + { + $resolvedName = new TableSchema(); + + $parts = explode('.', str_replace('"', '', $name)); + + if (isset($parts[1])) { + $resolvedName->schemaName($parts[0]); + $resolvedName->name($parts[1]); + } else { + $resolvedName->schemaName($this->defaultSchema); + $resolvedName->name($name); + } + + $fullName = ($resolvedName->getSchemaName() !== $this->defaultSchema + ? $resolvedName->getSchemaName() . '.' : '') . $resolvedName->getName(); + + $resolvedName->fullName($fullName); + + return $resolvedName; + } + + /** + * @see https://docs.oracle.com/cd/B28359_01/server.111/b28337/tdpsg_user_accounts.htm + */ + protected function findSchemaNames(): array + { + $sql = <<db->createCommand($sql)->queryColumn(); + } + + /** + * @param string $schema + * + * @throws Exception|InvalidConfigException|Throwable + * + * @return array + */ + protected function findTableNames(string $schema = ''): array + { + if ($schema === '') { + $sql = <<db->createCommand($sql); + } else { + $sql = <<db->createCommand($sql, [':schema' => $schema]); + } + + $rows = $command->queryAll(); + $names = []; + + foreach ($rows as $row) { + if ($this->db->getSlavePdo()->getAttribute(PDO::ATTR_CASE) === PDO::CASE_LOWER) { + $row = array_change_key_case($row, CASE_UPPER); + } + $names[] = $row['TABLE_NAME']; + } + + return $names; + } + + /** + * @param string $name + * + * @throws Exception|InvalidConfigException|Throwable + * + * @return TableSchema|null + */ + protected function loadTableSchema(string $name): ?TableSchema + { + $table = new TableSchema(); + + $this->resolveTableNames($table, $name); + + if ($this->findColumns($table)) { + $this->findConstraints($table); + return $table; + } + + return null; + } + + /** + * @param string $tableName + * + * @throws Exception|InvalidConfigException|NotSupportedException|Throwable + * + * @return Constraint|null + */ + protected function loadTablePrimaryKey(string $tableName): ?Constraint + { + return $this->loadTableConstraints($tableName, 'primaryKey'); + } + + /** + * @param string $tableName + * + * @throws Exception|InvalidConfigException|NotSupportedException|Throwable + * + * @return array + */ + protected function loadTableForeignKeys(string $tableName): array + { + return $this->loadTableConstraints($tableName, 'foreignKeys'); + } + + /** + * @param string $tableName + * + * @throws Exception|InvalidConfigException|NotSupportedException|Throwable + * + * @return array + */ + protected function loadTableIndexes(string $tableName): array + { + $sql = <<resolveTableName($tableName); + + $indexes = $this->db->createCommand($sql, [ + ':schemaName' => $resolvedName->getSchemaName(), + ':tableName' => $resolvedName->getName(), + ])->queryAll(); + + $indexes = $this->normalizePdoRowKeyCase($indexes, true); + + $indexes = ArrayHelper::index($indexes, null, 'name'); + + $result = []; + + /** + * @psalm-var object|string|null $name + * @psalm-var array[] $index + */ + foreach ($indexes as $name => $index) { + $columnNames = ArrayHelper::getColumn($index, 'column_name'); + + if ($columnNames[0] === null) { + $columnNames[0] = ''; + } + + $result[] = (new IndexConstraint()) + ->primary((bool) $index[0]['index_is_primary']) + ->unique((bool) $index[0]['index_is_unique']) + ->name($name) + ->columnNames($columnNames); + } + + return $result; + } + + /** + * @param string $tableName + * + * @throws Exception|InvalidConfigException|NotSupportedException|Throwable + * + * @return array + */ + protected function loadTableUniques(string $tableName): array + { + return $this->loadTableConstraints($tableName, 'uniques'); + } + + /** + * @param string $tableName + * + * @throws Exception|InvalidConfigException|NotSupportedException|Throwable + * + * @return array + */ + protected function loadTableChecks(string $tableName): array + { + return $this->loadTableConstraints($tableName, 'checks'); + } + + /** + * @param string $tableName + * + * @throws NotSupportedException if this method is called. + * + * @return array + */ + protected function loadTableDefaultValues(string $tableName): array + { + throw new NotSupportedException('Oracle does not support default value constraints.'); + } + + public function releaseSavepoint(string $name): void + { + /* does nothing as Oracle does not support this */ + } + + public function quoteSimpleTableName(string $name): string + { + return str_contains($name, '"') ? $name : '"' . $name . '"'; + } + + /** + * Create a column schema builder instance giving the type and value precision. + * + * This method may be overridden by child classes to create a DBMS-specific column schema builder. + * + * @param string $type type of the column. See {@see ColumnSchemaBuilder::$type}. + * @param array|int|string|null $length length or precision of the column {@see ColumnSchemaBuilder::$length}. + * + * @return ColumnSchemaBuilder column schema builder instance + */ + public function createColumnSchemaBuilder(string $type, array|int|string $length = null): ColumnSchemaBuilder + { + return new ColumnSchemaBuilder($type, $length); + } + + /** + * Resolves the table name and schema name (if any). + * + * @param TableSchema $table the table metadata object + * @param string $name the table name + */ + protected function resolveTableNames(TableSchema $table, string $name): void + { + $parts = explode('.', str_replace('"', '', $name)); + + if (isset($parts[1])) { + $table->schemaName($parts[0]); + $table->name($parts[1]); + } else { + $table->schemaName($this->defaultSchema); + $table->name($name); + } + + $table->fullName($table->getSchemaName() !== $this->defaultSchema + ? $table->getSchemaName() . '.' . $table->getName() : $table->getName()); + } + + /** + * Collects the table column metadata. + * + * @param TableSchema $table the table schema. + * + * @throws Exception|Throwable + * + * @return bool whether the table exists. + */ + protected function findColumns(TableSchema $table): bool + { + $sql = <<<'SQL' +SELECT + A.COLUMN_NAME, + A.DATA_TYPE, + A.DATA_PRECISION, + A.DATA_SCALE, + ( + CASE A.CHAR_USED WHEN 'C' THEN A.CHAR_LENGTH + ELSE A.DATA_LENGTH + END + ) AS DATA_LENGTH, + A.NULLABLE, + A.DATA_DEFAULT, + COM.COMMENTS AS COLUMN_COMMENT +FROM ALL_TAB_COLUMNS A + INNER JOIN ALL_OBJECTS B ON B.OWNER = A.OWNER AND LTRIM(B.OBJECT_NAME) = LTRIM(A.TABLE_NAME) + LEFT JOIN ALL_COL_COMMENTS COM ON (A.OWNER = COM.OWNER AND A.TABLE_NAME = COM.TABLE_NAME AND A.COLUMN_NAME = COM.COLUMN_NAME) +WHERE + A.OWNER = :schemaName + AND B.OBJECT_TYPE IN ('TABLE', 'VIEW', 'MATERIALIZED VIEW') + AND B.OBJECT_NAME = :tableName +ORDER BY A.COLUMN_ID +SQL; + + try { + $columns = $this->db->createCommand($sql, [ + ':tableName' => $table->getName(), + ':schemaName' => $table->getSchemaName(), + ])->queryAll(); + } catch (Exception $e) { + return false; + } + + if (empty($columns)) { + return false; + } + + foreach ($columns as $column) { + if ($this->db->getSlavePdo()->getAttribute(PDO::ATTR_CASE) === PDO::CASE_LOWER) { + $column = array_change_key_case($column, CASE_UPPER); + } + + $c = $this->createColumn($column); + + $table->columns($c->getName(), $c); + } + + return true; + } + + /** + * Sequence name of table. + * + * @param string $tableName + * + * @throws Exception|InvalidConfigException|Throwable + * + * @return int|null|string whether the sequence exists. + * + * @internal TableSchema `$table->getName()` the table schema. + */ + protected function getTableSequenceName(string $tableName): string|int|null + { + $sequenceNameSql = <<db->createCommand($sequenceNameSql, [':tableName' => $tableName])->queryScalar(); + + return $sequenceName === false ? null : $sequenceName; + } + + /** + * @Overrides method in class 'Schema' + * + * {@see https://secure.php.net/manual/en/function.PDO-lastInsertId.php} -> Oracle does not support this. + * + * Returns the ID of the last inserted row or sequence value. + * + * @param string $sequenceName name of the sequence object (required by some DBMS) + * + * @throws Exception|InvalidCallException|InvalidConfigException|Throwable if the DB connection is not active. + * + * @return string the row ID of the last row inserted, or the last value retrieved from the sequence object. + */ + public function getLastInsertID(string $sequenceName = ''): string + { + if ($this->db->isActive()) { + /* get the last insert id from the master connection */ + $sequenceName = $this->quoteSimpleTableName($sequenceName); + + return $this->db->useMaster(function (ConnectionPDOInterface $db) use ($sequenceName) { + return $db->createCommand("SELECT $sequenceName.CURRVAL FROM DUAL")->queryScalar(); + }); + } + + throw new InvalidCallException('DB Connection is not active.'); + } + + /** + * Creates ColumnSchema instance. + * + * @param array|string $column + * + * @return ColumnSchema + */ + protected function createColumn(array|string $column): ColumnSchema + { + $c = $this->createColumnSchema(); + + $c->name($column['COLUMN_NAME']); + $c->allowNull($column['NULLABLE'] === 'Y'); + $c->comment($column['COLUMN_COMMENT'] ?? ''); + $c->primaryKey(false); + + $this->extractColumnType( + $c, + $column['DATA_TYPE'], + $column['DATA_PRECISION'], + $column['DATA_SCALE'], + $column['DATA_LENGTH'] + ); + + $this->extractColumnSize( + $c, + $column['DATA_TYPE'], + $column['DATA_PRECISION'], + $column['DATA_SCALE'], + $column['DATA_LENGTH'] + ); + + $c->phpType($this->getColumnPhpType($c)); + + if (!$c->isPrimaryKey()) { + if ($column['DATA_DEFAULT'] !== null && stripos($column['DATA_DEFAULT'], 'timestamp') !== false) { + $c->defaultValue(null); + } else { + $defaultValue = $column['DATA_DEFAULT']; + + if ($c->getType() === 'timestamp' && $defaultValue === 'CURRENT_TIMESTAMP') { + $c->defaultValue(new Expression('CURRENT_TIMESTAMP')); + } else { + if ($defaultValue !== null) { + if (($len = strlen($defaultValue)) > 2 && $defaultValue[0] === "'" + && $defaultValue[$len - 1] === "'" + ) { + $defaultValue = substr($column['DATA_DEFAULT'], 1, -1); + } else { + $defaultValue = trim($defaultValue); + } + } + $c->defaultValue($c->phpTypecast($defaultValue)); + } + } + } + + return $c; + } + + /** + * Finds constraints and fills them into TableSchema object passed. + * + * @param TableSchema $table + * + * @throws Exception|InvalidConfigException|Throwable + */ + protected function findConstraints(TableSchema $table): void + { + $sql = <<<'SQL' +SELECT + /*+ PUSH_PRED(C) PUSH_PRED(D) PUSH_PRED(E) */ + D.CONSTRAINT_NAME, + D.CONSTRAINT_TYPE, + C.COLUMN_NAME, + C.POSITION, + D.R_CONSTRAINT_NAME, + E.TABLE_NAME AS TABLE_REF, + F.COLUMN_NAME AS COLUMN_REF, + C.TABLE_NAME +FROM ALL_CONS_COLUMNS C + INNER JOIN ALL_CONSTRAINTS D ON D.OWNER = C.OWNER AND D.CONSTRAINT_NAME = C.CONSTRAINT_NAME + LEFT JOIN ALL_CONSTRAINTS E ON E.OWNER = D.R_OWNER AND E.CONSTRAINT_NAME = D.R_CONSTRAINT_NAME + LEFT JOIN ALL_CONS_COLUMNS F ON F.OWNER = E.OWNER AND F.CONSTRAINT_NAME = E.CONSTRAINT_NAME AND F.POSITION = C.POSITION +WHERE + C.OWNER = :schemaName + AND C.TABLE_NAME = :tableName +ORDER BY D.CONSTRAINT_NAME, C.POSITION +SQL; + + $command = $this->db->createCommand($sql, [ + ':tableName' => $table->getName(), + ':schemaName' => $table->getSchemaName(), + ]); + + $constraints = []; + + foreach ($command->queryAll() as $row) { + if ($this->db->getSlavePdo()->getAttribute(PDO::ATTR_CASE) === PDO::CASE_LOWER) { + $row = array_change_key_case($row, CASE_UPPER); + } + + if ($row['CONSTRAINT_TYPE'] === 'P') { + $table->getColumns()[$row['COLUMN_NAME']]->primaryKey(true); + $table->primaryKey($row['COLUMN_NAME']); + + if (empty($table->getSequenceName())) { + $table->sequenceName($this->getTableSequenceName($table->getName())); + } + } + + if ($row['CONSTRAINT_TYPE'] !== 'R') { + /** + * This condition is not checked in SQL WHERE because of an Oracle Bug: + * + * {@see https://github.com/yiisoft/yii2/pull/8844} + */ + continue; + } + + $name = $row['CONSTRAINT_NAME']; + + if (!isset($constraints[$name])) { + $constraints[$name] = [ + 'tableName' => $row['TABLE_REF'], + 'columns' => [], + ]; + } + + $constraints[$name]['columns'][$row['COLUMN_NAME']] = $row['COLUMN_REF']; + } + + foreach ($constraints as $constraint) { + $name = current(array_keys($constraint)); + $table->foreignKey(array_merge([$constraint['tableName']], $constraint['columns'])); + } + } + + /** + * Returns all unique indexes for the given table. + * + * Each array element is of the following structure:. + * + * ```php + * [ + * 'IndexName1' => ['col1' [, ...]], + * 'IndexName2' => ['col2' [, ...]], + * ] + * ``` + * + * @param TableSchema $table the table metadata. + * + * @throws Exception|InvalidConfigException|Throwable + * + * @return array all unique indexes for the given table. + */ + public function findUniqueIndexes(TableSchema $table): array + { + $query = <<<'SQL' +SELECT + DIC.INDEX_NAME, + DIC.COLUMN_NAME +FROM ALL_INDEXES DI + INNER JOIN ALL_IND_COLUMNS DIC ON DI.TABLE_NAME = DIC.TABLE_NAME AND DI.INDEX_NAME = DIC.INDEX_NAME +WHERE + DI.UNIQUENESS = 'UNIQUE' + AND DIC.TABLE_OWNER = :schemaName + AND DIC.TABLE_NAME = :tableName +ORDER BY DIC.TABLE_NAME, DIC.INDEX_NAME, DIC.COLUMN_POSITION +SQL; + $result = []; + + $command = $this->db->createCommand($query, [ + ':tableName' => $table->getName(), + ':schemaName' => $table->getschemaName(), + ]); + + foreach ($command->queryAll() as $row) { + $result[$row['INDEX_NAME']][] = $row['COLUMN_NAME']; + } + + return $result; + } + + /** + * Extracts the data types for the given column. + * + * @param ColumnSchema $column + * @param string $dbType DB type. + * @param string|null $precision total number of digits. + * @param string|null $scale number of digits on the right of the decimal separator. + * @param string $length length for character types. + */ + protected function extractColumnType( + ColumnSchema $column, + string $dbType, + ?string $precision, + ?string $scale, + string $length + ): void { + $column->dbType($dbType); + + if (str_contains($dbType, 'FLOAT') || str_contains($dbType, 'DOUBLE')) { + $column->type('double'); + } elseif (str_contains($dbType, 'NUMBER')) { + if ($scale === null || $scale > 0) { + $column->type('decimal'); + } else { + $column->type('integer'); + } + } elseif (str_contains($dbType, 'INTEGER')) { + $column->type('integer'); + } elseif (str_contains($dbType, 'BLOB')) { + $column->type('binary'); + } elseif (str_contains($dbType, 'CLOB')) { + $column->type('text'); + } elseif (str_contains($dbType, 'TIMESTAMP')) { + $column->type('timestamp'); + } else { + $column->type('string'); + } + } + + /** + * Extracts size, precision and scale information from column's DB type. + * + * @param ColumnSchema $column + * @param string $dbType the column's DB type. + * @param string|null $precision total number of digits. + * @param string|null $scale number of digits on the right of the decimal separator. + * @param string $length length for character types. + */ + protected function extractColumnSize( + ColumnSchema $column, + string $dbType, + ?string $precision, + ?string $scale, + string $length + ): void { + $column->size(trim($length) === '' ? null : (int) $length); + $column->precision(trim((string) $precision) === '' ? null : (int) $precision); + $column->scale($scale === '' || $scale === null ? null : (int) $scale); + } + + /** + * @throws Exception|InvalidArgumentException|InvalidConfigException|NotSupportedException|Throwable + */ + public function insert($table, $columns): bool|array + { + $params = []; + $returnParams = []; + $sql = $this->db->getQueryBuilder()->insert($table, $columns, $params); + $tableSchema = $this->getTableSchema($table); + $returnColumns = $tableSchema->getPrimaryKey(); + + if (!empty($returnColumns)) { + $columnSchemas = $tableSchema->getColumns(); + + $returning = []; + foreach ($returnColumns as $name) { + $phName = QueryBuilder::PARAM_PREFIX . (count($params) + count($returnParams)); + + $returnParams[$phName] = [ + 'column' => $name, + 'value' => '', + ]; + + if (!isset($columnSchemas[$name]) || $columnSchemas[$name]->getPhpType() !== 'integer') { + $returnParams[$phName]['dataType'] = PDO::PARAM_STR; + } else { + $returnParams[$phName]['dataType'] = PDO::PARAM_INT; + } + + $returnParams[$phName]['size'] = $columnSchemas[$name]->getSize() ?? -1; + + $returning[] = $this->db->getQuoter()->quoteColumnName($name); + } + + $sql .= ' RETURNING ' . implode(', ', $returning) . ' INTO ' . implode(', ', array_keys($returnParams)); + } + + $command = $this->db->createCommand($sql, $params); + + $command->prepare(false); + + foreach ($returnParams as $name => &$value) { + $command->getPdoStatement()->bindParam($name, $value['value'], $value['dataType'], $value['size']); + } + + if (!$command->execute()) { + return false; + } + + $result = []; + foreach ($returnParams as $value) { + $result[$value['column']] = $value['value']; + } + + return $result; + } + + /** + * Loads multiple types of constraints and returns the specified ones. + * + * @param string $tableName table name. + * @param string $returnType return type: + * - primaryKey + * - foreignKeys + * - uniques + * - checks + * + * @throws Exception|InvalidConfigException|NotSupportedException|Throwable + * + * @return mixed constraints. + */ + private function loadTableConstraints(string $tableName, string $returnType): mixed + { + $sql = <<resolveTableName($tableName); + + $constraints = $this->db->createCommand($sql, [ + ':schemaName' => $resolvedName->getSchemaName(), + ':tableName' => $resolvedName->getName(), + ])->queryAll(); + + $constraints = $this->normalizePdoRowKeyCase($constraints, true); + + $constraints = ArrayHelper::index($constraints, null, ['type', 'name']); + + $result = [ + 'primaryKey' => null, + 'foreignKeys' => [], + 'uniques' => [], + 'checks' => [], + ]; + + /** + * @var string $type + * @var array $names + */ + foreach ($constraints as $type => $names) { + /** + * @psalm-var object|string|null $name + * @psalm-var ConstraintArray $constraint + */ + foreach ($names as $name => $constraint) { + switch ($type) { + case 'P': + $result['primaryKey'] = (new Constraint()) + ->name($name) + ->columnNames(ArrayHelper::getColumn($constraint, 'column_name')); + break; + case 'R': + $result['foreignKeys'][] = (new ForeignKeyConstraint()) + ->name($name) + ->columnNames(ArrayHelper::getColumn($constraint, 'column_name')) + ->foreignSchemaName($constraint[0]['foreign_table_schema']) + ->foreignTableName($constraint[0]['foreign_table_name']) + ->foreignColumnNames(ArrayHelper::getColumn($constraint, 'foreign_column_name')) + ->onDelete($constraint[0]['on_delete']) + ->onUpdate(null); + break; + case 'U': + $result['uniques'][] = (new Constraint()) + ->name($name) + ->columnNames(ArrayHelper::getColumn($constraint, 'column_name')); + break; + case 'C': + $result['checks'][] = (new CheckConstraint()) + ->name($name) + ->columnNames(ArrayHelper::getColumn($constraint, 'column_name')) + ->expression($constraint[0]['check_expr']); + break; + } + } + } + + foreach ($result as $type => $data) { + $this->setTableMetadata($tableName, $type, $data); + } + + return $result[$returnType]; + } + + /** + * Creates a column schema for the database. + * + * This method may be overridden by child classes to create a DBMS-specific column schema. + * + * @return ColumnSchema column schema instance. + */ + protected function createColumnSchema(): ColumnSchema + { + return new ColumnSchema(); + } + + public function rollBackSavepoint(string $name): void + { + $this->db->createCommand("ROLLBACK TO SAVEPOINT $name")->execute(); + } + + public function setTransactionIsolationLevel(string $level): void + { + $this->db->createCommand("SET TRANSACTION ISOLATION LEVEL $level")->execute(); + } + + /** + * Returns the actual name of a given table name. + * + * This method will strip off curly brackets from the given table name and replace the percentage character '%' with + * {@see ConnectionInterface::tablePrefix}. + * + * @param string $name the table name to be converted. + * + * @return string the real name of the given table name. + */ + public function getRawTableName(string $name): string + { + if (str_contains($name, '{{')) { + $name = preg_replace('/{{(.*?)}}/', '\1', $name); + + return str_replace('%', $this->db->getTablePrefix(), $name); + } + + return $name; + } + + /** + * Returns the cache key for the specified table name. + * + * @param string $name the table name. + * + * @return array the cache key. + */ + protected function getCacheKey(string $name): array + { + return [ + __CLASS__, + $this->db->getDriver()->getDsn(), + $this->db->getDriver()->getUsername(), + $this->getRawTableName($name), + ]; + } + + /** + * Returns the cache tag name. + * + * This allows {@see refresh()} to invalidate all cached table schemas. + * + * @return string the cache tag name. + */ + protected function getCacheTag(): string + { + return md5(serialize([ + __CLASS__, + $this->db->getDriver()->getDsn(), + $this->db->getDriver()->getUsername(), + ])); + } + + /** + * Changes row's array key case to lower if PDO's one is set to uppercase. + * + * @param array $row row's array or an array of row's arrays. + * @param bool $multiple whether multiple rows or a single row passed. + * + * @throws Exception + * + * @return array normalized row or rows. + */ + protected function normalizePdoRowKeyCase(array $row, bool $multiple): array + { + if ($this->db->getSlavePdo()->getAttribute(PDO::ATTR_CASE) !== PDO::CASE_UPPER) { + return $row; + } + + if ($multiple) { + return array_map(static function (array $row) { + return array_change_key_case($row, CASE_LOWER); + }, $row); + } + + return array_change_key_case($row, CASE_LOWER); + } + + /** + * @return bool whether this DBMS supports [savepoint](http://en.wikipedia.org/wiki/Savepoint). + */ + public function supportsSavepoint(): bool + { + return $this->db->isSavepointEnabled(); + } + + /** + * Creates a new savepoint. + * + * @param string $name the savepoint name + * + * @throws Exception|InvalidConfigException|Throwable + */ + public function createSavepoint(string $name): void + { + $this->db->createCommand("SAVEPOINT $name")->execute(); + } +} diff --git a/src/PDO/TransactionPDOOracle.php b/src/PDO/TransactionPDOOracle.php new file mode 100644 index 0000000..ce76d89 --- /dev/null +++ b/src/PDO/TransactionPDOOracle.php @@ -0,0 +1,175 @@ +db->open(); + + if ($this->level === 0) { + if ($isolationLevel !== null) { + $this->db->getSchema()->setTransactionIsolationLevel($isolationLevel); + } + + $this->logger?->log( + LogLevel::DEBUG, + 'Begin transaction' . ($isolationLevel ? ' with isolation level ' . $isolationLevel : '') + . ' ' . __METHOD__ + ); + $this->db->getPDO()->beginTransaction(); + $this->level = 1; + return; + } + + $schema = $this->db->getSchema(); + + if ($schema->supportsSavepoint()) { + $this->logger?->log(LogLevel::DEBUG, 'Set savepoint ' . $this->level . ' ' . __METHOD__); + $schema->createSavepoint('LEVEL' . $this->level); + } else { + $this->logger?->log( + LogLevel::DEBUG, + 'Transaction not started: nested transaction not supported ' . __METHOD__ + ); + throw new NotSupportedException('Transaction not started: nested transaction not supported.'); + } + + $this->level++; + } + + /** + * Commits a transaction. + * + * @throws Exception|Throwable if the transaction is not active + */ + public function commit(): void + { + if (!$this->isActive()) { + throw new Exception('Failed to commit transaction: transaction was inactive.'); + } + + $this->level--; + + if ($this->level === 0) { + $this->logger?->log(LogLevel::DEBUG, 'Commit transaction ' . __METHOD__); + $this->db->getPDO()->commit(); + return; + } + + $schema = $this->db->getSchema(); + + if ($schema->supportsSavepoint()) { + $this->logger?->log(LogLevel::DEBUG, 'Release savepoint ' . $this->level . ' ' . __METHOD__); + $schema->releaseSavepoint('LEVEL' . $this->level); + } else { + $this->logger?->log( + LogLevel::INFO, + 'Transaction not committed: nested transaction not supported ' . __METHOD__ + ); + } + } + + public function getLevel(): int + { + return $this->level; + } + + public function isActive(): bool + { + return $this->level > 0 && $this->db->isActive(); + } + + /** + * @throws Exception|InvalidConfigException|Throwable + */ + public function rollBack(): void + { + if (!$this->isActive()) { + /** + * do nothing if transaction is not active: this could be the transaction is committed but the event handler + * to "commitTransaction" throw an exception + */ + return; + } + + $this->level--; + if ($this->level === 0) { + $this->logger?->log(LogLevel::INFO, 'Roll back transaction ' . __METHOD__); + $this->db->getPDO()->rollBack(); + return; + } + + $schema = $this->db->getSchema(); + if ($schema->supportsSavepoint()) { + $this->logger?->log(LogLevel::DEBUG, 'Roll back to savepoint ' . $this->level . ' ' . __METHOD__); + $schema->rollBackSavepoint('LEVEL' . $this->level); + } else { + $this->logger?->log( + LogLevel::INFO, + 'Transaction not rolled back: nested transaction not supported ' . __METHOD__ + ); + } + } + + public function setIsolationLevel(string $level): void + { + if (!$this->isActive()) { + throw new Exception('Failed to set isolation level: transaction was inactive.'); + } + + $this->logger?->log( + LogLevel::DEBUG, + 'Setting transaction isolation level to ' . $this->level . ' ' . __METHOD__ + ); + $this->db->getSchema()->setTransactionIsolationLevel($level); + } +} diff --git a/tests/BatchQueryResultTest.php b/tests/BatchQueryResultTest.php index b45c1da..4095026 100644 --- a/tests/BatchQueryResultTest.php +++ b/tests/BatchQueryResultTest.php @@ -4,7 +4,7 @@ namespace Yiisoft\Db\Oracle\Tests; -use Yiisoft\Db\TestUtility\TestBatchQueryResultTrait; +use Yiisoft\Db\TestSupport\TestBatchQueryResultTrait; /** * @group oracle diff --git a/tests/ColumnSchemaBuilderTest.php b/tests/ColumnSchemaBuilderTest.php index 39623f2..98b0203 100644 --- a/tests/ColumnSchemaBuilderTest.php +++ b/tests/ColumnSchemaBuilderTest.php @@ -4,7 +4,7 @@ namespace Yiisoft\Db\Oracle\Tests; -use Yiisoft\Db\TestUtility\TestColumnSchemaBuilderTrait; +use Yiisoft\Db\TestSupport\TestColumnSchemaBuilderTrait; use Yiisoft\Db\Oracle\Schema; /** diff --git a/tests/CommandTest.php b/tests/CommandTest.php index 52c67a5..654fb0b 100644 --- a/tests/CommandTest.php +++ b/tests/CommandTest.php @@ -8,10 +8,10 @@ use Yiisoft\Db\Connection\Connection; use Yiisoft\Db\Exception\InvalidArgumentException; use Yiisoft\Db\Expression\Expression; +use Yiisoft\Db\Oracle\PDO\SchemaPDOOracle; use Yiisoft\Db\Pdo\PdoValue; use Yiisoft\Db\Query\Query; -use Yiisoft\Db\Oracle\Schema; -use Yiisoft\Db\TestUtility\TestCommandTrait; +use Yiisoft\Db\TestSupport\TestCommandTrait; /** * @group oracle @@ -86,7 +86,7 @@ public function testCLOBStringInsertion(): void $db->createCommand()->dropTable('longstring')->execute(); } - $db->createCommand()->createTable('longstring', ['message' => Schema::TYPE_TEXT])->execute(); + $db->createCommand()->createTable('longstring', ['message' => SchemaPDOOracle::TYPE_TEXT])->execute(); $longData = str_pad('-', 4001, '-=', STR_PAD_LEFT); $db->createCommand()->insert('longstring', [ @@ -546,7 +546,7 @@ public function testCreateTable(): void $db->createCommand()->createTable( '{{testCreateTable}}', - ['id' => Schema::TYPE_PK, 'bar' => Schema::TYPE_INTEGER] + ['id' => SchemaPDOOracle::TYPE_PK, 'bar' => SchemaPDOOracle::TYPE_INTEGER] )->execute(); $db->createCommand('CREATE SEQUENCE testCreateTable_SEQ START with 1 INCREMENT BY 1')->execute(); @@ -581,8 +581,8 @@ public function testCreateView(): void } $db->createCommand()->createTable('testCreateViewTable', [ - 'id' => Schema::TYPE_PK, - 'bar' => Schema::TYPE_INTEGER, + 'id' => SchemaPDOOracle::TYPE_PK, + 'bar' => SchemaPDOOracle::TYPE_INTEGER, ])->execute(); $db->createCommand('CREATE SEQUENCE testCreateViewTable_SEQ START with 1 INCREMENT BY 1')->execute(); @@ -643,7 +643,7 @@ public function testAlterTable(): void $db->createCommand()->createTable( 'testAlterTable', - ['id' => Schema::TYPE_PK, 'bar' => Schema::TYPE_INTEGER] + ['id' => SchemaPDOOracle::TYPE_PK, 'bar' => SchemaPDOOracle::TYPE_INTEGER] )->execute(); $db->createCommand('CREATE SEQUENCE testAlterTable_SEQ START with 1 INCREMENT BY 1')->execute(); diff --git a/tests/ConnectionTest.php b/tests/ConnectionTest.php index a92fe7b..df1d933 100644 --- a/tests/ConnectionTest.php +++ b/tests/ConnectionTest.php @@ -6,11 +6,11 @@ use PDO; use Yiisoft\Cache\CacheKeyNormalizer; +use Yiisoft\Db\Connection\ConnectionInterface; use Yiisoft\Db\Exception\Exception; use Yiisoft\Db\Exception\InvalidConfigException; -use Yiisoft\Db\Oracle\Connection; -use Yiisoft\Db\TestUtility\TestConnectionTrait; -use Yiisoft\Db\Transaction\Transaction; +use Yiisoft\Db\Oracle\PDO\TransactionPDOOracle; +use Yiisoft\Db\TestSupport\TestConnectionTrait; /** * @group oracle @@ -22,132 +22,120 @@ final class ConnectionTest extends TestCase public function testConstruct(): void { $db = $this->getConnection(); - - $this->assertEquals(self::DB_DSN, $db->getDsn()); + $this->assertEquals($this->dsn, $db->getDriver()->getDsn()); } public function testGetDriverName(): void { $db = $this->getConnection(); - $this->assertEquals('oci', $db->getDriverName()); } public function testOpenClose(): void { $db = $this->getConnection(); - $this->assertFalse($db->isActive()); $this->assertNull($db->getPDO()); $db->open(); - $this->assertTrue($db->isActive()); $this->assertInstanceOf(PDO::class, $db->getPDO()); $db->close(); - $this->assertFalse($db->isActive()); $this->assertNull($db->getPDO()); - $db = $this->createConnection('unknown::memory:'); - + $db = $this->getConnection(false, 'unknown::memory:'); $this->expectException(Exception::class); $this->expectExceptionMessage('could not find driver'); - $db->open(); } public function testSerialize() { $db = $this->getConnection(); - $db->open(); $serialized = serialize($db); $unserialized = unserialize($serialized); - $this->assertInstanceOf(Connection::class, $unserialized); + $this->assertInstanceOf(ConnectionInterface::class, $unserialized); $this->assertEquals(123, $unserialized->createCommand('SELECT 123 FROM DUAL')->queryScalar()); } public function testQuoteTableName() { - $db = $this->getConnection(false); - $this->assertEquals('"table"', $db->quoteTableName('table')); - $this->assertEquals('"table"', $db->quoteTableName('"table"')); - $this->assertEquals('"schema"."table"', $db->quoteTableName('schema.table')); - $this->assertEquals('"schema"."table"', $db->quoteTableName('schema."table"')); - $this->assertEquals('"schema"."table"', $db->quoteTableName('"schema"."table"')); - $this->assertEquals('{{table}}', $db->quoteTableName('{{table}}')); - $this->assertEquals('(table)', $db->quoteTableName('(table)')); + $db = $this->getConnection(); + $quoter = $db->getQuoter(); + + $this->assertEquals('"table"', $quoter->quoteTableName('table')); + $this->assertEquals('"table"', $quoter->quoteTableName('"table"')); + $this->assertEquals('"schema"."table"', $quoter->quoteTableName('schema.table')); + $this->assertEquals('"schema"."table"', $quoter->quoteTableName('schema."table"')); + $this->assertEquals('"schema"."table"', $quoter->quoteTableName('"schema"."table"')); + $this->assertEquals('{{table}}', $quoter->quoteTableName('{{table}}')); + $this->assertEquals('(table)', $quoter->quoteTableName('(table)')); } public function testQuoteColumnName() { - $db = $this->getConnection(false); - $this->assertEquals('"column"', $db->quoteColumnName('column')); - $this->assertEquals('"column"', $db->quoteColumnName('"column"')); - $this->assertEquals('[[column]]', $db->quoteColumnName('[[column]]')); - $this->assertEquals('{{column}}', $db->quoteColumnName('{{column}}')); - $this->assertEquals('(column)', $db->quoteColumnName('(column)')); - - $this->assertEquals('"column"', $db->quoteSql('[[column]]')); - $this->assertEquals('"column"', $db->quoteSql('{{column}}')); + $db = $this->getConnection(); + $quoter = $db->getQuoter(); + + $this->assertEquals('"column"', $quoter->quoteColumnName('column')); + $this->assertEquals('"column"', $quoter->quoteColumnName('"column"')); + $this->assertEquals('[[column]]', $quoter->quoteColumnName('[[column]]')); + $this->assertEquals('{{column}}', $quoter->quoteColumnName('{{column}}')); + $this->assertEquals('(column)', $quoter->quoteColumnName('(column)')); + + $this->assertEquals('"column"', $quoter->quoteSql('[[column]]')); + $this->assertEquals('"column"', $quoter->quoteSql('{{column}}')); } public function testQuoteFullColumnName() { - $db = $this->getConnection(false, false); - $this->assertEquals('"table"."column"', $db->quoteColumnName('table.column')); - $this->assertEquals('"table"."column"', $db->quoteColumnName('table."column"')); - $this->assertEquals('"table"."column"', $db->quoteColumnName('"table".column')); - $this->assertEquals('"table"."column"', $db->quoteColumnName('"table"."column"')); - - $this->assertEquals('[[table.column]]', $db->quoteColumnName('[[table.column]]')); - $this->assertEquals('{{table}}."column"', $db->quoteColumnName('{{table}}.column')); - $this->assertEquals('{{table}}."column"', $db->quoteColumnName('{{table}}."column"')); - $this->assertEquals('{{table}}.[[column]]', $db->quoteColumnName('{{table}}.[[column]]')); - $this->assertEquals('{{%table}}."column"', $db->quoteColumnName('{{%table}}.column')); - $this->assertEquals('{{%table}}."column"', $db->quoteColumnName('{{%table}}."column"')); - - $this->assertEquals('"table"."column"', $db->quoteSql('[[table.column]]')); - $this->assertEquals('"table"."column"', $db->quoteSql('{{table}}.[[column]]')); - $this->assertEquals('"table"."column"', $db->quoteSql('{{table}}."column"')); - $this->assertEquals('"table"."column"', $db->quoteSql('{{%table}}.[[column]]')); - $this->assertEquals('"table"."column"', $db->quoteSql('{{%table}}."column"')); + $db = $this->getConnection(); + $quoter = $db->getQuoter(); + + $this->assertEquals('"table"."column"', $quoter->quoteColumnName('table.column')); + $this->assertEquals('"table"."column"', $quoter->quoteColumnName('table."column"')); + $this->assertEquals('"table"."column"', $quoter->quoteColumnName('"table".column')); + $this->assertEquals('"table"."column"', $quoter->quoteColumnName('"table"."column"')); + + $this->assertEquals('[[table.column]]', $quoter->quoteColumnName('[[table.column]]')); + $this->assertEquals('{{table}}."column"', $quoter->quoteColumnName('{{table}}.column')); + $this->assertEquals('{{table}}."column"', $quoter->quoteColumnName('{{table}}."column"')); + $this->assertEquals('{{table}}.[[column]]', $quoter->quoteColumnName('{{table}}.[[column]]')); + $this->assertEquals('{{%table}}."column"', $quoter->quoteColumnName('{{%table}}.column')); + $this->assertEquals('{{%table}}."column"', $quoter->quoteColumnName('{{%table}}."column"')); + + $this->assertEquals('"table"."column"', $quoter->quoteSql('[[table.column]]')); + $this->assertEquals('"table"."column"', $quoter->quoteSql('{{table}}.[[column]]')); + $this->assertEquals('"table"."column"', $quoter->quoteSql('{{table}}."column"')); + $this->assertEquals('"table"."column"', $quoter->quoteSql('{{%table}}.[[column]]')); + $this->assertEquals('"table"."column"', $quoter->quoteSql('{{%table}}."column"')); } public function testTransactionIsolation() { - $db = $this->getConnection(true); + $db = $this->getConnection(); - $transaction = $db->beginTransaction(Transaction::READ_COMMITTED); + $transaction = $db->beginTransaction(TransactionPDOOracle::READ_COMMITTED); $transaction->commit(); - /* should not be any exception so far */ $this->assertTrue(true); - $transaction = $db->beginTransaction(Transaction::SERIALIZABLE); + $transaction = $db->beginTransaction(TransactionPDOOracle::SERIALIZABLE); $transaction->commit(); - /* should not be any exception so far */ $this->assertTrue(true); } - /** - * Note: The READ UNCOMMITTED isolation level allows dirty reads. Oracle Database doesn't use dirty reads, nor does - * it even allow them. - * - * Change Transaction::READ_UNCOMMITTED => Transaction::READ_COMMITTED. - */ public function testTransactionShortcutCustom() { $db = $this->getConnection(true); - - $result = $db->transaction(static function (Connection $db) { + $result = $db->transaction(static function (ConnectionInterface $db) { $db->createCommand()->insert('profile', ['description' => 'test transaction shortcut'])->execute(); return true; - }, Transaction::READ_COMMITTED); - + }, TransactionPDOOracle::READ_COMMITTED); $this->assertTrue($result, 'transaction shortcut valid value should be returned from callback'); $profilesCount = $db->createCommand( @@ -158,10 +146,12 @@ public function testTransactionShortcutCustom() public function testQuoteValue() { - $db = $this->getConnection(false); - $this->assertEquals(123, $db->quoteValue(123)); - $this->assertEquals("'string'", $db->quoteValue('string')); - $this->assertEquals("'It''s interesting'", $db->quoteValue("It's interesting")); + $db = $this->getConnection(); + $quoter = $db->getQuoter(); + + $this->assertEquals(123, $quoter->quoteValue(123)); + $this->assertEquals("'string'", $quoter->quoteValue('string')); + $this->assertEquals("'It''s interesting'", $quoter->quoteValue("It's interesting")); } /** @@ -173,19 +163,16 @@ public function testGetPdoAfterClose(): void { $db = $this->getConnection(); - $db->setSlave('1', $this->createConnection(self::DB_DSN)); - + $db->setSlave('1', $this->getConnection()); $this->assertNotNull($db->getSlavePdo(false)); $db->close(); $masterPdo = $db->getMasterPdo(); - $this->assertNotFalse($masterPdo); $this->assertNotNull($masterPdo); $slavePdo = $db->getSlavePdo(false); - $this->assertNotFalse($slavePdo); $this->assertNotNull($slavePdo); $this->assertNotSame($masterPdo, $slavePdo); @@ -193,21 +180,18 @@ public function testGetPdoAfterClose(): void public function testServerStatusCacheWorks(): void { - $cacheKeyNormalizer = new CacheKeyNormalizer(); $db = $this->getConnection(); + $cacheKeyNormalizer = new CacheKeyNormalizer(); - $db->setMaster('1', $this->createConnection(self::DB_DSN)); - + $db->setMaster('1', $this->getConnection()); $db->setShuffleMasters(false); $cacheKey = $cacheKeyNormalizer->normalize( - ['Yiisoft\Db\Connection\Connection::openFromPoolSequentially', $db->getDsn()] + ['Yiisoft\Db\Connection\Connection::openFromPoolSequentially', $db->getDriver()->getDsn()] ); - $this->assertFalse($this->cache->psr()->has($cacheKey)); $db->open(); - $this->assertFalse( $this->cache->psr()->has($cacheKey), 'Connection was successful – cache must not contain information about this DSN' @@ -215,14 +199,11 @@ public function testServerStatusCacheWorks(): void $db->close(); - $db = $this->getConnection(); - $cacheKey = $cacheKeyNormalizer->normalize( ['Yiisoft\Db\Connection\Connection::openFromPoolSequentially', 'host:invalid'] ); - $db->setMaster('1', $this->createConnection('host:invalid')); - + $db->setMaster('1', $this->getConnection(false, 'host:invalid')); $db->setShuffleMasters(true); try { @@ -240,24 +221,19 @@ public function testServerStatusCacheWorks(): void public function testServerStatusCacheCanBeDisabled(): void { - $cacheKeyNormalizer = new CacheKeyNormalizer(); - $db = $this->getConnection(); + $cacheKeyNormalizer = new CacheKeyNormalizer(); - $db->setMaster('1', $this->createConnection(self::DB_DSN)); - + $db->setMaster('1', $this->getConnection()); $this->schemaCache->setEnable(false); - $db->setShuffleMasters(false); $cacheKey = $cacheKeyNormalizer->normalize( - ['Yiisoft\Db\Connection\Connection::openFromPoolSequentially::', $db->getDsn()] + ['Yiisoft\Db\Connection\Connection::openFromPoolSequentially::', $db->getDriver()->getDsn()] ); - $this->assertFalse($this->cache->psr()->has($cacheKey)); $db->open(); - $this->assertFalse($this->cache->psr()->has($cacheKey), 'Caching is disabled'); $db->close(); @@ -265,8 +241,7 @@ public function testServerStatusCacheCanBeDisabled(): void $cacheKey = $cacheKeyNormalizer->normalize( ['Yiisoft\Db\Connection\Connection::openFromPoolSequentially', 'host:invalid'] ); - - $db->setMaster('1', $this->createConnection('host:invalid')); + $db->setMaster('1', $this->getConnection(false, 'host:invalid')); try { $db->open(); diff --git a/tests/Provider/QueryBuilderProvider.php b/tests/Provider/QueryBuilderProvider.php new file mode 100644 index 0000000..a068550 --- /dev/null +++ b/tests/Provider/QueryBuilderProvider.php @@ -0,0 +1,340 @@ + '!%', + '\_' => '!_', + '!' => '!!', + ]; + + public function addDropChecksProvider(): array + { + $tableName = 'T_constraints_1'; + $name = 'CN_check'; + + return [ + 'drop' => [ + "ALTER TABLE {{{$tableName}}} DROP CONSTRAINT [[$name]]", + static function (QueryBuilderInterface $qb) use ($tableName, $name) { + return $qb->dropCheck($name, $tableName); + }, + ], + 'add' => [ + "ALTER TABLE {{{$tableName}}} ADD CONSTRAINT [[$name]] CHECK ([[C_not_null]] > 100)", + static function (QueryBuilderInterface $qb) use ($tableName, $name) { + return $qb->addCheck($name, $tableName, '[[C_not_null]] > 100'); + }, + ], + ]; + } + + public function addDropForeignKeysProvider() + { + $tableName = 'T_constraints_3'; + $name = 'CN_constraints_3'; + $pkTableName = 'T_constraints_2'; + return [ + 'drop' => [ + "ALTER TABLE {{{$tableName}}} DROP CONSTRAINT [[$name]]", + function (QueryBuilderInterface $qb) use ($tableName, $name) { + return $qb->dropForeignKey($name, $tableName); + }, + ], + 'add' => [ + "ALTER TABLE {{{$tableName}}} ADD CONSTRAINT [[$name]] FOREIGN KEY ([[C_fk_id_1]]) REFERENCES {{{$pkTableName}}} ([[C_id_1]]) ON DELETE CASCADE", + function (QueryBuilderInterface $qb) use ($tableName, $name, $pkTableName) { + return $qb->addForeignKey($name, $tableName, 'C_fk_id_1', $pkTableName, 'C_id_1', 'CASCADE'); + }, + ], + 'add (2 columns)' => [ + "ALTER TABLE {{{$tableName}}} ADD CONSTRAINT [[$name]] FOREIGN KEY ([[C_fk_id_1]], [[C_fk_id_2]]) REFERENCES {{{$pkTableName}}} ([[C_id_1]], [[C_id_2]]) ON DELETE CASCADE", + function (QueryBuilderInterface $qb) use ($tableName, $name, $pkTableName) { + return $qb->addForeignKey($name, $tableName, 'C_fk_id_1, C_fk_id_2', $pkTableName, 'C_id_1, C_id_2', 'CASCADE'); + }, + ], + ]; + } + + public function addDropPrimaryKeysProvider(): array + { + return (new BaseQueryBuilderProvider($this->getConnection()))->addDropPrimaryKeysProvider(); + } + + public function addDropUniquesProvider(): array + { + return (new BaseQueryBuilderProvider($this->getConnection()))->addDropUniquesProvider(); + } + + public function batchInsertProvider(): array + { + $data = (new BaseQueryBuilderProvider($this->getConnection()))->batchInsertProvider(); + + $data[0][3] = 'INSERT ALL INTO "customer" ("email", "name", "address") ' . + "VALUES ('test@example.com', 'silverfire', 'Kyiv {{city}}, Ukraine') SELECT 1 FROM SYS.DUAL"; + + $data['escape-danger-chars']['expected'] = 'INSERT ALL INTO "customer" ("address") ' . + "VALUES ('SQL-danger chars are escaped: ''); --') SELECT 1 FROM SYS.DUAL"; + + $data[2][3] = 'INSERT ALL INTO "customer" () ' . + "VALUES ('no columns passed') SELECT 1 FROM SYS.DUAL"; + + $data['bool-false, bool2-null'][1] = ['[[bool_col]]', '[[bool_col2]]']; + $data['bool-false, bool2-null']['expected'] = 'INSERT ALL INTO "type" ([[bool_col]], [[bool_col2]]) ' . + 'VALUES (0, NULL) SELECT 1 FROM SYS.DUAL'; + + $data[3][3] = 'INSERT ALL INTO {{%type}} ({{%type}}.[[float_col]], [[time]]) ' . + 'VALUES (NULL, now()) SELECT 1 FROM SYS.DUAL'; + + $data['bool-false, time-now()']['expected'] = 'INSERT ALL INTO {{%type}} ({{%type}}.[[bool_col]], [[time]]) ' . + 'VALUES (0, now()) SELECT 1 FROM SYS.DUAL'; + + return $data; + } + + public function buildConditionsProvider(): array + { + return (new BaseQueryBuilderProvider($this->getConnection()))->buildConditionsProvider(); + } + + public function buildExistsParamsProvider(): array + { + return (new BaseQueryBuilderProvider($this->getConnection()))->buildExistsParamsProvider(); + } + + public function buildFilterConditionProvider(): array + { + return (new BaseQueryBuilderProvider($this->getConnection()))->buildFilterConditionProvider(); + } + + public function buildFromDataProvider(): array + { + return (new BaseQueryBuilderProvider($this->getConnection()))->buildFromDataProvider(); + } + + public function buildLikeConditionsProvider(): array + { + $db = $this->getConnection(); + /* + * Different pdo_oci8 versions may or may not implement PDO::quote(), so + * \Yiisoft\Db\Schema\Schema::quoteValue() may or may not quote \. + */ + try { + $encodedBackslash = substr($db->getQuoter()->quoteValue('\\\\'), 1, -1); + $this->likeParameterReplacements[$encodedBackslash] = '\\'; + } catch (\Exception $e) { + $this->markTestSkipped('Could not execute Connection::quoteValue() method: ' . $e->getMessage()); + } + + return (new BaseQueryBuilderProvider( + $this->getConnection(), + $this->likeEscapeCharSql, + $this->likeParameterReplacements + ))->buildLikeConditionsProvider(); + } + + public function createDropIndexesProvider(): array + { + $result = (new BaseQueryBuilderProvider($this->getConnection()))->createDropIndexesProvider(); + $result['drop'][0] = 'DROP INDEX [[CN_constraints_2_single]]'; + return $result; + } + + public function deleteProvider(): array + { + return (new BaseQueryBuilderProvider($this->getConnection()))->deleteProvider(); + } + + public function insertProvider(): array + { + return [ + 'regular-values' => [ + 'customer', + [ + 'email' => 'test@example.com', + 'name' => 'silverfire', + 'address' => 'Kyiv {{city}}, Ukraine', + 'is_active' => false, + 'related_id' => null, + ], + [], + $this->replaceQuotes( + 'INSERT INTO [[customer]] ([[email]], [[name]], [[address]], [[is_active]], [[related_id]])' + . ' VALUES (:qp0, :qp1, :qp2, :qp3, :qp4)' + ), + [ + ':qp0' => 'test@example.com', + ':qp1' => 'silverfire', + ':qp2' => 'Kyiv {{city}}, Ukraine', + ':qp3' => false, + ':qp4' => null, + ], + ], + 'params-and-expressions' => [ + '{{%type}}', + [ + '{{%type}}.[[related_id]]' => null, + '[[time]]' => new Expression('now()'), + ], + [], + 'INSERT INTO {{%type}} ({{%type}}.[[related_id]], [[time]]) VALUES (:qp0, now())', + [ + ':qp0' => null, + ], + ], + 'carry passed params' => [ + 'customer', + [ + 'email' => 'test@example.com', + 'name' => 'sergeymakinen', + 'address' => '{{city}}', + 'is_active' => false, + 'related_id' => null, + 'col' => new Expression('CONCAT(:phFoo, :phBar)', [':phFoo' => 'foo']), + ], + [':phBar' => 'bar'], + $this->replaceQuotes( + 'INSERT INTO [[customer]] ([[email]], [[name]], [[address]], [[is_active]], [[related_id]], [[col]])' + . ' VALUES (:qp1, :qp2, :qp3, :qp4, :qp5, CONCAT(:phFoo, :phBar))' + ), + [ + ':phBar' => 'bar', + ':qp1' => 'test@example.com', + ':qp2' => 'sergeymakinen', + ':qp3' => '{{city}}', + ':qp4' => false, + ':qp5' => null, + ':phFoo' => 'foo', + ], + ], + 'carry passed params (query)' => [ + 'customer', + (new Query($this->getConnection())) + ->select([ + 'email', + 'name', + 'address', + 'is_active', + 'related_id', + ]) + ->from('customer') + ->where([ + 'email' => 'test@example.com', + 'name' => 'sergeymakinen', + 'address' => '{{city}}', + 'is_active' => false, + 'related_id' => null, + 'col' => new Expression('CONCAT(:phFoo, :phBar)', [':phFoo' => 'foo']), + ]), + [':phBar' => 'bar'], + $this->replaceQuotes( + 'INSERT INTO [[customer]] ([[email]], [[name]], [[address]], [[is_active]], [[related_id]])' + . ' SELECT [[email]], [[name]], [[address]], [[is_active]], [[related_id]] FROM [[customer]]' + . ' WHERE ([[email]]=:qp1) AND ([[name]]=:qp2) AND ([[address]]=:qp3) AND ([[is_active]]=:qp4)' + . ' AND ([[related_id]] IS NULL) AND ([[col]]=CONCAT(:phFoo, :phBar))' + ), + [ + ':phBar' => 'bar', + ':qp1' => 'test@example.com', + ':qp2' => 'sergeymakinen', + ':qp3' => '{{city}}', + ':qp4' => false, + ':phFoo' => 'foo', + ], + ], + ]; + } + + public function updateProvider(): array + { + return [ + [ + 'customer', + [ + 'status' => 1, + 'updated_at' => new Expression('now()'), + ], + [ + 'id' => 100, + ], + $this->replaceQuotes( + 'UPDATE [[customer]] SET [[status]]=:qp0, [[updated_at]]=now() WHERE [[id]]=:qp1' + ), + [ + ':qp0' => 1, + ':qp1' => 100, + ], + ], + ]; + } + + public function upsertProvider(): array + { + $concreteData = [ + 'regular values' => [ + 3 => 'MERGE INTO "T_upsert" USING (SELECT :qp0 AS "email", :qp1 AS "address", :qp2 AS "status", :qp3 AS "profile_id" FROM "DUAL") "EXCLUDED" ON ("T_upsert"."email"="EXCLUDED"."email") WHEN MATCHED THEN UPDATE SET "address"="EXCLUDED"."address", "status"="EXCLUDED"."status", "profile_id"="EXCLUDED"."profile_id" WHEN NOT MATCHED THEN INSERT ("email", "address", "status", "profile_id") VALUES ("EXCLUDED"."email", "EXCLUDED"."address", "EXCLUDED"."status", "EXCLUDED"."profile_id")', + ], + 'regular values with update part' => [ + 3 => 'MERGE INTO "T_upsert" USING (SELECT :qp0 AS "email", :qp1 AS "address", :qp2 AS "status", :qp3 AS "profile_id" FROM "DUAL") "EXCLUDED" ON ("T_upsert"."email"="EXCLUDED"."email") WHEN MATCHED THEN UPDATE SET "address"=:qp4, "status"=:qp5, "orders"=T_upsert.orders + 1 WHEN NOT MATCHED THEN INSERT ("email", "address", "status", "profile_id") VALUES ("EXCLUDED"."email", "EXCLUDED"."address", "EXCLUDED"."status", "EXCLUDED"."profile_id")', + ], + 'regular values without update part' => [ + 3 => 'MERGE INTO "T_upsert" USING (SELECT :qp0 AS "email", :qp1 AS "address", :qp2 AS "status", :qp3 AS "profile_id" FROM "DUAL") "EXCLUDED" ON ("T_upsert"."email"="EXCLUDED"."email") WHEN NOT MATCHED THEN INSERT ("email", "address", "status", "profile_id") VALUES ("EXCLUDED"."email", "EXCLUDED"."address", "EXCLUDED"."status", "EXCLUDED"."profile_id")', + ], + 'query' => [ + 3 => << [ + 3 => << [ + 3 => << [ + 3 => 'INSERT INTO {{%T_upsert}} ({{%T_upsert}}.[[email]], [[ts]]) VALUES (:qp0, now())', + ], + 'values and expressions with update part' => [ + 3 => 'INSERT INTO {{%T_upsert}} ({{%T_upsert}}.[[email]], [[ts]]) VALUES (:qp0, now())', + ], + 'values and expressions without update part' => [ + 3 => 'INSERT INTO {{%T_upsert}} ({{%T_upsert}}.[[email]], [[ts]]) VALUES (:qp0, now())', + ], + 'query, values and expressions with update part' => [ + 3 => 'MERGE INTO {{%T_upsert}} USING (SELECT :phEmail AS "email", now() AS [[time]]) "EXCLUDED" ON ({{%T_upsert}}."email"="EXCLUDED"."email") WHEN MATCHED THEN UPDATE SET "ts"=:qp1, [[orders]]=T_upsert.orders + 1 WHEN NOT MATCHED THEN INSERT ("email", [[time]]) VALUES ("EXCLUDED"."email", "EXCLUDED".[[time]])', + ], + 'query, values and expressions without update part' => [ + 3 => 'MERGE INTO {{%T_upsert}} USING (SELECT :phEmail AS "email", now() AS [[time]]) "EXCLUDED" ON ({{%T_upsert}}."email"="EXCLUDED"."email") WHEN MATCHED THEN UPDATE SET "ts"=:qp1, [[orders]]=T_upsert.orders + 1 WHEN NOT MATCHED THEN INSERT ("email", [[time]]) VALUES ("EXCLUDED"."email", "EXCLUDED".[[time]])', + ], + ]; + + $newData = (new BaseQueryBuilderProvider($this->getConnection()))->upsertProvider(); + + foreach ($concreteData as $testName => $data) { + $newData[$testName] = array_replace($newData[$testName], $data); + } + + // skip test + unset($newData['no columns to update']); + + return $newData; + } +} diff --git a/tests/QueryBuilderTest.php b/tests/QueryBuilderTest.php index 22dbb6e..937c93f 100644 --- a/tests/QueryBuilderTest.php +++ b/tests/QueryBuilderTest.php @@ -6,9 +6,11 @@ use Closure; use Yiisoft\Arrays\ArrayHelper; +use Yiisoft\Db\Connection\ConnectionInterface; +use Yiisoft\Db\Oracle\PDO\QueryBuilderPDOOracle; use yiisoft\Db\Query\Query; -use Yiisoft\Db\Oracle\QueryBuilder; -use Yiisoft\Db\TestUtility\TestQueryBuilderTrait; +use Yiisoft\Db\Query\QueryBuilderInterface; +use Yiisoft\Db\TestSupport\TestQueryBuilderTrait; /** * @group oracle @@ -17,186 +19,108 @@ final class QueryBuilderTest extends TestCase { use TestQueryBuilderTrait; - protected string $likeEscapeCharSql = " ESCAPE '!'"; - - protected array $likeParameterReplacements = [ - '\%' => '!%', - '\_' => '!_', - '!' => '!!', - ]; - - protected function getQueryBuilder(bool $reset = false): QueryBuilder - { - return new QueryBuilder($this->getConnection($reset)); - } - /** - * @dataProvider addDropChecksProviderTrait + * @dataProvider \Yiisoft\Db\Oracle\Tests\Provider\QueryBuilderProvider::addDropChecksProvider * * @param string $sql * @param Closure $builder */ public function testAddDropCheck(string $sql, Closure $builder): void { - $this->assertSame($this->getConnection()->quoteSql($sql), $builder($this->getQueryBuilder())); - } - - public function addDropForeignKeysProvider() - { - $tableName = 'T_constraints_3'; - $name = 'CN_constraints_3'; - $pkTableName = 'T_constraints_2'; - return [ - 'drop' => [ - "ALTER TABLE {{{$tableName}}} DROP CONSTRAINT [[$name]]", - function (QueryBuilder $qb) use ($tableName, $name) { - return $qb->dropForeignKey($name, $tableName); - }, - ], - 'add' => [ - "ALTER TABLE {{{$tableName}}} ADD CONSTRAINT [[$name]] FOREIGN KEY ([[C_fk_id_1]]) REFERENCES {{{$pkTableName}}} ([[C_id_1]]) ON DELETE CASCADE", - function (QueryBuilder $qb) use ($tableName, $name, $pkTableName) { - return $qb->addForeignKey($name, $tableName, 'C_fk_id_1', $pkTableName, 'C_id_1', 'CASCADE'); - }, - ], - 'add (2 columns)' => [ - "ALTER TABLE {{{$tableName}}} ADD CONSTRAINT [[$name]] FOREIGN KEY ([[C_fk_id_1]], [[C_fk_id_2]]) REFERENCES {{{$pkTableName}}} ([[C_id_1]], [[C_id_2]]) ON DELETE CASCADE", - function (QueryBuilder $qb) use ($tableName, $name, $pkTableName) { - return $qb->addForeignKey($name, $tableName, 'C_fk_id_1, C_fk_id_2', $pkTableName, 'C_id_1, C_id_2', 'CASCADE'); - }, - ], - ]; + $db = $this->getConnection(); + $this->assertSame($db->getQuoter()->quoteSql($sql), $builder($db->getQueryBuilder())); } /** - * @dataProvider addDropForeignKeysProvider + * @dataProvider \Yiisoft\Db\Oracle\Tests\Provider\QueryBuilderProvider::addDropForeignKeysProvider * * @param string $sql * @param Closure $builder */ public function testAddDropForeignKey(string $sql, Closure $builder): void { - $this->assertSame($this->getConnection()->quoteSql($sql), $builder($this->getQueryBuilder())); + $db = $this->getConnection(); + $this->assertSame($db->getQuoter()->quoteSql($sql), $builder($db->getQueryBuilder())); } /** - * @dataProvider addDropPrimaryKeysProviderTrait + * @dataProvider \Yiisoft\Db\Oracle\Tests\Provider\QueryBuilderProvider::addDropPrimaryKeysProvider * * @param string $sql * @param Closure $builder */ public function testAddDropPrimaryKey(string $sql, Closure $builder): void { - $this->assertSame($this->getConnection()->quoteSql($sql), $builder($this->getQueryBuilder())); + $db = $this->getConnection(); + $this->assertSame($db->getQuoter()->quoteSql($sql), $builder($db->getQueryBuilder())); } /** - * @dataProvider addDropUniquesProviderTrait + * @dataProvider \Yiisoft\Db\Oracle\Tests\Provider\QueryBuilderProvider::addDropUniquesProvider * * @param string $sql * @param Closure $builder */ public function testAddDropUnique(string $sql, Closure $builder): void { - $this->assertSame($this->getConnection()->quoteSql($sql), $builder($this->getQueryBuilder())); - } - - public function batchInsertProvider(): array - { - $data = $this->batchInsertProviderTrait(); - - $data[0][3] = 'INSERT ALL INTO "customer" ("email", "name", "address") ' . - "VALUES ('test@example.com', 'silverfire', 'Kyiv {{city}}, Ukraine') SELECT 1 FROM SYS.DUAL"; - - $data['escape-danger-chars']['expected'] = 'INSERT ALL INTO "customer" ("address") ' . - "VALUES ('SQL-danger chars are escaped: ''); --') SELECT 1 FROM SYS.DUAL"; - - $data[2][3] = 'INSERT ALL INTO "customer" () ' . - "VALUES ('no columns passed') SELECT 1 FROM SYS.DUAL"; - - $data['bool-false, bool2-null'][1] = ['[[bool_col]]', '[[bool_col2]]']; - $data['bool-false, bool2-null']['expected'] = 'INSERT ALL INTO "type" ([[bool_col]], [[bool_col2]]) ' . - 'VALUES (0, NULL) SELECT 1 FROM SYS.DUAL'; - - $data[3][3] = 'INSERT ALL INTO {{%type}} ({{%type}}.[[float_col]], [[time]]) ' . - 'VALUES (NULL, now()) SELECT 1 FROM SYS.DUAL'; - - $data['bool-false, time-now()']['expected'] = 'INSERT ALL INTO {{%type}} ({{%type}}.[[bool_col]], [[time]]) ' . - 'VALUES (0, now()) SELECT 1 FROM SYS.DUAL'; - - return $data; + $db = $this->getConnection(); + $this->assertSame($db->getQuoter()->quoteSql($sql), $builder($db->getQueryBuilder())); } /** - * @dataProvider batchInsertProvider + * @dataProvider \Yiisoft\Db\Oracle\Tests\Provider\QueryBuilderProvider::batchInsertProvider * * @param string $table * @param array $columns - * @param $value + * @param array $value * @param string $expected * - * @throws Exception - * @throws InvalidArgumentException - * @throws InvalidConfigException - * @throws NotSupportedException + * @throws Exception|InvalidArgumentException|InvalidConfigException|NotSupportedException */ public function testBatchInsert(string $table, array $columns, array $value, string $expected): void { - $queryBuilder = $this->getQueryBuilder(); - - $sql = $queryBuilder->batchInsert($table, $columns, $value); - - $this->assertEquals($expected, $sql); + $db = $this->getConnection(); + $this->assertEquals($expected, $db->getQueryBuilder()->batchInsert($table, $columns, $value)); } /** - * @dataProvider buildConditionsProviderTrait + * @dataProvider \Yiisoft\Db\Oracle\Tests\Provider\QueryBuilderProvider::buildConditionsProvider * * @param array|ExpressionInterface $condition * @param string $expected * @param array $expectedParams * - * @throws Exception - * @throws InvalidArgumentException - * @throws InvalidConfigException - * @throws NotSupportedException + * @throws Exception|InvalidArgumentException|InvalidConfigException|NotSupportedException */ public function testBuildCondition($condition, string $expected, array $expectedParams): void { $db = $this->getConnection(); - $query = (new Query($db))->where($condition); - - [$sql, $params] = $this->getQueryBuilder()->build($query); - + [$sql, $params] = $db->getQueryBuilder()->build($query); $this->assertEquals('SELECT *' . (empty($expected) ? '' : ' WHERE ' . $this->replaceQuotes($expected)), $sql); $this->assertEquals($expectedParams, $params); } /** - * @dataProvider buildFilterConditionProviderTrait + * @dataProvider \Yiisoft\Db\Oracle\Tests\Provider\QueryBuilderProvider::buildFilterConditionProvider * * @param array $condition * @param string $expected * @param array $expectedParams * - * @throws Exception - * @throws InvalidArgumentException - * @throws InvalidConfigException - * @throws NotSupportedException + * @throws Exception|InvalidArgumentException|InvalidConfigException|NotSupportedException */ public function testBuildFilterCondition(array $condition, string $expected, array $expectedParams): void { - $query = (new Query($this->getConnection()))->filterWhere($condition); - - [$sql, $params] = $this->getQueryBuilder()->build($query); - + $db = $this->getConnection(); + $query = (new Query($db))->filterWhere($condition); + [$sql, $params] = $db->getQueryBuilder()->build($query); $this->assertEquals('SELECT *' . (empty($expected) ? '' : ' WHERE ' . $this->replaceQuotes($expected)), $sql); $this->assertEquals($expectedParams, $params); } /** - * @dataProvider buildFromDataProviderTrait + * @dataProvider \Yiisoft\Db\Oracle\Tests\Provider\QueryBuilderProvider::buildFromDataProvider * * @param string $table * @param string $expected @@ -205,159 +129,132 @@ public function testBuildFilterCondition(array $condition, string $expected, arr */ public function testBuildFrom(string $table, string $expected): void { + $db = $this->getConnection(); $params = []; - - $sql = $this->getQueryBuilder()->buildFrom([$table], $params); - + $sql = $db->getQueryBuilder()->buildFrom([$table], $params); $this->assertEquals('FROM ' . $this->replaceQuotes($expected), $sql); } - public function buildLikeConditionsProvider(): array - { - /* - * Different pdo_oci8 versions may or may not implement PDO::quote(), so - * \Yiisoft\Db\Schema\Schema::quoteValue() may or may not quote \. - */ - try { - $encodedBackslash = substr($this->getDb()->quoteValue('\\\\'), 1, -1); - $this->likeParameterReplacements[$encodedBackslash] = '\\'; - } catch (\Exception $e) { - $this->markTestSkipped('Could not execute Connection::quoteValue() method: ' . $e->getMessage()); - } - - return $this->buildLikeConditionsProviderTrait(); - } - /** - * @dataProvider buildLikeConditionsProvider + * @dataProvider \Yiisoft\Db\Oracle\Tests\Provider\QueryBuilderProvider::buildLikeConditionsProvider * * @param array|object $condition * @param string $expected * @param array $expectedParams * - * @throws Exception - * @throws InvalidArgumentException - * @throws InvalidConfigException - * @throws NotSupportedException + * @throws Exception|InvalidArgumentException|InvalidConfigException|NotSupportedException */ public function testBuildLikeCondition($condition, string $expected, array $expectedParams): void { $db = $this->getConnection(); - $query = (new Query($db))->where($condition); - - [$sql, $params] = $this->getQueryBuilder()->build($query); - + [$sql, $params] = $db->getQueryBuilder()->build($query); $this->assertEquals('SELECT *' . (empty($expected) ? '' : ' WHERE ' . $this->replaceQuotes($expected)), $sql); $this->assertEquals($expectedParams, $params); } /** - * @dataProvider buildExistsParamsProviderTrait + * @dataProvider \Yiisoft\Db\Oracle\Tests\Provider\QueryBuilderProvider::buildExistsParamsProvider * * @param string $cond * @param string $expectedQuerySql * - * @throws Exception - * @throws InvalidArgumentException - * @throws InvalidConfigException - * @throws NotSupportedException + * @throws Exception|InvalidArgumentException|InvalidConfigException|NotSupportedException */ public function testBuildWhereExists(string $cond, string $expectedQuerySql): void { $db = $this->getConnection(); - $expectedQueryParams = []; - $subQuery = new Query($db); - - $subQuery->select('1') - ->from('Website w'); - + $subQuery->select('1')->from('Website w'); $query = new Query($db); - - $query->select('id') - ->from('TotalExample t') - ->where([$cond, $subQuery]); - - [$actualQuerySql, $actualQueryParams] = $this->getQueryBuilder()->build($query); - + $query->select('id')->from('TotalExample t')->where([$cond, $subQuery]); + [$actualQuerySql, $actualQueryParams] = $db->getQueryBuilder()->build($query); $this->assertEquals($expectedQuerySql, $actualQuerySql); $this->assertEquals($expectedQueryParams, $actualQueryParams); } + /** + * @dataProvider \Yiisoft\Db\Oracle\Tests\Provider\QueryBuilderProvider::createDropIndexesProvider + * + * @param string $sql + */ + public function testCreateDropIndex(string $sql, Closure $builder): void + { + $db = $this->getConnection(); + $this->assertSame($db->getQuoter()->quoteSql($sql), $builder($db->getQueryBuilder())); + } + public function testCommentColumn() { - $qb = $this->getQueryBuilder(); + $db = $this->getConnection(); + $ddl = $db->getQueryBuilder(); $expected = "COMMENT ON COLUMN [[comment]].[[text]] IS 'This is my column.'"; - $sql = $qb->addCommentOnColumn('comment', 'text', 'This is my column.'); + $sql = $ddl->addCommentOnColumn('comment', 'text', 'This is my column.'); $this->assertEquals($this->replaceQuotes($expected), $sql); $expected = "COMMENT ON COLUMN [[comment]].[[text]] IS ''"; - $sql = $qb->dropCommentFromColumn('comment', 'text'); + $sql = $ddl->dropCommentFromColumn('comment', 'text'); $this->assertEquals($this->replaceQuotes($expected), $sql); } public function testCommentTable() { - $qb = $this->getQueryBuilder(); + $db = $this->getConnection(); + $ddl = $db->getQueryBuilder(); $expected = "COMMENT ON TABLE [[comment]] IS 'This is my table.'"; - $sql = $qb->addCommentOnTable('comment', 'This is my table.'); + $sql = $ddl->addCommentOnTable('comment', 'This is my table.'); $this->assertEquals($this->replaceQuotes($expected), $sql); $expected = "COMMENT ON TABLE [[comment]] IS ''"; - $sql = $qb->dropCommentFromTable('comment'); + $sql = $ddl->dropCommentFromTable('comment'); $this->assertEquals($this->replaceQuotes($expected), $sql); } - public function createDropIndexesProvider(): array - { - $result = $this->createDropIndexesProviderTrait(); - - $result['drop'][0] = 'DROP INDEX [[CN_constraints_2_single]]'; - - return $result; - } - /** - * @dataProvider createDropIndexesProvider + * @dataProvider \Yiisoft\Db\Oracle\Tests\Provider\QueryBuilderProvider::deleteProvider * - * @param string $sql + * @param string $table + * @param array|string $condition + * @param string $expectedSQL + * @param array $expectedParams + * + * @throws Exception|InvalidArgumentException|InvalidConfigException|NotSupportedException */ - public function testCreateDropIndex(string $sql, Closure $builder): void + public function testDelete(string $table, $condition, string $expectedSQL, array $expectedParams): void { - $this->assertSame($this->getConnection()->quoteSql($sql), $builder($this->getQueryBuilder())); + $actualParams = []; + $db = $this->getConnection(); + $this->assertSame($expectedSQL, $db->getQueryBuilder()->delete($table, $condition, $actualParams)); + $this->assertSame($expectedParams, $actualParams); } /** - * @dataProvider deleteProviderTrait + * @dataProvider \Yiisoft\Db\Oracle\Tests\Provider\QueryBuilderProvider::insertProvider * * @param string $table - * @param array|string $condition + * @param array|ColumnSchema $columns + * @param array $params * @param string $expectedSQL * @param array $expectedParams * - * @throws Exception - * @throws InvalidArgumentException - * @throws InvalidConfigException - * @throws NotSupportedException + * @throws Exception|InvalidArgumentException|InvalidConfigException|NotSupportedException */ - public function testDelete(string $table, $condition, string $expectedSQL, array $expectedParams): void + public function testInsert(string $table, $columns, array $params, string $expectedSQL, array $expectedParams): void { - $actualParams = []; - - $actualSQL = $this->getQueryBuilder()->delete($table, $condition, $actualParams); - + $actualParams = $params; + $db = $this->getConnection(); + $actualSQL = $db->getQueryBuilder()->insert($table, $columns, $actualParams); $this->assertSame($expectedSQL, $actualSQL); $this->assertSame($expectedParams, $actualParams); } public function testResetSequence() { - $db = $this->getConnection(true); - $qb = $this->getQueryBuilder(); + $db = $this->getConnection(); + $qb = $db->getQueryBuilder(); $sqlResult = "SELECT last_number FROM user_sequences WHERE sequence_name = 'item_SEQ'"; @@ -371,31 +268,7 @@ public function testResetSequence() } /** - * @dataProvider insertProviderTrait - * - * @param string $table - * @param array|ColumnSchema $columns - * @param array $params - * @param string $expectedSQL - * @param array $expectedParams - * - * @throws Exception - * @throws InvalidArgumentException - * @throws InvalidConfigException - * @throws NotSupportedException - */ - public function testInsert(string $table, $columns, array $params, string $expectedSQL, array $expectedParams): void - { - $actualParams = $params; - - $actualSQL = $this->getQueryBuilder()->insert($table, $columns, $actualParams); - - $this->assertSame($expectedSQL, $actualSQL); - $this->assertSame($expectedParams, $actualParams); - } - - /** - * @dataProvider updateProviderTrait + * @dataProvider \Yiisoft\Db\Oracle\Tests\Provider\QueryBuilderProvider::updateProvider * * @param string $table * @param array $columns @@ -403,10 +276,7 @@ public function testInsert(string $table, $columns, array $params, string $expec * @param string $expectedSQL * @param array $expectedParams * - * @throws Exception - * @throws InvalidArgumentException - * @throws InvalidConfigException - * @throws NotSupportedException + * @throws Exception|InvalidArgumentException|InvalidConfigException|NotSupportedException */ public function testUpdate( string $table, @@ -416,77 +286,13 @@ public function testUpdate( array $expectedParams ): void { $actualParams = []; - - $actualSQL = $this->getQueryBuilder()->update($table, $columns, $condition, $actualParams); - - $this->assertSame($expectedSQL, $actualSQL); + $db = $this->getConnection(); + $this->assertSame($expectedSQL, $db->getQueryBuilder()->update($table, $columns, $condition, $actualParams)); $this->assertSame($expectedParams, $actualParams); } - public function upsertProvider(): array - { - $concreteData = [ - 'regular values' => [ - 3 => 'MERGE INTO "T_upsert" USING (SELECT :qp0 AS "email", :qp1 AS "address", :qp2 AS "status", :qp3 AS "profile_id" FROM "DUAL") "EXCLUDED" ON ("T_upsert"."email"="EXCLUDED"."email") WHEN MATCHED THEN UPDATE SET "address"="EXCLUDED"."address", "status"="EXCLUDED"."status", "profile_id"="EXCLUDED"."profile_id" WHEN NOT MATCHED THEN INSERT ("email", "address", "status", "profile_id") VALUES ("EXCLUDED"."email", "EXCLUDED"."address", "EXCLUDED"."status", "EXCLUDED"."profile_id")', - ], - 'regular values with update part' => [ - 3 => 'MERGE INTO "T_upsert" USING (SELECT :qp0 AS "email", :qp1 AS "address", :qp2 AS "status", :qp3 AS "profile_id" FROM "DUAL") "EXCLUDED" ON ("T_upsert"."email"="EXCLUDED"."email") WHEN MATCHED THEN UPDATE SET "address"=:qp4, "status"=:qp5, "orders"=T_upsert.orders + 1 WHEN NOT MATCHED THEN INSERT ("email", "address", "status", "profile_id") VALUES ("EXCLUDED"."email", "EXCLUDED"."address", "EXCLUDED"."status", "EXCLUDED"."profile_id")', - ], - 'regular values without update part' => [ - 3 => 'MERGE INTO "T_upsert" USING (SELECT :qp0 AS "email", :qp1 AS "address", :qp2 AS "status", :qp3 AS "profile_id" FROM "DUAL") "EXCLUDED" ON ("T_upsert"."email"="EXCLUDED"."email") WHEN NOT MATCHED THEN INSERT ("email", "address", "status", "profile_id") VALUES ("EXCLUDED"."email", "EXCLUDED"."address", "EXCLUDED"."status", "EXCLUDED"."profile_id")', - ], - 'query' => [ - 3 => 'MERGE INTO "T_upsert" USING (WITH USER_SQL AS (SELECT "email", 2 AS "status" FROM "customer" WHERE "name"=:qp0), - PAGINATION AS (SELECT USER_SQL.*, rownum as rowNumId FROM USER_SQL) -SELECT * -FROM PAGINATION -WHERE rownum <= 1) "EXCLUDED" ON ("T_upsert"."email"="EXCLUDED"."email") WHEN MATCHED THEN UPDATE SET "status"="EXCLUDED"."status" WHEN NOT MATCHED THEN INSERT ("email", "status") VALUES ("EXCLUDED"."email", "EXCLUDED"."status")', - ], - 'query with update part' => [ - 3 => 'MERGE INTO "T_upsert" USING (WITH USER_SQL AS (SELECT "email", 2 AS "status" FROM "customer" WHERE "name"=:qp0), - PAGINATION AS (SELECT USER_SQL.*, rownum as rowNumId FROM USER_SQL) -SELECT * -FROM PAGINATION -WHERE rownum <= 1) "EXCLUDED" ON ("T_upsert"."email"="EXCLUDED"."email") WHEN MATCHED THEN UPDATE SET "address"=:qp1, "status"=:qp2, "orders"=T_upsert.orders + 1 WHEN NOT MATCHED THEN INSERT ("email", "status") VALUES ("EXCLUDED"."email", "EXCLUDED"."status")', - ], - 'query without update part' => [ - 3 => 'MERGE INTO "T_upsert" USING (WITH USER_SQL AS (SELECT "email", 2 AS "status" FROM "customer" WHERE "name"=:qp0), - PAGINATION AS (SELECT USER_SQL.*, rownum as rowNumId FROM USER_SQL) -SELECT * -FROM PAGINATION -WHERE rownum <= 1) "EXCLUDED" ON ("T_upsert"."email"="EXCLUDED"."email") WHEN NOT MATCHED THEN INSERT ("email", "status") VALUES ("EXCLUDED"."email", "EXCLUDED"."status")', - ], - 'values and expressions' => [ - 3 => 'INSERT INTO {{%T_upsert}} ({{%T_upsert}}.[[email]], [[ts]]) VALUES (:qp0, now())', - ], - 'values and expressions with update part' => [ - 3 => 'INSERT INTO {{%T_upsert}} ({{%T_upsert}}.[[email]], [[ts]]) VALUES (:qp0, now())', - ], - 'values and expressions without update part' => [ - 3 => 'INSERT INTO {{%T_upsert}} ({{%T_upsert}}.[[email]], [[ts]]) VALUES (:qp0, now())', - ], - 'query, values and expressions with update part' => [ - 3 => 'MERGE INTO {{%T_upsert}} USING (SELECT :phEmail AS "email", now() AS [[time]]) "EXCLUDED" ON ({{%T_upsert}}."email"="EXCLUDED"."email") WHEN MATCHED THEN UPDATE SET "ts"=:qp1, [[orders]]=T_upsert.orders + 1 WHEN NOT MATCHED THEN INSERT ("email", [[time]]) VALUES ("EXCLUDED"."email", "EXCLUDED".[[time]])', - ], - 'query, values and expressions without update part' => [ - 3 => 'MERGE INTO {{%T_upsert}} USING (SELECT :phEmail AS "email", now() AS [[time]]) "EXCLUDED" ON ({{%T_upsert}}."email"="EXCLUDED"."email") WHEN MATCHED THEN UPDATE SET "ts"=:qp1, [[orders]]=T_upsert.orders + 1 WHEN NOT MATCHED THEN INSERT ("email", [[time]]) VALUES ("EXCLUDED"."email", "EXCLUDED".[[time]])', - ], - ]; - - $newData = $this->upsertProviderTrait(); - - foreach ($concreteData as $testName => $data) { - $newData[$testName] = array_replace($newData[$testName], $data); - } - - // skip test - unset($newData['no columns to update']); - - return $newData; - } - /** - * @dataProvider upsertProvider + * @dataProvider \Yiisoft\Db\Oracle\Tests\Provider\QueryBuilderProvider::upsertProvider * * @param string $table * @param array|ColumnSchema $insertColumns @@ -494,15 +300,13 @@ public function upsertProvider(): array * @param string|string[] $expectedSQL * @param array $expectedParams * - * @throws NotSupportedException - * @throws Exception + * @throws Exception|NotSupportedException */ public function testUpsert(string $table, $insertColumns, $updateColumns, $expectedSQL, array $expectedParams): void { $actualParams = []; - - $actualSQL = $this->getQueryBuilder() - ->upsert($table, $insertColumns, $updateColumns, $actualParams); + $db = $this->getConnection(); + $actualSQL = $db->getQueryBuilder()->upsert($table, $insertColumns, $updateColumns, $actualParams); if (is_string($expectedSQL)) { $this->assertEqualsWithoutLE($expectedSQL, $actualSQL); @@ -516,4 +320,5 @@ public function testUpsert(string $table, $insertColumns, $updateColumns, $expec $this->assertIsOneOf($actualParams, $expectedParams); } } + } diff --git a/tests/QueryTest.php b/tests/QueryTest.php index b672ba5..3dc5bf0 100644 --- a/tests/QueryTest.php +++ b/tests/QueryTest.php @@ -4,7 +4,7 @@ namespace Yiisoft\Db\Oracle\Tests; -use Yiisoft\Db\TestUtility\TestQueryTrait; +use Yiisoft\Db\TestSupport\TestQueryTrait; /** * @group oracle diff --git a/tests/SchemaTest.php b/tests/SchemaTest.php index bfe7287..fcb4602 100644 --- a/tests/SchemaTest.php +++ b/tests/SchemaTest.php @@ -9,8 +9,8 @@ use Yiisoft\Db\Exception\NotSupportedException; use Yiisoft\Db\Oracle\Schema; use Yiisoft\Db\Oracle\TableSchema; -use Yiisoft\Db\TestUtility\AnyValue; -use Yiisoft\Db\TestUtility\TestSchemaTrait; +use Yiisoft\Db\TestSupport\AnyValue; +use Yiisoft\Db\TestSupport\TestSchemaTrait; /** * @group oracle diff --git a/tests/TestCase.php b/tests/TestCase.php index 8832de6..d0c374e 100644 --- a/tests/TestCase.php +++ b/tests/TestCase.php @@ -4,39 +4,62 @@ namespace Yiisoft\Db\Oracle\Tests; +use Exception; use PHPUnit\Framework\TestCase as AbstractTestCase; use Yiisoft\Db\Connection\ConnectionInterface; -use Yiisoft\Db\TestUtility\TestTrait; +use Yiisoft\Db\Driver\PDODriver; +use Yiisoft\Db\Oracle\PDO\ConnectionPDOOracle; +use Yiisoft\Db\TestSupport\TestTrait; class TestCase extends AbstractTestCase { use TestTrait; - protected const DB_CONNECTION_CLASS = \Yiisoft\Db\Oracle\Connection::class; - protected const DB_DRIVERNAME = 'oci'; - protected const DB_DSN = 'oci:dbname=localhost/XE;'; - protected const DB_FIXTURES_PATH = __DIR__ . '/Fixture/oci.sql'; - protected const DB_USERNAME = 'system'; - protected const DB_PASSWORD = 'oracle'; - protected const DB_CHARSET = 'AL32UTF8'; + protected string $drivername = 'oci'; + protected string $dsn = 'oci:dbname=localhost/XE;'; + protected string $username = 'system'; + protected string $password = 'oracle'; + protected string $charset = 'AL32UTF8'; protected array $dataProvider; protected string $likeEscapeCharSql = ''; protected array $likeParameterReplacements = []; - protected ConnectionInterface $connection; + protected ?ConnectionPDOOracle $db = null; - protected function setUp(): void - { - parent::setUp(); - $this->connection = $this->createConnection(self::DB_DSN); + /** + * @param bool $reset whether to clean up the test database. + * + * @return ConnectionPDOOracle + */ + protected function getConnection( + $reset = false, + ?string $dsn = null, + string $fixture = __DIR__ . '/Fixture/oci.sql' + ): ConnectionPDOOracle { + $pdoDriver = new PDODriver($dsn ?? $this->dsn, $this->username, $this->password); + $this->db = new ConnectionPDOOracle($pdoDriver, $this->createQueryCache(), $this->createSchemaCache()); + $this->db->setLogger($this->createLogger()); + $this->db->setProfiler($this->createProfiler()); + + if ($reset === false) { + return $this->db; + } + + try { + $this->prepareDatabase($this->db, $fixture); + } catch (Exception $e) { + $this->markTestSkipped('Something wrong when preparing database: ' . $e->getMessage()); + } + + return $this->db; } protected function tearDown(): void { parent::tearDown(); - $this->connection->close(); + $this->db?->close(); unset( $this->cache, - $this->connection, + $this->db, $this->logger, $this->queryCache, $this->schemaCache,