* @since 2.0 */ class QueryBuilder extends \yii\db\QueryBuilder { /** * @var array mapping from abstract column types (keys) to physical column types (values). */ public $typeMap = [ Schema::TYPE_PK => 'NUMBER(10) NOT NULL PRIMARY KEY', Schema::TYPE_UPK => 'NUMBER(10) UNSIGNED NOT NULL PRIMARY KEY', Schema::TYPE_BIGPK => 'NUMBER(20) NOT NULL PRIMARY KEY', Schema::TYPE_UBIGPK => 'NUMBER(20) UNSIGNED NOT NULL PRIMARY KEY', Schema::TYPE_CHAR => 'CHAR(1)', Schema::TYPE_STRING => 'VARCHAR2(255)', Schema::TYPE_TEXT => 'CLOB', Schema::TYPE_SMALLINT => 'NUMBER(5)', Schema::TYPE_INTEGER => 'NUMBER(10)', Schema::TYPE_BIGINT => 'NUMBER(20)', Schema::TYPE_FLOAT => 'NUMBER', Schema::TYPE_DOUBLE => 'NUMBER', Schema::TYPE_DECIMAL => 'NUMBER', Schema::TYPE_DATETIME => 'TIMESTAMP', Schema::TYPE_TIMESTAMP => 'TIMESTAMP', Schema::TYPE_TIME => 'TIMESTAMP', Schema::TYPE_DATE => 'DATE', Schema::TYPE_BINARY => 'BLOB', Schema::TYPE_BOOLEAN => 'NUMBER(1)', Schema::TYPE_MONEY => 'NUMBER(19,4)', ]; /** * {@inheritdoc} */ protected $likeEscapeCharacter = '!'; /** * `\` is initialized in [[buildLikeCondition()]] method since * we need to choose replacement value based on [[\yii\db\Schema::quoteValue()]]. * {@inheritdoc} */ protected $likeEscapingReplacements = [ '%' => '!%', '_' => '!_', '!' => '!!', ]; /** * {@inheritdoc} */ public function buildOrderByAndLimit($sql, $orderBy, $limit, $offset) { $orderBy = $this->buildOrderBy($orderBy); if ($orderBy !== '') { $sql .= $this->separator . $orderBy; } $filters = []; if ($this->hasOffset($offset)) { $filters[] = 'rowNumId > ' . $offset; } if ($this->hasLimit($limit)) { $filters[] = 'rownum <= ' . $limit; } if (empty($filters)) { return $sql; } $filter = implode(' AND ', $filters); return <<db->quoteTableName($table) . ' RENAME TO ' . $this->db->quoteTableName($newName); } /** * Builds a SQL statement for changing the definition of a column. * * @param string $table the table whose column is to be changed. The table name will be properly quoted by the method. * @param string $column the name of the column to be changed. The name will be properly quoted by the method. * @param string $type the new column type. The [[getColumnType]] method will be invoked to convert abstract column type (if any) * into the physical one. Anything that is not recognized as abstract type will be kept in the generated SQL. * For example, 'string' will be turned into 'varchar(255)', while 'string not null' will become 'varchar(255) not null'. * @return string the SQL statement for changing the definition of a column. */ public function alterColumn($table, $column, $type) { $type = $this->getColumnType($type); return 'ALTER TABLE ' . $this->db->quoteTableName($table) . ' MODIFY ' . $this->db->quoteColumnName($column) . ' ' . $this->getColumnType($type); } /** * Builds a SQL statement for dropping an index. * * @param string $name the name of the index to be dropped. The name will be properly quoted by the method. * @param string $table the table whose index is to be dropped. The name will be properly quoted by the method. * @return string the SQL statement for dropping an index. */ public function dropIndex($name, $table) { return 'DROP INDEX ' . $this->db->quoteTableName($name); } /** * {@inheritdoc} */ public function resetSequence($table, $value = null) { $tableSchema = $this->db->getTableSchema($table); if ($tableSchema === null) { throw new InvalidParamException("Unknown table: $table"); } if ($tableSchema->sequenceName === null) { return ''; } if ($value !== null) { $value = (int) $value; } else { // use master connection to get the biggest PK value $value = $this->db->useMaster(function (Connection $db) use ($tableSchema) { return $db->createCommand("SELECT MAX(\"{$tableSchema->primaryKey}\") FROM \"{$tableSchema->name}\"")->queryScalar(); }) + 1; } return "DROP SEQUENCE \"{$tableSchema->name}_SEQ\";" . "CREATE SEQUENCE \"{$tableSchema->name}_SEQ\" START WITH {$value} INCREMENT BY 1 NOMAXVALUE NOCACHE"; } /** * {@inheritdoc} */ public function addForeignKey($name, $table, $columns, $refTable, $refColumns, $delete = null, $update = null) { $sql = 'ALTER TABLE ' . $this->db->quoteTableName($table) . ' ADD CONSTRAINT ' . $this->db->quoteColumnName($name) . ' FOREIGN KEY (' . $this->buildColumns($columns) . ')' . ' REFERENCES ' . $this->db->quoteTableName($refTable) . ' (' . $this->buildColumns($refColumns) . ')'; if ($delete !== null) { $sql .= ' ON DELETE ' . $delete; } if ($update !== null) { throw new Exception('Oracle does not support ON UPDATE clause.'); } return $sql; } /** * {@inheritdoc} */ public function insert($table, $columns, &$params) { $schema = $this->db->getSchema(); if (($tableSchema = $schema->getTableSchema($table)) !== null) { $columnSchemas = $tableSchema->columns; } else { $columnSchemas = []; } $names = []; $placeholders = []; $values = ' DEFAULT VALUES'; if ($columns instanceof \yii\db\Query) { list($names, $values, $params) = $this->prepareInsertSelectSubQuery($columns, $schema, $params); } else { foreach ($columns as $name => $value) { $names[] = $schema->quoteColumnName($name); if ($value instanceof Expression) { $placeholders[] = $value->expression; foreach ($value->params as $n => $v) { $params[$n] = $v; } } elseif ($value instanceof \yii\db\Query) { list($sql, $params) = $this->build($value, $params); $placeholders[] = "($sql)"; } else { $phName = self::PARAM_PREFIX . count($params); $placeholders[] = $phName; $params[$phName] = !is_array($value) && isset($columnSchemas[$name]) ? $columnSchemas[$name]->dbTypecast($value) : $value; } } if (empty($names) && $tableSchema !== null) { $columns = !empty($tableSchema->primaryKey) ? $tableSchema->primaryKey : [reset($tableSchema->columns)->name]; foreach ($columns as $name) { $names[] = $schema->quoteColumnName($name); $placeholders[] = 'DEFAULT'; } } } return 'INSERT INTO ' . $schema->quoteTableName($table) . (!empty($names) ? ' (' . implode(', ', $names) . ')' : '') . (!empty($placeholders) ? ' VALUES (' . implode(', ', $placeholders) . ')' : $values); } /** * Generates a batch INSERT SQL statement. * * For example, * * ```php * $sql = $queryBuilder->batchInsert('user', ['name', 'age'], [ * ['Tom', 30], * ['Jane', 20], * ['Linda', 25], * ]); * ``` * * Note that the values in each row must match the corresponding column names. * * @param string $table the table that new rows will be inserted into. * @param array $columns the column names * @param array|\Generator $rows the rows to be batch inserted into the table * @return string the batch INSERT SQL statement */ public function batchInsert($table, $columns, $rows) { if (empty($rows)) { return ''; } $schema = $this->db->getSchema(); if (($tableSchema = $schema->getTableSchema($table)) !== null) { $columnSchemas = $tableSchema->columns; } else { $columnSchemas = []; } $values = []; foreach ($rows as $row) { $vs = []; foreach ($row as $i => $value) { if (isset($columns[$i], $columnSchemas[$columns[$i]]) && !is_array($value)) { $value = $columnSchemas[$columns[$i]]->dbTypecast($value); } if (is_string($value)) { $value = $schema->quoteValue($value); } elseif (is_float($value)) { // ensure type cast always has . as decimal separator in all locales $value = StringHelper::floatToString($value); } elseif ($value === false) { $value = 0; } elseif ($value === null) { $value = 'NULL'; } $vs[] = $value; } $values[] = '(' . implode(', ', $vs) . ')'; } if (empty($values)) { return ''; } foreach ($columns as $i => $name) { $columns[$i] = $schema->quoteColumnName($name); } $tableAndColumns = ' INTO ' . $schema->quoteTableName($table) . ' (' . implode(', ', $columns) . ') VALUES '; return 'INSERT ALL ' . $tableAndColumns . implode($tableAndColumns, $values) . ' SELECT 1 FROM SYS.DUAL'; } /** * {@inheritdoc} * @since 2.0.8 */ public function selectExists($rawSql) { return 'SELECT CASE WHEN EXISTS(' . $rawSql . ') THEN 1 ELSE 0 END FROM DUAL'; } /** * {@inheritdoc} * @since 2.0.8 */ public function dropCommentFromColumn($table, $column) { return 'COMMENT ON COLUMN ' . $this->db->quoteTableName($table) . '.' . $this->db->quoteColumnName($column) . " IS ''"; } /** * {@inheritdoc} * @since 2.0.8 */ public function dropCommentFromTable($table) { return 'COMMENT ON TABLE ' . $this->db->quoteTableName($table) . " IS ''"; } /** * @inheritDoc */ public function buildLikeCondition($operator, $operands, &$params) { if (!isset($this->likeEscapingReplacements['\\'])) { /* * Different pdo_oci8 versions may or may not implement PDO::quote(), so * yii\db\Schema::quoteValue() may or may not quote \. */ $this->likeEscapingReplacements['\\'] = substr($this->db->quoteValue('\\'), 1, -1); } return parent::buildLikeCondition($operator, $operands, $params); } /** * {@inheritdoc} */ public function buildInCondition($operator, $operands, &$params) { $splitCondition = $this->splitInCondition($operator, $operands, $params); if ($splitCondition !== null) { return $splitCondition; } return parent::buildInCondition($operator, $operands, $params); } /** * Oracle DBMS does not support more than 1000 parameters in `IN` condition. * This method splits long `IN` condition into series of smaller ones. * * @param string $operator * @param array $operands * @param array $params * @return null|string null when split is not required. Otherwise - built SQL condition. * @throws Exception * @since 2.0.12 */ protected function splitInCondition($operator, $operands, &$params) { if (!isset($operands[0], $operands[1])) { throw new Exception("Operator '$operator' requires two operands."); } list($column, $values) = $operands; if ($values instanceof \Traversable) { $values = iterator_to_array($values); } if (!is_array($values)) { return null; } $maxParameters = 1000; $count = count($values); if ($count <= $maxParameters) { return null; } $condition = [($operator === 'IN') ? 'OR' : 'AND']; for ($i = 0; $i < $count; $i += $maxParameters) { $condition[] = [$operator, $column, array_slice($values, $i, $maxParameters)]; } return $this->buildCondition(['AND', $condition], $params); } }