選択できるのは25トピックまでです。 トピックは、先頭が英数字で、英数字とダッシュ('-')を使用した35文字以内のものにしてください。

295 行
10KB

  1. <?php
  2. /**
  3. * @link http://www.yiiframework.com/
  4. * @copyright Copyright (c) 2008 Yii Software LLC
  5. * @license http://www.yiiframework.com/license/
  6. */
  7. namespace yii\db\oci;
  8. use yii\base\InvalidParamException;
  9. use yii\db\Connection;
  10. use yii\db\Exception;
  11. use yii\db\Expression;
  12. /**
  13. * QueryBuilder is the query builder for Oracle databases.
  14. *
  15. * @author Qiang Xue <qiang.xue@gmail.com>
  16. * @since 2.0
  17. */
  18. class QueryBuilder extends \yii\db\QueryBuilder
  19. {
  20. /**
  21. * @var array mapping from abstract column types (keys) to physical column types (values).
  22. */
  23. public $typeMap = [
  24. Schema::TYPE_PK => 'NUMBER(10) NOT NULL PRIMARY KEY',
  25. Schema::TYPE_UPK => 'NUMBER(10) UNSIGNED NOT NULL PRIMARY KEY',
  26. Schema::TYPE_BIGPK => 'NUMBER(20) NOT NULL PRIMARY KEY',
  27. Schema::TYPE_UBIGPK => 'NUMBER(20) UNSIGNED NOT NULL PRIMARY KEY',
  28. Schema::TYPE_CHAR => 'CHAR(1)',
  29. Schema::TYPE_STRING => 'VARCHAR2(255)',
  30. Schema::TYPE_TEXT => 'CLOB',
  31. Schema::TYPE_SMALLINT => 'NUMBER(5)',
  32. Schema::TYPE_INTEGER => 'NUMBER(10)',
  33. Schema::TYPE_BIGINT => 'NUMBER(20)',
  34. Schema::TYPE_FLOAT => 'NUMBER',
  35. Schema::TYPE_DOUBLE => 'NUMBER',
  36. Schema::TYPE_DECIMAL => 'NUMBER',
  37. Schema::TYPE_DATETIME => 'TIMESTAMP',
  38. Schema::TYPE_TIMESTAMP => 'TIMESTAMP',
  39. Schema::TYPE_TIME => 'TIMESTAMP',
  40. Schema::TYPE_DATE => 'DATE',
  41. Schema::TYPE_BINARY => 'BLOB',
  42. Schema::TYPE_BOOLEAN => 'NUMBER(1)',
  43. Schema::TYPE_MONEY => 'NUMBER(19,4)',
  44. ];
  45. /**
  46. * @inheritdoc
  47. */
  48. public function buildOrderByAndLimit($sql, $orderBy, $limit, $offset)
  49. {
  50. $orderBy = $this->buildOrderBy($orderBy);
  51. if ($orderBy !== '') {
  52. $sql .= $this->separator . $orderBy;
  53. }
  54. $filters = [];
  55. if ($this->hasOffset($offset)) {
  56. $filters[] = 'rowNumId > ' . $offset;
  57. }
  58. if ($this->hasLimit($limit)) {
  59. $filters[] = 'rownum <= ' . $limit;
  60. }
  61. if (empty($filters)) {
  62. return $sql;
  63. }
  64. $filter = implode(' AND ', $filters);
  65. return <<<EOD
  66. WITH USER_SQL AS ($sql),
  67. PAGINATION AS (SELECT USER_SQL.*, rownum as rowNumId FROM USER_SQL)
  68. SELECT *
  69. FROM PAGINATION
  70. WHERE $filter
  71. EOD;
  72. }
  73. /**
  74. * Builds a SQL statement for renaming a DB table.
  75. *
  76. * @param string $table the table to be renamed. The name will be properly quoted by the method.
  77. * @param string $newName the new table name. The name will be properly quoted by the method.
  78. * @return string the SQL statement for renaming a DB table.
  79. */
  80. public function renameTable($table, $newName)
  81. {
  82. return 'ALTER TABLE ' . $this->db->quoteTableName($table) . ' RENAME TO ' . $this->db->quoteTableName($newName);
  83. }
  84. /**
  85. * Builds a SQL statement for changing the definition of a column.
  86. *
  87. * @param string $table the table whose column is to be changed. The table name will be properly quoted by the method.
  88. * @param string $column the name of the column to be changed. The name will be properly quoted by the method.
  89. * @param string $type the new column type. The [[getColumnType]] method will be invoked to convert abstract column type (if any)
  90. * into the physical one. Anything that is not recognized as abstract type will be kept in the generated SQL.
  91. * For example, 'string' will be turned into 'varchar(255)', while 'string not null' will become 'varchar(255) not null'.
  92. * @return string the SQL statement for changing the definition of a column.
  93. */
  94. public function alterColumn($table, $column, $type)
  95. {
  96. $type = $this->getColumnType($type);
  97. return 'ALTER TABLE ' . $this->db->quoteTableName($table) . ' MODIFY ' . $this->db->quoteColumnName($column) . ' ' . $this->getColumnType($type);
  98. }
  99. /**
  100. * Builds a SQL statement for dropping an index.
  101. *
  102. * @param string $name the name of the index to be dropped. The name will be properly quoted by the method.
  103. * @param string $table the table whose index is to be dropped. The name will be properly quoted by the method.
  104. * @return string the SQL statement for dropping an index.
  105. */
  106. public function dropIndex($name, $table)
  107. {
  108. return 'DROP INDEX ' . $this->db->quoteTableName($name);
  109. }
  110. /**
  111. * @inheritdoc
  112. */
  113. public function resetSequence($table, $value = null)
  114. {
  115. $tableSchema = $this->db->getTableSchema($table);
  116. if ($tableSchema === null) {
  117. throw new InvalidParamException("Unknown table: $table");
  118. }
  119. if ($tableSchema->sequenceName === null) {
  120. return '';
  121. }
  122. if ($value !== null) {
  123. $value = (int) $value;
  124. } else {
  125. // use master connection to get the biggest PK value
  126. $value = $this->db->useMaster(function (Connection $db) use ($tableSchema) {
  127. return $db->createCommand("SELECT MAX(\"{$tableSchema->primaryKey}\") FROM \"{$tableSchema->name}\"")->queryScalar();
  128. }) + 1;
  129. }
  130. return "DROP SEQUENCE \"{$tableSchema->name}_SEQ\";"
  131. . "CREATE SEQUENCE \"{$tableSchema->name}_SEQ\" START WITH {$value} INCREMENT BY 1 NOMAXVALUE NOCACHE";
  132. }
  133. /**
  134. * @inheritdoc
  135. */
  136. public function addForeignKey($name, $table, $columns, $refTable, $refColumns, $delete = null, $update = null)
  137. {
  138. $sql = 'ALTER TABLE ' . $this->db->quoteTableName($table)
  139. . ' ADD CONSTRAINT ' . $this->db->quoteColumnName($name)
  140. . ' FOREIGN KEY (' . $this->buildColumns($columns) . ')'
  141. . ' REFERENCES ' . $this->db->quoteTableName($refTable)
  142. . ' (' . $this->buildColumns($refColumns) . ')';
  143. if ($delete !== null) {
  144. $sql .= ' ON DELETE ' . $delete;
  145. }
  146. if ($update !== null) {
  147. throw new Exception('Oracle does not support ON UPDATE clause.');
  148. }
  149. return $sql;
  150. }
  151. /**
  152. * @inheritdoc
  153. */
  154. public function insert($table, $columns, &$params)
  155. {
  156. $schema = $this->db->getSchema();
  157. if (($tableSchema = $schema->getTableSchema($table)) !== null) {
  158. $columnSchemas = $tableSchema->columns;
  159. } else {
  160. $columnSchemas = [];
  161. }
  162. $names = [];
  163. $placeholders = [];
  164. foreach ($columns as $name => $value) {
  165. $names[] = $schema->quoteColumnName($name);
  166. if ($value instanceof Expression) {
  167. $placeholders[] = $value->expression;
  168. foreach ($value->params as $n => $v) {
  169. $params[$n] = $v;
  170. }
  171. } else {
  172. $phName = self::PARAM_PREFIX . count($params);
  173. $placeholders[] = $phName;
  174. $params[$phName] = !is_array($value) && isset($columnSchemas[$name]) ? $columnSchemas[$name]->dbTypecast($value) : $value;
  175. }
  176. }
  177. if (empty($names) && $tableSchema !== null) {
  178. $columns = !empty($tableSchema->primaryKey) ? $tableSchema->primaryKey : reset($tableSchema->columns)->name;
  179. foreach ($columns as $name) {
  180. $names[] = $schema->quoteColumnName($name);
  181. $placeholders[] = 'DEFAULT';
  182. }
  183. }
  184. return 'INSERT INTO ' . $schema->quoteTableName($table)
  185. . (!empty($names) ? ' (' . implode(', ', $names) . ')' : '')
  186. . (!empty($placeholders) ? ' VALUES (' . implode(', ', $placeholders) . ')' : ' DEFAULT VALUES');
  187. }
  188. /**
  189. * Generates a batch INSERT SQL statement.
  190. * For example,
  191. *
  192. * ```php
  193. * $sql = $queryBuilder->batchInsert('user', ['name', 'age'], [
  194. * ['Tom', 30],
  195. * ['Jane', 20],
  196. * ['Linda', 25],
  197. * ]);
  198. * ```
  199. *
  200. * Note that the values in each row must match the corresponding column names.
  201. *
  202. * @param string $table the table that new rows will be inserted into.
  203. * @param array $columns the column names
  204. * @param array $rows the rows to be batch inserted into the table
  205. * @return string the batch INSERT SQL statement
  206. */
  207. public function batchInsert($table, $columns, $rows)
  208. {
  209. if (empty($rows)) {
  210. return '';
  211. }
  212. $schema = $this->db->getSchema();
  213. if (($tableSchema = $schema->getTableSchema($table)) !== null) {
  214. $columnSchemas = $tableSchema->columns;
  215. } else {
  216. $columnSchemas = [];
  217. }
  218. $values = [];
  219. foreach ($rows as $row) {
  220. $vs = [];
  221. foreach ($row as $i => $value) {
  222. if (isset($columns[$i], $columnSchemas[$columns[$i]]) && !is_array($value)) {
  223. $value = $columnSchemas[$columns[$i]]->dbTypecast($value);
  224. }
  225. if (is_string($value)) {
  226. $value = $schema->quoteValue($value);
  227. } elseif ($value === false) {
  228. $value = 0;
  229. } elseif ($value === null) {
  230. $value = 'NULL';
  231. }
  232. $vs[] = $value;
  233. }
  234. $values[] = '(' . implode(', ', $vs) . ')';
  235. }
  236. foreach ($columns as $i => $name) {
  237. $columns[$i] = $schema->quoteColumnName($name);
  238. }
  239. $tableAndColumns = ' INTO ' . $schema->quoteTableName($table)
  240. . ' (' . implode(', ', $columns) . ') VALUES ';
  241. return 'INSERT ALL ' . $tableAndColumns . implode($tableAndColumns, $values) . ' SELECT 1 FROM SYS.DUAL';
  242. }
  243. /**
  244. * @inheritdoc
  245. * @since 2.0.8
  246. */
  247. public function selectExists($rawSql)
  248. {
  249. return 'SELECT CASE WHEN EXISTS(' . $rawSql . ') THEN 1 ELSE 0 END FROM DUAL';
  250. }
  251. /**
  252. * @inheritdoc
  253. * @since 2.0.8
  254. */
  255. public function dropCommentFromColumn($table, $column)
  256. {
  257. return 'COMMENT ON COLUMN ' . $this->db->quoteTableName($table) . '.' . $this->db->quoteColumnName($column) . " IS ''";
  258. }
  259. /**
  260. * @inheritdoc
  261. * @since 2.0.8
  262. */
  263. public function dropCommentFromTable($table)
  264. {
  265. return 'COMMENT ON TABLE ' . $this->db->quoteTableName($table) . " IS ''";
  266. }
  267. }