diff --git a/.github/workflows/test-phpunit.yml b/.github/workflows/test-phpunit.yml index 6908f2be88e2..5f2189f41e42 100644 --- a/.github/workflows/test-phpunit.yml +++ b/.github/workflows/test-phpunit.yml @@ -31,7 +31,7 @@ jobs: fail-fast: false matrix: php-versions: ['7.4', '8.0', '8.1'] - db-platforms: ['MySQLi', 'Postgre', 'SQLite3', 'SQLSRV'] + db-platforms: ['MySQLi', 'Postgre', 'SQLite3', 'SQLSRV', 'OCI8'] mysql-versions: ['5.7'] include: - php-versions: '7.4' @@ -68,6 +68,14 @@ jobs: - 1433:1433 options: --health-cmd="/opt/mssql-tools/bin/sqlcmd -S 127.0.0.1 -U sa -P 1Secure*Password1 -Q 'SELECT @@VERSION'" --health-interval=10s --health-timeout=5s --health-retries=3 + oracle: + image: quillbuilduser/oracle-18-xe + env: + ORACLE_ALLOW_REMOTE: true + ports: + - 1521:1521 + options: --health-cmd="/opt/oracle/product/18c/dbhomeXE/bin/sqlplus -s sys/Oracle18@oracledbxe/XE as sysdba <<< 'SELECT 1 FROM DUAL'" --health-interval=10s --health-timeout=5s --health-retries=3 + redis: image: redis ports: @@ -84,6 +92,28 @@ jobs: if: matrix.db-platforms == 'SQLSRV' run: sqlcmd -S 127.0.0.1 -U sa -P 1Secure*Password1 -Q "CREATE DATABASE test" + - name: Install Oracle InstantClient + if: matrix.db-platforms == 'OCI8' + run: | + sudo apt-get install wget libaio1 alien + sudo wget https://download.oracle.com/otn_software/linux/instantclient/185000/oracle-instantclient18.5-basic-18.5.0.0.0-3.x86_64.rpm + sudo wget https://download.oracle.com/otn_software/linux/instantclient/185000/oracle-instantclient18.5-devel-18.5.0.0.0-3.x86_64.rpm + sudo wget https://download.oracle.com/otn_software/linux/instantclient/185000/oracle-instantclient18.5-sqlplus-18.5.0.0.0-3.x86_64.rpm + sudo alien oracle-instantclient18.5-basic-18.5.0.0.0-3.x86_64.rpm + sudo alien oracle-instantclient18.5-devel-18.5.0.0.0-3.x86_64.rpm + sudo alien oracle-instantclient18.5-sqlplus-18.5.0.0.0-3.x86_64.rpm + sudo dpkg -i oracle-instantclient18.5-basic_18.5.0.0.0-4_amd64.deb oracle-instantclient18.5-devel_18.5.0.0.0-4_amd64.deb oracle-instantclient18.5-sqlplus_18.5.0.0.0-4_amd64.deb + echo "LD_LIBRARY_PATH=/lib/oracle/18.5/client64/lib/" >> $GITHUB_ENV + echo "NLS_LANG=AMERICAN_AMERICA.UTF8" >> $GITHUB_ENV + echo "C_INCLUDE_PATH=/usr/include/oracle/18.5/client64" >> $GITHUB_ENV + echo 'NLS_DATE_FORMAT=YYYY-MM-DD HH24:MI:SS' >> $GITHUB_ENV + echo 'NLS_TIMESTAMP_FORMAT=YYYY-MM-DD HH24:MI:SS' >> $GITHUB_ENV + echo 'NLS_TIMESTAMP_TZ_FORMAT=YYYY-MM-DD HH24:MI:SS' >> $GITHUB_ENV + + - name: Create database for Oracle Database + if: matrix.db-platforms == 'OCI8' + run: echo -e "ALTER SESSION SET CONTAINER = XEPDB1;\nCREATE BIGFILE TABLESPACE \"TEST\" DATAFILE '/opt/oracle/product/18c/dbhomeXE/dbs/TEST' SIZE 10M AUTOEXTEND ON MAXSIZE UNLIMITED SEGMENT SPACE MANAGEMENT AUTO EXTENT MANAGEMENT LOCAL AUTOALLOCATE;\nCREATE USER \"ORACLE\" IDENTIFIED BY \"ORACLE\" DEFAULT TABLESPACE \"TEST\" TEMPORARY TABLESPACE TEMP QUOTA UNLIMITED ON \"TEST\";\nGRANT CONNECT,RESOURCE TO \"ORACLE\";\nexit;" | /lib/oracle/18.5/client64/bin/sqlplus -s sys/Oracle18@localhost:1521/XE as sysdba + - name: Checkout uses: actions/checkout@v2 @@ -92,7 +122,7 @@ jobs: with: php-version: ${{ matrix.php-versions }} tools: composer, pecl - extensions: imagick, sqlsrv, gd, sqlite3, redis, memcached, pgsql + extensions: imagick, sqlsrv, gd, sqlite3, redis, memcached, oci8, pgsql coverage: xdebug env: update: true diff --git a/system/Database/OCI8/Builder.php b/system/Database/OCI8/Builder.php new file mode 100644 index 000000000000..ac64b7ba5ca7 --- /dev/null +++ b/system/Database/OCI8/Builder.php @@ -0,0 +1,231 @@ + + * + * For the full copyright and license information, please view + * the LICENSE file that was distributed with this source code. + */ + +namespace CodeIgniter\Database\OCI8; + +use CodeIgniter\Database\BaseBuilder; +use CodeIgniter\Database\Exceptions\DatabaseException; + +/** + * Builder for OCI8 + */ +class Builder extends BaseBuilder +{ + /** + * Identifier escape character + * + * @var string + */ + protected $escapeChar = '"'; + + /** + * ORDER BY random keyword + * + * @var array + */ + protected $randomKeyword = [ + '"DBMS_RANDOM"."RANDOM"', + ]; + + /** + * COUNT string + * + * @used-by CI_DB_driver::count_all() + * @used-by BaseBuilder::count_all_results() + * + * @var string + */ + protected $countString = 'SELECT COUNT(1) '; + + /** + * Limit used flag + * + * If we use LIMIT, we'll add a field that will + * throw off num_fields later. + * + * @var bool + */ + protected $limitUsed = false; + + /** + * A reference to the database connection. + * + * @var Connection + */ + protected $db; + + /** + * Generates a platform-specific insert string from the supplied data. + */ + protected function _insertBatch(string $table, array $keys, array $values): string + { + $insertKeys = implode(', ', $keys); + $hasPrimaryKey = in_array('PRIMARY', array_column($this->db->getIndexData($table), 'type'), true); + + // ORA-00001 measures + if ($hasPrimaryKey) { + $sql = 'INSERT INTO ' . $table . ' (' . $insertKeys . ") \n SELECT * FROM (\n"; + $selectQueryValues = []; + + foreach ($values as $value) { + $selectValues = implode(',', array_map(static fn ($value, $key) => $value . ' as ' . $key, explode(',', substr(substr($value, 1), 0, -1)), $keys)); + $selectQueryValues[] = 'SELECT ' . $selectValues . ' FROM DUAL'; + } + + return $sql . implode("\n UNION ALL \n", $selectQueryValues) . "\n)"; + } + + $sql = "INSERT ALL\n"; + + foreach ($values as $value) { + $sql .= ' INTO ' . $table . ' (' . $insertKeys . ') VALUES ' . $value . "\n"; + } + + return $sql . 'SELECT * FROM DUAL'; + } + + /** + * Generates a platform-specific replace string from the supplied data + */ + protected function _replace(string $table, array $keys, array $values): string + { + $fieldNames = array_map(static fn ($columnName) => trim($columnName, '"'), $keys); + + $uniqueIndexes = array_filter($this->db->getIndexData($table), static function ($index) use ($fieldNames) { + $hasAllFields = count(array_intersect($index->fields, $fieldNames)) === count($index->fields); + + return ($index->type === 'PRIMARY') && $hasAllFields; + }); + $replaceableFields = array_filter($keys, static function ($columnName) use ($uniqueIndexes) { + foreach ($uniqueIndexes as $index) { + if (in_array(trim($columnName, '"'), $index->fields, true)) { + return false; + } + } + + return true; + }); + + $sql = 'MERGE INTO ' . $table . "\n USING (SELECT "; + + $sql .= implode(', ', array_map(static fn ($columnName, $value) => $value . ' ' . $columnName, $keys, $values)); + + $sql .= ' FROM DUAL) "_replace" ON ( '; + + $onList = []; + $onList[] = '1 != 1'; + + foreach ($uniqueIndexes as $index) { + $onList[] = '(' . implode(' AND ', array_map(static fn ($columnName) => $table . '."' . $columnName . '" = "_replace"."' . $columnName . '"', $index->fields)) . ')'; + } + + $sql .= implode(' OR ', $onList) . ') WHEN MATCHED THEN UPDATE SET '; + + $sql .= implode(', ', array_map(static fn ($columnName) => $columnName . ' = "_replace".' . $columnName, $replaceableFields)); + + $sql .= ' WHEN NOT MATCHED THEN INSERT (' . implode(', ', $replaceableFields) . ') VALUES '; + $sql .= ' (' . implode(', ', array_map(static fn ($columnName) => '"_replace".' . $columnName, $replaceableFields)) . ')'; + + return $sql; + } + + /** + * Generates a platform-specific truncate string from the supplied data + * + * If the database does not support the truncate() command, + * then this method maps to 'DELETE FROM table' + */ + protected function _truncate(string $table): string + { + return 'TRUNCATE TABLE ' . $table; + } + + /** + * Compiles a delete string and runs the query + * + * @param mixed $where + * + * @throws DatabaseException + * + * @return mixed + */ + public function delete($where = '', ?int $limit = null, bool $resetData = true) + { + if (! empty($limit)) { + $this->QBLimit = $limit; + } + + return parent::delete($where, null, $resetData); + } + + /** + * Generates a platform-specific delete string from the supplied data + */ + protected function _delete(string $table): string + { + if ($this->QBLimit) { + $this->where('rownum <= ', $this->QBLimit, false); + $this->QBLimit = false; + } + + return parent::_delete($table); + } + + /** + * Generates a platform-specific update string from the supplied data + */ + protected function _update(string $table, array $values): string + { + $valStr = []; + + foreach ($values as $key => $val) { + $valStr[] = $key . ' = ' . $val; + } + + if ($this->QBLimit) { + $this->where('rownum <= ', $this->QBLimit, false); + } + + return 'UPDATE ' . $this->compileIgnore('update') . $table . ' SET ' . implode(', ', $valStr) + . $this->compileWhereHaving('QBWhere') + . $this->compileOrderBy(); + } + + /** + * Generates a platform-specific LIMIT clause. + */ + protected function _limit(string $sql, bool $offsetIgnore = false): string + { + $offset = (int) ($offsetIgnore === false ? $this->QBOffset : 0); + if (version_compare($this->db->getVersion(), '12.1', '>=')) { + // OFFSET-FETCH can be used only with the ORDER BY clause + if (empty($this->QBOrderBy)) { + $sql .= ' ORDER BY 1'; + } + + return $sql . ' OFFSET ' . $offset . ' ROWS FETCH NEXT ' . $this->QBLimit . ' ROWS ONLY'; + } + + $this->limitUsed = true; + $limitTemplateQuery = 'SELECT * FROM (SELECT INNER_QUERY.*, ROWNUM RNUM FROM (%s) INNER_QUERY WHERE ROWNUM < %d)' . ($offset ? ' WHERE RNUM >= %d' : ''); + + return sprintf($limitTemplateQuery, $sql, $offset + $this->QBLimit + 1, $offset); + } + + /** + * Resets the query builder values. Called by the get() function + */ + protected function resetSelect() + { + $this->limitUsed = false; + parent::resetSelect(); + } +} diff --git a/system/Database/OCI8/Connection.php b/system/Database/OCI8/Connection.php new file mode 100644 index 000000000000..dc0b26f57c0e --- /dev/null +++ b/system/Database/OCI8/Connection.php @@ -0,0 +1,720 @@ + + * + * For the full copyright and license information, please view + * the LICENSE file that was distributed with this source code. + */ + +namespace CodeIgniter\Database\OCI8; + +use CodeIgniter\Database\BaseConnection; +use CodeIgniter\Database\ConnectionInterface; +use CodeIgniter\Database\Exceptions\DatabaseException; +use CodeIgniter\Database\Query; +use ErrorException; +use stdClass; + +/** + * Connection for OCI8 + */ +class Connection extends BaseConnection implements ConnectionInterface +{ + /** + * Database driver + * + * @var string + */ + protected $DBDriver = 'OCI8'; + + /** + * Identifier escape character + * + * @var string + */ + public $escapeChar = '"'; + + /** + * List of reserved identifiers + * + * Identifiers that must NOT be escaped. + * + * @var array + */ + protected $reservedIdentifiers = [ + '*', + 'rownum', + ]; + + protected $validDSNs = [ + 'tns' => '/^\(DESCRIPTION=(\(.+\)){2,}\)$/', // TNS + // Easy Connect string (Oracle 10g+) + 'ec' => '/^(\/\/)?[a-z0-9.:_-]+(:[1-9][0-9]{0,4})?(\/[a-z0-9$_]+)?(:[^\/])?(\/[a-z0-9$_]+)?$/i', + 'in' => '/^[a-z0-9$_]+$/i', // Instance name (defined in tnsnames.ora) + ]; + + /** + * Reset $stmtId flag + * + * Used by storedProcedure() to prevent execute() from + * re-setting the statement ID. + */ + protected $resetStmtId = true; + + /** + * Statement ID + * + * @var resource + */ + protected $stmtId; + + /** + * Commit mode flag + * + * @used-by PreparedQuery::_execute() + * + * @var int + */ + public $commitMode = OCI_COMMIT_ON_SUCCESS; + + /** + * Cursor ID + * + * @var resource + */ + protected $cursorId; + + /** + * Latest inserted table name. + * + * @used-by PreparedQuery::_execute() + * + * @var string|null + */ + public $lastInsertedTableName; + + /** + * confirm DNS format. + */ + private function isValidDSN(): bool + { + foreach ($this->validDSNs as $regexp) { + if (preg_match($regexp, $this->DSN)) { + return true; + } + } + + return false; + } + + /** + * Connect to the database. + * + * @return mixed + */ + public function connect(bool $persistent = false) + { + if (empty($this->DSN) && ! $this->isValidDSN()) { + $this->buildDSN(); + } + + $func = $persistent ? 'oci_pconnect' : 'oci_connect'; + + return empty($this->charset) + ? $func($this->username, $this->password, $this->DSN) + : $func($this->username, $this->password, $this->DSN, $this->charset); + } + + /** + * Keep or establish the connection if no queries have been sent for + * a length of time exceeding the server's idle timeout. + * + * @return void + */ + public function reconnect() + { + } + + /** + * Close the database connection. + * + * @return void + */ + protected function _close() + { + if (is_resource($this->cursorId)) { + oci_free_statement($this->cursorId); + } + if (is_resource($this->stmtId)) { + oci_free_statement($this->stmtId); + } + oci_close($this->connID); + } + + /** + * Select a specific database table to use. + */ + public function setDatabase(string $databaseName): bool + { + return false; + } + + /** + * Returns a string containing the version of the database being used. + */ + public function getVersion(): string + { + if (isset($this->dataCache['version'])) { + return $this->dataCache['version']; + } + + if (! $this->connID || ($versionString = oci_server_version($this->connID)) === false) { + return ''; + } + if (preg_match('#Release\s(\d+(?:\.\d+)+)#', $versionString, $match)) { + return $this->dataCache['version'] = $match[1]; + } + + return ''; + } + + /** + * Executes the query against the database. + * + * @return false|resource + */ + protected function execute(string $sql) + { + try { + if ($this->resetStmtId === true) { + $this->stmtId = oci_parse($this->connID, $sql); + } + + oci_set_prefetch($this->stmtId, 1000); + + $result = oci_execute($this->stmtId, $this->commitMode) ? $this->stmtId : false; + $insertTableName = $this->parseInsertTableName($sql); + + if ($result && $insertTableName !== '') { + $this->lastInsertedTableName = $insertTableName; + } + + return $result; + } catch (ErrorException $e) { + log_message('error', $e->getMessage()); + + if ($this->DBDebug) { + throw $e; + } + } + + return false; + } + + /** + * Get the table name for the insert statement from sql. + */ + public function parseInsertTableName(string $sql): string + { + $commentStrippedSql = preg_replace(['/\/\*(.|\n)*?\*\//m', '/--.+/'], '', $sql); + $isInsertQuery = strpos(strtoupper(ltrim($commentStrippedSql)), 'INSERT') === 0; + + if (! $isInsertQuery) { + return ''; + } + + preg_match('/(?is)\b(?:into)\s+("?\w+"?)/', $commentStrippedSql, $match); + $tableName = $match[1] ?? ''; + + return strpos($tableName, '"') === 0 ? trim($tableName, '"') : strtoupper($tableName); + } + + /** + * Returns the total number of rows affected by this query. + */ + public function affectedRows(): int + { + return oci_num_rows($this->stmtId); + } + + /** + * Generates the SQL for listing tables in a platform-dependent manner. + */ + protected function _listTables(bool $prefixLimit = false): string + { + $sql = 'SELECT "TABLE_NAME" FROM "USER_TABLES"'; + + if ($prefixLimit !== false && $this->DBPrefix !== '') { + return $sql . ' WHERE "TABLE_NAME" LIKE \'' . $this->escapeLikeString($this->DBPrefix) . "%' " + . sprintf($this->likeEscapeStr, $this->likeEscapeChar); + } + + return $sql; + } + + /** + * Generates a platform-specific query string so that the column names can be fetched. + */ + protected function _listColumns(string $table = ''): string + { + if (strpos($table, '.') !== false) { + sscanf($table, '%[^.].%s', $owner, $table); + } else { + $owner = $this->username; + } + + return 'SELECT COLUMN_NAME FROM ALL_TAB_COLUMNS + WHERE UPPER(OWNER) = ' . $this->escape(strtoupper($owner)) . ' + AND UPPER(TABLE_NAME) = ' . $this->escape(strtoupper($this->DBPrefix . $table)); + } + + /** + * Returns an array of objects with field data + * + * @throws DatabaseException + * + * @return stdClass[] + */ + protected function _fieldData(string $table): array + { + if (strpos($table, '.') !== false) { + sscanf($table, '%[^.].%s', $owner, $table); + } else { + $owner = $this->username; + } + + $sql = 'SELECT COLUMN_NAME, DATA_TYPE, CHAR_LENGTH, DATA_PRECISION, DATA_LENGTH, DATA_DEFAULT, NULLABLE + FROM ALL_TAB_COLUMNS + WHERE UPPER(OWNER) = ' . $this->escape(strtoupper($owner)) . ' + AND UPPER(TABLE_NAME) = ' . $this->escape(strtoupper($table)); + + if (($query = $this->query($sql)) === false) { + throw new DatabaseException(lang('Database.failGetFieldData')); + } + $query = $query->getResultObject(); + + $retval = []; + + for ($i = 0, $c = count($query); $i < $c; $i++) { + $retval[$i] = new stdClass(); + $retval[$i]->name = $query[$i]->COLUMN_NAME; + $retval[$i]->type = $query[$i]->DATA_TYPE; + + $length = $query[$i]->CHAR_LENGTH > 0 ? $query[$i]->CHAR_LENGTH : $query[$i]->DATA_PRECISION; + $length ??= $query[$i]->DATA_LENGTH; + + $retval[$i]->max_length = $length; + + $default = $query[$i]->DATA_DEFAULT; + if ($default === null && $query[$i]->NULLABLE === 'N') { + $default = ''; + } + $retval[$i]->default = $default; + $retval[$i]->nullable = $query[$i]->NULLABLE === 'Y'; + } + + return $retval; + } + + /** + * Returns an array of objects with index data + * + * @throws DatabaseException + * + * @return stdClass[] + */ + protected function _indexData(string $table): array + { + if (strpos($table, '.') !== false) { + sscanf($table, '%[^.].%s', $owner, $table); + } else { + $owner = $this->username; + } + + $sql = 'SELECT AIC.INDEX_NAME, UC.CONSTRAINT_TYPE, AIC.COLUMN_NAME ' + . ' FROM ALL_IND_COLUMNS AIC ' + . ' LEFT JOIN USER_CONSTRAINTS UC ON AIC.INDEX_NAME = UC.CONSTRAINT_NAME AND AIC.TABLE_NAME = UC.TABLE_NAME ' + . 'WHERE AIC.TABLE_NAME = ' . $this->escape(strtolower($table)) . ' ' + . 'AND AIC.TABLE_OWNER = ' . $this->escape(strtoupper($owner)) . ' ' + . ' ORDER BY UC.CONSTRAINT_TYPE, AIC.COLUMN_POSITION'; + + if (($query = $this->query($sql)) === false) { + throw new DatabaseException(lang('Database.failGetIndexData')); + } + $query = $query->getResultObject(); + + $retVal = []; + $constraintTypes = [ + 'P' => 'PRIMARY', + 'U' => 'UNIQUE', + ]; + + foreach ($query as $row) { + if (isset($retVal[$row->INDEX_NAME])) { + $retVal[$row->INDEX_NAME]->fields[] = $row->COLUMN_NAME; + + continue; + } + + $retVal[$row->INDEX_NAME] = new stdClass(); + $retVal[$row->INDEX_NAME]->name = $row->INDEX_NAME; + $retVal[$row->INDEX_NAME]->fields = [$row->COLUMN_NAME]; + $retVal[$row->INDEX_NAME]->type = $constraintTypes[$row->CONSTRAINT_TYPE] ?? 'INDEX'; + } + + return $retVal; + } + + /** + * Returns an array of objects with Foreign key data + * + * @throws DatabaseException + * + * @return stdClass[] + */ + protected function _foreignKeyData(string $table): array + { + $sql = 'SELECT + acc.constraint_name, + acc.table_name, + acc.column_name, + ccu.table_name foreign_table_name, + accu.column_name foreign_column_name + FROM all_cons_columns acc + JOIN all_constraints ac + ON acc.owner = ac.owner + AND acc.constraint_name = ac.constraint_name + JOIN all_constraints ccu + ON ac.r_owner = ccu.owner + AND ac.r_constraint_name = ccu.constraint_name + JOIN all_cons_columns accu + ON accu.constraint_name = ccu.constraint_name + AND accu.table_name = ccu.table_name + WHERE ac.constraint_type = ' . $this->escape('R') . ' + AND acc.table_name = ' . $this->escape($table); + $query = $this->query($sql); + + if ($query === false) { + throw new DatabaseException(lang('Database.failGetForeignKeyData')); + } + $query = $query->getResultObject(); + + $retVal = []; + + foreach ($query as $row) { + $obj = new stdClass(); + $obj->constraint_name = $row->CONSTRAINT_NAME; + $obj->table_name = $row->TABLE_NAME; + $obj->column_name = $row->COLUMN_NAME; + $obj->foreign_table_name = $row->FOREIGN_TABLE_NAME; + $obj->foreign_column_name = $row->FOREIGN_COLUMN_NAME; + $retVal[] = $obj; + } + + return $retVal; + } + + /** + * Returns platform-specific SQL to disable foreign key checks. + * + * @return string + */ + protected function _disableForeignKeyChecks() + { + return <<<'SQL' + BEGIN + FOR c IN + (SELECT c.owner, c.table_name, c.constraint_name + FROM user_constraints c, user_tables t + WHERE c.table_name = t.table_name + AND c.status = 'ENABLED' + AND c.constraint_type = 'R' + AND t.iot_type IS NULL + ORDER BY c.constraint_type DESC) + LOOP + dbms_utility.exec_ddl_statement('alter table "' || c.owner || '"."' || c.table_name || '" disable constraint "' || c.constraint_name || '"'); + END LOOP; + END; + SQL; + } + + /** + * Returns platform-specific SQL to enable foreign key checks. + * + * @return string + */ + protected function _enableForeignKeyChecks() + { + return <<<'SQL' + BEGIN + FOR c IN + (SELECT c.owner, c.table_name, c.constraint_name + FROM user_constraints c, user_tables t + WHERE c.table_name = t.table_name + AND c.status = 'DISABLED' + AND c.constraint_type = 'R' + AND t.iot_type IS NULL + ORDER BY c.constraint_type DESC) + LOOP + dbms_utility.exec_ddl_statement('alter table "' || c.owner || '"."' || c.table_name || '" enable constraint "' || c.constraint_name || '"'); + END LOOP; + END; + SQL; + } + + /** + * Get cursor. Returns a cursor from the database + * + * @return resource + */ + public function getCursor() + { + return $this->cursorId = oci_new_cursor($this->connID); + } + + /** + * Executes a stored procedure + * + * @param string $procedureName procedure name to execute + * @param array $params params array keys + * KEY OPTIONAL NOTES + * name no the name of the parameter should be in : format + * value no the value of the parameter. If this is an OUT or IN OUT parameter, + * this should be a reference to a variable + * type yes the type of the parameter + * length yes the max size of the parameter + * + * @return bool|Query|Result + */ + public function storedProcedure(string $procedureName, array $params) + { + if ($procedureName === '') { + throw new DatabaseException(lang('Database.invalidArgument', [$procedureName])); + } + + // Build the query string + $sql = sprintf( + 'BEGIN %s (' . substr(str_repeat(',%s', count($params)), 1) . '); END;', + $procedureName, + ...array_map(static fn ($row) => $row['name'], $params) + ); + + $this->resetStmtId = false; + $this->stmtId = oci_parse($this->connID, $sql); + $this->bindParams($params); + $result = $this->query($sql); + $this->resetStmtId = true; + + return $result; + } + + /** + * Bind parameters + * + * @param array $params + * + * @return void + */ + protected function bindParams($params) + { + if (! is_array($params) || ! is_resource($this->stmtId)) { + return; + } + + foreach ($params as $param) { + oci_bind_by_name( + $this->stmtId, + $param['name'], + $param['value'], + $param['length'] ?? -1, + $param['type'] ?? SQLT_CHR + ); + } + } + + /** + * Returns the last error code and message. + * + * Must return an array with keys 'code' and 'message': + * + * return ['code' => null, 'message' => null); + */ + public function error(): array + { + // oci_error() returns an array that already contains + // 'code' and 'message' keys, but it can return false + // if there was no error .... + $error = oci_error(); + $resources = [$this->cursorId, $this->stmtId, $this->connID]; + + foreach ($resources as $resource) { + if (is_resource($resource)) { + $error = oci_error($resource); + break; + } + } + + return is_array($error) + ? $error + : [ + 'code' => '', + 'message' => '', + ]; + } + + public function insertID(): int + { + if (empty($this->lastInsertedTableName)) { + return 0; + } + + $indexs = $this->getIndexData($this->lastInsertedTableName); + $fieldDatas = $this->getFieldData($this->lastInsertedTableName); + + if (! $indexs || ! $fieldDatas) { + return 0; + } + + $columnTypeList = array_column($fieldDatas, 'type', 'name'); + $primaryColumnName = ''; + + foreach ($indexs as $index) { + if ($index->type !== 'PRIMARY' || count($index->fields) !== 1) { + continue; + } + + $primaryColumnName = $this->protectIdentifiers($index->fields[0], false, false); + $primaryColumnType = $columnTypeList[$primaryColumnName]; + + if ($primaryColumnType !== 'NUMBER') { + $primaryColumnName = ''; + } + } + + if (! $primaryColumnName) { + return 0; + } + + $query = $this->query('SELECT DATA_DEFAULT FROM USER_TAB_COLUMNS WHERE TABLE_NAME = ? AND COLUMN_NAME = ?', [$this->lastInsertedTableName, $primaryColumnName])->getRow(); + $lastInsertValue = str_replace('nextval', 'currval', $query->DATA_DEFAULT ?? '0'); + $query = $this->query(sprintf('SELECT %s SEQ FROM DUAL', $lastInsertValue))->getRow(); + + return (int) ($query->SEQ ?? 0); + } + + /** + * Build a DSN from the provided parameters + * + * @return void + */ + protected function buildDSN() + { + if ($this->DSN !== '') { + $this->DSN = ''; + } + + // Legacy support for TNS in the hostname configuration field + $this->hostname = str_replace(["\n", "\r", "\t", ' '], '', $this->hostname); + + if (preg_match($this->validDSNs['tns'], $this->hostname)) { + $this->DSN = $this->hostname; + + return; + } + + $isEasyConnectableHostName = $this->hostname !== '' && strpos($this->hostname, '/') === false && strpos($this->hostname, ':') === false; + $easyConnectablePort = ! empty($this->port) && ctype_digit($this->port) ? ':' . $this->port : ''; + $easyConnectableDatabase = $this->database !== '' ? '/' . ltrim($this->database, '/') : ''; + + if ($isEasyConnectableHostName && ($easyConnectablePort !== '' || $easyConnectableDatabase !== '')) { + /* If the hostname field isn't empty, doesn't contain + * ':' and/or '/' and if port and/or database aren't + * empty, then the hostname field is most likely indeed + * just a hostname. Therefore we'll try and build an + * Easy Connect string from these 3 settings, assuming + * that the database field is a service name. + */ + $this->DSN = $this->hostname . $easyConnectablePort . $easyConnectableDatabase; + + if (preg_match($this->validDSNs['ec'], $this->DSN)) { + return; + } + } + + /* At this point, we can only try and validate the hostname and + * database fields separately as DSNs. + */ + if (preg_match($this->validDSNs['ec'], $this->hostname) || preg_match($this->validDSNs['in'], $this->hostname)) { + $this->DSN = $this->hostname; + + return; + } + + $this->database = str_replace(["\n", "\r", "\t", ' '], '', $this->database); + + foreach ($this->validDSNs as $regexp) { + if (preg_match($regexp, $this->database)) { + return; + } + } + + /* Well - OK, an empty string should work as well. + * PHP will try to use environment variables to + * determine which Oracle instance to connect to. + */ + $this->DSN = ''; + } + + /** + * Begin Transaction + */ + protected function _transBegin(): bool + { + $this->commitMode = OCI_NO_AUTO_COMMIT; + + return true; + } + + /** + * Commit Transaction + */ + protected function _transCommit(): bool + { + $this->commitMode = OCI_COMMIT_ON_SUCCESS; + + return oci_commit($this->connID); + } + + /** + * Rollback Transaction + */ + protected function _transRollback(): bool + { + $this->commitMode = OCI_COMMIT_ON_SUCCESS; + + return oci_rollback($this->connID); + } + + /** + * Returns the name of the current database being used. + */ + public function getDatabase(): string + { + if (! empty($this->database)) { + return $this->database; + } + + return $this->query('SELECT DEFAULT_TABLESPACE FROM USER_USERS')->getRow()->DEFAULT_TABLESPACE ?? ''; + } + + /** + * Get the prefix of the function to access the DB. + */ + protected function getDriverFunctionPrefix(): string + { + return 'oci_'; + } +} diff --git a/system/Database/OCI8/Forge.php b/system/Database/OCI8/Forge.php new file mode 100644 index 000000000000..d5ca20a9e4d9 --- /dev/null +++ b/system/Database/OCI8/Forge.php @@ -0,0 +1,299 @@ + + * + * For the full copyright and license information, please view + * the LICENSE file that was distributed with this source code. + */ + +namespace CodeIgniter\Database\OCI8; + +/** + * Forge for OCI8 + */ +class Forge extends \CodeIgniter\Database\Forge +{ + /** + * DROP INDEX statement + * + * @var string + */ + protected $dropIndexStr = 'DROP INDEX %s'; + + /** + * CREATE DATABASE statement + * + * @var false + */ + protected $createDatabaseStr = false; + + /** + * CREATE TABLE IF statement + * + * @var false + */ + protected $createTableIfStr = false; + + /** + * DROP TABLE IF EXISTS statement + * + * @var false + */ + protected $dropTableIfStr = false; + + /** + * DROP DATABASE statement + * + * @var false + */ + protected $dropDatabaseStr = false; + + /** + * UNSIGNED support + * + * @var array|bool + */ + protected $unsigned = false; + + /** + * NULL value representation in CREATE/ALTER TABLE statements + * + * @var string + */ + protected $null = 'NULL'; + + /** + * RENAME TABLE statement + * + * @var string + */ + protected $renameTableStr = 'ALTER TABLE %s RENAME TO %s'; + + /** + * DROP CONSTRAINT statement + * + * @var string + */ + protected $dropConstraintStr = 'ALTER TABLE %s DROP CONSTRAINT %s'; + + /** + * ALTER TABLE + * + * @param string $alterType ALTER type + * @param string $table Table name + * @param mixed $field Column definition + * + * @return string|string[] + */ + protected function _alterTable(string $alterType, string $table, $field) + { + $sql = 'ALTER TABLE ' . $this->db->escapeIdentifiers($table); + + if ($alterType === 'DROP') { + $fields = array_map(fn ($field) => $this->db->escapeIdentifiers(trim($field)), is_string($field) ? explode(',', $field) : $field); + + return $sql . ' DROP (' . implode(',', $fields) . ') CASCADE CONSTRAINT INVALIDATE'; + } + if ($alterType === 'CHANGE') { + $alterType = 'MODIFY'; + } + + $nullableMap = array_column($this->db->getFieldData($table), 'nullable', 'name'); + $sqls = []; + + for ($i = 0, $c = count($field); $i < $c; $i++) { + if ($alterType === 'MODIFY') { + // If a null constraint is added to a column with a null constraint, + // ORA-01451 will occur, + // so add null constraint is used only when it is different from the current null constraint. + $isWantToAddNull = strpos($field[$i]['null'], ' NOT') === false; + $currentNullAddable = $nullableMap[$field[$i]['name']]; + + if ($isWantToAddNull === $currentNullAddable) { + $field[$i]['null'] = ''; + } + } + + if ($field[$i]['_literal'] !== false) { + $field[$i] = "\n\t" . $field[$i]['_literal']; + } else { + $field[$i]['_literal'] = "\n\t" . $this->_processColumn($field[$i]); + + if (! empty($field[$i]['comment'])) { + $sqls[] = 'COMMENT ON COLUMN ' + . $this->db->escapeIdentifiers($table) . '.' . $this->db->escapeIdentifiers($field[$i]['name']) + . ' IS ' . $field[$i]['comment']; + } + + if ($alterType === 'MODIFY' && ! empty($field[$i]['new_name'])) { + $sqls[] = $sql . ' RENAME COLUMN ' . $this->db->escapeIdentifiers($field[$i]['name']) + . ' TO ' . $this->db->escapeIdentifiers($field[$i]['new_name']); + } + + $field[$i] = "\n\t" . $field[$i]['_literal']; + } + } + + $sql .= ' ' . $alterType . ' '; + $sql .= count($field) === 1 + ? $field[0] + : '(' . implode(',', $field) . ')'; + + // RENAME COLUMN must be executed after MODIFY + array_unshift($sqls, $sql); + + return $sqls; + } + + /** + * Field attribute AUTO_INCREMENT + * + * @return void + */ + protected function _attributeAutoIncrement(array &$attributes, array &$field) + { + if (! empty($attributes['AUTO_INCREMENT']) && $attributes['AUTO_INCREMENT'] === true + && stripos($field['type'], 'NUMBER') !== false + && version_compare($this->db->getVersion(), '12.1', '>=') + ) { + $field['auto_increment'] = ' GENERATED BY DEFAULT AS IDENTITY'; + } + } + + /** + * Process column + */ + protected function _processColumn(array $field): string + { + $constraint = ''; + // @todo: can’t cover multi pattern when set type. + if ($field['type'] === 'VARCHAR2' && strpos($field['length'], "('") === 0) { + $constraint = ' CHECK(' . $this->db->escapeIdentifiers($field['name']) + . ' IN ' . $field['length'] . ')'; + + $field['length'] = '(' . max(array_map('mb_strlen', explode("','", mb_substr($field['length'], 2, -2)))) . ')' . $constraint; + } elseif (count($this->primaryKeys) === 1 && $field['name'] === $this->primaryKeys[0]) { + $field['unique'] = ''; + } + + return $this->db->escapeIdentifiers($field['name']) + . ' ' . $field['type'] . $field['length'] + . $field['unsigned'] + . $field['default'] + . $field['auto_increment'] + . $field['null'] + . $field['unique']; + } + + /** + * Performs a data type mapping between different databases. + * + * @return void + */ + protected function _attributeType(array &$attributes) + { + // Reset field lengths for data types that don't support it + // Usually overridden by drivers + switch (strtoupper($attributes['TYPE'])) { + case 'TINYINT': + $attributes['CONSTRAINT'] ??= 3; + // no break + case 'SMALLINT': + $attributes['CONSTRAINT'] ??= 5; + // no break + case 'MEDIUMINT': + $attributes['CONSTRAINT'] ??= 7; + // no break + case 'INT': + case 'INTEGER': + $attributes['CONSTRAINT'] ??= 11; + // no break + case 'BIGINT': + $attributes['CONSTRAINT'] ??= 19; + // no break + case 'NUMERIC': + $attributes['TYPE'] = 'NUMBER'; + + return; + + case 'BOOLEAN': + $attributes['TYPE'] = 'NUMBER'; + $attributes['CONSTRAINT'] = 1; + $attributes['UNSIGNED'] = true; + $attributes['NULL'] = false; + + return; + + case 'DOUBLE': + $attributes['TYPE'] = 'FLOAT'; + $attributes['CONSTRAINT'] ??= 126; + + return; + + case 'DATETIME': + case 'TIME': + $attributes['TYPE'] = 'DATE'; + + return; + + case 'SET': + case 'ENUM': + case 'VARCHAR': + $attributes['CONSTRAINT'] ??= 255; + // no break + case 'TEXT': + case 'MEDIUMTEXT': + $attributes['CONSTRAINT'] ??= 4000; + $attributes['TYPE'] = 'VARCHAR2'; + } + } + + /** + * Generates a platform-specific DROP TABLE string + * + * @return bool|string + */ + protected function _dropTable(string $table, bool $ifExists, bool $cascade) + { + $sql = parent::_dropTable($table, $ifExists, $cascade); + + if ($sql !== true && $cascade === true) { + $sql .= ' CASCADE CONSTRAINTS PURGE'; + } elseif ($sql !== true) { + $sql .= ' PURGE'; + } + + return $sql; + } + + protected function _processForeignKeys(string $table): string + { + $sql = ''; + + $allowActions = [ + 'CASCADE', + 'SET NULL', + 'NO ACTION', + ]; + + foreach ($this->foreignKeys as $fkey) { + $nameIndex = $table . '_' . implode('_', $fkey['field']) . '_fk'; + $nameIndexFilled = $this->db->escapeIdentifiers($nameIndex); + $foreignKeyFilled = implode(', ', $this->db->escapeIdentifiers($fkey['field'])); + $referenceTableFilled = $this->db->escapeIdentifiers($this->db->DBPrefix . $fkey['referenceTable']); + $referenceFieldFilled = implode(', ', $this->db->escapeIdentifiers($fkey['referenceField'])); + + $formatSql = ",\n\tCONSTRAINT %s FOREIGN KEY (%s) REFERENCES %s(%s)"; + $sql .= sprintf($formatSql, $nameIndexFilled, $foreignKeyFilled, $referenceTableFilled, $referenceFieldFilled); + + if ($fkey['onDelete'] !== false && in_array($fkey['onDelete'], $allowActions, true)) { + $sql .= ' ON DELETE ' . $fkey['onDelete']; + } + } + + return $sql; + } +} diff --git a/system/Database/OCI8/PreparedQuery.php b/system/Database/OCI8/PreparedQuery.php new file mode 100644 index 000000000000..311dacc4045f --- /dev/null +++ b/system/Database/OCI8/PreparedQuery.php @@ -0,0 +1,109 @@ + + * + * For the full copyright and license information, please view + * the LICENSE file that was distributed with this source code. + */ + +namespace CodeIgniter\Database\OCI8; + +use BadMethodCallException; +use CodeIgniter\Database\BasePreparedQuery; +use CodeIgniter\Database\PreparedQueryInterface; + +/** + * Prepared query for OCI8 + */ +class PreparedQuery extends BasePreparedQuery implements PreparedQueryInterface +{ + /** + * A reference to the db connection to use. + * + * @var Connection + */ + protected $db; + + /** + * Latest inserted table name. + */ + private ?string $lastInsertTableName = null; + + /** + * Prepares the query against the database, and saves the connection + * info necessary to execute the query later. + * + * NOTE: This version is based on SQL code. Child classes should + * override this method. + * + * @param array $options Passed to the connection's prepare statement. + * Unused in the OCI8 driver. + * + * @return mixed + */ + public function _prepare(string $sql, array $options = []) + { + if (! $this->statement = oci_parse($this->db->connID, $this->parameterize($sql))) { + $error = oci_error($this->db->connID); + $this->errorCode = $error['code'] ?? 0; + $this->errorString = $error['message'] ?? ''; + } + + $this->lastInsertTableName = $this->db->parseInsertTableName($sql); + + return $this; + } + + /** + * Takes a new set of data and runs it against the currently + * prepared query. Upon success, will return a Results object. + */ + public function _execute(array $data): bool + { + if (null === $this->statement) { + throw new BadMethodCallException('You must call prepare before trying to execute a prepared statement.'); + } + + $lastKey = 0; + + foreach (array_keys($data) as $key) { + oci_bind_by_name($this->statement, ':' . $key, $data[$key]); + $lastKey = $key; + } + + $result = oci_execute($this->statement, $this->db->commitMode); + + if ($result && $this->lastInsertTableName !== '') { + $this->db->lastInsertedTableName = $this->lastInsertTableName; + } + + return $result; + } + + /** + * Returns the result object for the prepared query. + * + * @return mixed + */ + public function _getResult() + { + return $this->statement; + } + + /** + * Replaces the ? placeholders with :0, :1, etc parameters for use + * within the prepared query. + */ + public function parameterize(string $sql): string + { + // Track our current value + $count = 0; + + return preg_replace_callback('/\?/', static function ($matches) use (&$count) { + return ':' . ($count++); + }, $sql); + } +} diff --git a/system/Database/OCI8/Result.php b/system/Database/OCI8/Result.php new file mode 100644 index 000000000000..ce3a73def1c4 --- /dev/null +++ b/system/Database/OCI8/Result.php @@ -0,0 +1,116 @@ + + * + * For the full copyright and license information, please view + * the LICENSE file that was distributed with this source code. + */ + +namespace CodeIgniter\Database\OCI8; + +use CodeIgniter\Database\BaseResult; +use CodeIgniter\Database\ResultInterface; +use CodeIgniter\Entity; +use stdClass; + +/** + * Result for OCI8 + */ +class Result extends BaseResult implements ResultInterface +{ + /** + * Gets the number of fields in the result set. + */ + public function getFieldCount(): int + { + return oci_num_fields($this->resultID); + } + + /** + * Generates an array of column names in the result set. + */ + public function getFieldNames(): array + { + return array_map(fn ($fieldIndex) => oci_field_name($this->resultID, $fieldIndex), range(1, $this->getFieldCount())); + } + + /** + * Generates an array of objects representing field meta-data. + */ + public function getFieldData(): array + { + return array_map(fn ($fieldIndex) => (object) [ + 'name' => oci_field_name($this->resultID, $fieldIndex), + 'type' => oci_field_type($this->resultID, $fieldIndex), + 'max_length' => oci_field_size($this->resultID, $fieldIndex), + ], range(1, $this->getFieldCount())); + } + + /** + * Frees the current result. + * + * @return void + */ + public function freeResult() + { + if (is_resource($this->resultID)) { + oci_free_statement($this->resultID); + $this->resultID = false; + } + } + + /** + * Moves the internal pointer to the desired offset. This is called + * internally before fetching results to make sure the result set + * starts at zero. + * + * @return false + */ + public function dataSeek(int $n = 0) + { + // We can't support data seek by oci + return false; + } + + /** + * Returns the result set as an array. + * + * Overridden by driver classes. + * + * @return mixed + */ + protected function fetchAssoc() + { + return oci_fetch_assoc($this->resultID); + } + + /** + * Returns the result set as an object. + * + * Overridden by child classes. + * + * @return bool|Entity|object + */ + protected function fetchObject(string $className = stdClass::class) + { + $row = oci_fetch_object($this->resultID); + + if ($className === 'stdClass' || ! $row) { + return $row; + } + if (is_subclass_of($className, Entity::class)) { + return (new $className())->setAttributes((array) $row); + } + + $instance = new $className(); + + foreach (get_object_vars($row) as $key => $value) { + $instance->{$key} = $value; + } + + return $instance; + } +} diff --git a/system/Database/OCI8/Utils.php b/system/Database/OCI8/Utils.php new file mode 100644 index 000000000000..870306d8b8b1 --- /dev/null +++ b/system/Database/OCI8/Utils.php @@ -0,0 +1,38 @@ + + * + * For the full copyright and license information, please view + * the LICENSE file that was distributed with this source code. + */ + +namespace CodeIgniter\Database\OCI8; + +use CodeIgniter\Database\BaseUtils; +use CodeIgniter\Database\Exceptions\DatabaseException; + +/** + * Utils for OCI8 + */ +class Utils extends BaseUtils +{ + /** + * List databases statement + * + * @var string + */ + protected $listDatabases = 'SELECT TABLESPACE_NAME FROM USER_TABLESPACES'; + + /** + * Platform dependent version of the backup function. + * + * @return mixed + */ + public function _backup(?array $prefs = null) + { + throw new DatabaseException('Unsupported feature of the database platform you are using.'); + } +} diff --git a/tests/_support/Config/Registrar.php b/tests/_support/Config/Registrar.php index 989b406655b1..b568629ea19f 100644 --- a/tests/_support/Config/Registrar.php +++ b/tests/_support/Config/Registrar.php @@ -100,6 +100,24 @@ class Registrar 'failover' => [], 'port' => 1433, ], + 'OCI8' => [ + 'DSN' => 'localhost:1521/XEPDB1', + 'hostname' => '', + 'username' => 'ORACLE', + 'password' => 'ORACLE', + 'database' => '', + 'DBDriver' => 'OCI8', + 'DBPrefix' => 'db_', + 'pConnect' => false, + 'DBDebug' => (ENVIRONMENT !== 'production'), + 'charset' => 'utf8', + 'DBCollat' => 'utf8_general_ci', + 'swapPre' => '', + 'encrypt' => false, + 'compress' => false, + 'strictOn' => false, + 'failover' => [], + ], ]; /** diff --git a/tests/_support/Database/Migrations/20160428212500_Create_test_tables.php b/tests/_support/Database/Migrations/20160428212500_Create_test_tables.php index cf517e988ebc..e802dcedc9be 100644 --- a/tests/_support/Database/Migrations/20160428212500_Create_test_tables.php +++ b/tests/_support/Database/Migrations/20160428212500_Create_test_tables.php @@ -151,6 +151,13 @@ public function up() $this->forge->addKey('id', true); $this->forge->createTable('ci_sessions', true); } + + if ($this->db->DBDriver === 'OCI8') { + $this->db->query('CREATE OR REPLACE PACKAGE calculator AS PROCEDURE plus(left IN NUMBER, right IN NUMBER, result OUT NUMBER); END;'); + $this->db->query('CREATE OR REPLACE PACKAGE BODY calculator AS PROCEDURE plus(left IN NUMBER, right IN NUMBER, result OUT NUMBER) IS BEGIN result := left + right; END plus; END calculator;'); + $this->db->query('CREATE OR REPLACE PROCEDURE plus(left IN NUMBER, right IN NUMBER, output OUT NUMBER) IS BEGIN output := left + right; END;'); + $this->db->query('CREATE OR REPLACE PROCEDURE one(cursor OUT SYS_REFCURSOR) IS BEGIN open cursor for select 1 AS ONE from DUAL; END;'); + } } public function down() @@ -168,5 +175,11 @@ public function down() if (in_array($this->db->DBDriver, ['MySQLi', 'Postgre'], true)) { $this->forge->dropTable('ci_sessions', true); } + + if ($this->db->DBDriver === 'OCI8') { + $this->db->query('DROP PROCEDURE one'); + $this->db->query('DROP PROCEDURE plus'); + $this->db->query('DROP PACKAGE BODY calculator'); + } } } diff --git a/tests/_support/Database/Seeds/CITestSeeder.php b/tests/_support/Database/Seeds/CITestSeeder.php index 372697aaa6ba..d9a0ec8f3bed 100644 --- a/tests/_support/Database/Seeds/CITestSeeder.php +++ b/tests/_support/Database/Seeds/CITestSeeder.php @@ -166,6 +166,16 @@ public function run() ]; } + if ($this->db->DBDriver === 'OCI8') { + $this->db->query('alter session set NLS_DATE_FORMAT=?', ['YYYY/MM/DD HH24:MI:SS']); + $data['type_test'][0]['type_time'] = '2020-07-18 15:22:00'; + $data['type_test'][0]['type_date'] = '2020-01-11 22:11:00'; + $data['type_test'][0]['type_time'] = '2020-07-18 15:22:00'; + $data['type_test'][0]['type_datetime'] = '2020-06-18 05:12:24'; + $data['type_test'][0]['type_timestamp'] = '2020-06-18 21:53:21'; + unset($data['type_test'][0]['type_blob']); + } + foreach ($data as $table => $dummy_data) { $this->db->table($table)->truncate(); diff --git a/tests/system/Commands/CreateDatabaseTest.php b/tests/system/Commands/CreateDatabaseTest.php index a00de5c437a1..ccbadc51f0c3 100644 --- a/tests/system/Commands/CreateDatabaseTest.php +++ b/tests/system/Commands/CreateDatabaseTest.php @@ -13,6 +13,7 @@ use CodeIgniter\Database\BaseConnection; use CodeIgniter\Database\Database as DatabaseFactory; +use CodeIgniter\Database\OCI8\Connection as OCI8Connection; use CodeIgniter\Database\SQLite3\Connection as SQLite3Connection; use CodeIgniter\Test\CIUnitTestCase; use CodeIgniter\Test\Filters\CITestStreamFilter; @@ -68,6 +69,10 @@ protected function getBuffer() public function testCreateDatabase() { + if ($this->connection instanceof OCI8Connection) { + $this->markTestSkipped('Needs to run on non-OCI8 drivers.'); + } + command('db:create foobar'); $this->assertStringContainsString('successfully created.', $this->getBuffer()); } @@ -87,8 +92,8 @@ public function testSqliteDatabaseDuplicated() public function testOtherDriverDuplicatedDatabase() { - if ($this->connection instanceof SQLite3Connection) { - $this->markTestSkipped('Needs to run on non-SQLite3 drivers.'); + if ($this->connection instanceof SQLite3Connection || $this->connection instanceof OCI8Connection) { + $this->markTestSkipped('Needs to run on non-SQLite3 and non-OCI8 drivers.'); } command('db:create foobar'); diff --git a/tests/system/Database/Live/DbUtilsTest.php b/tests/system/Database/Live/DbUtilsTest.php index 2e8beda5f82f..e767d0b6991d 100644 --- a/tests/system/Database/Live/DbUtilsTest.php +++ b/tests/system/Database/Live/DbUtilsTest.php @@ -76,7 +76,7 @@ public function testUtilsListDatabases() { $util = (new Database())->loadUtils($this->db); - if (in_array($this->db->DBDriver, ['MySQLi', 'Postgre', 'SQLSRV'], true)) { + if (in_array($this->db->DBDriver, ['MySQLi', 'Postgre', 'SQLSRV', 'OCI8'], true)) { $databases = $util->listDatabases(); $this->assertContains($this->db->getDatabase(), $databases); @@ -92,7 +92,7 @@ public function testUtilsDatabaseExist() { $util = (new Database())->loadUtils($this->db); - if (in_array($this->db->DBDriver, ['MySQLi', 'Postgre', 'SQLSRV'], true)) { + if (in_array($this->db->DBDriver, ['MySQLi', 'Postgre', 'SQLSRV', 'OCI8'], true)) { $exist = $util->databaseExists($this->db->getDatabase()); $this->assertTrue($exist); @@ -108,6 +108,12 @@ public function testUtilsOptimizeDatabase() { $util = (new Database())->loadUtils($this->db); + if ($this->db->DBDriver === 'OCI8') { + $this->markTestSkipped( + 'Unsupported feature of the oracle database platform.' + ); + } + $d = $util->optimizeDatabase(); $this->assertTrue((bool) $d); @@ -147,6 +153,12 @@ public function testUtilsOptimizeTable() { $util = (new Database())->loadUtils($this->db); + if ($this->db->DBDriver === 'OCI8') { + $this->markTestSkipped( + 'Unsupported feature of the oracle database platform.' + ); + } + $d = $util->optimizeTable('db_job'); $this->assertTrue((bool) $d); diff --git a/tests/system/Database/Live/ForgeTest.php b/tests/system/Database/Live/ForgeTest.php index 08ca65e03b95..e20f26556f1d 100644 --- a/tests/system/Database/Live/ForgeTest.php +++ b/tests/system/Database/Live/ForgeTest.php @@ -44,6 +44,9 @@ protected function setUp(): void public function testCreateDatabase() { + if ($this->db->DBDriver === 'OCI8') { + $this->markTestSkipped('OCI8 does not support create database.'); + } $databaseCreated = $this->forge->createDatabase('test_forge_database'); $this->assertTrue($databaseCreated); @@ -51,6 +54,9 @@ public function testCreateDatabase() public function testCreateDatabaseIfNotExists() { + if ($this->db->DBDriver === 'OCI8') { + $this->markTestSkipped('OCI8 does not support create database.'); + } $dbName = 'test_forge_database_exist'; $databaseCreateIfNotExists = $this->forge->createDatabase($dbName, true); @@ -63,6 +69,9 @@ public function testCreateDatabaseIfNotExists() public function testCreateDatabaseIfNotExistsWithDb() { + if ($this->db->DBDriver === 'OCI8') { + $this->markTestSkipped('OCI8 does not support create database.'); + } $dbName = 'test_forge_database_exist'; $this->forge->createDatabase($dbName); @@ -76,6 +85,9 @@ public function testCreateDatabaseIfNotExistsWithDb() public function testDropDatabase() { + if ($this->db->DBDriver === 'OCI8') { + $this->markTestSkipped('OCI8 does not support drop database.'); + } if ($this->db->DBDriver === 'SQLite3') { $this->markTestSkipped('SQLite3 requires file path to drop database'); } @@ -169,6 +181,8 @@ public function testCreateTableApplyBigInt() $this->assertSame(strtolower($fieldsData[0]->type), 'bigint'); } elseif ($this->db->DBDriver === 'SQLite3') { $this->assertSame(strtolower($fieldsData[0]->type), 'integer'); + } elseif ($this->db->DBDriver === 'OCI8') { + $this->assertSame(strtolower($fieldsData[0]->type), 'number'); } elseif ($this->db->DBDriver === 'SQLSRV') { $this->assertSame(strtolower($fieldsData[0]->type), 'bigint'); } @@ -178,6 +192,9 @@ public function testCreateTableApplyBigInt() public function testCreateTableWithAttributes() { + if ($this->db->DBDriver === 'OCI8') { + $this->markTestSkipped('OCI8 does not support comments on tables or columns.'); + } if ($this->db->DBDriver === 'SQLite3') { $this->markTestSkipped('SQLite3 does not support comments on tables or columns.'); } @@ -409,22 +426,31 @@ public function testForeignKey() $this->forge->addKey('id', true); $this->forge->addForeignKey('users_id', 'forge_test_users', 'id', 'CASCADE', 'CASCADE'); - $this->forge->createTable('forge_test_invoices', true, $attributes); + $tableName = 'forge_test_invoices'; + if ($this->db->DBDriver === 'OCI8') { + $tableName = 'forge_test_inv'; + } + + $this->forge->createTable($tableName, true, $attributes); - $foreignKeyData = $this->db->getForeignKeyData('forge_test_invoices'); + $foreignKeyData = $this->db->getForeignKeyData($tableName); if ($this->db->DBDriver === 'SQLite3') { $this->assertSame($foreignKeyData[0]->constraint_name, 'users_id to db_forge_test_users.id'); $this->assertSame($foreignKeyData[0]->sequence, 0); + } elseif ($this->db->DBDriver === 'OCI8') { + $this->assertSame($foreignKeyData[0]->constraint_name, $this->db->DBPrefix . 'forge_test_inv_users_id_fk'); + $this->assertSame($foreignKeyData[0]->column_name, 'users_id'); + $this->assertSame($foreignKeyData[0]->foreign_column_name, 'id'); } else { $this->assertSame($foreignKeyData[0]->constraint_name, $this->db->DBPrefix . 'forge_test_invoices_users_id_foreign'); $this->assertSame($foreignKeyData[0]->column_name, 'users_id'); $this->assertSame($foreignKeyData[0]->foreign_column_name, 'id'); } - $this->assertSame($foreignKeyData[0]->table_name, $this->db->DBPrefix . 'forge_test_invoices'); + $this->assertSame($foreignKeyData[0]->table_name, $this->db->DBPrefix . $tableName); $this->assertSame($foreignKeyData[0]->foreign_table_name, $this->db->DBPrefix . 'forge_test_users'); - $this->forge->dropTable('forge_test_invoices', true); + $this->forge->dropTable($tableName, true); $this->forge->dropTable('forge_test_users', true); } @@ -493,38 +519,59 @@ public function testCompositeForeignKey() $this->forge->addPrimaryKey(['id', 'second_id']); $this->forge->createTable('forge_test_users', true, $attributes); - $this->forge->addField([ + $forgeTestInvoicesTableName = 'forge_test_invoices'; + $userIdColumnName = 'users_id'; + $userSecondIdColumnName = 'users_second_id'; + $fields = [ 'id' => [ 'type' => 'INTEGER', 'constraint' => 11, ], - 'users_id' => [ - 'type' => 'INTEGER', - 'constraint' => 11, - ], - 'users_second_id' => [ - 'type' => 'VARCHAR', - 'constraint' => 50, - ], 'name' => [ 'type' => 'VARCHAR', 'constraint' => 255, ], - ]); + ]; + + if ($this->db->DBDriver === 'OCI8') { + $userIdColumnName = 'uid'; + $userSecondIdColumnName = 'usid'; + $forgeTestInvoicesTableName = 'forge_test_inv'; + } + + $fields[$userIdColumnName] = [ + 'type' => 'INTEGER', + 'constraint' => 11, + ]; + + $fields[$userSecondIdColumnName] = [ + 'type' => 'VARCHAR', + 'constraint' => 50, + ]; + + $this->forge->addField($fields); $this->forge->addPrimaryKey('id'); - $this->forge->addForeignKey(['users_id', 'users_second_id'], 'forge_test_users', ['id', 'second_id'], 'CASCADE', 'CASCADE'); + $this->forge->addForeignKey([$userIdColumnName, $userSecondIdColumnName], 'forge_test_users', ['id', 'second_id'], 'CASCADE', 'CASCADE'); - $this->forge->createTable('forge_test_invoices', true, $attributes); + $this->forge->createTable($forgeTestInvoicesTableName, true, $attributes); - $foreignKeyData = $this->db->getForeignKeyData('forge_test_invoices'); + $foreignKeyData = $this->db->getForeignKeyData($forgeTestInvoicesTableName); if ($this->db->DBDriver === 'SQLite3') { $this->assertSame('users_id to db_forge_test_users.id', $foreignKeyData[0]->constraint_name); $this->assertSame(0, $foreignKeyData[0]->sequence); $this->assertSame('users_second_id to db_forge_test_users.second_id', $foreignKeyData[1]->constraint_name); $this->assertSame(1, $foreignKeyData[1]->sequence); + } elseif ($this->db->DBDriver === 'OCI8') { + $haystack = [$userIdColumnName, $userSecondIdColumnName]; + $this->assertSame($this->db->DBPrefix . 'forge_test_inv_uid_usid_fk', $foreignKeyData[0]->constraint_name); + $this->assertContains($foreignKeyData[0]->column_name, $haystack); + + $secondIdKey = 1; + $this->assertSame($this->db->DBPrefix . 'forge_test_inv_uid_usid_fk', $foreignKeyData[$secondIdKey]->constraint_name); + $this->assertContains($foreignKeyData[$secondIdKey]->column_name, $haystack); } else { - $haystack = ['users_id', 'users_second_id']; + $haystack = [$userIdColumnName, $userSecondIdColumnName]; $this->assertSame($this->db->DBPrefix . 'forge_test_invoices_users_id_users_second_id_foreign', $foreignKeyData[0]->constraint_name); $this->assertContains($foreignKeyData[0]->column_name, $haystack); @@ -532,10 +579,10 @@ public function testCompositeForeignKey() $this->assertSame($this->db->DBPrefix . 'forge_test_invoices_users_id_users_second_id_foreign', $foreignKeyData[$secondIdKey]->constraint_name); $this->assertContains($foreignKeyData[$secondIdKey]->column_name, $haystack); } - $this->assertSame($this->db->DBPrefix . 'forge_test_invoices', $foreignKeyData[0]->table_name); + $this->assertSame($this->db->DBPrefix . $forgeTestInvoicesTableName, $foreignKeyData[0]->table_name); $this->assertSame($this->db->DBPrefix . 'forge_test_users', $foreignKeyData[0]->foreign_table_name); - $this->forge->dropTable('forge_test_invoices', true); + $this->forge->dropTable($forgeTestInvoicesTableName, true); $this->forge->dropTable('forge_test_users', true); } @@ -678,15 +725,22 @@ public function testDropForeignKey() $this->forge->addKey('id', true); $this->forge->addForeignKey('users_id', 'forge_test_users', 'id', 'CASCADE', 'CASCADE'); - $this->forge->createTable('forge_test_invoices', true, $attributes); + $tableName = 'forge_test_invoices'; + $foreignKeyName = 'forge_test_invoices_users_id_foreign'; + if ($this->db->DBDriver === 'OCI8') { + $tableName = 'forge_test_inv'; + $foreignKeyName = 'forge_test_inv_users_id_fk'; + } - $this->forge->dropForeignKey('forge_test_invoices', 'forge_test_invoices_users_id_foreign'); + $this->forge->createTable($tableName, true, $attributes); - $foreignKeyData = $this->db->getForeignKeyData('forge_test_invoices'); + $this->forge->dropForeignKey($tableName, $foreignKeyName); + + $foreignKeyData = $this->db->getForeignKeyData($tableName); $this->assertEmpty($foreignKeyData); - $this->forge->dropTable('forge_test_invoices', true); + $this->forge->dropTable($tableName, true); $this->forge->dropTable('forge_test_users', true); } @@ -727,7 +781,11 @@ public function testAddColumn() public function testAddFields() { - $this->forge->dropTable('forge_test_fields', true); + $tableName = 'forge_test_fields'; + if ($this->db->DBDriver === 'OCI8') { + $tableName = 'getestfield'; + } + $this->forge->dropTable($tableName, true); $this->forge->addField([ 'id' => [ @@ -754,18 +812,14 @@ public function testAddFields() $this->forge->addKey('id', true); $this->forge->addUniqueKey(['username', 'active']); - $this->forge->createTable('forge_test_fields', true); + $create = $this->forge->createTable($tableName, true); - $fieldsNames = $this->db->getFieldNames('forge_test_fields'); - $fieldsData = $this->db->getFieldData('forge_test_fields'); + $fieldsNames = $this->db->getFieldNames($tableName); + $fieldsData = $this->db->getFieldData($tableName); - $this->forge->dropTable('forge_test_fields', true); + $this->forge->dropTable($tableName, true); $this->assertIsArray($fieldsNames); - $this->assertContains('id', $fieldsNames); - $this->assertContains('username', $fieldsNames); - $this->assertContains('name', $fieldsNames); - $this->assertContains('active', $fieldsNames); $fields = ['id', 'name', 'username', 'active']; $this->assertContains($fieldsData[0]->name, $fields); @@ -803,6 +857,13 @@ public function testAddFields() $this->assertSame('varchar', $fieldsData[1]->type); $this->assertNull($fieldsData[1]->default); $this->assertSame(255, (int) $fieldsData[1]->max_length); + } elseif ($this->db->DBDriver === 'OCI8') { + // Check types + $this->assertSame('NUMBER', $fieldsData[0]->type); + $this->assertSame('VARCHAR2', $fieldsData[1]->type); + $this->assertSame('11', $fieldsData[0]->max_length); + $this->assertSame('', $fieldsData[1]->default); + $this->assertSame('255', $fieldsData[1]->max_length); } else { $this->fail(sprintf('DB driver "%s" is not supported.', $this->db->DBDriver)); } @@ -875,6 +936,16 @@ public function testCompositeKey() $this->assertSame($keys['db_forge_test_1_code_company']->fields, ['code', 'company']); $this->assertSame($keys['db_forge_test_1_code_company']->type, 'INDEX'); + $this->assertSame($keys['db_forge_test_1_code_active']->name, 'db_forge_test_1_code_active'); + $this->assertSame($keys['db_forge_test_1_code_active']->fields, ['code', 'active']); + $this->assertSame($keys['db_forge_test_1_code_active']->type, 'UNIQUE'); + } elseif ($this->db->DBDriver === 'OCI8') { + $this->assertSame($keys['pk_db_forge_test_1']->name, 'pk_db_forge_test_1'); + $this->assertSame($keys['pk_db_forge_test_1']->fields, ['id']); + $this->assertSame($keys['pk_db_forge_test_1']->type, 'PRIMARY'); + $this->assertSame($keys['db_forge_test_1_code_company']->name, 'db_forge_test_1_code_company'); + $this->assertSame($keys['db_forge_test_1_code_company']->fields, ['code', 'company']); + $this->assertSame($keys['db_forge_test_1_code_company']->type, 'INDEX'); $this->assertSame($keys['db_forge_test_1_code_active']->name, 'db_forge_test_1_code_active'); $this->assertSame($keys['db_forge_test_1_code_active']->fields, ['code', 'active']); $this->assertSame($keys['db_forge_test_1_code_active']->type, 'UNIQUE'); diff --git a/tests/system/Database/Live/GetTest.php b/tests/system/Database/Live/GetTest.php index 63f5ee9afd0c..20ae2e099d0d 100644 --- a/tests/system/Database/Live/GetTest.php +++ b/tests/system/Database/Live/GetTest.php @@ -175,6 +175,8 @@ public function testGetDataSeek() if ($this->db->DBDriver === 'SQLite3') { $this->expectException(DatabaseException::class); $this->expectExceptionMessage('SQLite3 doesn\'t support seeking to other offset.'); + } elseif ($this->db->DBDriver === 'OCI8') { + $this->markTestSkipped('OCI8 does not support data seek.'); } $data->dataSeek(3); diff --git a/tests/system/Database/Live/GroupTest.php b/tests/system/Database/Live/GroupTest.php index 705172ac97f0..c7514d0954dc 100644 --- a/tests/system/Database/Live/GroupTest.php +++ b/tests/system/Database/Live/GroupTest.php @@ -39,25 +39,48 @@ public function testGroupBy() public function testHavingBy() { - $result = $this->db->table('job') - ->select('name') - ->groupBy('name') - ->having('SUM(id) > 2') - ->get() - ->getResultArray(); + $isANSISQL = in_array($this->db->DBDriver, ['OCI8'], true); + + if ($isANSISQL) { + $result = $this->db->table('job') + ->select('name') + ->groupBy('name') + ->having('SUM("id") >', 2) + ->get() + ->getResultArray(); + } else { + $result = $this->db->table('job') + ->select('name') + ->groupBy('name') + ->having('SUM(id) >', 2) + ->get() + ->getResultArray(); + } $this->assertCount(2, $result); } public function testOrHavingBy() { - $result = $this->db->table('user') - ->select('id') - ->groupBy('id') - ->having('id >', 3) - ->orHaving('SUM(id) > 2') - ->get() - ->getResult(); + $isANSISQL = in_array($this->db->DBDriver, ['OCI8'], true); + + if ($isANSISQL) { + $result = $this->db->table('user') + ->select('id') + ->groupBy('id') + ->having('id >', 3) + ->orHaving('SUM("id") >', 2) + ->get() + ->getResult(); + } else { + $result = $this->db->table('user') + ->select('id') + ->groupBy('id') + ->having('id >', 3) + ->orHaving('SUM(id) >', 2) + ->get() + ->getResult(); + } $this->assertCount(2, $result); } @@ -110,14 +133,27 @@ public function testHavingNotIn() public function testOrHavingNotIn() { - $result = $this->db->table('job') - ->select('name') - ->groupBy('name') - ->orderBy('name', 'asc') - ->having('SUM(id) > 2') - ->orHavingNotIn('name', ['Developer', 'Politician']) - ->get() - ->getResult(); + $isANSISQL = in_array($this->db->DBDriver, ['OCI8'], true); + + if ($isANSISQL) { + $result = $this->db->table('job') + ->select('name') + ->groupBy('name') + ->orderBy('name', 'asc') + ->having('SUM("id") >', 2) + ->orHavingNotIn('name', ['Developer', 'Politician']) + ->get() + ->getResult(); + } else { + $result = $this->db->table('job') + ->select('name') + ->groupBy('name') + ->orderBy('name', 'asc') + ->having('SUM(id) >', 2) + ->orHavingNotIn('name', ['Developer', 'Politician']) + ->get() + ->getResult(); + } $this->assertCount(2, $result); $this->assertSame('Accountant', $result[0]->name); @@ -170,14 +206,27 @@ public function testOrHavingLike() public function testOrNotHavingLike() { - $result = $this->db->table('job') - ->select('name') - ->groupBy('name') - ->orderBy('name', 'asc') - ->having('SUM(id) > 2') - ->orNotHavingLike('name', 'ian') - ->get() - ->getResult(); + $isANSISQL = in_array($this->db->DBDriver, ['OCI8'], true); + + if ($isANSISQL) { + $result = $this->db->table('job') + ->select('name') + ->groupBy('name') + ->orderBy('name', 'asc') + ->having('SUM("id") >', 2) + ->orNotHavingLike('name', 'ian') + ->get() + ->getResult(); + } else { + $result = $this->db->table('job') + ->select('name') + ->groupBy('name') + ->orderBy('name', 'asc') + ->having('SUM(id) >', 2) + ->orNotHavingLike('name', 'ian') + ->get() + ->getResult(); + } $this->assertCount(3, $result); $this->assertSame('Accountant', $result[0]->name); @@ -187,17 +236,33 @@ public function testOrNotHavingLike() public function testAndHavingGroupStart() { - $result = $this->db->table('job') - ->select('name') - ->groupBy('name') - ->orderBy('name', 'asc') - ->having('SUM(id) > 2') - ->havingGroupStart() - ->having('SUM(id) <= 4') - ->havingLike('name', 'ant', 'before') - ->havingGroupEnd() - ->get() - ->getResult(); + $isANSISQL = in_array($this->db->DBDriver, ['OCI8'], true); + + if ($isANSISQL) { + $result = $this->db->table('job') + ->select('name') + ->groupBy('name') + ->orderBy('name', 'asc') + ->having('SUM("id") >', 2) + ->havingGroupStart() + ->having('SUM("id") <=', 4) + ->havingLike('name', 'ant', 'before') + ->havingGroupEnd() + ->get() + ->getResult(); + } else { + $result = $this->db->table('job') + ->select('name') + ->groupBy('name') + ->orderBy('name', 'asc') + ->having('SUM(id) >', 2) + ->havingGroupStart() + ->having('SUM(id) <=', 4) + ->havingLike('name', 'ant', 'before') + ->havingGroupEnd() + ->get() + ->getResult(); + } $this->assertCount(1, $result); $this->assertSame('Accountant', $result[0]->name); @@ -205,17 +270,33 @@ public function testAndHavingGroupStart() public function testOrHavingGroupStart() { - $result = $this->db->table('job') - ->select('name') - ->groupBy('name') - ->orderBy('name', 'asc') - ->having('SUM(id) > 2') - ->orHavingGroupStart() - ->having('SUM(id) <= 4') - ->havingLike('name', 'ant', 'before') - ->havingGroupEnd() - ->get() - ->getResult(); + $isANSISQL = in_array($this->db->DBDriver, ['OCI8'], true); + + if ($isANSISQL) { + $result = $this->db->table('job') + ->select('name') + ->groupBy('name') + ->orderBy('name', 'asc') + ->having('SUM("id") >', 2) + ->orHavingGroupStart() + ->having('SUM("id") <=', 4) + ->havingLike('name', 'ant', 'before') + ->havingGroupEnd() + ->get() + ->getResult(); + } else { + $result = $this->db->table('job') + ->select('name') + ->groupBy('name') + ->orderBy('name', 'asc') + ->having('SUM(id) >', 2) + ->orHavingGroupStart() + ->having('SUM(id) <=', 4) + ->havingLike('name', 'ant', 'before') + ->havingGroupEnd() + ->get() + ->getResult(); + } $this->assertCount(2, $result); $this->assertSame('Accountant', $result[0]->name); @@ -224,17 +305,33 @@ public function testOrHavingGroupStart() public function testNotHavingGroupStart() { - $result = $this->db->table('job') - ->select('name') - ->groupBy('name') - ->orderBy('name', 'asc') - ->having('SUM(id) > 2') - ->notHavingGroupStart() - ->having('SUM(id) <= 4') - ->havingLike('name', 'ant', 'before') - ->havingGroupEnd() - ->get() - ->getResult(); + $isANSISQL = in_array($this->db->DBDriver, ['OCI8'], true); + + if ($isANSISQL) { + $result = $this->db->table('job') + ->select('name') + ->groupBy('name') + ->orderBy('name', 'asc') + ->having('SUM("id") >', 2) + ->notHavingGroupStart() + ->having('SUM("id") <=', 4) + ->havingLike('name', 'ant', 'before') + ->havingGroupEnd() + ->get() + ->getResult(); + } else { + $result = $this->db->table('job') + ->select('name') + ->groupBy('name') + ->orderBy('name', 'asc') + ->having('SUM(id) >', 2) + ->notHavingGroupStart() + ->having('SUM(id) <=', 4) + ->havingLike('name', 'ant', 'before') + ->havingGroupEnd() + ->get() + ->getResult(); + } $this->assertCount(1, $result); $this->assertSame('Musician', $result[0]->name); @@ -242,17 +339,33 @@ public function testNotHavingGroupStart() public function testOrNotHavingGroupStart() { - $result = $this->db->table('job') - ->select('name') - ->groupBy('name') - ->orderBy('name', 'asc') - ->having('SUM(id) > 2') - ->orNotHavingGroupStart() - ->having('SUM(id) < 2') - ->havingLike('name', 'o') - ->havingGroupEnd() - ->get() - ->getResult(); + $isANSISQL = in_array($this->db->DBDriver, ['OCI8'], true); + + if ($isANSISQL) { + $result = $this->db->table('job') + ->select('name') + ->groupBy('name') + ->orderBy('name', 'asc') + ->having('SUM("id") >', 2) + ->orNotHavingGroupStart() + ->having('SUM("id") <', 2) + ->havingLike('name', 'o') + ->havingGroupEnd() + ->get() + ->getResult(); + } else { + $result = $this->db->table('job') + ->select('name') + ->groupBy('name') + ->orderBy('name', 'asc') + ->having('SUM(id) >', 2) + ->orNotHavingGroupStart() + ->having('SUM(id) <', 2) + ->havingLike('name', 'o') + ->havingGroupEnd() + ->get() + ->getResult(); + } $this->assertCount(3, $result); $this->assertSame('Accountant', $result[0]->name); diff --git a/tests/system/Database/Live/OCI8/CallStoredProcedureTest.php b/tests/system/Database/Live/OCI8/CallStoredProcedureTest.php new file mode 100644 index 000000000000..3b85fd068d36 --- /dev/null +++ b/tests/system/Database/Live/OCI8/CallStoredProcedureTest.php @@ -0,0 +1,101 @@ + + * + * For the full copyright and license information, please view + * the LICENSE file that was distributed with this source code. + */ + +namespace CodeIgniter\Database\Live\OCI8; + +use CodeIgniter\Test\CIUnitTestCase; +use CodeIgniter\Test\DatabaseTestTrait; + +/** + * @group DatabaseLive + * + * @internal + */ +final class CallStoredProcedureTest extends CIUnitTestCase +{ + use DatabaseTestTrait; + + protected $refresh = true; + + protected function setUp(): void + { + parent::setUp(); + + if ($this->db->DBDriver !== 'OCI8') { + $this->markTestSkipped('Only OCI8 has its own implementation.'); + } + } + + public function testCallPackageProcedure() + { + $result = 0; + + $this->db->storedProcedure('calculator.plus', [ + [ + 'name' => ':left', + 'value' => 2, + ], + [ + 'name' => ':right', + 'value' => 5, + ], + [ + 'name' => ':output', + 'value' => &$result, + ], + + ]); + + $this->assertSame($result, '7'); + } + + public function testCallStoredProcedure() + { + $result = 0; + + $this->db->storedProcedure('plus', [ + [ + 'name' => ':left', + 'value' => 2, + ], + [ + 'name' => ':right', + 'value' => 5, + ], + [ + 'name' => ':output', + 'value' => &$result, + ], + + ]); + + $this->assertSame($result, '7'); + } + + public function testCallStoredProcedureForCursor() + { + $result = $this->db->getCursor(); + + $this->db->storedProcedure('one', [ + [ + 'name' => ':cursor', + 'type' => OCI_B_CURSOR, + 'value' => &$result, + ], + + ]); + + oci_execute($result); + $row = oci_fetch_array($result, OCI_ASSOC + OCI_RETURN_NULLS); + + $this->assertSame($row, ['ONE' => '1']); + } +} diff --git a/tests/system/Database/Live/OCI8/LastInsertIDTest.php b/tests/system/Database/Live/OCI8/LastInsertIDTest.php new file mode 100644 index 000000000000..16e4d84e989c --- /dev/null +++ b/tests/system/Database/Live/OCI8/LastInsertIDTest.php @@ -0,0 +1,89 @@ + + * + * For the full copyright and license information, please view + * the LICENSE file that was distributed with this source code. + */ + +namespace CodeIgniter\Database\Live\OCI8; + +use CodeIgniter\Database\Query; +use CodeIgniter\Test\CIUnitTestCase; +use CodeIgniter\Test\DatabaseTestTrait; + +/** + * @group DatabaseLive + * + * @internal + */ +final class LastInsertIDTest extends CIUnitTestCase +{ + use DatabaseTestTrait; + + protected $refresh = true; + protected $seed = 'Tests\Support\Database\Seeds\CITestSeeder'; + + protected function setUp(): void + { + parent::setUp(); + + if ($this->db->DBDriver !== 'OCI8') { + $this->markTestSkipped('Only OCI8 has its own implementation.'); + } + } + + public function testGetInsertIDWithInsert() + { + $jobData = [ + 'name' => 'Grocery Sales', + 'description' => 'Discount!', + ]; + + $this->db->table('job')->insert($jobData); + $actual = $this->db->insertID(); + + $this->assertSame($actual, 5); + } + + public function testGetInsertIDWithQuery() + { + $this->db->query('INSERT INTO "db_job" ("name", "description") VALUES (?, ?)', ['Grocery Sales', 'Discount!']); + $actual = $this->db->insertID(); + + $this->assertSame($actual, 5); + } + + public function testGetInsertIDWithHasCommentQuery() + { + $sql = <<<'SQL' + -- INSERT INTO "db_misc" ("key", "value") VALUES ('key', 'value') + --INSERT INTO "db_misc" ("key", "value") VALUES ('key', 'value') + /* INSERT INTO "db_misc" ("key", "value") VALUES ('key', 'value') */ + /*INSERT INTO "db_misc" ("key", "value") VALUES ('key', 'value')*/ + INSERT /* INTO "db_misc" */ INTO -- comment "db_misc" + "db_job" ("name", "description") VALUES (' INTO "abc"', ?) + SQL; + $this->db->query($sql, ['Discount!']); + $actual = $this->db->insertID(); + + $this->assertSame($actual, 5); + } + + public function testGetInsertIDWithPreparedQuery() + { + $query = $this->db->prepare(static function ($db) { + $sql = 'INSERT INTO "db_job" ("name", "description") VALUES (?, ?)'; + + return (new Query($db))->setQuery($sql); + }); + + $query->execute('foo', 'bar'); + $actual = $this->db->insertID(); + + $this->assertSame($actual, 5); + } +} diff --git a/tests/system/Database/Live/OrderTest.php b/tests/system/Database/Live/OrderTest.php index 76f7e8374f32..eaab910edc5e 100644 --- a/tests/system/Database/Live/OrderTest.php +++ b/tests/system/Database/Live/OrderTest.php @@ -83,6 +83,8 @@ public function testOrderRandom() } elseif ($this->db->DBDriver === 'SQLSRV') { $key = 'NEWID()'; $table = '"' . $this->db->getDatabase() . '"."' . $this->db->schema . '".' . $table; + } elseif ($this->db->DBDriver === 'OCI8') { + $key = '"DBMS_RANDOM"."RANDOM"'; } $expected = 'SELECT * FROM ' . $table . ' ORDER BY ' . $key; diff --git a/tests/system/Database/Live/PreparedQueryTest.php b/tests/system/Database/Live/PreparedQueryTest.php index acfc17277982..ef71e1500065 100644 --- a/tests/system/Database/Live/PreparedQueryTest.php +++ b/tests/system/Database/Live/PreparedQueryTest.php @@ -112,7 +112,11 @@ public function testExecuteRunsQueryAndReturnsResultObject() public function testExecuteRunsQueryAndReturnsManualResultObject() { $this->query = $this->db->prepare(static function ($db) { - $sql = "INSERT INTO {$db->DBPrefix}user (name, email, country) VALUES (?, ?, ?)"; + $sql = "INSERT INTO {$db->protectIdentifiers($db->DBPrefix . 'user')} (" + . $db->protectIdentifiers('name') . ', ' + . $db->protectIdentifiers('email') . ', ' + . $db->protectIdentifiers('country') + . ') VALUES (?, ?, ?)'; if ($db->DBDriver === 'SQLSRV') { $sql = "INSERT INTO {$db->schema}.{$db->DBPrefix}user (name, email, country) VALUES (?, ?, ?)"; @@ -121,8 +125,8 @@ public function testExecuteRunsQueryAndReturnsManualResultObject() return (new Query($db))->setQuery($sql); }); - $this->query->execute('foo', 'foo@example.com', ''); - $this->query->execute('bar', 'bar@example.com', ''); + $this->query->execute('foo', 'foo@example.com', 'US'); + $this->query->execute('bar', 'bar@example.com', 'GB'); $this->seeInDatabase($this->db->DBPrefix . 'user', ['name' => 'foo', 'email' => 'foo@example.com']); $this->seeInDatabase($this->db->DBPrefix . 'user', ['name' => 'bar', 'email' => 'bar@example.com']); diff --git a/tests/system/Database/Live/UpdateTest.php b/tests/system/Database/Live/UpdateTest.php index f7e2fb5e4b32..c5502ce949a1 100644 --- a/tests/system/Database/Live/UpdateTest.php +++ b/tests/system/Database/Live/UpdateTest.php @@ -14,6 +14,7 @@ use CodeIgniter\Database\Exceptions\DatabaseException; use CodeIgniter\Test\CIUnitTestCase; use CodeIgniter\Test\DatabaseTestTrait; +use Config\Database; /** * @group DatabaseLive @@ -202,7 +203,7 @@ public function testUpdatePeriods() public function testSetWithoutEscape() { $this->db->table('job') - ->set('description', 'name', false) + ->set('description', $this->db->escapeIdentifiers('name'), false) ->update(); $this->seeInDatabase('job', [ diff --git a/tests/system/Database/Live/WhereTest.php b/tests/system/Database/Live/WhereTest.php index 76756e19a219..f349418eef0d 100644 --- a/tests/system/Database/Live/WhereTest.php +++ b/tests/system/Database/Live/WhereTest.php @@ -127,10 +127,18 @@ public function testSubQuery() ->where('name', 'Developer') ->getCompiledSelect(); - $jobs = $this->db->table('job') - ->where('id not in (' . $subQuery . ')', null, false) - ->get() - ->getResult(); + if ($this->db->DBDriver === 'OCI8') { + $jobs = $this->db->table('job') + ->where('"id" not in (' . $subQuery . ')', null, false) + ->orderBy('id') + ->get() + ->getResult(); + } else { + $jobs = $this->db->table('job') + ->where('id not in (' . $subQuery . ')', null, false) + ->get() + ->getResult(); + } $this->assertCount(3, $jobs); $this->assertSame('Politician', $jobs[0]->name); @@ -145,10 +153,17 @@ public function testSubQueryAnotherType() ->where('name', 'Developer') ->getCompiledSelect(); - $jobs = $this->db->table('job') - ->where('id = (' . $subQuery . ')', null, false) - ->get() - ->getResult(); + if ($this->db->DBDriver === 'OCI8') { + $jobs = $this->db->table('job') + ->where('"id" = (' . $subQuery . ')', null, false) + ->get() + ->getResult(); + } else { + $jobs = $this->db->table('job') + ->where('id = (' . $subQuery . ')', null, false) + ->get() + ->getResult(); + } $this->assertCount(1, $jobs); $this->assertSame('Developer', $jobs[0]->name); @@ -215,8 +230,15 @@ public function testWhereWithLower() 'description' => null, ]); + $ANSISQLDriverNames = ['OCI8']; + $lowerJobName = sprintf('LOWER(%s.name)', $this->db->prefixTable('job')); + + if (in_array($this->db->DBDriver, $ANSISQLDriverNames, true)) { + $lowerJobName = sprintf('LOWER("%s"."name")', $this->db->prefixTable('job')); + } + $job = $builder - ->where(sprintf('LOWER(%s.name)', $this->db->prefixTable('job')), 'brewmaster') + ->where($lowerJobName, 'brewmaster') ->get() ->getResult(); $this->assertCount(1, $job); diff --git a/tests/system/Models/FindModelTest.php b/tests/system/Models/FindModelTest.php index bf06422d8f5f..e564f570ec8c 100644 --- a/tests/system/Models/FindModelTest.php +++ b/tests/system/Models/FindModelTest.php @@ -168,7 +168,17 @@ public function testFirstAggregate($groupBy, $total): void $this->model->groupBy('id'); } - $user = $this->model->select('SUM(id) as total')->where('id >', 2)->first(); + $ANSISQLDriverNames = ['OCI8']; + + if (in_array($this->db->DBDriver, $ANSISQLDriverNames, true)) { + $this->model->select('SUM("id") as "total"'); + } else { + $this->model->select('SUM(id) as total'); + } + + $user = $this->model + ->where('id >', 2) + ->first(); $this->assertSame($total, (int) $user->total); } @@ -195,10 +205,20 @@ public function testFirstRespectsSoftDeletes($aggregate, $groupBy): void $this->createModel(UserModel::class); if ($aggregate) { - $this->model->select('SUM(id) as id'); + $ANSISQLDriverNames = ['OCI8']; + + if (in_array($this->db->DBDriver, $ANSISQLDriverNames, true)) { + $this->model->select('SUM("id") as "id"'); + } else { + $this->model->select('SUM(id) as id'); + } } if ($groupBy) { + if (! $aggregate) { + $this->model->select('id'); + } + $this->model->groupBy('id'); } @@ -212,7 +232,7 @@ public function testFirstRespectsSoftDeletes($aggregate, $groupBy): void $this->assertSame(9, (int) $user->id); } - $user = $this->model->withDeleted()->first(); + $user = $this->model->withDeleted()->select('id')->first(); $this->assertSame(1, (int) $user->id); } @@ -228,7 +248,15 @@ public function testFirstRecoverTempUseSoftDeletes($aggregate, $groupBy): void $this->model->delete(1); if ($aggregate) { - $this->model->select('sum(id) as id'); + $ANSISQLDriverNames = ['OCI8']; + + if (in_array($this->db->DBDriver, $ANSISQLDriverNames, true)) { + $this->model->select('SUM("id") as "id"'); + } else { + $this->model->select('SUM(id) as id'); + } + } else { + $this->model->select('id'); } if ($groupBy) { @@ -238,7 +266,7 @@ public function testFirstRecoverTempUseSoftDeletes($aggregate, $groupBy): void $user = $this->model->withDeleted()->first(); $this->assertSame(1, (int) $user->id); - $user2 = $this->model->first(); + $user2 = $this->model->select('id')->first(); $this->assertSame(2, (int) $user2->id); } diff --git a/tests/system/Models/PaginateModelTest.php b/tests/system/Models/PaginateModelTest.php index 35e58221ecee..ae93f2f6c62b 100644 --- a/tests/system/Models/PaginateModelTest.php +++ b/tests/system/Models/PaginateModelTest.php @@ -46,7 +46,7 @@ public function testPaginatePassPerPageParameter(): void public function testPaginateForQueryWithGroupBy(): void { $this->createModel(ValidModel::class); - $this->model->groupBy('id'); + $this->model->select('id')->groupBy('id'); $this->model->paginate(); $this->assertSame(4, $this->model->pager->getDetails()['total']); } diff --git a/user_guide_src/source/changelogs/v4.2.0.rst b/user_guide_src/source/changelogs/v4.2.0.rst index 98d14b6e9197..94024f4192f8 100644 --- a/user_guide_src/source/changelogs/v4.2.0.rst +++ b/user_guide_src/source/changelogs/v4.2.0.rst @@ -26,6 +26,8 @@ Enhancements - New View Decorators allow modifying the generated HTML prior to caching. - Added Subqueries in the FROM section. See :ref:`query-builder-from-subquery`. - Added Validation Strict Rules. See :ref:`validation-traditional-and-strict-rules`. +- Added new OCI8 driver for database. + - It can access Oracle Database and supports SQL and PL/SQL statements. Changes ******* diff --git a/user_guide_src/source/database/queries.rst b/user_guide_src/source/database/queries.rst index af15bacea038..b78cc1907b4c 100644 --- a/user_guide_src/source/database/queries.rst +++ b/user_guide_src/source/database/queries.rst @@ -27,6 +27,9 @@ this:: $query = $db->query('YOUR QUERY HERE'); +.. note:: If you are using OCI8 Driver, SQL statements should not end with a semi-colon (``;``). + PL/SQL statements should end with a semi-colon (``;``). + Simplified Queries ================== diff --git a/user_guide_src/source/database/query_builder.rst b/user_guide_src/source/database/query_builder.rst index d21896e3c251..e4283cf52f67 100755 --- a/user_guide_src/source/database/query_builder.rst +++ b/user_guide_src/source/database/query_builder.rst @@ -779,9 +779,6 @@ be ignored, unless you specify a numeric seed value. $builder->orderBy(42, 'RANDOM'); // Produces: ORDER BY RAND(42) -.. note:: Random ordering is not currently supported in Oracle and - will default to ASC instead. - **************************** Limiting or Counting Results **************************** diff --git a/user_guide_src/source/intro/requirements.rst b/user_guide_src/source/intro/requirements.rst index 2a3d41ded92c..a55b8c46d0d9 100644 --- a/user_guide_src/source/intro/requirements.rst +++ b/user_guide_src/source/intro/requirements.rst @@ -19,12 +19,13 @@ Currently supported databases are: - PostgreSQL via the *Postgre* driver - SQLite3 via the *SQLite3* driver - MSSQL via the *SQLSRV* driver (version 2005 and above only) + - Oracle via the *OCI8* driver (version 12.1 and above only) Not all of the drivers have been converted/rewritten for CodeIgniter4. The list below shows the outstanding ones. - MySQL (5.1+) via the *pdo* driver - - Oracle via the *oci8* and *pdo* drivers + - Oracle via the *pdo* drivers - PostgreSQL via the *pdo* driver - MSSQL via the *pdo* driver - SQLite via the *sqlite* (version 2) and *pdo* drivers