├── tests
├── Runtime
│ └── .gitignore
├── .env
├── bootstrap.php
├── Support
│ ├── Fixture
│ │ ├── FixtureDump.php
│ │ ├── oci21.sql
│ │ └── oci.sql
│ ├── OracleTestHelper.php
│ ├── TestConnection.php
│ └── IntegrationTestTrait.php
├── BatchQueryResultTest.php
├── QueryGetTableAliasTest.php
├── Provider
│ ├── ColumnBuilderProvider.php
│ ├── SqlParserProvider.php
│ ├── ColumnDefinitionParserProvider.php
│ ├── CommandPdoProvider.php
│ ├── QuoterProvider.php
│ ├── ColumnFactoryProvider.php
│ ├── CommandProvider.php
│ ├── ColumnProvider.php
│ └── SchemaProvider.php
├── SqlParserTest.php
├── ColumnDefinitionParserTest.php
├── ColumnBuilderTest.php
├── QueryTest.php
├── PdoCommandTest.php
├── QuoterTest.php
├── DsnTest.php
├── ColumnFactoryTest.php
├── Column
│ └── EnumColumnTest.php
├── PdoConnectionTest.php
├── ConnectionTest.php
├── SchemaTest.php
└── ColumnTest.php
├── tools
├── .gitignore
├── psalm
│ └── composer.json
└── infection
│ └── composer.json
├── .phpunit-watcher.yml
├── docker-compose.yml
├── infection.json.dist
├── src
├── Transaction.php
├── Quoter.php
├── ServerInfo.php
├── IndexType.php
├── Column
│ ├── BooleanColumn.php
│ ├── BinaryColumn.php
│ ├── JsonColumn.php
│ ├── ColumnBuilder.php
│ ├── ColumnDefinitionParser.php
│ ├── DateTimeColumn.php
│ ├── ColumnFactory.php
│ └── ColumnDefinitionBuilder.php
├── Driver.php
├── QueryBuilder.php
├── Builder
│ ├── ShortestBuilder.php
│ ├── LongestBuilder.php
│ ├── LikeBuilder.php
│ ├── ArrayMergeBuilder.php
│ └── InBuilder.php
├── Dsn.php
├── SqlParser.php
├── Connection.php
├── DQLQueryBuilder.php
├── DDLQueryBuilder.php
├── Command.php
├── DMLQueryBuilder.php
└── Schema.php
├── .php-cs-fixer.dist.php
├── psalm.xml
├── rector.php
├── LICENSE.md
├── composer.json
├── README.md
└── CHANGELOG.md
/tests/Runtime/.gitignore:
--------------------------------------------------------------------------------
1 |
--------------------------------------------------------------------------------
/tools/.gitignore:
--------------------------------------------------------------------------------
1 | /*/vendor
2 | /*/composer.lock
3 |
--------------------------------------------------------------------------------
/tools/psalm/composer.json:
--------------------------------------------------------------------------------
1 | {
2 | "require-dev": {
3 | "vimeo/psalm": "^5.26.1 || ^6.8.8"
4 | }
5 | }
6 |
--------------------------------------------------------------------------------
/tests/.env:
--------------------------------------------------------------------------------
1 | ENVIRONMENT=local
2 | YII_ORACLE_SID=XE
3 | YII_ORACLE_HOST=oracle
4 | YII_ORACLE_PORT=1521
5 | YII_ORACLE_USER=system
6 | YII_ORACLE_PASSWORD=root
7 |
--------------------------------------------------------------------------------
/tests/bootstrap.php:
--------------------------------------------------------------------------------
1 | load();
8 | }
9 |
--------------------------------------------------------------------------------
/tools/infection/composer.json:
--------------------------------------------------------------------------------
1 | {
2 | "require-dev": {
3 | "infection/infection": "^0.26 || ^0.31.9"
4 | },
5 | "config": {
6 | "allow-plugins": {
7 | "infection/extension-installer": true
8 | }
9 | }
10 | }
11 |
--------------------------------------------------------------------------------
/.phpunit-watcher.yml:
--------------------------------------------------------------------------------
1 | watch:
2 | directories:
3 | - src
4 | - tests
5 | fileMask: '*.php'
6 | notifications:
7 | passingTests: false
8 | failingTests: false
9 | phpunit:
10 | binaryPath: vendor/bin/phpunit
11 | timeout: 180
12 |
--------------------------------------------------------------------------------
/docker-compose.yml:
--------------------------------------------------------------------------------
1 | version: '3'
2 |
3 | services:
4 | oracle:
5 | image: gvenzl/oracle-xe:21
6 | ports:
7 | - 1521:1521
8 | environment:
9 | ORACLE_PASSWORD : root
10 | ORACLE_DATABASE : yiitest
11 | APP_USER: yiitest
12 | APP_USER_PASSWORD: root
13 |
--------------------------------------------------------------------------------
/tests/Support/Fixture/FixtureDump.php:
--------------------------------------------------------------------------------
1 | in([
10 | __DIR__ . '/src',
11 | __DIR__ . '/tests',
12 | ]);
13 |
14 | return (new Config())
15 | ->setParallelConfig(ParallelConfigFactory::detect())
16 | ->setRules([
17 | '@PER-CS3.0' => true,
18 | 'no_unused_imports' => true,
19 | 'ordered_class_elements' => true,
20 | 'class_attributes_separation' => ['elements' => ['method' => 'one']],
21 | ])
22 | ->setFinder($finder);
23 |
--------------------------------------------------------------------------------
/src/ServerInfo.php:
--------------------------------------------------------------------------------
1 | timezone) || $refresh) {
18 | /** @var string */
19 | $this->timezone = $this->db->createCommand('SELECT SESSIONTIMEZONE FROM DUAL')->queryScalar();
20 | }
21 |
22 | return $this->timezone;
23 | }
24 | }
25 |
--------------------------------------------------------------------------------
/src/IndexType.php:
--------------------------------------------------------------------------------
1 |
2 |
13 |
14 |
15 |
16 |
17 |
18 |
19 |
20 |
21 |
22 |
23 |
24 |
25 |
--------------------------------------------------------------------------------
/tests/SqlParserTest.php:
--------------------------------------------------------------------------------
1 | '1',
19 | false => '0',
20 | null, '' => null,
21 | default => $value instanceof ExpressionInterface ? $value : ($value ? '1' : '0'),
22 | };
23 | }
24 |
25 | public function phpTypecast(mixed $value): ?bool
26 | {
27 | if ($value === null) {
28 | return null;
29 | }
30 |
31 | return $value && $value !== "\0";
32 | }
33 | }
34 |
--------------------------------------------------------------------------------
/tests/ColumnBuilderTest.php:
--------------------------------------------------------------------------------
1 | $value) {
26 | $str = match ($value) {
27 | '1' => preg_replace('/\bTRUE\b/i', $param, $str, 1),
28 | '0' => preg_replace('/\bFALSE\b/i', $param, $str, 1),
29 | default => $str,
30 | };
31 | }
32 | }
33 | }
34 |
--------------------------------------------------------------------------------
/src/Column/BinaryColumn.php:
--------------------------------------------------------------------------------
1 | getDbType() === 'blob') {
19 | if ($value instanceof Param) {
20 | $value = $value->value;
21 | } elseif ($value instanceof StringableStream) {
22 | $value = $value->getValue();
23 | }
24 |
25 | if (is_string($value)) {
26 | return new Expression('TO_BLOB(UTL_RAW.CAST_TO_RAW(:value))', ['value' => $value]);
27 | }
28 | }
29 |
30 | return parent::dbTypecast($value);
31 | }
32 | }
33 |
--------------------------------------------------------------------------------
/src/Column/JsonColumn.php:
--------------------------------------------------------------------------------
1 | withPaths([
15 | __DIR__ . '/src',
16 | __DIR__ . '/tests',
17 | ])
18 | ->withPhpSets(php81: true)
19 | ->withRules([
20 | InlineConstructorDefaultToPropertyRector::class,
21 | ])
22 | ->withSkip([
23 | NullToStrictStringFuncCallArgRector::class,
24 | ReadOnlyPropertyRector::class,
25 | SensitiveHereNowDocRector::class,
26 | RemoveParentCallWithoutParentRector::class,
27 | AddParamBasedOnParentClassMethodRector::class,
28 | ]);
29 |
--------------------------------------------------------------------------------
/src/Driver.php:
--------------------------------------------------------------------------------
1 | attributes += [PDO::ATTR_ERRMODE => PDO::ERRMODE_EXCEPTION];
20 |
21 | $pdo = parent::createConnection();
22 |
23 | $pdo->exec(
24 | <<getSharedConnection();
26 | $this->loadFixture();
27 |
28 | $selectExpression = "[[customer]].[[name]] || ' in ' || [[p]].[[description]] name";
29 |
30 | $result = (new Query($db))
31 | ->select([$selectExpression])
32 | ->from('customer')
33 | ->innerJoin('profile p', '[[customer]].[[profile_id]] = [[p]].[[id]]')
34 | ->indexBy('id')
35 | ->column();
36 |
37 | $this->assertSame([1 => 'user1 in profile customer 1', 3 => 'user3 in profile customer 3'], $result);
38 | }
39 | }
40 |
--------------------------------------------------------------------------------
/tests/Provider/ColumnDefinitionParserProvider.php:
--------------------------------------------------------------------------------
1 | 'long raw']],
14 | ['interval day to second', ['type' => 'interval day to second']],
15 | ['interval day to second (2)', ['type' => 'interval day to second', 'size' => 2]],
16 | ['interval day(0) to second(2)', ['type' => 'interval day to second', 'size' => 2, 'scale' => 0]],
17 | ['timestamp with time zone', ['type' => 'timestamp with time zone']],
18 | ['timestamp (3) with time zone', ['type' => 'timestamp with time zone', 'size' => 3]],
19 | ['timestamp(3) with local time zone', ['type' => 'timestamp with local time zone', 'size' => 3]],
20 | ['interval year to month', ['type' => 'interval year to month']],
21 | ['interval year (3) to month', ['type' => 'interval year to month', 'scale' => 3]],
22 | ];
23 | }
24 | }
25 |
--------------------------------------------------------------------------------
/src/QueryBuilder.php:
--------------------------------------------------------------------------------
1 | getQuoter();
25 | $schema = $db->getSchema();
26 |
27 | parent::__construct(
28 | $db,
29 | new DDLQueryBuilder($this, $quoter, $schema),
30 | new DMLQueryBuilder($this, $quoter, $schema),
31 | new DQLQueryBuilder($this, $quoter),
32 | new ColumnDefinitionBuilder($this),
33 | );
34 | }
35 |
36 | protected function prepareBinary(string $binary): string
37 | {
38 | return "HEXTORAW('" . bin2hex($binary) . "')";
39 | }
40 |
41 | protected function createSqlParser(string $sql): SqlParser
42 | {
43 | return new SqlParser($sql);
44 | }
45 | }
46 |
--------------------------------------------------------------------------------
/tests/PdoCommandTest.php:
--------------------------------------------------------------------------------
1 | markTestSkipped('It must be implemented.');
41 | }
42 | }
43 |
--------------------------------------------------------------------------------
/tests/Support/Fixture/oci21.sql:
--------------------------------------------------------------------------------
1 | BEGIN EXECUTE IMMEDIATE 'DROP TABLE "type"'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -942 THEN RAISE; END IF; END;--
2 |
3 | /* STATEMENTS */
4 |
5 | CREATE TABLE "type" (
6 | "int_col" integer NOT NULL,
7 | "int_col2" integer DEFAULT 1,
8 | "tinyint_col" number(3) DEFAULT 1,
9 | "smallint_col" smallint DEFAULT 1,
10 | "char_col" char(100) NOT NULL,
11 | "char_col2" varchar2(100) DEFAULT 'some''thing',
12 | "char_col3" varchar2(4000),
13 | "nvarchar_col" nvarchar2(100) DEFAULT '',
14 | "float_col" double precision NOT NULL,
15 | "float_col2" double precision DEFAULT 1.23,
16 | "blob_col" blob DEFAULT NULL,
17 | "numeric_col" decimal(5,2) DEFAULT 33.22,
18 | "timestamp_col" timestamp DEFAULT to_timestamp('2002-01-01 00:00:00', 'yyyy-mm-dd hh24:mi:ss') NOT NULL,
19 | "timestamp_local" timestamp with local time zone,
20 | "time_col" interval day (0) to second(0) DEFAULT INTERVAL '0 10:33:21' DAY(0) TO SECOND(0),
21 | "interval_day_col" interval day (1) to second(0) DEFAULT INTERVAL '2 04:56:12' DAY(1) TO SECOND(0),
22 | "bool_col" char NOT NULL check ("bool_col" in (0,1)),
23 | "bool_col2" char DEFAULT 1 check("bool_col2" in (0,1)),
24 | "ts_default" TIMESTAMP DEFAULT CURRENT_TIMESTAMP NOT NULL,
25 | "bit_col" number(3) DEFAULT 130 NOT NULL,
26 | "json_col" json DEFAULT '{"a":1}'
27 | );
28 |
29 | /* TRIGGERS */
30 |
31 | /* TRIGGERS */
32 |
--------------------------------------------------------------------------------
/tests/Provider/CommandPdoProvider.php:
--------------------------------------------------------------------------------
1 | '1',
23 | 'email' => 'user1@example.com',
24 | 'name' => 'user1',
25 | 'address' => 'address1',
26 | 'status' => '1',
27 | 'profile_id' => '1',
28 | ],
29 | ],
30 | ];
31 | }
32 |
33 | public static function bindParamsNonWhere(): array
34 | {
35 | return [
36 | [
37 | <<
23 | */
24 | final class ShortestBuilder extends MultiOperandFunctionBuilder
25 | {
26 | /**
27 | * Builds a SQL expression to represent the function which returns the shortest string.
28 | *
29 | * @param Shortest $expression The expression to build.
30 | * @param array $params The parameters to bind.
31 | *
32 | * @return string The SQL expression.
33 | */
34 | protected function buildFromExpression(MultiOperandFunction $expression, array &$params): string
35 | {
36 | $selects = [];
37 |
38 | foreach ($expression->getOperands() as $operand) {
39 | $selects[] = 'SELECT ' . $this->buildOperand($operand, $params) . ' AS value FROM DUAL';
40 | }
41 |
42 | $unions = implode(' UNION ', $selects);
43 |
44 | return "(SELECT value FROM ($unions) ORDER BY LENGTH(value) ASC FETCH FIRST 1 ROWS ONLY)";
45 | }
46 | }
47 |
--------------------------------------------------------------------------------
/tests/QuoterTest.php:
--------------------------------------------------------------------------------
1 |
24 | */
25 | final class LongestBuilder extends MultiOperandFunctionBuilder
26 | {
27 | /**
28 | * Builds a SQL expression to represent the function which returns the longest string.
29 | *
30 | * @param Greatest $expression The expression to build.
31 | * @param array $params The parameters to bind.
32 | *
33 | * @return string The SQL expression.
34 | */
35 | protected function buildFromExpression(MultiOperandFunction $expression, array &$params): string
36 | {
37 | $selects = [];
38 |
39 | foreach ($expression->getOperands() as $operand) {
40 | $selects[] = 'SELECT ' . $this->buildOperand($operand, $params) . ' AS value FROM DUAL';
41 | }
42 |
43 | $unions = implode(' UNION ', $selects);
44 |
45 | return "(SELECT value FROM ($unions) ORDER BY LENGTH(value) DESC FETCH FIRST 1 ROWS ONLY)";
46 | }
47 | }
48 |
--------------------------------------------------------------------------------
/src/Column/ColumnBuilder.php:
--------------------------------------------------------------------------------
1 | 'AL32UTF8']);
18 |
19 | $this->assertSame('oci', $dsn->driver);
20 | $this->assertSame('localhost', $dsn->host);
21 | $this->assertSame('yiitest', $dsn->databaseName);
22 | $this->assertSame('1522', $dsn->port);
23 | $this->assertSame(['charset' => 'AL32UTF8'], $dsn->options);
24 | $this->assertSame('oci:dbname=localhost:1522/yiitest;charset=AL32UTF8', (string) $dsn);
25 | }
26 |
27 | public function testConstructDefaults(): void
28 | {
29 | $dsn = new Dsn();
30 |
31 | $this->assertSame('oci', $dsn->driver);
32 | $this->assertSame('127.0.0.1', $dsn->host);
33 | $this->assertSame('', $dsn->databaseName);
34 | $this->assertSame('1521', $dsn->port);
35 | $this->assertSame([], $dsn->options);
36 | $this->assertSame('oci:dbname=127.0.0.1:1521', (string) $dsn);
37 | }
38 |
39 | public function testConstructWithEmptyPort(): void
40 | {
41 | $dsn = new Dsn('oci', 'localhost', port: '');
42 |
43 | $this->assertSame('oci', $dsn->driver);
44 | $this->assertSame('localhost', $dsn->host);
45 | $this->assertSame('', $dsn->databaseName);
46 | $this->assertSame('', $dsn->port);
47 | $this->assertSame([], $dsn->options);
48 | $this->assertSame('oci:dbname=localhost:', (string) $dsn);
49 | }
50 | }
51 |
--------------------------------------------------------------------------------
/src/Column/ColumnDefinitionParser.php:
--------------------------------------------------------------------------------
1 | $type];
36 |
37 | $typeDetails = $matches[6] ?? $matches[2] ?? '';
38 |
39 | if ($typeDetails !== '') {
40 | if ($type === 'enum') {
41 | $info += $this->enumInfo($typeDetails);
42 | } else {
43 | $info += $this->sizeInfo($typeDetails);
44 | }
45 | }
46 |
47 | $scale = $matches[5] ?? $matches[3] ?? '';
48 |
49 | if ($scale !== '') {
50 | $info += ['scale' => (int) $scale];
51 | }
52 |
53 | if (isset($matches[7])) {
54 | /** @psalm-var positive-int */
55 | $info['dimension'] = substr_count($matches[7], '[');
56 | }
57 |
58 | $extra = substr($definition, strlen($matches[0]));
59 |
60 | return $info + $this->extraInfo($extra);
61 | }
62 | }
63 |
--------------------------------------------------------------------------------
/src/Dsn.php:
--------------------------------------------------------------------------------
1 | $options
20 | */
21 | public function __construct(
22 | public readonly string $driver = 'oci',
23 | public readonly string $host = '127.0.0.1',
24 | public readonly string $databaseName = '',
25 | public readonly string $port = '1521',
26 | public readonly array $options = [],
27 | ) {}
28 |
29 | /**
30 | * @return string The Data Source Name, or DSN, contains the information required to connect to the database.
31 | *
32 | * Please refer to the [PHP manual](https://php.net/manual/en/pdo.construct.php) on the format of the DSN string.
33 | *
34 | * The `driver` property is used as the driver prefix of the DSN. For example:
35 | *
36 | * ```php
37 | * $dsn = new Dsn('oci', 'localhost', 'yiitest', '1521', ['charset' => 'AL32UTF8']);
38 | * $driver = new Driver($dsn, 'username', 'password');
39 | * $connection = new Connection($driver, 'system', 'root');
40 | * ```
41 | *
42 | * Will result in the DSN string `oci:dbname=localhost:1521/yiitest;charset=AL32UTF8`.
43 | */
44 | public function __toString(): string
45 | {
46 | $dsn = "$this->driver:dbname=$this->host:$this->port";
47 |
48 | if ($this->databaseName !== '') {
49 | $dsn .= "/$this->databaseName";
50 | }
51 |
52 | foreach ($this->options as $key => $value) {
53 | $dsn .= ";$key=$value";
54 | }
55 |
56 | return $dsn;
57 | }
58 | }
59 |
--------------------------------------------------------------------------------
/src/SqlParser.php:
--------------------------------------------------------------------------------
1 | length - 1;
15 |
16 | while ($this->position < $length) {
17 | $pos = $this->position++;
18 |
19 | match ($this->sql[$pos]) {
20 | ':' => ($word = $this->parseWord()) === ''
21 | ? $this->skipChars(':')
22 | : $result = ':' . $word,
23 | '"' => $this->skipToAfterChar('"'),
24 | "'" => $this->skipQuotedWithoutEscape($this->sql[$pos]),
25 | 'q', 'Q' => $this->sql[$this->position] === "'"
26 | ? $this->skipQuotedWithQ()
27 | : null,
28 | '-' => $this->sql[$this->position] === '-'
29 | ? ++$this->position && $this->skipToAfterChar("\n")
30 | : null,
31 | '/' => $this->sql[$this->position] === '*'
32 | ? ++$this->position && $this->skipToAfterString('*/')
33 | : null,
34 | default => null,
35 | };
36 |
37 | if ($result !== null) {
38 | $position = $pos;
39 |
40 | return $result;
41 | }
42 | }
43 |
44 | return null;
45 | }
46 |
47 | /**
48 | * Skips quoted string with Q-operator.
49 | */
50 | private function skipQuotedWithQ(): void
51 | {
52 | $endChar = match ($this->sql[++$this->position]) {
53 | '[' => ']',
54 | '<' => '>',
55 | '{' => '}',
56 | '(' => ')',
57 | default => $this->sql[$this->position],
58 | };
59 |
60 | ++$this->position;
61 |
62 | $this->skipToAfterString("$endChar'");
63 | }
64 | }
65 |
--------------------------------------------------------------------------------
/tests/Provider/QuoterProvider.php:
--------------------------------------------------------------------------------
1 | '']],
55 | ['""', ['name' => '']],
56 | ['animal', ['name' => 'animal']],
57 | ['"animal"', ['name' => 'animal']],
58 | ['dbo.animal', ['schemaName' => 'dbo', 'name' => 'animal']],
59 | ['"dbo"."animal"', ['schemaName' => 'dbo', 'name' => 'animal']],
60 | ['"dbo".animal', ['schemaName' => 'dbo', 'name' => 'animal']],
61 | ['dbo."animal"', ['schemaName' => 'dbo', 'name' => 'animal']],
62 | ];
63 | }
64 | }
65 |
--------------------------------------------------------------------------------
/tests/ColumnFactoryTest.php:
--------------------------------------------------------------------------------
1 | '!%',
28 | '_' => '!_',
29 | '!' => '!!',
30 | ];
31 |
32 | public function __construct(
33 | private readonly QueryBuilderInterface $queryBuilder,
34 | ) {
35 | parent::__construct($queryBuilder);
36 |
37 | /**
38 | * Different pdo_oci8 versions may or may not implement `PDO::quote()`, so {@see Quoter::quoteValue()} may or
39 | * may not quote `\`.
40 | */
41 | $this->escapingReplacements['\\'] = substr($this->queryBuilder->getQuoter()->quoteValue('\\'), 1, -1);
42 | }
43 |
44 | protected function prepareColumn(Like|NotLike $condition, array &$params): string
45 | {
46 | $column = parent::prepareColumn($condition, $params);
47 |
48 | if ($condition->caseSensitive === false) {
49 | $column = 'LOWER(' . $column . ')';
50 | }
51 |
52 | return $column;
53 | }
54 |
55 | protected function preparePlaceholderName(
56 | string|Stringable|int|ExpressionInterface $value,
57 | Like|NotLike $condition,
58 | array &$params,
59 | ): string {
60 | $placeholderName = parent::preparePlaceholderName($value, $condition, $params);
61 |
62 | if ($condition->caseSensitive === false) {
63 | $placeholderName = 'LOWER(' . $placeholderName . ')';
64 | }
65 |
66 | return $placeholderName;
67 | }
68 | }
69 |
--------------------------------------------------------------------------------
/tests/Support/TestConnection.php:
--------------------------------------------------------------------------------
1 | getSchema()->refresh();
21 | return $db;
22 | }
23 |
24 | public static function getServerVersion(): string
25 | {
26 | return self::getShared()->getServerInfo()->getVersion();
27 | }
28 |
29 | public static function dsn(): string
30 | {
31 | return self::$dsn ??= (string) new Dsn(
32 | host: self::host(),
33 | databaseName: self::sid(),
34 | port: self::port(),
35 | options: ['charset' => 'AL32UTF8'],
36 | );
37 | }
38 |
39 | public static function create(?string $dsn = null): Connection
40 | {
41 | return new Connection(self::createDriver($dsn), TestHelper::createMemorySchemaCache());
42 | }
43 |
44 | public static function createDriver(?string $dsn = null): Driver
45 | {
46 | return new Driver($dsn ?? self::dsn(), self::username(), self::password());
47 | }
48 |
49 | public static function databaseName(): string
50 | {
51 | return getenv('YII_ORACLE_DATABASE') ?: 'YIITEST';
52 | }
53 |
54 | private static function sid(): string
55 | {
56 | return getenv('YII_ORACLE_SID') ?: 'XE';
57 | }
58 |
59 | private static function host(): string
60 | {
61 | return getenv('YII_ORACLE_HOST') ?: 'localhost';
62 | }
63 |
64 | private static function port(): string
65 | {
66 | return getenv('YII_ORACLE_PORT') ?: '1521';
67 | }
68 |
69 | private static function username(): string
70 | {
71 | return getenv('YII_ORACLE_USER') ?: 'system';
72 | }
73 |
74 | private static function password(): string
75 | {
76 | return getenv('YII_ORACLE_PASSWORD') ?: 'root';
77 | }
78 | }
79 |
--------------------------------------------------------------------------------
/tests/Column/EnumColumnTest.php:
--------------------------------------------------------------------------------
1 | dropTable('test_enum_table');
24 | $this->executeStatements(
25 | <<getSharedConnection();
34 | $column = $db->getTableSchema('test_enum_table')->getColumn('status');
35 |
36 | $this->assertNotInstanceOf(EnumColumn::class, $column);
37 |
38 | $this->dropTable('test_enum_table');
39 | }
40 |
41 | protected function createDatabaseObjectsStatements(): array
42 | {
43 | return [
44 | <<getQuoter()->quoteTableName($table);
48 | $sql = <<createCommand($sql)->execute();
59 | }
60 |
61 | protected function dropView(ConnectionInterface $db, string $view): void
62 | {
63 | $view = $db->getQuoter()->quoteTableName($view);
64 | $sql = <<createCommand($sql)->execute();
75 | }
76 | }
77 |
--------------------------------------------------------------------------------
/composer.json:
--------------------------------------------------------------------------------
1 | {
2 | "name": "yiisoft/db-oracle",
3 | "description": "Oracle driver for Yii Database",
4 | "keywords": [
5 | "yii",
6 | "oracle",
7 | "database",
8 | "sql",
9 | "dbal",
10 | "query-builder"
11 | ],
12 | "type": "library",
13 | "license": "BSD-3-Clause",
14 | "support": {
15 | "issues": "https://github.com/yiisoft/db-oracle/issues?state=open",
16 | "source": "https://github.com/yiisoft/db-oracle",
17 | "forum": "https://www.yiiframework.com/forum/",
18 | "wiki": "https://www.yiiframework.com/wiki/",
19 | "irc": "ircs://irc.libera.chat:6697/yii",
20 | "chat": "https://t.me/yii3en"
21 | },
22 | "funding": [
23 | {
24 | "type": "opencollective",
25 | "url": "https://opencollective.com/yiisoft"
26 | },
27 | {
28 | "type": "github",
29 | "url": "https://github.com/sponsors/yiisoft"
30 | }
31 | ],
32 | "require": {
33 | "ext-pdo": "*",
34 | "php": "8.1 - 8.5",
35 | "yiisoft/db": "^2.0"
36 | },
37 | "require-dev": {
38 | "bamarni/composer-bin-plugin": "^1.8.3",
39 | "friendsofphp/php-cs-fixer": "^3.89.1",
40 | "maglnet/composer-require-checker": "^4.7.1",
41 | "phpunit/phpunit": "^10.5.45",
42 | "rector/rector": "^2.0.10",
43 | "spatie/phpunit-watcher": "^1.24",
44 | "vlucas/phpdotenv": "^5.6.1",
45 | "yiisoft/aliases": "^2.0",
46 | "yiisoft/psr-dummy-provider": "^1.0",
47 | "yiisoft/test-support": "^3.0",
48 | "yiisoft/var-dumper": "^1.7"
49 | },
50 | "provide": {
51 | "yiisoft/db-implementation": "1.0.0"
52 | },
53 | "autoload": {
54 | "psr-4": {
55 | "Yiisoft\\Db\\Oracle\\": "src"
56 | }
57 | },
58 | "autoload-dev": {
59 | "psr-4": {
60 | "Yiisoft\\Db\\Oracle\\Tests\\": "tests",
61 | "Yiisoft\\Db\\Tests\\": "vendor/yiisoft/db/tests"
62 | },
63 | "files": ["tests/bootstrap.php"]
64 | },
65 | "extra": {
66 | "bamarni-bin": {
67 | "bin-links": true,
68 | "target-directory": "tools",
69 | "forward-command": true
70 | }
71 | },
72 | "config": {
73 | "sort-packages": true,
74 | "allow-plugins": {
75 | "bamarni/composer-bin-plugin": true,
76 | "composer/package-versions-deprecated": true
77 | }
78 | },
79 | "prefer-stable": true,
80 | "scripts": {
81 | "test": "phpunit --testdox --no-interaction",
82 | "test-watch": "phpunit-watcher watch"
83 | }
84 | }
85 |
--------------------------------------------------------------------------------
/src/Builder/ArrayMergeBuilder.php:
--------------------------------------------------------------------------------
1 |
29 | */
30 | final class ArrayMergeBuilder extends MultiOperandFunctionBuilder
31 | {
32 | private const DEFAULT_OPERAND_TYPE = '';
33 |
34 | /**
35 | * Builds a SQL expression which merges arrays from the given {@see ArrayMerge} object.
36 | *
37 | * @param ArrayMerge $expression The expression to build.
38 | * @param array $params The parameters to bind.
39 | *
40 | * @return string The SQL expression.
41 | */
42 | protected function buildFromExpression(MultiOperandFunction $expression, array &$params): string
43 | {
44 | $selects = [];
45 | $operandType = $this->buildOperandType($expression->getType());
46 |
47 | foreach ($expression->getOperands() as $operand) {
48 | $builtOperand = $this->buildOperand($operand, $params);
49 | $selects[] = "SELECT value FROM JSON_TABLE($builtOperand, '$[*]' COLUMNS(value $operandType PATH '$'))";
50 | }
51 |
52 | $orderBy = $expression->getOrdered() ? ' ORDER BY value' : '';
53 | $unions = implode(' UNION ', $selects);
54 |
55 | return "(SELECT JSON_ARRAYAGG(value$orderBy) AS value FROM ($unions))";
56 | }
57 |
58 | private function buildOperandType(string|ColumnInterface $type): string
59 | {
60 | if (is_string($type)) {
61 | return $type === '' ? self::DEFAULT_OPERAND_TYPE : rtrim($type, '[]');
62 | }
63 |
64 | if ($type instanceof AbstractArrayColumn) {
65 | if ($type->getDimension() > 1) {
66 | return self::DEFAULT_OPERAND_TYPE;
67 | }
68 |
69 | $type = $type->getColumn();
70 |
71 | if ($type === null) {
72 | return self::DEFAULT_OPERAND_TYPE;
73 | }
74 | }
75 |
76 | return $this->queryBuilder->getColumnDefinitionBuilder()->buildType($type);
77 | }
78 | }
79 |
--------------------------------------------------------------------------------
/tests/PdoConnectionTest.php:
--------------------------------------------------------------------------------
1 | getSharedConnection();
24 | $this->loadFixture();
25 |
26 | $command = $db->createCommand();
27 | $command->insert('item', ['name' => 'Yii2 starter', 'category_id' => 1])->execute();
28 | $command->insert('item', ['name' => 'Yii3 starter', 'category_id' => 1])->execute();
29 |
30 | $this->assertSame('7', $db->getLastInsertId('item_SEQ'));
31 |
32 | $db->close();
33 | }
34 |
35 | public function testGetLastInsertIDWithException(): void
36 | {
37 | $db = $this->getSharedConnection();
38 | $this->loadFixture();
39 |
40 | $command = $db->createCommand();
41 | $command->insert('item', ['name' => 'Yii2 starter', 'category_id' => 1])->execute();
42 | $command->insert('item', ['name' => 'Yii3 starter', 'category_id' => 1])->execute();
43 |
44 | $this->expectException(InvalidArgumentException::class);
45 | $this->expectExceptionMessage('Oracle not support lastInsertId without sequence name.');
46 |
47 | $db->getLastInsertId();
48 | }
49 |
50 | public function testGetLastInsertIdWithTwoConnection()
51 | {
52 | $db1 = $this->createConnection();
53 | $db2 = $this->createConnection();
54 |
55 | $sql = 'INSERT INTO {{profile}}([[description]]) VALUES (\'non duplicate1\')';
56 | $db1->createCommand($sql)->execute();
57 |
58 | $sql = 'INSERT INTO {{profile}}([[description]]) VALUES (\'non duplicate2\')';
59 | $db2->createCommand($sql)->execute();
60 |
61 | $this->assertNotEquals($db1->getLastInsertId('profile_SEQ'), $db2->getLastInsertId('profile_SEQ'));
62 | $this->assertNotEquals($db2->getLastInsertId('profile_SEQ'), $db1->getLastInsertId('profile_SEQ'));
63 |
64 | $db1->close();
65 | $db2->close();
66 | }
67 |
68 | public function testGetServerInfo(): void
69 | {
70 | $db = $this->createConnection();
71 | $serverInfo = $db->getServerInfo();
72 |
73 | $this->assertInstanceOf(ServerInfo::class, $serverInfo);
74 |
75 | $dbTimezone = $serverInfo->getTimezone();
76 |
77 | $this->assertSame(6, strlen($dbTimezone));
78 |
79 | $db->createCommand("ALTER SESSION SET TIME_ZONE = '+06:15'")->execute();
80 |
81 | $this->assertSame($dbTimezone, $serverInfo->getTimezone());
82 | $this->assertNotSame($dbTimezone, $serverInfo->getTimezone(true));
83 | $this->assertSame('+06:15', $serverInfo->getTimezone());
84 |
85 | $db->close();
86 | }
87 | }
88 |
--------------------------------------------------------------------------------
/src/Builder/InBuilder.php:
--------------------------------------------------------------------------------
1 | splitCondition($expression, $params);
41 |
42 | return $splitCondition ?? parent::build($expression, $params);
43 | }
44 |
45 | /**
46 | * Oracle DBMS doesn't support more than 1000 parameters in `IN` condition.
47 | *
48 | * This method splits long `IN` condition into series of smaller ones.
49 | *
50 | * @param array $params The binding parameters.
51 | *
52 | * @throws Exception
53 | * @throws InvalidArgumentException
54 | * @throws InvalidConfigException
55 | * @throws NotSupportedException
56 | *
57 | * @return string|null `null` when split isn't required. Otherwise - built SQL condition.
58 | */
59 | protected function splitCondition(In|NotIn $condition, array &$params): ?string
60 | {
61 | $operator = match ($condition::class) {
62 | In::class => 'IN',
63 | NotIn::class => 'NOT IN',
64 | };
65 | $values = $condition->values;
66 | $column = $condition->column;
67 |
68 | if (!is_array($values)) {
69 | return null;
70 | }
71 |
72 | $maxParameters = 1000;
73 | $count = count($values);
74 |
75 | if ($count <= $maxParameters) {
76 | return null;
77 | }
78 |
79 | $slices = [];
80 |
81 | for ($i = 0; $i < $count; $i += $maxParameters) {
82 | $slices[] = $this->queryBuilder->createConditionFromArray(
83 | [$operator, $column, array_slice($values, $i, $maxParameters)],
84 | );
85 | }
86 |
87 | array_unshift($slices, ($operator === 'IN') ? 'OR' : 'AND');
88 |
89 | return $this->queryBuilder->buildCondition($slices, $params);
90 | }
91 | }
92 |
--------------------------------------------------------------------------------
/src/Column/DateTimeColumn.php:
--------------------------------------------------------------------------------
1 | [!WARNING]
20 | * > Oracle DBMS converts `TIMESTAMP WITH LOCAL TIME ZONE` column type values from database session time zone
21 | * > to the database time zone for storage, and back from the database time zone to the session time zone when retrieve
22 | * > the values.
23 | *
24 | * `TIMESTAMP WITH LOCAL TIME ZONE` database type does not store time zone offset and require to convert datetime values
25 | * to the database session time zone before insert and back to the PHP time zone after retrieve the values.
26 | * This will be done in the {@see dbTypecast()} and {@see phpTypecast()} methods and guarantees that the values
27 | * are stored in the database in the correct time zone.
28 | *
29 | * To avoid possible time zone issues with the datetime values conversion, it is recommended to set the PHP and database
30 | * time zones to UTC.
31 | */
32 | final class DateTimeColumn extends \Yiisoft\Db\Schema\Column\DateTimeColumn
33 | {
34 | public function dbTypecast(mixed $value): float|int|string|ExpressionInterface|null
35 | {
36 | $value = parent::dbTypecast($value);
37 |
38 | if (!is_string($value)) {
39 | return $value;
40 | }
41 |
42 | $value = str_replace(["'", '"', "\000", "\032"], '', $value);
43 |
44 | return match ($this->getType()) {
45 | ColumnType::TIMESTAMP, ColumnType::DATETIME, ColumnType::DATETIMETZ => new Expression("TIMESTAMP '$value'"),
46 | ColumnType::TIME, ColumnType::TIMETZ => new Expression(
47 | "INTERVAL '$value' DAY(0) TO SECOND" . (($size = $this->getSize()) !== null ? "($size)" : ''),
48 | ),
49 | ColumnType::DATE => new Expression("DATE '$value'"),
50 | default => $value,
51 | };
52 | }
53 |
54 | public function phpTypecast(mixed $value): ?DateTimeImmutable
55 | {
56 | if (is_string($value) && match ($this->getType()) {
57 | ColumnType::TIME, ColumnType::TIMETZ => true,
58 | default => false,
59 | }) {
60 | $value = explode(' ', $value, 2)[1] ?? $value;
61 | }
62 |
63 | return parent::phpTypecast($value);
64 | }
65 |
66 | protected function getFormat(): string
67 | {
68 | return $this->format ??= match ($this->getType()) {
69 | ColumnType::TIME, ColumnType::TIMETZ => '0 H:i:s' . $this->getMillisecondsFormat(),
70 | default => parent::getFormat(),
71 | };
72 | }
73 |
74 | protected function shouldConvertTimezone(): bool
75 | {
76 | return $this->shouldConvertTimezone ??= !empty($this->dbTimezone) && match ($this->getType()) {
77 | ColumnType::DATETIMETZ,
78 | ColumnType::DATE => false,
79 | default => true,
80 | };
81 | }
82 | }
83 |
--------------------------------------------------------------------------------
/src/Connection.php:
--------------------------------------------------------------------------------
1 | setSql($sql);
36 | }
37 |
38 | if ($this->logger !== null) {
39 | $command->setLogger($this->logger);
40 | }
41 |
42 | if ($this->profiler !== null) {
43 | $command->setProfiler($this->profiler);
44 | }
45 |
46 | return $command->bindValues($params);
47 | }
48 |
49 | public function createTransaction(): TransactionInterface
50 | {
51 | return new Transaction($this);
52 | }
53 |
54 | public function getColumnBuilderClass(): string
55 | {
56 | return ColumnBuilder::class;
57 | }
58 |
59 | public function getColumnFactory(): ColumnFactoryInterface
60 | {
61 | return $this->columnFactory ??= new ColumnFactory();
62 | }
63 |
64 | /**
65 | * Override base behaviour to support Oracle sequences.
66 | *
67 | * @throws Exception
68 | * @throws InvalidConfigException
69 | * @throws InvalidCallException
70 | * @throws Throwable
71 | */
72 | public function getLastInsertId(?string $sequenceName = null): string
73 | {
74 | if ($sequenceName === null) {
75 | throw new InvalidArgumentException('Oracle not support lastInsertId without sequence name.');
76 | }
77 |
78 | if ($this->isActive()) {
79 | // get the last insert id from connection
80 | $sequenceName = $this->getQuoter()->quoteSimpleTableName($sequenceName);
81 |
82 | return (string) $this->createCommand("SELECT $sequenceName.CURRVAL FROM DUAL")->queryScalar();
83 | }
84 |
85 | throw new InvalidCallException('DB Connection is not active.');
86 | }
87 |
88 | public function getQueryBuilder(): QueryBuilderInterface
89 | {
90 | return $this->queryBuilder ??= new QueryBuilder($this);
91 | }
92 |
93 | public function getQuoter(): QuoterInterface
94 | {
95 | return $this->quoter ??= new Quoter('"', '"', $this->getTablePrefix());
96 | }
97 |
98 | public function getSchema(): SchemaInterface
99 | {
100 | return $this->schema ??= new Schema($this, $this->schemaCache, strtoupper($this->driver->getUsername()));
101 | }
102 |
103 | public function getServerInfo(): ServerInfoInterface
104 | {
105 | return $this->serverInfo ??= new ServerInfo($this);
106 | }
107 | }
108 |
--------------------------------------------------------------------------------
/src/DQLQueryBuilder.php:
--------------------------------------------------------------------------------
1 | buildOrderBy($orderBy, $params);
39 |
40 | if ($orderByString !== '') {
41 | $sql .= $this->separator . $orderByString;
42 | }
43 |
44 | $filters = [];
45 |
46 | if (!empty($offset)) {
47 | $filters[] = 'rowNumId > '
48 | . ($offset instanceof ExpressionInterface ? $this->buildExpression($offset) : (string) $offset);
49 | }
50 |
51 | if ($limit !== null) {
52 | $filters[] = 'rownum <= '
53 | . ($limit instanceof ExpressionInterface ? $this->buildExpression($limit) : (string) $limit);
54 | }
55 |
56 | if (empty($filters)) {
57 | return $sql;
58 | }
59 |
60 | $filter = implode(' AND ', $filters);
61 | return << new WithQuery(
85 | $withQuery->query,
86 | $withQuery->alias,
87 | false,
88 | ),
89 | $withQueries,
90 | );
91 |
92 | return parent::buildWithQueries($withQueries, $params);
93 | }
94 |
95 | protected function defaultExpressionBuilders(): array
96 | {
97 | return [
98 | ...parent::defaultExpressionBuilders(),
99 | In::class => InBuilder::class,
100 | NotIn::class => InBuilder::class,
101 | Like::class => LikeBuilder::class,
102 | NotLike::class => LikeBuilder::class,
103 | ArrayMerge::class => ArrayMergeBuilder::class,
104 | Longest::class => LongestBuilder::class,
105 | Shortest::class => ShortestBuilder::class,
106 | ];
107 | }
108 | }
109 |
--------------------------------------------------------------------------------
/src/DDLQueryBuilder.php:
--------------------------------------------------------------------------------
1 | quoter->quoteTableName($table)
32 | . ' ADD CONSTRAINT ' . $this->quoter->quoteColumnName($name)
33 | . ' FOREIGN KEY (' . $this->queryBuilder->buildColumns($columns) . ')'
34 | . ' REFERENCES ' . $this->quoter->quoteTableName($referenceTable)
35 | . ' (' . $this->queryBuilder->buildColumns($referenceColumns) . ')';
36 |
37 | if ($delete !== null) {
38 | $sql .= ' ON DELETE ' . $delete;
39 | }
40 |
41 | if ($update !== null) {
42 | throw new Exception('Oracle does not support ON UPDATE clause.');
43 | }
44 |
45 | return $sql;
46 | }
47 |
48 | public function alterColumn(string $table, string $column, ColumnInterface|string $type): string
49 | {
50 | return 'ALTER TABLE '
51 | . $this->quoter->quoteTableName($table)
52 | . ' MODIFY '
53 | . $this->quoter->quoteColumnName($column)
54 | . ' ' . $this->queryBuilder->buildColumnDefinition($type);
55 | }
56 |
57 | public function checkIntegrity(string $schema = '', string $table = '', bool $check = true): string
58 | {
59 | throw new NotSupportedException(__METHOD__ . ' is not supported by Oracle.');
60 | }
61 |
62 | public function dropCommentFromColumn(string $table, string $column): string
63 | {
64 | return 'COMMENT ON COLUMN '
65 | . $this->quoter->quoteTableName($table)
66 | . '.'
67 | . $this->quoter->quoteColumnName($column)
68 | . " IS ''";
69 | }
70 |
71 | public function dropCommentFromTable(string $table): string
72 | {
73 | return 'COMMENT ON TABLE ' . $this->quoter->quoteTableName($table) . " IS ''";
74 | }
75 |
76 | public function dropDefaultValue(string $table, string $name): string
77 | {
78 | throw new NotSupportedException(__METHOD__ . ' is not supported by Oracle.');
79 | }
80 |
81 | public function dropIndex(string $table, string $name): string
82 | {
83 | return 'DROP INDEX ' . $this->quoter->quoteTableName($name);
84 | }
85 |
86 | /**
87 | * @throws NotSupportedException Oracle doesn't support "IF EXISTS" option on drop table.
88 | */
89 | public function dropTable(string $table, bool $ifExists = false, bool $cascade = false): string
90 | {
91 | if ($ifExists) {
92 | throw new NotSupportedException('Oracle doesn\'t support "IF EXISTS" option on drop table.');
93 | }
94 | return 'DROP TABLE '
95 | . $this->quoter->quoteTableName($table)
96 | . ($cascade ? ' CASCADE CONSTRAINTS' : '');
97 | }
98 |
99 | public function renameTable(string $oldName, string $newName): string
100 | {
101 | return 'ALTER TABLE ' . $this->quoter->quoteTableName($oldName) . ' RENAME TO '
102 | . $this->quoter->quoteTableName($newName);
103 | }
104 | }
105 |
--------------------------------------------------------------------------------
/README.md:
--------------------------------------------------------------------------------
1 |
2 |
3 |
4 |
5 |
6 |
7 |
8 |
Yii Database Oracle Driver
9 |
10 |
11 |
12 | [](https://packagist.org/packages/yiisoft/db-oracle)
13 | [](https://packagist.org/packages/yiisoft/db-oracle)
14 | [](https://github.com/yiisoft/db-oracle/actions/workflows/build.yml)
15 | [](https://codecov.io/gh/yiisoft/db-oracle)
16 | [](https://dashboard.stryker-mutator.io/reports/github.com/yiisoft/db-oracle/master)
17 | [](https://github.com/yiisoft/db-oracle/actions?query=workflow%3A%22static+analysis%22)
18 | [](https://shepherd.dev/github/yiisoft/db-oracle)
19 | [](https://shepherd.dev/github/yiisoft/db-oracle)
20 |
21 | Oracle driver for [Yii Database](https://github.com/yiisoft/db) is a package for working with
22 | [Oracle](https://www.oracle.com/database/technologies/) databases in PHP. It includes a database connection class,
23 | a command builder class, and a set of classes for representing database tables and rows as PHP objects.
24 |
25 | Driver supports Oracle 12c - 21c.
26 |
27 | ## Requirements
28 |
29 | - PHP 8.1 - 8.5.
30 | - `pdo` PHP extension.
31 |
32 | ## Installation
33 |
34 | The package could be installed with [Composer](https://getcomposer.org):
35 |
36 | ```shell
37 | composer require yiisoft/db-oracle
38 | ```
39 |
40 | > [!IMPORTANT]
41 | > See also [installation notes](https://github.com/yiisoft/db/?tab=readme-ov-file#installation) for `yiisoft/db`
42 | > package.
43 |
44 | ## Documentation
45 |
46 | For config connection to Oracle database check
47 | [Connecting Oracle](https://github.com/yiisoft/db/blob/master/docs/guide/en/connection/oracle.md).
48 |
49 | Check the `yiisoft/db` [docs](https://github.com/yiisoft/db/blob/master/docs/guide/en/README.md) to learn about usage.
50 |
51 | - [Internals](docs/internals.md)
52 |
53 | If you need help or have a question, the [Yii Forum](https://forum.yiiframework.com/c/yii-3-0/63) is a good place for that.
54 | You may also check out other [Yii Community Resources](https://www.yiiframework.com/community).
55 |
56 | ## License
57 |
58 | The Yii Database Oracle Driver is free software. It is released under the terms of the BSD License.
59 | Please see [`LICENSE`](./LICENSE.md) for more information.
60 |
61 | Maintained by [Yii Software](https://www.yiiframework.com/).
62 |
63 | ## Support the project
64 |
65 | [](https://opencollective.com/yiisoft)
66 |
67 | ## Follow updates
68 |
69 | [](https://www.yiiframework.com/)
70 | [](https://twitter.com/yiiframework)
71 | [](https://t.me/yii3en)
72 | [](https://www.facebook.com/groups/yiitalk)
73 | [](https://yiiframework.com/go/slack)
74 |
--------------------------------------------------------------------------------
/src/Command.php:
--------------------------------------------------------------------------------
1 | db->getSchema()->getTableSchema($table);
39 | $returnColumns = $tableSchema?->getPrimaryKey() ?? [];
40 |
41 | if ($returnColumns === []) {
42 | $this->insert($table, $columns)->execute();
43 | return [];
44 | }
45 | /** @var TableSchema $tableSchema */
46 |
47 | if ($columns instanceof QueryInterface) {
48 | throw new NotSupportedException(
49 | __METHOD__ . '() is not supported by Oracle when inserting sub-query.',
50 | );
51 | }
52 |
53 | $params = [];
54 | $sql = $this->getQueryBuilder()->insert($table, $columns, $params);
55 | $tableColumns = $tableSchema->getColumns();
56 |
57 | /**
58 | * @psalm-var array $returnParams
64 | */
65 | $returnParams = [];
66 |
67 | foreach ($returnColumns as $name) {
68 | $phName = AbstractQueryBuilder::PARAM_PREFIX . (count($params) + count($returnParams));
69 |
70 | $returnParams[$phName] = [
71 | 'column' => $name,
72 | 'value' => '',
73 | ];
74 |
75 | $column = $tableColumns[$name];
76 |
77 | $returnParams[$phName]['dataType'] = in_array($column->getType(), self::INTEGER_COLUMN_TYPES, true)
78 | ? PDO::PARAM_INT
79 | : PDO::PARAM_STR;
80 |
81 | $returnParams[$phName]['size'] = ($column->getSize() ?? 3998) + 2;
82 | }
83 |
84 | $quotedReturnColumns = array_map($this->db->getQuoter()->quoteColumnName(...), $returnColumns);
85 |
86 | $sql .= ' RETURNING ' . implode(', ', $quotedReturnColumns) . ' INTO ' . implode(', ', array_keys($returnParams));
87 |
88 | $this->setSql($sql)->bindValues($params);
89 | $this->prepare(false);
90 |
91 | foreach ($returnParams as $name => &$value) {
92 | $this->bindParam($name, $value['value'], $value['dataType'], $value['size']);
93 | }
94 |
95 | unset($value);
96 |
97 | $this->execute();
98 |
99 | $result = [];
100 |
101 | foreach ($returnParams as $value) {
102 | $result[$value['column']] = $value['value'];
103 | }
104 |
105 | if ($this->phpTypecasting) {
106 | foreach ($result as $column => &$value) {
107 | $value = $tableColumns[$column]->phpTypecast($value);
108 | }
109 | }
110 |
111 | return $result;
112 | }
113 |
114 | public function showDatabases(): array
115 | {
116 | $sql = <<setSql($sql)->queryColumn();
121 | }
122 |
123 | protected function bindPendingParams(): void
124 | {
125 | $paramsPassedByReference = [];
126 | foreach ($this->params as $name => $param) {
127 | if (PDO::PARAM_STR === $param->type) {
128 | $paramsPassedByReference[$name] = $param->value;
129 | $this->pdoStatement?->bindParam(
130 | $name,
131 | $paramsPassedByReference[$name],
132 | $param->type,
133 | strlen((string) $param->value),
134 | );
135 | } else {
136 | $this->pdoStatement?->bindValue($name, $param->value, $param->type);
137 | }
138 | }
139 | }
140 | }
141 |
--------------------------------------------------------------------------------
/tests/ConnectionTest.php:
--------------------------------------------------------------------------------
1 | getSharedConnection();
29 |
30 | $db->open();
31 | $serialized = serialize($db);
32 | $unserialized = unserialize($serialized);
33 |
34 | $this->assertInstanceOf(ConnectionInterface::class, $unserialized);
35 | $this->assertSame('123', $unserialized->createCommand('SELECT 123 FROM DUAL')->queryScalar());
36 |
37 | $db->close();
38 | }
39 |
40 | public function testSettingDefaultAttributes(): void
41 | {
42 | $db = $this->getSharedConnection();
43 |
44 | $this->assertSame(PDO::ERRMODE_EXCEPTION, $db->getActivePDO()?->getAttribute(PDO::ATTR_ERRMODE));
45 |
46 | $db->close();
47 | }
48 |
49 | public function testTransactionIsolation(): void
50 | {
51 | $db = $this->getSharedConnection();
52 |
53 | $transaction = $db->beginTransaction(TransactionInterface::READ_COMMITTED);
54 | $transaction->commit();
55 |
56 | /* should not be any exception so far */
57 | $this->assertTrue(true);
58 |
59 | $transaction = $db->beginTransaction(TransactionInterface::SERIALIZABLE);
60 | $transaction->commit();
61 |
62 | /* should not be any exception so far */
63 | $this->assertTrue(true);
64 |
65 | $db->close();
66 | }
67 |
68 | public function testTransactionShortcutCustom(): void
69 | {
70 | $db = $this->getSharedConnection();
71 | $this->loadFixture();
72 |
73 | $command = $db->createCommand();
74 |
75 | $this->assertTrue(
76 | $db->transaction(
77 | static function (ConnectionInterface $db) {
78 | $db->createCommand()->insert('profile', ['description' => 'test transaction shortcut'])->execute();
79 |
80 | return true;
81 | },
82 | TransactionInterface::READ_COMMITTED,
83 | ),
84 | 'transaction shortcut valid value should be returned from callback',
85 | );
86 |
87 | $this->assertSame(
88 | '1',
89 | $command->setSql(
90 | <<queryScalar(),
94 | 'profile should be inserted in transaction shortcut',
95 | );
96 |
97 | $db->close();
98 | }
99 |
100 | public function testSerialized(): void
101 | {
102 | $connection = $this->createConnection();
103 | $connection->open();
104 | $serialized = serialize($connection);
105 | $this->assertNotNull($connection->getPdo());
106 |
107 | $unserialized = unserialize($serialized);
108 | $this->assertInstanceOf(PdoConnectionInterface::class, $unserialized);
109 | $this->assertNull($unserialized->getPdo());
110 | $this->assertEquals(123, $unserialized->createCommand('SELECT 123 FROM DUAL')->queryScalar());
111 | $this->assertNotNull($connection->getPdo());
112 |
113 | $connection->close();
114 | }
115 |
116 | public function getColumnBuilderClass(): void
117 | {
118 | $db = $this->getSharedConnection();
119 |
120 | $this->assertSame(ColumnBuilder::class, $db->getColumnBuilderClass());
121 |
122 | $db->close();
123 | }
124 |
125 | public function testGetColumnFactory(): void
126 | {
127 | $db = $this->getSharedConnection();
128 |
129 | $this->assertInstanceOf(ColumnFactory::class, $db->getColumnFactory());
130 |
131 | $db->close();
132 | }
133 |
134 | public function testUserDefinedColumnFactory(): void
135 | {
136 | $columnFactory = new ColumnFactory();
137 |
138 | $db = new Connection(
139 | TestConnection::createDriver(),
140 | TestHelper::createMemorySchemaCache(),
141 | $columnFactory,
142 | );
143 |
144 | $this->assertSame($columnFactory, $db->getColumnFactory());
145 |
146 | $db->close();
147 | }
148 | }
149 |
--------------------------------------------------------------------------------
/src/Column/ColumnFactory.php:
--------------------------------------------------------------------------------
1 |
26 | */
27 | protected const TYPE_MAP = [
28 | 'char' => ColumnType::CHAR,
29 | 'nchar' => ColumnType::CHAR,
30 | 'character' => ColumnType::CHAR,
31 | 'varchar' => ColumnType::STRING,
32 | 'varchar2' => ColumnType::STRING,
33 | 'nvarchar2' => ColumnType::STRING,
34 | 'clob' => ColumnType::TEXT,
35 | 'nclob' => ColumnType::TEXT,
36 | 'blob' => ColumnType::BINARY,
37 | 'bfile' => ColumnType::BINARY,
38 | 'long raw' => ColumnType::BINARY,
39 | 'raw' => ColumnType::BINARY,
40 | 'number' => ColumnType::DECIMAL,
41 | 'binary_float' => ColumnType::FLOAT, // 32 bit
42 | 'binary_double' => ColumnType::DOUBLE, // 64 bit
43 | 'float' => ColumnType::DOUBLE, // 126 bit
44 | 'date' => ColumnType::DATE,
45 | 'timestamp' => ColumnType::DATETIME,
46 | 'timestamp with time zone' => ColumnType::DATETIMETZ,
47 | 'timestamp with local time zone' => ColumnType::DATETIME,
48 | 'interval day to second' => ColumnType::STRING,
49 | 'interval year to month' => ColumnType::STRING,
50 | 'json' => ColumnType::JSON,
51 |
52 | /** Deprecated */
53 | 'long' => ColumnType::TEXT,
54 | ];
55 | private const DATETIME_REGEX = "/^(?:TIMESTAMP|DATE|INTERVAL|to_timestamp(?:_tz)?\(|to_date\(|to_dsinterval\()\s*'(?:\d )?([^']+)/";
56 |
57 | public function fromPseudoType(string $pseudoType, array $info = []): ColumnInterface
58 | {
59 | return parent::fromPseudoType($pseudoType, $info)->unsigned(false);
60 | }
61 |
62 | protected function columnDefinitionParser(): ColumnDefinitionParser
63 | {
64 | return new ColumnDefinitionParser();
65 | }
66 |
67 | protected function getType(string $dbType, array $info = []): string
68 | {
69 | if ($dbType === 'number') {
70 | return match ($info['scale'] ?? null) {
71 | null => ColumnType::DOUBLE,
72 | 0 => ColumnType::INTEGER,
73 | default => ColumnType::DECIMAL,
74 | };
75 | }
76 |
77 | if (isset($info['check'], $info['name'])) {
78 | if (strcasecmp($info['check'], '"' . $info['name'] . '" is json') === 0) {
79 | return ColumnType::JSON;
80 | }
81 |
82 | if (isset($info['size'])
83 | && $dbType === 'char'
84 | && $info['size'] === 1
85 | && strcasecmp($info['check'], '"' . $info['name'] . '" in (0,1)') === 0
86 | ) {
87 | return ColumnType::BOOLEAN;
88 | }
89 | }
90 |
91 | if ($dbType === 'interval day to second' && isset($info['scale']) && $info['scale'] === 0) {
92 | return ColumnType::TIME;
93 | }
94 |
95 | return parent::getType($dbType, $info);
96 | }
97 |
98 | protected function getColumnClass(string $type, array $info = []): string
99 | {
100 | return match ($type) {
101 | ColumnType::BINARY => BinaryColumn::class,
102 | ColumnType::BOOLEAN => BooleanColumn::class,
103 | ColumnType::DATETIME => DateTimeColumn::class,
104 | ColumnType::DATETIMETZ => DateTimeColumn::class,
105 | ColumnType::TIME => DateTimeColumn::class,
106 | ColumnType::TIMETZ => DateTimeColumn::class,
107 | ColumnType::DATE => DateTimeColumn::class,
108 | ColumnType::JSON => JsonColumn::class,
109 | default => parent::getColumnClass($type, $info),
110 | };
111 | }
112 |
113 | protected function normalizeNotNullDefaultValue(string $defaultValue, ColumnInterface $column): mixed
114 | {
115 | $value = parent::normalizeNotNullDefaultValue(rtrim($defaultValue), $column);
116 |
117 | if ($column instanceof DateTimeColumn
118 | && $value instanceof Expression
119 | && preg_match(self::DATETIME_REGEX, (string) $value, $matches) === 1
120 | ) {
121 | return date_create_immutable($matches[1]) !== false
122 | ? $column->phpTypecast($matches[1])
123 | : new Expression($matches[1]);
124 | }
125 |
126 | return $value;
127 | }
128 | }
129 |
--------------------------------------------------------------------------------
/tests/Provider/ColumnFactoryProvider.php:
--------------------------------------------------------------------------------
1 | dbType('clob');
66 | $definitions['text NOT NULL'][0] = 'clob NOT NULL';
67 | $definitions['text NOT NULL'][1]->dbType('clob');
68 | $definitions['decimal(10,2)'][0] = 'number(10,2)';
69 | $definitions['decimal(10,2)'][1]->dbType('number');
70 | $definitions['bigint UNSIGNED'][1] = new BigIntColumn(unsigned: true);
71 | $definitions['integer[]'] = ['number(10,0)[]', new ArrayColumn(dbType: 'number', size: 10, column: new IntegerColumn(dbType: 'number', size: 10))];
72 |
73 | return [
74 | ...$definitions,
75 | ['interval day to second', new StringColumn(dbType: 'interval day to second')],
76 | ['interval day(0) to second', new DateTimeColumn(ColumnType::TIME, dbType: 'interval day to second', scale: 0)],
77 | ['interval day (0) to second(6)', new DateTimeColumn(ColumnType::TIME, dbType: 'interval day to second', scale: 0, size: 6)],
78 | ['interval day to second (0)', new StringColumn(dbType: 'interval day to second', size: 0)],
79 | ['interval year to month', new StringColumn(dbType: 'interval year to month')],
80 | ['interval year (2) to month', new StringColumn(dbType: 'interval year to month', scale: 2)],
81 | ];
82 | }
83 |
84 | public static function defaultValueRaw(): array
85 | {
86 | $defaultValueRaw = parent::defaultValueRaw();
87 |
88 | $defaultValueRaw[] = [ColumnType::STRING, 'NULL ', null];
89 | $defaultValueRaw[] = [ColumnType::STRING, "'str''ing' ", "str'ing"];
90 | $defaultValueRaw[] = [ColumnType::INTEGER, '-1 ', -1];
91 | $defaultValueRaw[] = [ColumnType::DATETIME, 'now() ', new Expression('now()')];
92 |
93 | return $defaultValueRaw;
94 | }
95 |
96 | public static function types(): array
97 | {
98 | $types = parent::types();
99 |
100 | $types['binary'][2] = BinaryColumn::class;
101 | $types['boolean'][2] = BooleanColumn::class;
102 | $types['json'][2] = JsonColumn::class;
103 |
104 | return $types;
105 | }
106 | }
107 |
--------------------------------------------------------------------------------
/tests/Provider/CommandProvider.php:
--------------------------------------------------------------------------------
1 | [
25 | ':qp1' => '1',
26 | ':qp2' => 'test string2',
27 | ':qp3' => '0',
28 | ],
29 | 'issue11242' => [
30 | ':qp1' => '1',
31 | ],
32 | 'table name with column name with brackets' => [
33 | ':qp1' => '0',
34 | ],
35 | 'binds params from expression' => [
36 | ':qp2' => '0',
37 | ],
38 | 'with associative values with different keys' => [
39 | ':qp1' => '1',
40 | ],
41 | 'with associative values with different keys and columns with keys' => [
42 | ':qp1' => '1',
43 | ],
44 | 'with associative values with keys of column names' => [
45 | ':qp0' => '1',
46 | ':qp1' => '10',
47 | ],
48 | 'with associative values with keys of column keys' => [
49 | ':qp0' => '1',
50 | ':qp1' => '10',
51 | ],
52 | 'with shuffled indexes of values' => [
53 | ':qp0' => '1',
54 | ':qp1' => '10',
55 | ],
56 | 'empty columns and associative values' => [
57 | ':qp1' => '1',
58 | ],
59 | 'empty columns and objects' => [
60 | ':qp1' => '1',
61 | ],
62 | 'empty columns and a Traversable value' => [
63 | ':qp1' => '1',
64 | ],
65 | 'empty columns and Traversable values' => [
66 | ':qp1' => '1',
67 | ],
68 | 'binds json params' => [
69 | ':qp1' => '1',
70 | ':qp2' => '{"a":1,"b":true,"c":[1,2,3]}',
71 | ':qp3' => 'b',
72 | ':qp4' => '0',
73 | ':qp5' => '{"d":"e","f":false,"g":[4,5,null]}',
74 | ],
75 | ];
76 |
77 | foreach ($replaceParams as $key => $expectedParams) {
78 | OracleTestHelper::changeSqlForBatchInsert($batchInsert[$key]['expected'], $expectedParams);
79 | $batchInsert[$key]['expectedParams'] = array_merge($batchInsert[$key]['expectedParams'], $expectedParams);
80 | }
81 |
82 | $batchInsert['multirow']['expected'] = << 'string', 'integer' => 1234], JSON_THROW_ON_ERROR),
117 | json_encode(['string' => 'string', 'integer' => 1234], JSON_THROW_ON_ERROR),
118 | ],
119 | [
120 | serialize(['string' => 'string', 'integer' => 1234]),
121 | new Param(serialize(['string' => 'string', 'integer' => 1234]), PDO::PARAM_LOB),
122 | ],
123 | ['simple string', 'simple string'],
124 | ];
125 | }
126 |
127 | public static function rawSql(): array
128 | {
129 | $rawSql = parent::rawSql();
130 |
131 | foreach ($rawSql as &$values) {
132 | $values[2] = strtr($values[2], [
133 | 'FALSE' => "'0'",
134 | 'TRUE' => "'1'",
135 | ]);
136 | }
137 |
138 | return $rawSql;
139 | }
140 |
141 | public static function createIndex(): array
142 | {
143 | return [
144 | ...parent::createIndex(),
145 | [['col1' => ColumnBuilder::integer()], ['col1'], IndexType::UNIQUE, null],
146 | [['col1' => ColumnBuilder::integer()], ['col1'], IndexType::BITMAP, null],
147 | ];
148 | }
149 |
150 | public static function upsertReturning(): array
151 | {
152 | return [['table', [], true, ['col1'], [], []]];
153 | }
154 | }
155 |
--------------------------------------------------------------------------------
/CHANGELOG.md:
--------------------------------------------------------------------------------
1 | # Oracle driver for Yii Database Change Log
2 |
3 | ## 2.0.1 under development
4 |
5 | - no changes in this release.
6 |
7 | ## 2.0.0 December 05, 2025
8 |
9 | - New #236, #349: Implement `ColumnInterface` classes according to the data type of database table columns
10 | for type casting performance. Related with yiisoft/db#752 (@Tigrov)
11 | - New #276, #288: Implement `ColumnFactory` class (@Tigrov)
12 | - New #280, #291: Realize `ColumnBuilder` class (@Tigrov)
13 | - New #282, #291, #299, #302: Add `ColumnDefinitionBuilder` class (@Tigrov)
14 | - New #292: Override `QueryBuilder::prepareBinary()` method (@Tigrov)
15 | - New #301: Add `IndexType` class (@Tigrov)
16 | - New #303: Support JSON type (@Tigrov)
17 | - New #307: Add parameters `$ifExists` and `$cascade` to `CommandInterface::dropTable()` and
18 | `DDLQueryBuilderInterface::dropTable()` methods (@vjik)
19 | - New #311: Add `caseSensitive` option to like condition (@vjik)
20 | - New #316: Realize `Schema::loadResultColumn()` method (@Tigrov)
21 | - New #323: Use `DateTimeColumn` class for datetime column types (@Tigrov)
22 | - New #357, #363: Implement `ArrayMergeBuilder`, `LongestBuilder` and `ShortestBuilder` classes (@Tigrov)
23 | - New #358: Add `Connection::getColumnBuilderClass()` method (@Tigrov)
24 | - New #382: Add enumeration column type support (@vjik)
25 | - New #387: Add source of column information (@Tigrov)
26 | - Chg #272: Replace call of `SchemaInterface::getRawTableName()` to `QuoterInterface::getRawTableName()` (@Tigrov)
27 | - Chg #294: Update `QueryBuilder` constructor (@Tigrov)
28 | - Chg #306, #385: Change supported PHP versions to `8.1 - 8.5` (@Tigrov, @vjik)
29 | - Chg #310: Remove usage of `hasLimit()` and `hasOffset()` methods of `DQLQueryBuilder` class (@Tigrov)
30 | - Chg #326: Add alias in `DQLQueryBuilder::selectExists()` method for consistency with other DBMS (@Tigrov)
31 | - Chg #330: Rename `insertWithReturningPks()` to `insertReturningPks()` in `Command` and `DMLQueryBuilder` classes (@Tigrov)
32 | - Chg #332: Use `\InvalidArgumentException` instead of `Yiisoft\Db\Exception\InvalidArgumentException` (@DikoIbragimov)
33 | - Chg #365: Update expression namespaces according to changes in `yiisoft/db` package (@Tigrov)
34 | - Chg #378: Throw exception on "unsigned" column usage (@vjik)
35 | - Enh #255, #321: Implement and use `SqlParser` class (@Tigrov)
36 | - Enh #260: Support `Traversable` values for `DMLQueryBuilder::batchInsert()` method with empty columns (@Tigrov)
37 | - Enh #268: Rename `batchInsert()` to `insertBatch()` in `DMLQueryBuilder` and change parameters
38 | from `$table, $columns, $rows` to `$table, $rows, $columns = []` (@Tigrov)
39 | - Enh #275: Refactor PHP type of `ColumnSchemaInterface` instances (@Tigrov)
40 | - Enh #277: Raise minimum PHP version to `^8.1` with minor refactoring (@Tigrov)
41 | - Enh #279: Separate column type constants (@Tigrov)
42 | - Enh #281: Update according changes in `ColumnSchemaInterface` (@Tigrov)
43 | - Enh #283, #344: Refactor `Dsn` class (@Tigrov)
44 | - Enh #286: Use constructor to create columns and initialize properties (@Tigrov)
45 | - Enh #288, #317: Refactor `Schema::findColumns()` method (@Tigrov)
46 | - Enh #289: Refactor `Schema::normalizeDefaultValue()` method and move it to `ColumnFactory` class (@Tigrov)
47 | - Enh #293: Use `ColumnDefinitionBuilder` to generate table column SQL representation (@Tigrov)
48 | - Enh #296: Remove `ColumnInterface` (@Tigrov)
49 | - Enh #298: Rename `ColumnSchemaInterface` to `ColumnInterface` (@Tigrov)
50 | - Enh #298: Refactor `DMLQueryBuilder::prepareInsertValues()` method (@Tigrov)
51 | - Enh #299: Add `ColumnDefinitionParser` class (@Tigrov)
52 | - Enh #299: Convert database types to lower case (@Tigrov)
53 | - Enh #300: Replace `DbArrayHelper::getColumn()` with `array_column()` (@Tigrov)
54 | - Enh #306: Minor refactoring (@Tigrov)
55 | - Enh #313, #347: Refactor according changes in `db` package (@Tigrov)
56 | - Enh #315: Remove `getCacheKey()` and `getCacheTag()` methods from `Schema` class (@Tigrov)
57 | - Enh #318, #320: Use `DbArrayHelper::arrange()` instead of `DbArrayHelper::index()` method (@Tigrov)
58 | - Enh #319: Support `boolean` type (@Tigrov)
59 | - Enh #324: Refactor `Command::insertWithReturningPks()` method (@Tigrov)
60 | - Enh #325: Refactor `DMLQueryBuilder::upsert()` method (@Tigrov)
61 | - Enh #327, #343: Refactor constraints (@Tigrov)
62 | - Enh #336: Provide `yiisoft/db-implementation` virtual package (@vjik)
63 | - Enh #340: Adapt to `Param` refactoring in `yiisoft/db` package (@vjik)
64 | - Enh #341, #342, #345: Adapt to conditions refactoring in `yiisoft/db` package (@vjik)
65 | - Enh #348: Remove `TableSchema` class and refactor `Schema` class (@Tigrov)
66 | - Enh #350: Adapt to `Like` changes in `yiisoft/db` package (@vjik)
67 | - Enh #352: Support column's collation (@Tigrov)
68 | - Enh #359: Update `DMLQueryBuilder::update()` method to adapt changes in `yiisoft/db` (@rustamwin)
69 | - Enh #360: Refactor `DMLQueryBuilder::upsert()` method (@Tigrov)
70 | - Enh #373: Adapt to `DQLQueryBuilderInterface::buildWithQueries()` signature changes in `yiisoft/db` package (@vjik)
71 | - Bug #285: Fix `DMLQueryBuilder::insertBatch()` method (@Tigrov)
72 | - Bug #305: Explicitly mark nullable parameters (@vjik)
73 | - Bug #383: Fix column definition parsing in cases with parentheses (@vjik)
74 |
75 | ## 1.3.0 March 21, 2024
76 |
77 | - Enh #248: Change property `Schema::$typeMap` to constant `Schema::TYPE_MAP` (@Tigrov)
78 | - Enh #251: Allow to use `DMLQueryBuilderInterface::batchInsert()` method with empty columns (@Tigrov)
79 | - Enh #253: Resolve deprecated methods (@Tigrov)
80 | - Bug #238: Fix execution `Query` without table(s) to select from (@Tigrov)
81 | - Bug #250: Fix `Command::insertWithReturningPks()` method for table without primary keys (@Tigrov)
82 | - Bug #254: Fix, table sequence name should be null if sequence name not found (@Tigrov)
83 |
84 | ## 1.2.0 November 12, 2023
85 |
86 | - Enh #230: Improve column type #230 (@Tigrov)
87 | - Enh #243: Move methods from `Command` to `AbstractPdoCommand` class (@Tigrov)
88 | - Bug #233: Refactor `DMLQueryBuilder`, related with yiisoft/db#746 (@Tigrov)
89 | - Bug #240: Remove `RECURSIVE` expression from CTE queries (@Tigrov)
90 | - Bug #242: Fix `AbstractDMLQueryBuilder::batchInsert()` for values as associative arrays,
91 | related with yiisoft/db#769 (@Tigrov)
92 |
93 | ## 1.1.0 July 24, 2023
94 |
95 | - Enh #225: Typecast refactoring (@Tigrov)
96 | - Enh #226: Add support for auto increment in primary key column. (@terabytesoftw)
97 | - Bug #229: Fix bugs related with default value (@Tigrov)
98 |
99 | ## 1.0.0 April 12, 2023
100 |
101 | - Initial release.
102 |
--------------------------------------------------------------------------------
/src/Column/ColumnDefinitionBuilder.php:
--------------------------------------------------------------------------------
1 | isUnsigned()) {
46 | throw new NotSupportedException('The "unsigned" attribute is not supported by Oracle.');
47 | }
48 |
49 | return $this->buildType($column)
50 | . $this->buildAutoIncrement($column)
51 | . $this->buildDefault($column)
52 | . $this->buildPrimaryKey($column)
53 | . $this->buildUnique($column)
54 | . $this->buildNotNull($column)
55 | . $this->buildCheck($column)
56 | . $this->buildCollate($column)
57 | . $this->buildReferences($column)
58 | . $this->buildExtra($column);
59 | }
60 |
61 | protected function buildCheck(ColumnInterface $column): string
62 | {
63 | $check = $column->getCheck();
64 |
65 | if (empty($check)) {
66 | $name = $column->getName();
67 | if (!empty($name)) {
68 | $type = $column->getType();
69 | if (in_array($type, [ColumnType::ARRAY, ColumnType::STRUCTURED, ColumnType::JSON], true)) {
70 | return version_compare($this->queryBuilder->getServerInfo()->getVersion(), '21', '<')
71 | ? ' CHECK (' . $this->queryBuilder->getQuoter()->quoteSimpleColumnName($name) . ' IS JSON)'
72 | : '';
73 | }
74 | if ($type === ColumnType::BOOLEAN) {
75 | return ' CHECK (' . $this->queryBuilder->getQuoter()->quoteSimpleColumnName($name) . ' IN (0,1))';
76 | }
77 | }
78 | }
79 |
80 | return parent::buildCheck($column);
81 | }
82 |
83 | protected function buildOnDelete(string $onDelete): string
84 | {
85 | return match ($onDelete = strtoupper($onDelete)) {
86 | ReferentialAction::CASCADE,
87 | ReferentialAction::SET_NULL => " ON DELETE $onDelete",
88 | default => '',
89 | };
90 | }
91 |
92 | protected function buildOnUpdate(string $onUpdate): string
93 | {
94 | return '';
95 | }
96 |
97 | protected function getDbType(ColumnInterface $column): string
98 | {
99 | $dbType = $column->getDbType();
100 | $size = $column->getSize();
101 | $scale = $column->getScale();
102 |
103 | /** @psalm-suppress DocblockTypeContradiction */
104 | return match ($dbType) {
105 | default => $dbType,
106 | null => match ($column->getType()) {
107 | ColumnType::BOOLEAN => 'char(1)',
108 | ColumnType::BIT => match (true) {
109 | $size === null => 'number(38)',
110 | $size <= 126 => 'number(' . ceil(log10(2 ** $size)) . ')',
111 | default => 'raw(' . ceil($size / 8) . ')',
112 | },
113 | ColumnType::TINYINT => 'number(' . ($size ?? 3) . ')',
114 | ColumnType::SMALLINT => 'number(' . ($size ?? 5) . ')',
115 | ColumnType::INTEGER => 'number(' . ($size ?? 10) . ')',
116 | ColumnType::BIGINT => 'number(' . ($size ?? 20) . ')',
117 | ColumnType::FLOAT => 'binary_float',
118 | ColumnType::DOUBLE => 'binary_double',
119 | ColumnType::DECIMAL => 'number(' . ($size ?? 10) . ',' . ($scale ?? 0) . ')',
120 | ColumnType::MONEY => 'number(' . ($size ?? 19) . ',' . ($scale ?? 4) . ')',
121 | ColumnType::CHAR => 'char',
122 | ColumnType::STRING => 'varchar2(' . ($size ?? 255) . ')',
123 | ColumnType::TEXT => 'clob',
124 | ColumnType::BINARY => 'blob',
125 | ColumnType::UUID => 'raw(16)',
126 | ColumnType::TIMESTAMP => 'timestamp',
127 | ColumnType::DATETIME => 'timestamp',
128 | ColumnType::DATETIMETZ => 'timestamp' . ($size !== null ? "($size)" : '') . ' with time zone',
129 | ColumnType::TIME => 'interval day(0) to second',
130 | ColumnType::TIMETZ => 'interval day(0) to second',
131 | ColumnType::DATE => 'date',
132 | ColumnType::ARRAY, ColumnType::STRUCTURED, ColumnType::JSON
133 | => version_compare($this->queryBuilder->getServerInfo()->getVersion(), '21', '>=')
134 | ? 'json'
135 | : 'clob',
136 | ColumnType::ENUM => 'varchar2(' . $this->calcEnumSize($column) . ' BYTE)',
137 | default => 'varchar2',
138 | },
139 | 'timestamp with time zone' => 'timestamp' . ($size !== null ? "($size)" : '') . ' with time zone',
140 | 'timestamp with local time zone' => 'timestamp' . ($size !== null ? "($size)" : '') . ' with local time zone',
141 | 'interval day to second' => 'interval day' . ($scale !== null ? "($scale)" : '') . ' to second' . ($size !== null ? "($size)" : ''),
142 | 'interval year to month' => 'interval year' . ($scale !== null ? "($scale)" : '') . ' to month',
143 | };
144 | }
145 |
146 | protected function getDefaultUuidExpression(): string
147 | {
148 | return 'sys_guid()';
149 | }
150 |
151 | private function calcEnumSize(ColumnInterface $column): int
152 | {
153 | $size = $column->getSize();
154 | if ($size !== null) {
155 | return $size;
156 | }
157 |
158 | if ($column instanceof EnumColumn) {
159 | return max(
160 | array_map(
161 | strlen(...),
162 | $column->getValues(),
163 | ),
164 | );
165 | }
166 |
167 | throw new LogicException('Cannot calculate enum size. Set the size explicitly or use `EnumColumn` instance.');
168 | }
169 | }
170 |
--------------------------------------------------------------------------------
/src/DMLQueryBuilder.php:
--------------------------------------------------------------------------------
1 | prepareTraversable($rows);
29 | }
30 |
31 | if (empty($rows)) {
32 | return '';
33 | }
34 |
35 | $columns = $this->extractColumnNames($rows, $columns);
36 | $values = $this->prepareBatchInsertValues($table, $rows, $columns, $params);
37 |
38 | if (empty($values)) {
39 | return '';
40 | }
41 |
42 | $query = 'INSERT INTO ' . $this->quoter->quoteTableName($table);
43 |
44 | if (count($columns) > 0) {
45 | $quotedColumnNames = array_map($this->quoter->quoteColumnName(...), $columns);
46 |
47 | $query .= ' (' . implode(', ', $quotedColumnNames) . ')';
48 | }
49 |
50 | return $query . "\nSELECT " . implode(" FROM DUAL UNION ALL\nSELECT ", $values) . ' FROM DUAL';
51 | }
52 |
53 | public function insertReturningPks(string $table, array|QueryInterface $columns, array &$params = []): string
54 | {
55 | throw new NotSupportedException(__METHOD__ . ' is not supported by Oracle.');
56 | }
57 |
58 | public function update(
59 | string $table,
60 | array $columns,
61 | array|string|ExpressionInterface $condition,
62 | array|string|ExpressionInterface|null $from = null,
63 | array &$params = [],
64 | ): string {
65 | if ($from !== null) {
66 | throw new NotSupportedException('Oracle does not support FROM clause in UPDATE statement.');
67 | }
68 | return parent::update($table, $columns, $condition, null, $params);
69 | }
70 |
71 | /**
72 | * @link https://docs.oracle.com/cd/B28359_01/server.111/b28286/statements_9016.htm#SQLRF01606
73 | */
74 | public function upsert(
75 | string $table,
76 | array|QueryInterface $insertColumns,
77 | array|bool $updateColumns = true,
78 | array &$params = [],
79 | ): string {
80 | $constraints = [];
81 |
82 | [$uniqueNames, $insertNames, $updateNames] = $this->prepareUpsertColumns(
83 | $table,
84 | $insertColumns,
85 | $updateColumns,
86 | $constraints,
87 | );
88 |
89 | if (empty($uniqueNames)) {
90 | return $this->insert($table, $insertColumns, $params);
91 | }
92 |
93 | $onCondition = ['or'];
94 | $quotedTableName = $this->quoter->quoteTableName($table);
95 |
96 | foreach ($constraints as $constraint) {
97 | $columnNames = $constraint->columnNames;
98 | $constraintCondition = ['and'];
99 |
100 | foreach ($columnNames as $name) {
101 | $quotedName = $this->quoter->quoteColumnName($name);
102 | $constraintCondition[] = "$quotedTableName.$quotedName=EXCLUDED.$quotedName";
103 | }
104 |
105 | $onCondition[] = $constraintCondition;
106 | }
107 |
108 | $on = $this->queryBuilder->buildCondition($onCondition, $params);
109 |
110 | [, $placeholders, $values, $params] = $this->prepareInsertValues($table, $insertColumns, $params);
111 |
112 | if (!empty($placeholders)) {
113 | $values = $this->buildSimpleSelect(array_combine($insertNames, $placeholders)) . ' FROM "DUAL"';
114 | }
115 |
116 | $insertValues = [];
117 | $quotedInsertNames = array_map($this->quoter->quoteColumnName(...), $insertNames);
118 |
119 | foreach ($quotedInsertNames as $quotedName) {
120 | $insertValues[] = 'EXCLUDED.' . $quotedName;
121 | }
122 |
123 | $mergeSql = 'MERGE INTO ' . $quotedTableName . ' USING (' . $values . ') EXCLUDED ON (' . $on . ')';
124 | $insertSql = 'INSERT (' . implode(', ', $quotedInsertNames) . ')'
125 | . ' VALUES (' . implode(', ', $insertValues) . ')';
126 |
127 | if (empty($updateColumns) || $updateNames === []) {
128 | /** there are no columns to update */
129 | return "$mergeSql WHEN NOT MATCHED THEN $insertSql";
130 | }
131 |
132 | $updates = $this->prepareUpsertSets($table, $updateColumns, $updateNames, $params);
133 | $updateSql = 'UPDATE SET ' . implode(', ', $updates);
134 |
135 | return "$mergeSql WHEN MATCHED THEN $updateSql WHEN NOT MATCHED THEN $insertSql";
136 | }
137 |
138 | public function upsertReturning(
139 | string $table,
140 | array|QueryInterface $insertColumns,
141 | array|bool $updateColumns = true,
142 | ?array $returnColumns = null,
143 | array &$params = [],
144 | ): string {
145 | throw new NotSupportedException(__METHOD__ . '() is not supported by Oracle.');
146 | }
147 |
148 | public function resetSequence(string $table, int|string|null $value = null): string
149 | {
150 | $tableSchema = $this->schema->getTableSchema($table);
151 |
152 | if ($tableSchema === null) {
153 | throw new InvalidArgumentException("Table not found: '$table'.");
154 | }
155 |
156 | $sequenceName = $tableSchema->getSequenceName();
157 |
158 | if ($sequenceName === null) {
159 | throw new InvalidArgumentException("There is not sequence associated with table '$table'.");
160 | }
161 |
162 | if ($value === null && count($tableSchema->getPrimaryKey()) > 1) {
163 | throw new InvalidArgumentException("Can't reset sequence for composite primary key in table: $table");
164 | }
165 |
166 | /**
167 | * Oracle needs at least many queries to reset a sequence (see adding transactions and/or use an alter method to
168 | * avoid grant issue?)
169 | */
170 | return 'declare
171 | lastSeq number' . ($value !== null ? (' := ' . $value) : '') . ';
172 | begin' . ($value === null ? '
173 | SELECT MAX("' . $tableSchema->getPrimaryKey()[0] . '") + 1 INTO lastSeq FROM "' . $tableSchema->getName() . '";' : '') . '
174 | if lastSeq IS NULL then lastSeq := 1; end if;
175 | execute immediate \'DROP SEQUENCE "' . $sequenceName . '"\';
176 | execute immediate \'CREATE SEQUENCE "' . $sequenceName . '" START WITH \' || lastSeq || \' INCREMENT BY 1 NOMAXVALUE NOCACHE\';
177 | end;';
178 | }
179 |
180 | protected function prepareInsertValues(string $table, array|QueryInterface $columns, array $params = []): array
181 | {
182 | if (empty($columns)) {
183 | $names = [];
184 | $placeholders = [];
185 | $tableSchema = $this->schema->getTableSchema($table);
186 |
187 | if ($tableSchema !== null) {
188 | if (!empty($tableSchema->getPrimaryKey())) {
189 | $names = $tableSchema->getPrimaryKey();
190 | } else {
191 | /**
192 | * @psalm-suppress PossiblyNullArgument
193 | * @var string[] $names
194 | */
195 | $names = [array_key_first($tableSchema->getColumns())];
196 | }
197 |
198 | $placeholders = array_fill(0, count($names), 'DEFAULT');
199 | }
200 |
201 | return [$names, $placeholders, '', $params];
202 | }
203 |
204 | return parent::prepareInsertValues($table, $columns, $params);
205 | }
206 | }
207 |
--------------------------------------------------------------------------------
/tests/Provider/ColumnProvider.php:
--------------------------------------------------------------------------------
1 | getSharedConnection();
36 | $version21 = version_compare(TestConnection::getServerVersion(), '21', '>=');
37 |
38 | if ($version21 && $tableName === 'type') {
39 | $dump = FixtureDump::OCI21;
40 | $columns['json_col']->dbType('json');
41 | $columns['json_col']->check(null);
42 | }
43 |
44 | parent::testColumns($columns, $tableName, $dump);
45 | }
46 |
47 | public function testCompositeFk(): void
48 | {
49 | $db = $this->getSharedConnection();
50 | $this->loadFixture();
51 |
52 | $schema = $db->getSchema();
53 | $table = $schema->getTableSchema('composite_fk');
54 |
55 | $this->assertEquals(
56 | [
57 | 'FK_composite_fk_order_item' => new ForeignKey(
58 | 'FK_composite_fk_order_item',
59 | ['order_id', 'item_id'],
60 | 'SYSTEM',
61 | 'order_item',
62 | ['order_id', 'item_id'],
63 | ReferentialAction::CASCADE,
64 | ),
65 | ],
66 | $table->getForeignKeys(),
67 | );
68 |
69 | $db->close();
70 | }
71 |
72 | public function testGetDefaultSchema(): void
73 | {
74 | $db = $this->getSharedConnection();
75 |
76 | $schema = $db->getSchema();
77 |
78 | $this->assertSame('SYSTEM', $schema->getDefaultSchema());
79 |
80 | $db->close();
81 | }
82 |
83 | public function testGetSchemaDefaultValues(): void
84 | {
85 | $this->expectException(NotSupportedException::class);
86 | $this->expectExceptionMessage('Yiisoft\Db\Oracle\Schema::loadTableDefaultValues is not supported by Oracle.');
87 |
88 | parent::testGetSchemaDefaultValues();
89 | }
90 |
91 | public function testGetSchemaNames(): void
92 | {
93 | $db = $this->getSharedConnection();
94 | $this->loadFixture();
95 |
96 | $schema = $db->getSchema();
97 |
98 | if (version_compare(TestConnection::getServerVersion(), '12', '>')) {
99 | $this->assertContains('SYSBACKUP', $schema->getSchemaNames());
100 | } else {
101 | $this->assertEmpty($schema->getSchemaNames());
102 | }
103 |
104 | $db->close();
105 | }
106 |
107 | public function testGetTableNamesWithSchema(): void
108 | {
109 | $db = $this->getSharedConnection();
110 | $this->loadFixture();
111 |
112 | $schema = $db->getSchema();
113 | $tablesNames = $schema->getTableNames('SYSTEM');
114 |
115 | $expectedTableNames = [
116 | 'animal',
117 | 'animal_view',
118 | 'bit_values',
119 | 'category',
120 | 'composite_fk',
121 | 'constraints',
122 | 'customer',
123 | 'default_pk',
124 | 'department',
125 | 'document',
126 | 'dossier',
127 | 'employee',
128 | 'item',
129 | 'negative_default_values',
130 | 'null_values',
131 | 'order',
132 | 'order_item',
133 | 'order_item_with_null_fk',
134 | 'order_with_null_fk',
135 | 'profile',
136 | 'quoter',
137 | 'T_constraints_1',
138 | 'T_constraints_2',
139 | 'T_constraints_3',
140 | 'T_constraints_4',
141 | 'T_upsert',
142 | 'T_upsert_1',
143 | 'type',
144 | ];
145 |
146 | foreach ($expectedTableNames as $tableName) {
147 | $this->assertContains($tableName, $tablesNames);
148 | }
149 |
150 | $db->close();
151 | }
152 |
153 | public function testGetViewNames(): void
154 | {
155 | $db = $this->getSharedConnection();
156 | $this->loadFixture();
157 |
158 | $schema = $db->getSchema();
159 | $views = $schema->getViewNames();
160 |
161 | $this->assertContains('animal_view', $views);
162 |
163 | $db->close();
164 | }
165 |
166 | public function testGetViewNamesWithSchema(): void
167 | {
168 | $db = $this->getSharedConnection();
169 | $this->loadFixture();
170 |
171 | $schema = $db->getSchema();
172 | $views = $schema->getViewNames('SYSTEM');
173 |
174 | $this->assertContains('animal_view', $views);
175 |
176 | $db->close();
177 | }
178 |
179 | #[DataProviderExternal(SchemaProvider::class, 'constraints')]
180 | public function testTableSchemaConstraints(string $tableName, string $type, mixed $expected): void
181 | {
182 | parent::testTableSchemaConstraints($tableName, $type, $expected);
183 | }
184 |
185 | #[DataProviderExternal(SchemaProvider::class, 'constraints')]
186 | public function testTableSchemaConstraintsWithPdoLowercase(string $tableName, string $type, mixed $expected): void
187 | {
188 | parent::testTableSchemaConstraintsWithPdoLowercase($tableName, $type, $expected);
189 | }
190 |
191 | #[DataProviderExternal(SchemaProvider::class, 'constraints')]
192 | public function testTableSchemaConstraintsWithPdoUppercase(string $tableName, string $type, mixed $expected): void
193 | {
194 | parent::testTableSchemaConstraintsWithPdoUppercase($tableName, $type, $expected);
195 | }
196 |
197 | #[DataProviderExternal(SchemaProvider::class, 'tableSchemaWithDbSchemes')]
198 | public function testTableSchemaWithDbSchemes(
199 | string $tableName,
200 | string $expectedTableName,
201 | string $expectedSchemaName = '',
202 | ): void {
203 | $db = $this->getSharedConnection();
204 |
205 | $commandMock = $this->createMock(CommandInterface::class);
206 | $commandMock->method('queryAll')->willReturn([]);
207 | $mockDb = $this->createMock(PdoConnectionInterface::class);
208 | $mockDb->method('getQuoter')->willReturn($db->getQuoter());
209 | $mockDb
210 | ->method('createCommand')
211 | ->with(
212 | self::callback(static fn($sql) => true),
213 | self::callback(
214 | function ($params) use ($expectedTableName, $expectedSchemaName) {
215 | $this->assertEquals($expectedTableName, $params[':tableName']);
216 | $this->assertEquals($expectedSchemaName, $params[':schemaName']);
217 |
218 | return true;
219 | },
220 | ),
221 | )
222 | ->willReturn($commandMock);
223 | $schema = new Schema($mockDb, TestHelper::createMemorySchemaCache(), 'dbo');
224 | $schema->getTablePrimaryKey($tableName, true);
225 |
226 | $db->close();
227 | }
228 |
229 | public function testWorkWithDefaultValueConstraint(): void
230 | {
231 | $this->expectException(NotSupportedException::class);
232 | $this->expectExceptionMessage(
233 | 'Yiisoft\Db\Oracle\DDLQueryBuilder::addDefaultValue is not supported by Oracle.',
234 | );
235 |
236 | parent::testWorkWithDefaultValueConstraint();
237 | }
238 |
239 | public function testNotConnectionPDO(): void
240 | {
241 | $db = $this->createMock(ConnectionInterface::class);
242 | $schema = new Schema($db, TestHelper::createMemorySchemaCache(), 'system');
243 |
244 | $this->expectException(NotSupportedException::class);
245 | $this->expectExceptionMessage('Only PDO connections are supported.');
246 |
247 | $schema->refresh();
248 | }
249 |
250 | #[DataProviderExternal(SchemaProvider::class, 'resultColumns')]
251 | public function testGetResultColumn(?ColumnInterface $expected, array $info): void
252 | {
253 | parent::testGetResultColumn($expected, $info);
254 | }
255 | }
256 |
--------------------------------------------------------------------------------
/tests/ColumnTest.php:
--------------------------------------------------------------------------------
1 | getSharedConnection();
43 | $isOldVersion = version_compare(TestConnection::getServerVersion(), '21', '<');
44 |
45 | $this->loadFixture($isOldVersion ? FixtureDump::DEFAULT : FixtureDump::OCI21);
46 |
47 | $this->insertTypeValues($db);
48 |
49 | $query = (new Query($db))->from('type')->withTypecasting();
50 |
51 | $result = $query->one();
52 |
53 | $this->assertTypecastedValues($result, !$isOldVersion);
54 |
55 | $result = $query->all();
56 |
57 | $this->assertTypecastedValues($result[0], !$isOldVersion);
58 |
59 | $db->close();
60 | }
61 |
62 | public function testCommandWithPhpTypecasting(): void
63 | {
64 | $db = $this->getSharedConnection();
65 | $isOldVersion = version_compare(TestConnection::getServerVersion(), '21', '<');
66 |
67 | $this->loadFixture($isOldVersion ? FixtureDump::DEFAULT : FixtureDump::OCI21);
68 |
69 | $this->insertTypeValues($db);
70 |
71 | $command = $db->createCommand('SELECT * FROM "type"');
72 |
73 | $result = $command->withPhpTypecasting()->queryOne();
74 |
75 | $this->assertTypecastedValues($result, !$isOldVersion);
76 |
77 | $result = $command->withPhpTypecasting()->queryAll();
78 |
79 | $this->assertTypecastedValues($result[0], !$isOldVersion);
80 |
81 | $db->close();
82 | }
83 |
84 | public function testSelectWithPhpTypecasting(): void
85 | {
86 | $db = $this->getSharedConnection();
87 |
88 | $sql = "SELECT null, 1, 2.5, 'string' FROM DUAL";
89 |
90 | $expected = [
91 | 'NULL' => null,
92 | 1 => 1.0,
93 | '2.5' => 2.5,
94 | "'STRING'" => 'string',
95 | ];
96 |
97 | $result = $db->createCommand($sql)
98 | ->withPhpTypecasting()
99 | ->queryOne();
100 |
101 | $this->assertSame($expected, $result);
102 |
103 | $result = $db->createCommand($sql)
104 | ->withPhpTypecasting()
105 | ->queryAll();
106 |
107 | $this->assertSame([$expected], $result);
108 |
109 | $result = $db->createCommand($sql)
110 | ->withPhpTypecasting()
111 | ->query();
112 |
113 | $this->assertSame([$expected], iterator_to_array($result));
114 |
115 | $result = $db->createCommand('SELECT 2.5 FROM DUAL')
116 | ->withPhpTypecasting()
117 | ->queryScalar();
118 |
119 | $this->assertSame(2.5, $result);
120 |
121 | $result = $db->createCommand('SELECT 2.5 FROM DUAL UNION SELECT 3.3 FROM DUAL')
122 | ->withPhpTypecasting()
123 | ->queryColumn();
124 |
125 | $this->assertSame([2.5, 3.3], $result);
126 |
127 | $db->close();
128 | }
129 |
130 | public function testPhpTypecast(): void
131 | {
132 | $db = $this->getSharedConnection();
133 | $isOldVersion = version_compare(TestConnection::getServerVersion(), '21', '<');
134 |
135 | $this->loadFixture($isOldVersion ? FixtureDump::DEFAULT : FixtureDump::OCI21);
136 |
137 | parent::testPhpTypecast();
138 | }
139 |
140 | public function testColumnInstance(): void
141 | {
142 | $db = $this->getSharedConnection();
143 | $isOldVersion = version_compare(TestConnection::getServerVersion(), '21', '<');
144 |
145 | $this->loadFixture($isOldVersion ? FixtureDump::DEFAULT : FixtureDump::OCI21);
146 |
147 | $schema = $db->getSchema();
148 | $tableSchema = $schema->getTableSchema('type');
149 |
150 | $this->assertInstanceOf(IntegerColumn::class, $tableSchema->getColumn('int_col'));
151 | $this->assertInstanceOf(StringColumn::class, $tableSchema->getColumn('char_col'));
152 | $this->assertInstanceOf(DoubleColumn::class, $tableSchema->getColumn('float_col'));
153 | $this->assertInstanceOf(BinaryColumn::class, $tableSchema->getColumn('blob_col'));
154 | $this->assertInstanceOf(JsonColumn::class, $tableSchema->getColumn('json_col'));
155 | }
156 |
157 | #[DataProviderExternal(ColumnProvider::class, 'predefinedTypes')]
158 | public function testPredefinedType(string $className, string $type)
159 | {
160 | parent::testPredefinedType($className, $type);
161 | }
162 |
163 | #[DataProviderExternal(ColumnProvider::class, 'dbTypecastColumns')]
164 | public function testDbTypecastColumns(ColumnInterface $column, array $values)
165 | {
166 | parent::testDbTypecastColumns($column, $values);
167 | }
168 |
169 | #[DataProviderExternal(ColumnProvider::class, 'phpTypecastColumns')]
170 | public function testPhpTypecastColumns(ColumnInterface $column, array $values)
171 | {
172 | parent::testPhpTypecastColumns($column, $values);
173 | }
174 |
175 | public function testBinaryColumn(): void
176 | {
177 | $binaryCol = new BinaryColumn();
178 | $binaryCol->dbType('blob');
179 |
180 | $expected = new Expression('TO_BLOB(UTL_RAW.CAST_TO_RAW(:value))', ['value' => "\x10\x11\x12"]);
181 |
182 | $this->assertEquals(
183 | $expected,
184 | $binaryCol->dbTypecast("\x10\x11\x12"),
185 | );
186 | $this->assertEquals(
187 | $expected,
188 | $binaryCol->dbTypecast(new Param("\x10\x11\x12", PDO::PARAM_LOB)),
189 | );
190 | $this->assertEquals(
191 | $expected,
192 | $binaryCol->dbTypecast(new StringableStream("\x10\x11\x12")),
193 | );
194 | }
195 |
196 | public function testJsonColumn(): void
197 | {
198 | $jsonCol = new JsonColumn();
199 |
200 | $this->assertNull($jsonCol->phpTypecast(null));
201 | }
202 |
203 | public function testUniqueColumn(): void
204 | {
205 | $db = $this->getSharedConnection();
206 | $this->loadFixture();
207 |
208 | $schema = $db->getSchema();
209 |
210 | $this->assertTrue($schema->getTableSchema('T_constraints_1')?->getColumn('C_unique')->isUnique());
211 | $this->assertFalse($schema->getTableSchema('T_constraints_2')?->getColumn('C_index_2_1')->isUnique());
212 | $this->assertFalse($schema->getTableSchema('T_constraints_2')?->getColumn('C_index_2_2')->isUnique());
213 | $this->assertTrue($schema->getTableSchema('T_upsert')?->getColumn('email')->isUnique());
214 | $this->assertFalse($schema->getTableSchema('T_upsert')?->getColumn('recovery_email')->isUnique());
215 | }
216 |
217 | public function testTimestampColumnOnDifferentTimezones(): void
218 | {
219 | $db = $this->createConnection();
220 | $schema = $db->getSchema();
221 | $command = $db->createCommand();
222 | $tableName = 'timestamp_column_test';
223 |
224 | $command->setSql("ALTER SESSION SET TIME_ZONE = '+03:00'")->execute();
225 |
226 | $this->assertSame('+03:00', $db->getServerInfo()->getTimezone());
227 |
228 | $phpTimezone = date_default_timezone_get();
229 | date_default_timezone_set('America/New_York');
230 |
231 | if ($schema->hasTable($tableName)) {
232 | $command->dropTable($tableName)->execute();
233 | }
234 |
235 | $command->createTable(
236 | $tableName,
237 | [
238 | 'timestamp_col' => ColumnBuilder::timestamp(),
239 | 'datetime_col' => ColumnBuilder::datetime(),
240 | ],
241 | )->execute();
242 |
243 | $command->insert($tableName, [
244 | 'timestamp_col' => new DateTimeImmutable('2025-04-19 14:11:35'),
245 | 'datetime_col' => new DateTimeImmutable('2025-04-19 14:11:35'),
246 | ])->execute();
247 |
248 | $command->setSql("ALTER SESSION SET TIME_ZONE = '+04:00'")->execute();
249 |
250 | $this->assertSame('+04:00', $db->getServerInfo()->getTimezone(true));
251 |
252 | $columns = $schema->getTableSchema($tableName, true)->getColumns();
253 | $query = (new Query($db))->from($tableName);
254 |
255 | $result = $query->one();
256 |
257 | $this->assertEquals(new DateTimeImmutable('2025-04-19 14:11:35'), $columns['timestamp_col']->phpTypecast($result['timestamp_col']));
258 | $this->assertEquals(new DateTimeImmutable('2025-04-19 14:11:35'), $columns['datetime_col']->phpTypecast($result['datetime_col']));
259 |
260 | $result = $query->withTypecasting()->one();
261 |
262 | $this->assertEquals(new DateTimeImmutable('2025-04-19 14:11:35'), $result['timestamp_col']);
263 | $this->assertEquals(new DateTimeImmutable('2025-04-19 14:11:35'), $result['datetime_col']);
264 |
265 | date_default_timezone_set($phpTimezone);
266 |
267 | $db->close();
268 | }
269 |
270 | protected function insertTypeValues(ConnectionInterface $db): void
271 | {
272 | $db->createCommand()->insert(
273 | 'type',
274 | [
275 | 'int_col' => 1,
276 | 'char_col' => str_repeat('x', 100),
277 | 'char_col3' => null,
278 | 'float_col' => 1.234,
279 | 'blob_col' => "\x10\x11\x12",
280 | 'timestamp_col' => new Expression("TIMESTAMP '2023-07-11 14:50:23'"),
281 | 'timestamp_local' => '2023-07-11 14:50:23',
282 | 'time_col' => new DateTimeImmutable('14:50:23'),
283 | 'bool_col' => false,
284 | 'bit_col' => 0b0110_0110, // 102
285 | 'json_col' => [['a' => 1, 'b' => null, 'c' => [1, 3, 5]]],
286 | ],
287 | )->execute();
288 | }
289 |
290 | protected function assertTypecastedValues(array $result, bool $allTypecasted = false): void
291 | {
292 | $utcTimezone = new DateTimeZone('UTC');
293 |
294 | $this->assertSame(1, $result['int_col']);
295 | $this->assertSame(str_repeat('x', 100), $result['char_col']);
296 | $this->assertNull($result['char_col3']);
297 | $this->assertSame(1.234, $result['float_col']);
298 | $this->assertSame("\x10\x11\x12", (string) $result['blob_col']);
299 | $this->assertEquals(new DateTimeImmutable('2023-07-11 14:50:23', $utcTimezone), $result['timestamp_col']);
300 | $this->assertEquals(new DateTimeImmutable('2023-07-11 14:50:23', $utcTimezone), $result['timestamp_local']);
301 | $this->assertEquals(new DateTimeImmutable('14:50:23'), $result['time_col']);
302 | $this->assertEquals(false, $result['bool_col']);
303 | $this->assertSame(0b0110_0110, $result['bit_col']);
304 |
305 | if ($allTypecasted) {
306 | $this->assertSame([['a' => 1, 'b' => null, 'c' => [1, 3, 5]]], $result['json_col']);
307 | } else {
308 | $this->assertSame('[{"a":1,"b":null,"c":[1,3,5]}]', (string) $result['json_col']);
309 | }
310 | }
311 | }
312 |
--------------------------------------------------------------------------------
/tests/Provider/SchemaProvider.php:
--------------------------------------------------------------------------------
1 | getServerInfo()->getTimezone();
27 |
28 | return [
29 | [
30 | [
31 | 'int_col' => new IntegerColumn(
32 | dbType: 'number',
33 | notNull: true,
34 | scale: 0,
35 | ),
36 | 'int_col2' => new IntegerColumn(
37 | dbType: 'number',
38 | scale: 0,
39 | defaultValue: 1,
40 | ),
41 | 'tinyint_col' => new IntegerColumn(
42 | dbType: 'number',
43 | scale: 0,
44 | size: 3,
45 | defaultValue: 1,
46 | ),
47 | 'smallint_col' => new IntegerColumn(
48 | dbType: 'number',
49 | scale: 0,
50 | defaultValue: 1,
51 | ),
52 | 'char_col' => new StringColumn(
53 | ColumnType::CHAR,
54 | dbType: 'char',
55 | notNull: true,
56 | size: 100,
57 | collation: 'USING_NLS_COMP',
58 | ),
59 | 'char_col2' => new StringColumn(
60 | dbType: 'varchar2',
61 | size: 100,
62 | collation: 'USING_NLS_COMP',
63 | defaultValue: 'some\'thing',
64 | ),
65 | 'char_col3' => new StringColumn(
66 | dbType: 'varchar2',
67 | size: 4000,
68 | collation: 'USING_NLS_COMP',
69 | ),
70 | 'nvarchar_col' => new StringColumn(
71 | dbType: 'nvarchar2',
72 | size: 100,
73 | collation: 'USING_NLS_COMP',
74 | defaultValue: '',
75 | ),
76 | 'float_col' => new DoubleColumn(
77 | dbType: 'float',
78 | notNull: true,
79 | size: 126,
80 | ),
81 | 'float_col2' => new DoubleColumn(
82 | dbType: 'float',
83 | size: 126,
84 | defaultValue: 1.23,
85 | ),
86 | 'blob_col' => new BinaryColumn(
87 | dbType: 'blob',
88 | ),
89 | 'numeric_col' => new StringColumn(
90 | ColumnType::DECIMAL,
91 | dbType: 'number',
92 | scale: 2,
93 | size: 5,
94 | defaultValue: '33.22',
95 | ),
96 | 'timestamp_col' => new DateTimeColumn(
97 | dbType: 'timestamp',
98 | notNull: true,
99 | size: 6,
100 | defaultValue: new DateTimeImmutable('2002-01-01 00:00:00', new DateTimeZone('UTC')),
101 | shouldConvertTimezone: true,
102 | ),
103 | 'timestamp_local' => new DateTimeColumn(
104 | dbType: 'timestamp with local time zone',
105 | size: 6,
106 | dbTimezone: $dbTimezone,
107 | ),
108 | 'time_col' => new DateTimeColumn(
109 | ColumnType::TIME,
110 | dbType: 'interval day to second',
111 | scale: 0,
112 | size: 0,
113 | defaultValue: new DateTimeImmutable('10:33:21', new DateTimeZone('UTC')),
114 | shouldConvertTimezone: true,
115 | ),
116 | 'interval_day_col' => new StringColumn(
117 | dbType: 'interval day to second',
118 | scale: 1,
119 | size: 0,
120 | defaultValue: new Expression("INTERVAL '2 04:56:12' DAY(1) TO SECOND(0)"),
121 | ),
122 | 'bool_col' => new BooleanColumn(
123 | check: '"bool_col" in (0,1)',
124 | dbType: 'char',
125 | notNull: true,
126 | size: 1,
127 | ),
128 | 'bool_col2' => new BooleanColumn(
129 | check: '"bool_col2" in (0,1)',
130 | dbType: 'char',
131 | size: 1,
132 | defaultValue: true,
133 | ),
134 | 'ts_default' => new DateTimeColumn(
135 | dbType: 'timestamp',
136 | notNull: true,
137 | size: 6,
138 | defaultValue: new Expression('CURRENT_TIMESTAMP'),
139 | ),
140 | 'bit_col' => new IntegerColumn(
141 | dbType: 'number',
142 | notNull: true,
143 | scale: 0,
144 | size: 3,
145 | defaultValue: 130, // b'10000010'
146 | ),
147 | 'json_col' => new JsonColumn(
148 | check: '"json_col" is json',
149 | dbType: 'clob',
150 | defaultValue: ['a' => 1],
151 | ),
152 | ],
153 | 'type',
154 | ],
155 | [
156 | [
157 | 'id' => new IntegerColumn(
158 | autoIncrement: true,
159 | dbType: 'number',
160 | primaryKey: true,
161 | notNull: true,
162 | scale: 0,
163 | ),
164 | 'type' => new StringColumn(
165 | dbType: 'varchar2',
166 | notNull: true,
167 | size: 255,
168 | collation: 'USING_NLS_COMP',
169 | ),
170 | ],
171 | 'animal',
172 | ],
173 | ];
174 | }
175 |
176 | public static function constraints(): array
177 | {
178 | $constraints = parent::constraints();
179 |
180 | Assert::setPropertyValue($constraints['1: check'][2][0], 'expression', '"C_check" <> \'\'');
181 | $constraints['1: check'][2][] = new Check('', ['C_id'], '"C_id" IS NOT NULL');
182 | $constraints['1: check'][2][] = new Check('', ['C_not_null'], '"C_not_null" IS NOT NULL');
183 | $constraints['1: check'][2][] = new Check('', ['C_unique'], '"C_unique" IS NOT NULL');
184 | $constraints['1: check'][2][] = new Check('', ['C_default'], '"C_default" IS NOT NULL');
185 |
186 | $constraints['2: check'][2][] = new Check('', ['C_id_1'], '"C_id_1" IS NOT NULL');
187 | $constraints['2: check'][2][] = new Check('', ['C_id_2'], '"C_id_2" IS NOT NULL');
188 |
189 | Assert::setPropertyValue($constraints['3: foreign key'][2][0], 'foreignSchemaName', 'SYSTEM');
190 | Assert::setPropertyValue($constraints['3: foreign key'][2][0], 'foreignTableName', 'T_constraints_2');
191 | Assert::setPropertyValue($constraints['3: foreign key'][2][0], 'onUpdate', null);
192 | $constraints['3: index'][2] = [];
193 | $constraints['3: check'][2][] = new Check('', ['C_fk_id_1'], '"C_fk_id_1" IS NOT NULL');
194 | $constraints['3: check'][2][] = new Check('', ['C_fk_id_2'], '"C_fk_id_2" IS NOT NULL');
195 | $constraints['3: check'][2][] = new Check('', ['C_id'], '"C_id" IS NOT NULL');
196 |
197 | $constraints['4: check'][2][] = new Check('', ['C_id'], '"C_id" IS NOT NULL');
198 | $constraints['4: check'][2][] = new Check('', ['C_col_2'], '"C_col_2" IS NOT NULL');
199 |
200 | return $constraints;
201 | }
202 |
203 | public static function resultColumns(): array
204 | {
205 | return [
206 | [null, []],
207 | [null, ['oci:decl_type' => '']],
208 | [new IntegerColumn(dbType: 'number', name: 'int_col', notNull: true, size: 38, scale: 0), [
209 | 'oci:decl_type' => 'NUMBER',
210 | 'native_type' => 'NUMBER',
211 | 'pdo_type' => 2,
212 | 'scale' => 0,
213 | 'flags' => ['not_null'],
214 | 'name' => 'int_col',
215 | 'len' => 22,
216 | 'precision' => 38,
217 | ]],
218 | [new IntegerColumn(dbType: 'number', name: 'tinyint_col', notNull: false, size: 3, scale: 0), [
219 | 'oci:decl_type' => 'NUMBER',
220 | 'native_type' => 'NUMBER',
221 | 'pdo_type' => 2,
222 | 'scale' => 0,
223 | 'flags' => ['nullable'],
224 | 'name' => 'tinyint_col',
225 | 'len' => 22,
226 | 'precision' => 3,
227 | ]],
228 | [new StringColumn(ColumnType::CHAR, dbType: 'char', name: 'char_col', notNull: true, size: 100), [
229 | 'oci:decl_type' => 'CHAR',
230 | 'native_type' => 'CHAR',
231 | 'pdo_type' => 2,
232 | 'scale' => 0,
233 | 'flags' => ['not_null'],
234 | 'name' => 'char_col',
235 | 'len' => 100,
236 | 'precision' => 0,
237 | ]],
238 | [new StringColumn(dbType: 'varchar2', name: 'char_col2', notNull: false, size: 100), [
239 | 'oci:decl_type' => 'VARCHAR2',
240 | 'native_type' => 'VARCHAR2',
241 | 'pdo_type' => 2,
242 | 'scale' => 0,
243 | 'flags' => ['nullable'],
244 | 'name' => 'char_col2',
245 | 'len' => 100,
246 | 'precision' => 0,
247 | ]],
248 | [new DoubleColumn(dbType: 'float', name: 'float_col', notNull: true, size: 126), [
249 | 'oci:decl_type' => 'FLOAT',
250 | 'native_type' => 'FLOAT',
251 | 'pdo_type' => 2,
252 | 'scale' => -127,
253 | 'flags' => ['not_null'],
254 | 'name' => 'float_col',
255 | 'len' => 22,
256 | 'precision' => 126,
257 | ]],
258 | [new BinaryColumn(dbType: 'blob', name: 'blob_col', notNull: false, size: 4000), [
259 | 'oci:decl_type' => 'BLOB',
260 | 'native_type' => 'BLOB',
261 | 'pdo_type' => 3,
262 | 'scale' => 0,
263 | 'flags' => ['blob', 'nullable'],
264 | 'name' => 'blob_col',
265 | 'len' => 4000,
266 | 'precision' => 0,
267 | ]],
268 | [
269 | new StringColumn(
270 | ColumnType::DECIMAL,
271 | dbType: 'number',
272 | name: 'numeric_col',
273 | notNull: false,
274 | scale: 2,
275 | size: 5,
276 | ),
277 | [
278 | 'oci:decl_type' => 'NUMBER',
279 | 'native_type' => 'NUMBER',
280 | 'pdo_type' => 2,
281 | 'scale' => 2,
282 | 'flags' => ['nullable'],
283 | 'name' => 'numeric_col',
284 | 'len' => 22,
285 | 'precision' => 5,
286 | ],
287 | ],
288 | [new DateTimeColumn(dbType: 'timestamp', name: 'timestamp_col', notNull: true, size: 6), [
289 | 'oci:decl_type' => 'TIMESTAMP',
290 | 'native_type' => 'TIMESTAMP',
291 | 'pdo_type' => 2,
292 | 'scale' => 6,
293 | 'flags' => ['not_null'],
294 | 'name' => 'timestamp_col',
295 | 'len' => 11,
296 | 'precision' => 0,
297 | ]],
298 | [new DateTimeColumn(ColumnType::TIME, dbType: 'interval day to second', name: 'time_col', notNull: false, size: 0), [
299 | 'oci:decl_type' => 'INTERVAL DAY TO SECOND',
300 | 'native_type' => 'INTERVAL DAY TO SECOND',
301 | 'pdo_type' => 2,
302 | 'scale' => 0,
303 | 'flags' => ['nullable'],
304 | 'name' => 'time_col',
305 | 'len' => 11,
306 | 'precision' => 0,
307 | ]],
308 | [new BinaryColumn(dbType: 'clob', name: 'json_col', notNull: false, size: 4000), [
309 | 'oci:decl_type' => 'CLOB',
310 | 'native_type' => 'CLOB',
311 | 'pdo_type' => 3,
312 | 'scale' => 0,
313 | 'flags' => ['blob', 'nullable'],
314 | 'name' => 'json_col',
315 | 'len' => 4000,
316 | 'precision' => 0,
317 | ]],
318 | [new JsonColumn(dbType: 'json', name: 'json_col', notNull: false, size: 8200), [
319 | 'oci:decl_type' => 119,
320 | 'native_type' => 'UNKNOWN',
321 | 'pdo_type' => 2,
322 | 'scale' => 0,
323 | 'flags' => ['nullable'],
324 | 'name' => 'json_col',
325 | 'len' => 8200,
326 | 'precision' => 0,
327 | ]],
328 | [new StringColumn(dbType: 'varchar2', name: 'NULL', notNull: false), [
329 | 'oci:decl_type' => 'VARCHAR2',
330 | 'native_type' => 'VARCHAR2',
331 | 'pdo_type' => 2,
332 | 'scale' => 0,
333 | 'flags' => ['nullable'],
334 | 'name' => 'NULL',
335 | 'len' => 0,
336 | 'precision' => 0,
337 | ]],
338 | [new DoubleColumn(dbType: 'number', name: '1', notNull: false), [
339 | 'oci:decl_type' => 'NUMBER',
340 | 'native_type' => 'NUMBER',
341 | 'pdo_type' => 2,
342 | 'scale' => -127,
343 | 'flags' => ['nullable'],
344 | 'name' => '1',
345 | 'len' => 2,
346 | 'precision' => 0,
347 | ]],
348 | [new StringColumn(ColumnType::CHAR, dbType: 'char', name: "'STRING'", notNull: false, size: 6), [
349 | 'oci:decl_type' => 'CHAR',
350 | 'native_type' => 'CHAR',
351 | 'pdo_type' => 2,
352 | 'scale' => 0,
353 | 'flags' => ['nullable'],
354 | 'name' => "'STRING'",
355 | 'len' => 6,
356 | 'precision' => 0,
357 | ]],
358 | [new DateTimeColumn(ColumnType::DATETIMETZ, dbType: 'timestamp with time zone', name: 'TIMESTAMP(3)', notNull: false, size: 3), [
359 | 'oci:decl_type' => 'TIMESTAMP WITH TIMEZONE',
360 | 'native_type' => 'TIMESTAMP WITH TIMEZONE',
361 | 'pdo_type' => 2,
362 | 'scale' => 3,
363 | 'flags' => ['nullable'],
364 | 'name' => 'TIMESTAMP(3)',
365 | 'len' => 13,
366 | 'precision' => 0,
367 | ]],
368 | ];
369 | }
370 |
371 | public static function tableSchemaWithDbSchemes(): array
372 | {
373 | return [
374 | ['animal', 'animal', 'dbo'],
375 | ['dbo.animal', 'animal', 'dbo'],
376 | ['"dbo"."animal"', 'animal', 'dbo'],
377 | ['"other"."animal2"', 'animal2', 'other',],
378 | ['other."animal2"', 'animal2', 'other',],
379 | ['other.animal2', 'animal2', 'other',],
380 | ['catalog.other.animal2', 'animal2', 'other'],
381 | ];
382 | }
383 | }
384 |
--------------------------------------------------------------------------------
/tests/Support/Fixture/oci.sql:
--------------------------------------------------------------------------------
1 | /**
2 | * This is the database schema for testing Oracle support of Yii Active Record.
3 | */
4 |
5 | BEGIN EXECUTE IMMEDIATE 'DROP TABLE "composite_fk"'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -942 THEN RAISE; END IF; END;--
6 | BEGIN EXECUTE IMMEDIATE 'DROP TABLE "order_item"'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -942 THEN RAISE; END IF; END;--
7 | BEGIN EXECUTE IMMEDIATE 'DROP TABLE "item"'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -942 THEN RAISE; END IF; END;--
8 | BEGIN EXECUTE IMMEDIATE 'DROP TABLE "order_item_with_null_fk"'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -942 THEN RAISE; END IF; END;--
9 | BEGIN EXECUTE IMMEDIATE 'DROP TABLE "order"'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -942 THEN RAISE; END IF; END;--
10 | BEGIN EXECUTE IMMEDIATE 'DROP TABLE "order_with_null_fk"'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -942 THEN RAISE; END IF; END;--
11 | BEGIN EXECUTE IMMEDIATE 'DROP TABLE "category"'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -942 THEN RAISE; END IF; END;--
12 | BEGIN EXECUTE IMMEDIATE 'DROP TABLE "customer"'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -942 THEN RAISE; END IF; END;--
13 | BEGIN EXECUTE IMMEDIATE 'DROP TABLE "profile"'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -942 THEN RAISE; END IF; END;--
14 | BEGIN EXECUTE IMMEDIATE 'DROP TABLE "quoter"'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -942 THEN RAISE; END IF; END;--
15 | BEGIN EXECUTE IMMEDIATE 'DROP TABLE "type"'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -942 THEN RAISE; END IF; END;--
16 | BEGIN EXECUTE IMMEDIATE 'DROP TABLE "null_values"'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -942 THEN RAISE; END IF; END;--
17 | BEGIN EXECUTE IMMEDIATE 'DROP TABLE "negative_default_values"'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -942 THEN RAISE; END IF; END;--
18 | BEGIN EXECUTE IMMEDIATE 'DROP TABLE "constraints"'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -942 THEN RAISE; END IF; END;--
19 | BEGIN EXECUTE IMMEDIATE 'DROP TABLE "bool_values"'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -942 THEN RAISE; END IF; END;--
20 | BEGIN EXECUTE IMMEDIATE 'DROP TABLE "animal"'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -942 THEN RAISE; END IF; END;--
21 | BEGIN EXECUTE IMMEDIATE 'DROP TABLE "default_pk"'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -942 THEN RAISE; END IF; END;--
22 | BEGIN EXECUTE IMMEDIATE 'DROP TABLE "notauto_pk"'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -942 THEN RAISE; END IF; END;--
23 | BEGIN EXECUTE IMMEDIATE 'DROP TABLE "default_multiple_pk"'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -942 THEN RAISE; END IF; END;--
24 | BEGIN EXECUTE IMMEDIATE 'DROP TABLE "document"'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -942 THEN RAISE; END IF; END;--
25 | BEGIN EXECUTE IMMEDIATE 'DROP TABLE "dossier"'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -942 THEN RAISE; END IF; END;--
26 | BEGIN EXECUTE IMMEDIATE 'DROP TABLE "employee"'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -942 THEN RAISE; END IF; END;--
27 | BEGIN EXECUTE IMMEDIATE 'DROP TABLE "department"'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -942 THEN RAISE; END IF; END;--
28 | BEGIN EXECUTE IMMEDIATE 'DROP VIEW "animal_view"'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -942 THEN RAISE; END IF; END;--
29 | BEGIN EXECUTE IMMEDIATE 'DROP TABLE "bit_values"'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -942 THEN RAISE; END IF; END; --
30 | BEGIN EXECUTE IMMEDIATE 'DROP TABLE "T_constraints_4"'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -942 THEN RAISE; END IF; END;--
31 | BEGIN EXECUTE IMMEDIATE 'DROP TABLE "T_constraints_3"'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -942 THEN RAISE; END IF; END;--
32 | BEGIN EXECUTE IMMEDIATE 'DROP TABLE "T_constraints_2"'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -942 THEN RAISE; END IF; END;--
33 | BEGIN EXECUTE IMMEDIATE 'DROP TABLE "T_constraints_1"'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -942 THEN RAISE; END IF; END;--
34 | BEGIN EXECUTE IMMEDIATE 'DROP TABLE "T_upsert"'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -942 THEN RAISE; END IF; END;--
35 | BEGIN EXECUTE IMMEDIATE 'DROP TABLE "T_upsert_1"'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -942 THEN RAISE; END IF; END;--
36 | BEGIN EXECUTE IMMEDIATE 'DROP TABLE "T_upsert_varbinary"'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -942 THEN RAISE; END IF; END;--
37 |
38 | BEGIN EXECUTE IMMEDIATE 'DROP SEQUENCE "profile_SEQ"'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -2289 THEN RAISE; END IF; END;--
39 | BEGIN EXECUTE IMMEDIATE 'DROP SEQUENCE "customer_SEQ"'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -2289 THEN RAISE; END IF; END;--
40 | BEGIN EXECUTE IMMEDIATE 'DROP SEQUENCE "category_SEQ"'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -2289 THEN RAISE; END IF; END;--
41 | BEGIN EXECUTE IMMEDIATE 'DROP SEQUENCE "item_SEQ"'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -2289 THEN RAISE; END IF; END;--
42 | BEGIN EXECUTE IMMEDIATE 'DROP SEQUENCE "order_SEQ"'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -2289 THEN RAISE; END IF; END;--
43 | BEGIN EXECUTE IMMEDIATE 'DROP SEQUENCE "order_with_null_fk_SEQ"'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -2289 THEN RAISE; END IF; END;--
44 | BEGIN EXECUTE IMMEDIATE 'DROP SEQUENCE "null_values_SEQ"'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -2289 THEN RAISE; END IF; END;--
45 | BEGIN EXECUTE IMMEDIATE 'DROP SEQUENCE "bool_values_SEQ"'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -2289 THEN RAISE; END IF; END;--
46 | BEGIN EXECUTE IMMEDIATE 'DROP SEQUENCE "animal_SEQ"'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -2289 THEN RAISE; END IF; END;--
47 | BEGIN EXECUTE IMMEDIATE 'DROP SEQUENCE "document_SEQ"'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -2289 THEN RAISE; END IF; END;--
48 | BEGIN EXECUTE IMMEDIATE 'DROP SEQUENCE "T_upsert_SEQ"'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -2289 THEN RAISE; END IF; END;--
49 | BEGIN EXECUTE IMMEDIATE 'DROP SEQUENCE "department_SEQ"'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -2289 THEN RAISE; END IF; END;--
50 | BEGIN EXECUTE IMMEDIATE 'DROP SEQUENCE "employee_SEQ"'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -2289 THEN RAISE; END IF; END;--
51 |
52 | /* STATEMENTS */
53 |
54 | CREATE TABLE "constraints"
55 | (
56 | "id" integer not null,
57 | "field1" varchar2(255)
58 | );
59 |
60 | CREATE TABLE "profile" (
61 | "id" integer not null,
62 | "description" varchar2(128) NOT NULL,
63 | CONSTRAINT "profile_PK" PRIMARY KEY ("id") ENABLE
64 | );
65 |
66 | CREATE TABLE "quoter" (
67 | "name" varchar2(16) NOT NULL,
68 | "description" varchar2(128) NOT NULL,
69 | CONSTRAINT "quoter_PK" PRIMARY KEY ("name") ENABLE
70 | );
71 |
72 | CREATE SEQUENCE "profile_SEQ";
73 |
74 | CREATE TABLE "customer" (
75 | "id" integer not null,
76 | "email" varchar2(128) NOT NULL UNIQUE,
77 | "name" varchar2(128),
78 | "address" varchar(4000),
79 | "status" integer DEFAULT 0,
80 | "profile_id" integer,
81 | CONSTRAINT "customer_PK" PRIMARY KEY ("id") ENABLE
82 | );
83 | CREATE SEQUENCE "customer_SEQ";
84 |
85 | comment on column "customer"."email" is 'someone@example.com';
86 |
87 | CREATE TABLE "category" (
88 | "id" integer not null,
89 | "name" varchar2(128) NOT NULL,
90 | CONSTRAINT "category_PK" PRIMARY KEY ("id") ENABLE
91 | );
92 | CREATE SEQUENCE "category_SEQ";
93 |
94 | CREATE TABLE "item" (
95 | "id" integer not null,
96 | "name" varchar2(128) NOT NULL,
97 | "category_id" integer NOT NULL references "category"("id") on DELETE CASCADE,
98 | CONSTRAINT "item_PK" PRIMARY KEY ("id") ENABLE
99 | );
100 | CREATE SEQUENCE "item_SEQ";
101 |
102 | CREATE TABLE "order" (
103 | "id" integer not null,
104 | "customer_id" integer NOT NULL references "customer"("id") on DELETE CASCADE,
105 | "created_at" integer NOT NULL,
106 | "total" decimal(10,2) NOT NULL,
107 | CONSTRAINT "order_PK" PRIMARY KEY ("id") ENABLE
108 | );
109 | CREATE SEQUENCE "order_SEQ";
110 |
111 | CREATE TABLE "order_with_null_fk" (
112 | "id" integer not null,
113 | "customer_id" integer,
114 | "created_at" integer NOT NULL,
115 | "total" decimal(10,0) NOT NULL,
116 | CONSTRAINT "order_with_null_fk_PK" PRIMARY KEY ("id") ENABLE
117 | );
118 | CREATE SEQUENCE "order_with_null_fk_SEQ";
119 |
120 | CREATE TABLE "order_item" (
121 | "order_id" integer NOT NULL references "order"("id") on DELETE CASCADE,
122 | "item_id" integer NOT NULL references "item"("id") on DELETE CASCADE,
123 | "quantity" integer NOT NULL,
124 | "subtotal" decimal(10,0) NOT NULL,
125 | CONSTRAINT "order_item_PK" PRIMARY KEY ("order_id", "item_id") ENABLE
126 | );
127 |
128 | CREATE TABLE "order_item_with_null_fk" (
129 | "order_id" integer,
130 | "item_id" integer,
131 | "quantity" integer NOT NULL,
132 | "subtotal" decimal(10,0) NOT NULL
133 | );
134 |
135 | CREATE TABLE "composite_fk" (
136 | "id" integer NOT NULL,
137 | "order_id" integer NOT NULL,
138 | "item_id" integer NOT NULL,
139 | CONSTRAINT "composite_fk_PK" PRIMARY KEY ("id") ENABLE,
140 | CONSTRAINT "FK_composite_fk_order_item" FOREIGN KEY ("order_id", "item_id")
141 | REFERENCES "order_item" ("order_id", "item_id") ON DELETE CASCADE
142 | );
143 |
144 | CREATE TABLE "null_values" (
145 | "id" INT NOT NULL,
146 | "var1" INT NULL,
147 | "var2" INT NULL,
148 | "var3" INT DEFAULT NULL,
149 | "stringcol" varchar2(32) DEFAULT NULL,
150 | CONSTRAINT "null_values_PK" PRIMARY KEY ("id") ENABLE
151 | );
152 | CREATE SEQUENCE "null_values_SEQ";
153 |
154 | CREATE TABLE "negative_default_values" (
155 | "tinyint_col" number(3) default -123,
156 | "smallint_col" smallint default -123,
157 | "int_col" integer default -123,
158 | "bigint_col" integer default -123,
159 | "float_col" double precision default -12345.6789,
160 | "numeric_col" decimal(5,2) default -33.22
161 | );
162 |
163 | CREATE TABLE "type" (
164 | "int_col" integer NOT NULL,
165 | "int_col2" integer DEFAULT 1,
166 | "tinyint_col" number(3) DEFAULT 1,
167 | "smallint_col" smallint DEFAULT 1,
168 | "char_col" char(100) NOT NULL,
169 | "char_col2" varchar2(100) DEFAULT 'some''thing',
170 | "char_col3" varchar2(4000),
171 | "nvarchar_col" nvarchar2(100) DEFAULT '',
172 | "float_col" double precision NOT NULL,
173 | "float_col2" double precision DEFAULT 1.23,
174 | "blob_col" blob DEFAULT NULL,
175 | "numeric_col" decimal(5,2) DEFAULT 33.22,
176 | "timestamp_col" timestamp DEFAULT to_timestamp('2002-01-01 00:00:00', 'yyyy-mm-dd hh24:mi:ss') NOT NULL,
177 | "timestamp_local" timestamp with local time zone,
178 | "time_col" interval day (0) to second(0) DEFAULT INTERVAL '0 10:33:21' DAY(0) TO SECOND(0),
179 | "interval_day_col" interval day (1) to second(0) DEFAULT INTERVAL '2 04:56:12' DAY(1) TO SECOND(0),
180 | "bool_col" char NOT NULL check ("bool_col" in (0,1)),
181 | "bool_col2" char DEFAULT 1 check("bool_col2" in (0,1)),
182 | "ts_default" TIMESTAMP DEFAULT CURRENT_TIMESTAMP NOT NULL,
183 | "bit_col" number(3) DEFAULT 130 NOT NULL,
184 | "json_col" clob DEFAULT '{"a":1}' CHECK ("json_col" is json)
185 | );
186 |
187 | CREATE TABLE "bool_values" (
188 | "id" integer not null,
189 | "bool_col" char check ("bool_col" in (0,1)),
190 | "default_true" char default 1 not null check ("default_true" in (0,1)),
191 | "default_false" char default 0 not null check ("default_false" in (0,1)),
192 | CONSTRAINT "bool_values_PK" PRIMARY KEY ("id") ENABLE
193 | );
194 | CREATE SEQUENCE "bool_values_SEQ";
195 |
196 |
197 | CREATE TABLE "animal" (
198 | "id" integer generated by default as identity,
199 | "type" varchar2(255) not null,
200 | CONSTRAINT "animal_PK" PRIMARY KEY ("id") ENABLE
201 | );
202 | CREATE SEQUENCE "animal_SEQ";
203 |
204 | CREATE TABLE "default_pk" (
205 | "id" integer default 5 not null,
206 | "type" varchar2(255) not null,
207 | CONSTRAINT "default_pk_PK" PRIMARY KEY ("id") ENABLE
208 | );
209 |
210 | CREATE TABLE "notauto_pk" (
211 | "id_1" INTEGER,
212 | "id_2" DECIMAL(5,2),
213 | "type" VARCHAR2(255) NOT NULL,
214 | CONSTRAINT "notauto_pk_PK" PRIMARY KEY ("id_1", "id_2") ENABLE
215 | );
216 |
217 | CREATE TABLE "default_multiple_pk" (
218 | "id" integer not null,
219 | "second_key_column" char(10) not null,
220 | "type" varchar2(255) not null,
221 | CONSTRAINT "default_multiple_pk_PK" PRIMARY KEY ("id", "second_key_column") ENABLE
222 | );
223 |
224 | CREATE TABLE "document" (
225 | "id" integer,
226 | "title" varchar2(255) not null,
227 | "content" varchar(4000),
228 | "version" integer default 0 not null,
229 | CONSTRAINT "document_PK" PRIMARY KEY ("id") ENABLE
230 | );
231 | CREATE SEQUENCE "document_SEQ";
232 |
233 | CREATE TABLE "department" (
234 | "id" INTEGER NOT NULL,
235 | "title" varchar2(255) not null,
236 | CONSTRAINT "department_PK" PRIMARY KEY ("id") ENABLE
237 | );
238 | CREATE SEQUENCE "department_SEQ";
239 |
240 | CREATE TABLE "employee" (
241 | "id" INTEGER NOT NULL,
242 | "department_id" INTEGER NOT NULL,
243 | "first_name" varchar2(255) not null,
244 | "last_name" varchar2(255) not null,
245 | CONSTRAINT "employee_PK" PRIMARY KEY ("id", "department_id") ENABLE
246 | );
247 | CREATE SEQUENCE "employee_SEQ";
248 |
249 | CREATE TABLE "dossier" (
250 | "id" INTEGER NOT NULL,
251 | "department_id" INTEGER NOT NULL,
252 | "employee_id" INTEGER NOT NULL,
253 | "summary" varchar2(255) not null,
254 | CONSTRAINT "dossier_PK" PRIMARY KEY ("id", "department_id") ENABLE
255 | );
256 |
257 | CREATE VIEW "animal_view" AS SELECT * FROM "animal";
258 |
259 | CREATE TABLE "bit_values" (
260 | "id" integer not null,
261 | "val" char(1) NOT NULL,
262 | CONSTRAINT "bit_values_PK" PRIMARY KEY ("id") ENABLE,
263 | CONSTRAINT "bit_values_val" CHECK ("val" IN ('1','0'))
264 | );
265 |
266 | CREATE TABLE "T_constraints_1"
267 | (
268 | "C_id" INT NOT NULL PRIMARY KEY,
269 | "C_not_null" INT NOT NULL,
270 | "C_check" VARCHAR(255) NULL CHECK ("C_check" <> ''),
271 | "C_unique" INT NOT NULL,
272 | "C_default" INT DEFAULT 0 NOT NULL,
273 | CONSTRAINT "CN_unique" UNIQUE ("C_unique")
274 | );
275 |
276 | CREATE TABLE "T_constraints_2"
277 | (
278 | "C_id_1" INT NOT NULL,
279 | "C_id_2" INT NOT NULL,
280 | "C_index_1" INT NULL,
281 | "C_index_2_1" INT NULL,
282 | "C_index_2_2" INT NULL,
283 | CONSTRAINT "CN_constraints_2_multi" UNIQUE ("C_index_2_1", "C_index_2_2"),
284 | CONSTRAINT "CN_pk" PRIMARY KEY ("C_id_1", "C_id_2")
285 | );
286 |
287 | CREATE INDEX "CN_constraints_2_single" ON "T_constraints_2" ("C_index_1");
288 |
289 | CREATE TABLE "T_constraints_3"
290 | (
291 | "C_id" INT NOT NULL,
292 | "C_fk_id_1" INT NOT NULL,
293 | "C_fk_id_2" INT NOT NULL,
294 | CONSTRAINT "CN_constraints_3" FOREIGN KEY ("C_fk_id_1", "C_fk_id_2") REFERENCES "T_constraints_2" ("C_id_1", "C_id_2") ON DELETE CASCADE
295 | );
296 |
297 | CREATE TABLE "T_constraints_4"
298 | (
299 | "C_id" INT NOT NULL PRIMARY KEY,
300 | "C_col_1" INT NULL,
301 | "C_col_2" INT NOT NULL,
302 | CONSTRAINT "CN_constraints_4" UNIQUE ("C_col_1", "C_col_2")
303 | );
304 |
305 | CREATE TABLE "T_upsert"
306 | (
307 | "id" INT NOT NULL PRIMARY KEY,
308 | "ts" INT NULL,
309 | "email" VARCHAR(128) NOT NULL UNIQUE,
310 | "recovery_email" VARCHAR(128) NULL,
311 | "address" CLOB NULL,
312 | "status" NUMBER(5,0) DEFAULT 0 NOT NULL,
313 | "orders" INT DEFAULT 0 NOT NULL,
314 | "profile_id" INT NULL,
315 | CONSTRAINT "CN_T_upsert_multi" UNIQUE ("email", "recovery_email")
316 | );
317 | CREATE SEQUENCE "T_upsert_SEQ";
318 |
319 | CREATE TABLE "T_upsert_1"
320 | (
321 | "a" INT NOT NULL PRIMARY KEY
322 | );
323 |
324 | CREATE TABLE "T_upsert_varbinary"
325 | (
326 | "id" integer not null,
327 | "blob_col" blob,
328 | CONSTRAINT "T_upsert_varbinary_PK" PRIMARY KEY ("id") ENABLE
329 | );
330 |
331 | /* TRIGGERS */
332 |
333 | CREATE TRIGGER "profile_TRG" BEFORE INSERT ON "profile" FOR EACH ROW BEGIN <> BEGIN
334 | IF INSERTING AND :NEW."id" IS NULL THEN SELECT "profile_SEQ".NEXTVAL INTO :NEW."id" FROM SYS.DUAL; END IF;
335 | END COLUMN_SEQUENCES;
336 | END;
337 | /
338 | CREATE TRIGGER "customer_TRG" BEFORE INSERT ON "customer" FOR EACH ROW BEGIN <> BEGIN
339 | IF INSERTING AND :NEW."id" IS NULL THEN SELECT "customer_SEQ".NEXTVAL INTO :NEW."id" FROM SYS.DUAL; END IF;
340 | END COLUMN_SEQUENCES;
341 | END;
342 | /
343 | CREATE TRIGGER "category_TRG" BEFORE INSERT ON "category" FOR EACH ROW BEGIN <> BEGIN
344 | IF INSERTING AND :NEW."id" IS NULL THEN SELECT "category_SEQ".NEXTVAL INTO :NEW."id" FROM SYS.DUAL; END IF;
345 | END COLUMN_SEQUENCES;
346 | END;
347 | /
348 | CREATE TRIGGER "item_TRG" BEFORE INSERT ON "item" FOR EACH ROW BEGIN <> BEGIN
349 | IF INSERTING AND :NEW."id" IS NULL THEN SELECT "item_SEQ".NEXTVAL INTO :NEW."id" FROM SYS.DUAL; END IF;
350 | END COLUMN_SEQUENCES;
351 | END;
352 | /
353 | CREATE TRIGGER "order_TRG" BEFORE INSERT ON "order" FOR EACH ROW BEGIN <> BEGIN
354 | IF INSERTING AND :NEW."id" IS NULL THEN SELECT "order_SEQ".NEXTVAL INTO :NEW."id" FROM SYS.DUAL; END IF;
355 | END COLUMN_SEQUENCES;
356 | END;
357 | /
358 | CREATE TRIGGER "order_with_null_fk_TRG" BEFORE INSERT ON "order_with_null_fk" FOR EACH ROW BEGIN <> BEGIN
359 | IF INSERTING AND :NEW."id" IS NULL THEN SELECT "order_with_null_fk_SEQ".NEXTVAL INTO :NEW."id" FROM SYS.DUAL; END IF;
360 | END COLUMN_SEQUENCES;
361 | END;
362 | /
363 | CREATE TRIGGER "null_values_TRG" BEFORE INSERT ON "null_values" FOR EACH ROW BEGIN <> BEGIN
364 | IF INSERTING AND :NEW."id" IS NULL THEN SELECT "null_values_SEQ".NEXTVAL INTO :NEW."id" FROM SYS.DUAL; END IF;
365 | END COLUMN_SEQUENCES;
366 | END;
367 | /
368 | CREATE TRIGGER "bool_values_TRG" BEFORE INSERT ON "bool_values" FOR EACH ROW BEGIN <> BEGIN
369 | IF INSERTING AND :NEW."id" IS NULL THEN SELECT "bool_values_SEQ".NEXTVAL INTO :NEW."id" FROM SYS.DUAL; END IF;
370 | END COLUMN_SEQUENCES;
371 | END;
372 | /
373 | CREATE TRIGGER "animal_TRG" BEFORE INSERT ON "animal" FOR EACH ROW BEGIN <> BEGIN
374 | IF INSERTING AND :NEW."id" IS NULL THEN SELECT "animal_SEQ".NEXTVAL INTO :NEW."id" FROM SYS.DUAL; END IF;
375 | END COLUMN_SEQUENCES;
376 | END;
377 | /
378 | CREATE TRIGGER "document_TRG" BEFORE INSERT ON "document" FOR EACH ROW BEGIN <> BEGIN
379 | IF INSERTING AND :NEW."id" IS NULL THEN SELECT "document_SEQ".NEXTVAL INTO :NEW."id" FROM SYS.DUAL; END IF;
380 | END COLUMN_SEQUENCES;
381 | END;
382 | /
383 | CREATE TRIGGER "T_upsert_TRG" BEFORE INSERT ON "T_upsert" FOR EACH ROW BEGIN <> BEGIN
384 | IF INSERTING AND :NEW."id" IS NULL THEN SELECT "T_upsert_SEQ".NEXTVAL INTO :NEW."id" FROM SYS.DUAL; END IF;
385 | END COLUMN_SEQUENCES;
386 | END;
387 | /
388 |
389 | /* TRIGGERS */
390 |
391 | INSERT INTO "animal" ("type") VALUES ('yiiunit\data\ar\Cat');
392 | INSERT INTO "animal" ("type") VALUES ('yiiunit\data\ar\Dog');
393 |
394 |
395 | INSERT INTO "profile" ("description") VALUES ('profile customer 1');
396 | INSERT INTO "profile" ("description") VALUES ('profile customer 3');
397 |
398 | INSERT INTO "customer" ("email", "name", "address", "status", "profile_id") VALUES ('user1@example.com', 'user1', 'address1', 1, 1);
399 | INSERT INTO "customer" ("email", "name", "address", "status") VALUES ('user2@example.com', 'user2', 'address2', 1);
400 | INSERT INTO "customer" ("email", "name", "address", "status", "profile_id") VALUES ('user3@example.com', 'user3', 'address3', 2, 2);
401 |
402 | INSERT INTO "category" ("name") VALUES ('Books');
403 | INSERT INTO "category" ("name") VALUES ('Movies');
404 |
405 | INSERT INTO "item" ("name", "category_id") VALUES ('Agile Web Application Development with Yii1.1 and PHP5', 1);
406 | INSERT INTO "item" ("name", "category_id") VALUES ('Yii 1.1 Application Development Cookbook', 1);
407 | INSERT INTO "item" ("name", "category_id") VALUES ('Ice Age', 2);
408 | INSERT INTO "item" ("name", "category_id") VALUES ('Toy Story', 2);
409 | INSERT INTO "item" ("name", "category_id") VALUES ('Cars', 2);
410 |
411 | INSERT INTO "order" ("customer_id", "created_at", "total") VALUES (1, 1325282384, 110.0);
412 | INSERT INTO "order" ("customer_id", "created_at", "total") VALUES (2, 1325334482, 33.0);
413 | INSERT INTO "order" ("customer_id", "created_at", "total") VALUES (2, 1325502201, 40.0);
414 |
415 | INSERT INTO "order_with_null_fk" ("customer_id", "created_at", "total") VALUES (1, 1325282384, 110.0);
416 | INSERT INTO "order_with_null_fk" ("customer_id", "created_at", "total") VALUES (2, 1325334482, 33.0);
417 | INSERT INTO "order_with_null_fk" ("customer_id", "created_at", "total") VALUES (2, 1325502201, 40.0);
418 |
419 | INSERT INTO "order_item" ("order_id", "item_id", "quantity", "subtotal") VALUES (1, 1, 1, 30.0);
420 | INSERT INTO "order_item" ("order_id", "item_id", "quantity", "subtotal") VALUES (1, 2, 2, 40.0);
421 | INSERT INTO "order_item" ("order_id", "item_id", "quantity", "subtotal") VALUES (2, 4, 1, 10.0);
422 | INSERT INTO "order_item" ("order_id", "item_id", "quantity", "subtotal") VALUES (2, 5, 1, 15.0);
423 | INSERT INTO "order_item" ("order_id", "item_id", "quantity", "subtotal") VALUES (2, 3, 1, 8.0);
424 | INSERT INTO "order_item" ("order_id", "item_id", "quantity", "subtotal") VALUES (3, 2, 1, 40.0);
425 |
426 | INSERT INTO "order_item_with_null_fk" ("order_id", "item_id", "quantity", "subtotal") VALUES (1, 1, 1, 30.0);
427 | INSERT INTO "order_item_with_null_fk" ("order_id", "item_id", "quantity", "subtotal") VALUES (1, 2, 2, 40.0);
428 | INSERT INTO "order_item_with_null_fk" ("order_id", "item_id", "quantity", "subtotal") VALUES (2, 4, 1, 10.0);
429 | INSERT INTO "order_item_with_null_fk" ("order_id", "item_id", "quantity", "subtotal") VALUES (2, 5, 1, 15.0);
430 | INSERT INTO "order_item_with_null_fk" ("order_id", "item_id", "quantity", "subtotal") VALUES (2, 3, 1, 8.0);
431 | INSERT INTO "order_item_with_null_fk" ("order_id", "item_id", "quantity", "subtotal") VALUES (3, 2, 1, 40.0);
432 |
433 | INSERT INTO "document" ("title", "content", "version") VALUES ('Yii 2.0 guide', 'This is Yii 2.0 guide', 0);
434 |
435 | INSERT INTO "department" ("id", "title") VALUES (1, 'IT');
436 | INSERT INTO "department" ("id", "title") VALUES (2, 'accounting');
437 |
438 | INSERT INTO "employee" ("id", "department_id", "first_name", "last_name") VALUES (1, 1, 'John', 'Doe');
439 | INSERT INTO "employee" ("id", "department_id", "first_name", "last_name") VALUES (1, 2, 'Ann', 'Smith');
440 | INSERT INTO "employee" ("id", "department_id", "first_name", "last_name") VALUES (2, 2, 'Will', 'Smith');
441 |
442 | INSERT INTO "dossier" ("id", "department_id", "employee_id", "summary") VALUES (1, 1, 1, 'Excellent employee.');
443 | INSERT INTO "dossier" ("id", "department_id", "employee_id", "summary") VALUES (2, 2, 1, 'Brilliant employee.');
444 | INSERT INTO "dossier" ("id", "department_id", "employee_id", "summary") VALUES (3, 2, 2, 'Good employee.');
445 |
446 | INSERT INTO "bit_values" ("id", "val")
447 | SELECT 1, '0' FROM SYS.DUAL
448 | UNION ALL SELECT 2, '1' FROM SYS.DUAL;
449 |
--------------------------------------------------------------------------------
/src/Schema.php:
--------------------------------------------------------------------------------
1 |
62 | */
63 | final class Schema extends AbstractPdoSchema
64 | {
65 | public function __construct(protected ConnectionInterface $db, SchemaCache $schemaCache, string $defaultSchema)
66 | {
67 | $this->defaultSchema = $defaultSchema;
68 | parent::__construct($db, $schemaCache);
69 | }
70 |
71 | protected function findConstraints(TableSchemaInterface $table): void
72 | {
73 | $tableName = $this->resolveFullName($table->getName(), $table->getSchemaName());
74 |
75 | $table->checks(...$this->getTableMetadata($tableName, SchemaInterface::CHECKS));
76 | $table->foreignKeys(...$this->getTableMetadata($tableName, SchemaInterface::FOREIGN_KEYS));
77 | $table->indexes(...$this->getTableMetadata($tableName, SchemaInterface::INDEXES));
78 | }
79 |
80 | /**
81 | * @link https://docs.oracle.com/cd/B28359_01/server.111/b28337/tdpsg_user_accounts.htm
82 | */
83 | protected function findSchemaNames(): array
84 | {
85 | $sql = <<db->createCommand($sql)->queryColumn();
94 | }
95 |
96 | protected function findTableComment(TableSchemaInterface $tableSchema): void
97 | {
98 | $sql = <<db->createCommand($sql, [
107 | ':schemaName' => $tableSchema->getSchemaName() ?: $this->defaultSchema,
108 | ':tableName' => $tableSchema->getName(),
109 | ])->queryScalar();
110 |
111 | $tableSchema->comment(is_string($comment) ? $comment : null);
112 | }
113 |
114 | protected function findTableNames(string $schema = ''): array
115 | {
116 | if ($schema === '') {
117 | $sql = <<db->createCommand($sql);
130 | } else {
131 | $sql = <<db->createCommand($sql, [':schema' => $schema]);
138 | }
139 |
140 | /** @var string[] */
141 | return $command->queryColumn();
142 | }
143 |
144 | /**
145 | * @param array{
146 | * "oci:decl_type": int|string,
147 | * native_type: string,
148 | * pdo_type: int,
149 | * scale: int,
150 | * table?: string,
151 | * flags: string[],
152 | * name: string,
153 | * len: int,
154 | * precision: int,
155 | * } $metadata
156 | *
157 | * @psalm-suppress MoreSpecificImplementedParamType
158 | */
159 | protected function loadResultColumn(array $metadata): ?ColumnInterface
160 | {
161 | if (empty($metadata['oci:decl_type'])) {
162 | return null;
163 | }
164 |
165 | $dbType = match ($metadata['oci:decl_type']) {
166 | 119 => 'json',
167 | 'TIMESTAMP WITH TIMEZONE' => 'timestamp with time zone',
168 | 'TIMESTAMP WITH LOCAL TIMEZONE' => 'timestamp with local time zone',
169 | default => strtolower((string) $metadata['oci:decl_type']),
170 | };
171 |
172 | $columnInfo = ['source' => ColumnInfoSource::QUERY_RESULT];
173 |
174 | if (!empty($metadata['table'])) {
175 | $columnInfo['table'] = $metadata['table'];
176 | $columnInfo['name'] = $metadata['name'];
177 | } elseif (!empty($metadata['name'])) {
178 | $columnInfo['name'] = $metadata['name'];
179 | }
180 |
181 | if ($metadata['pdo_type'] === 3) {
182 | $columnInfo['type'] = ColumnType::BINARY;
183 | }
184 |
185 | if (!empty($metadata['precision'])) {
186 | $columnInfo['size'] = $metadata['precision'];
187 | }
188 |
189 | /** @psalm-suppress PossiblyUndefinedArrayOffset, InvalidArrayOffset */
190 | match ($dbType) {
191 | 'timestamp',
192 | 'timestamp with time zone',
193 | 'timestamp with local time zone' => $columnInfo['size'] = $metadata['scale'],
194 | 'interval day to second',
195 | 'interval year to month'
196 | => [$columnInfo['size'], $columnInfo['scale']] = [$metadata['scale'], $metadata['precision']],
197 | 'number' => $metadata['scale'] !== -127 ? $columnInfo['scale'] = $metadata['scale'] : null,
198 | 'float' => null,
199 | default => $columnInfo['size'] = $metadata['len'],
200 | };
201 |
202 | if ($dbType === 'timestamp with local time zone') {
203 | $columnInfo['dbTimezone'] = $this->db->getServerInfo()->getTimezone();
204 | }
205 |
206 | $columnInfo['notNull'] = in_array('not_null', $metadata['flags'], true);
207 |
208 | /** @psalm-suppress MixedArgumentTypeCoercion */
209 | return $this->db->getColumnFactory()->fromDbType($dbType, $columnInfo);
210 | }
211 |
212 | protected function loadTableSchema(string $name): ?TableSchemaInterface
213 | {
214 | $table = new TableSchema(...$this->db->getQuoter()->getTableNameParts($name));
215 |
216 | if ($this->findColumns($table)) {
217 | $this->findTableComment($table);
218 | $this->findConstraints($table);
219 | $table->sequenceName($this->getTableSequenceName($table->getName()));
220 |
221 | return $table;
222 | }
223 |
224 | return null;
225 | }
226 |
227 | protected function loadTableForeignKeys(string $tableName): array
228 | {
229 | /** @var ForeignKey[] */
230 | return $this->loadTableConstraints($tableName, self::FOREIGN_KEYS);
231 | }
232 |
233 | protected function loadTableIndexes(string $tableName): array
234 | {
235 | $sql = <<db->getQuoter()->getTableNameParts($tableName);
249 | $indexes = $this->db->createCommand($sql, [
250 | ':schemaName' => $nameParts['schemaName'] ?? $this->defaultSchema,
251 | ':tableName' => $nameParts['name'],
252 | ])->queryAll();
253 |
254 | /** @psalm-var list> $indexes */
255 | $indexes = array_map(array_change_key_case(...), $indexes);
256 | $indexes = DbArrayHelper::arrange($indexes, ['name']);
257 |
258 | $result = [];
259 |
260 | /**
261 | * @var string $name
262 | * @var array[] $index
263 | */
264 | foreach ($indexes as $name => $index) {
265 | $columnNames = array_column($index, 'column_name');
266 |
267 | if ($columnNames === [null]) {
268 | $columnNames = [];
269 | }
270 |
271 | /** @var list $columnNames */
272 | $result[$name] = new Index(
273 | $name,
274 | $columnNames,
275 | (bool) $index[0]['is_unique'],
276 | (bool) $index[0]['is_primary_key'],
277 | );
278 | }
279 |
280 | return $result;
281 | }
282 |
283 | protected function loadTableChecks(string $tableName): array
284 | {
285 | /** @var Check[] */
286 | return $this->loadTableConstraints($tableName, self::CHECKS);
287 | }
288 |
289 | /**
290 | * @throws NotSupportedException If this method is called.
291 | */
292 | protected function loadTableDefaultValues(string $tableName): array
293 | {
294 | throw new NotSupportedException(__METHOD__ . ' is not supported by Oracle.');
295 | }
296 |
297 | /**
298 | * Collects the table column metadata.
299 | *
300 | * @param TableSchemaInterface $table The table schema.
301 | *
302 | * @return bool Whether the table exists.
303 | */
304 | protected function findColumns(TableSchemaInterface $table): bool
305 | {
306 | $schemaName = $table->getSchemaName() ?: $this->defaultSchema;
307 | $tableName = $table->getName();
308 |
309 | $sql = << 0 THEN A.CHAR_LENGTH ELSE A.DATA_PRECISION END) AS "size",
334 | A.NULLABLE,
335 | A.DATA_DEFAULT,
336 | A.COLLATION,
337 | C.CONSTRAINT_TYPE,
338 | C2.SEARCH_CONDITION AS "check",
339 | COM.COMMENTS AS COLUMN_COMMENT
340 | FROM ALL_TAB_COLUMNS A
341 | INNER JOIN ALL_OBJECTS B
342 | ON B.OWNER = A.OWNER
343 | AND B.OBJECT_NAME = A.TABLE_NAME
344 | LEFT JOIN ALL_COL_COMMENTS COM
345 | ON COM.OWNER = A.OWNER
346 | AND COM.TABLE_NAME = A.TABLE_NAME
347 | AND COM.COLUMN_NAME = A.COLUMN_NAME
348 | LEFT JOIN C
349 | ON C.COLUMN_NAME = A.COLUMN_NAME
350 | AND C.CONSTRAINT_TYPE IN ('P', 'U')
351 | LEFT JOIN C C2
352 | ON C2.COLUMN_NAME = A.COLUMN_NAME
353 | AND C2.CONSTRAINT_TYPE = 'C'
354 | WHERE A.OWNER = :schemaName
355 | AND A.TABLE_NAME = :tableName
356 | AND B.OBJECT_TYPE IN ('TABLE', 'VIEW', 'MATERIALIZED VIEW')
357 | ORDER BY A.COLUMN_ID
358 | SQL;
359 |
360 | $columns = $this->db->createCommand($sql, [
361 | ':schemaName' => $schemaName,
362 | ':schemaName2' => $schemaName,
363 | ':tableName' => $tableName,
364 | ':tableName2' => $tableName,
365 | ])->queryAll();
366 |
367 | if ($columns === []) {
368 | return false;
369 | }
370 |
371 | /** @psalm-var string[][] $info */
372 | foreach ($columns as $info) {
373 | $info = array_change_key_case($info);
374 |
375 | $info['schema'] = $schemaName;
376 | $info['table'] = $tableName;
377 |
378 | /** @psalm-var ColumnArray $info */
379 | $column = $this->loadColumn($info);
380 |
381 | $table->column($info['column_name'], $column);
382 | }
383 |
384 | return true;
385 | }
386 |
387 | /**
388 | * Sequence name of table.
389 | *
390 | * @return string|null Whether the sequence exists.
391 | *
392 | * @internal TableSchemaInterface `$table->getName()` The table schema.
393 | */
394 | protected function getTableSequenceName(string $tableName): ?string
395 | {
396 | $sequenceNameSql = <<db->createCommand($sequenceNameSql, [':tableName' => $tableName])->queryScalar();
407 |
408 | /** @var string|null */
409 | return $sequenceName === false ? null : $sequenceName;
410 | }
411 |
412 | protected function findViewNames(string $schema = ''): array
413 | {
414 | $sql = match ($schema) {
415 | '' => 'SELECT VIEW_NAME FROM USER_VIEWS',
416 | default => "SELECT VIEW_NAME FROM ALL_VIEWS WHERE OWNER = '$schema'",
417 | };
418 |
419 | /** @var string[] */
420 | return $this->db->createCommand($sql)->queryColumn();
421 | }
422 |
423 | /**
424 | * Loads the column information into a {@see ColumnInterface} object.
425 | *
426 | * @param array $info The column information.
427 | *
428 | * @return ColumnInterface The column object.
429 | *
430 | * @psalm-param ColumnArray $info The column information.
431 | */
432 | private function loadColumn(array $info): ColumnInterface
433 | {
434 | /** @var string $dbType */
435 | $dbType = preg_replace('/\([^)]+\)/', '', $info['data_type']);
436 | $dbType = strtolower($dbType);
437 |
438 | match ($dbType) {
439 | 'timestamp',
440 | 'timestamp with time zone',
441 | 'timestamp with local time zone',
442 | 'interval day to second',
443 | 'interval year to month' => [$info['size'], $info['data_scale']] = [$info['data_scale'], $info['size']],
444 | default => null,
445 | };
446 |
447 | $columnInfo = [
448 | 'autoIncrement' => $info['identity_column'] === 'YES',
449 | 'check' => $info['check'],
450 | 'collation' => $info['collation'],
451 | 'comment' => $info['column_comment'],
452 | 'defaultValueRaw' => $info['data_default'],
453 | 'name' => $info['column_name'],
454 | 'notNull' => $info['nullable'] !== 'Y',
455 | 'primaryKey' => $info['constraint_type'] === 'P',
456 | 'scale' => $info['data_scale'] !== null ? (int) $info['data_scale'] : null,
457 | 'schema' => $info['schema'],
458 | 'size' => $info['size'] !== null ? (int) $info['size'] : null,
459 | 'source' => ColumnInfoSource::TABLE_SCHEMA,
460 | 'table' => $info['table'],
461 | 'unique' => $info['constraint_type'] === 'U',
462 | 'values' => $this->tryGetEnumValuesFromCheck($info['column_name'], $info['check']),
463 | ];
464 |
465 | if ($dbType === 'timestamp with local time zone') {
466 | $columnInfo['dbTimezone'] = $this->db->getServerInfo()->getTimezone();
467 | }
468 |
469 | return $this->db->getColumnFactory()->fromDbType($dbType, $columnInfo);
470 | }
471 |
472 | /**
473 | * Loads multiple types of constraints and returns the specified ones.
474 | *
475 | * @param string $tableName The table name.
476 | * @param string $returnType The return type:
477 | * - foreignKeys
478 | * - checks
479 | *
480 | * @return Check[]|ForeignKey[] Constraints.
481 | */
482 | private function loadTableConstraints(string $tableName, string $returnType): array
483 | {
484 | $sql = <<db->getQuoter()->getTableNameParts($tableName);
506 | $constraints = $this->db->createCommand($sql, [
507 | ':schemaName' => $nameParts['schemaName'] ?? $this->defaultSchema,
508 | ':tableName' => $nameParts['name'],
509 | ])->queryAll();
510 |
511 | /** @psalm-var list> $constraints */
512 | $constraints = array_map(array_change_key_case(...), $constraints);
513 | $constraints = DbArrayHelper::arrange($constraints, ['type', 'name']);
514 |
515 | $result = [
516 | self::FOREIGN_KEYS => [],
517 | self::CHECKS => [],
518 | ];
519 |
520 | foreach ($constraints as $type => $names) {
521 | /**
522 | * @var string $name
523 | * @psalm-var ConstraintArray $constraint
524 | */
525 | foreach ($names as $name => $constraint) {
526 | match ($type) {
527 | 'R' => $result[self::FOREIGN_KEYS][$name] = new ForeignKey(
528 | $name,
529 | array_column($constraint, 'column_name'),
530 | $constraint[0]['foreign_table_schema'],
531 | $constraint[0]['foreign_table_name'],
532 | array_column($constraint, 'foreign_column_name'),
533 | $constraint[0]['on_delete'],
534 | ),
535 | 'C' => $result[self::CHECKS][$name] = new Check(
536 | $name,
537 | array_column($constraint, 'column_name'),
538 | $constraint[0]['check_expr'],
539 | ),
540 | };
541 | }
542 | }
543 |
544 | foreach ($result as $type => $data) {
545 | $this->setTableMetadata($tableName, $type, $data);
546 | }
547 |
548 | return $result[$returnType];
549 | }
550 |
551 | /**
552 | * @psalm-return list|null
553 | */
554 | private function tryGetEnumValuesFromCheck(string $columnName, ?string $check): ?array
555 | {
556 | if ($check === null) {
557 | return null;
558 | }
559 |
560 | $quotedColumnName = preg_quote($columnName, '~');
561 | if (!preg_match(
562 | "~^\s*(?:\"$quotedColumnName\"|$quotedColumnName)\s+IN\s*\(\s*(('(?:''|[^'])*')(?:,\s*(?2))*)\s*\)\s*$~i",
563 | $check,
564 | $block,
565 | )) {
566 | return null;
567 | }
568 |
569 | preg_match_all("~'((?:''|[^'])*)'~", $block[1], $matches);
570 |
571 | return array_map(
572 | static fn($v) => str_replace("''", "'", $v),
573 | $matches[1],
574 | );
575 | }
576 | }
577 |
--------------------------------------------------------------------------------