Update code_sniffer build.xml file to be executable on our system
[phpbb.git] / phpBB / includes / db / oracle.php
blob3a69565e05d1733f60c35697bcccd058e9e7432a
1 <?php
2 /**
4 * @package dbal
5 * @version $Id$
6 * @copyright (c) 2005 phpBB Group
7 * @license http://opensource.org/licenses/gpl-license.php GNU Public License
9 */
11 /**
12 * @ignore
14 if (!defined('IN_PHPBB'))
16 exit;
19 /**
20 * Oracle Database Abstraction Layer
21 * Minimum Requirement: 9.2+
22 * @package dbal
24 class phpbb_dbal_oracle extends phpbb_dbal
26 /**
27 * @var string Database type. No distinction between versions or used extensions.
29 public $dbms_type = 'oracle';
31 /**
32 * @var array Database type map, column layout information
34 public $dbms_type_map = array(
35 'INT:' => 'number(%d)',
36 'BINT' => 'number(20)',
37 'UINT' => 'number(8)',
38 'UINT:' => 'number(%d)',
39 'TINT:' => 'number(%d)',
40 'USINT' => 'number(4)',
41 'BOOL' => 'number(1)',
42 'VCHAR' => 'varchar2(255)',
43 'VCHAR:' => 'varchar2(%d)',
44 'CHAR:' => 'char(%d)',
45 'XSTEXT' => 'varchar2(1000)',
46 'STEXT' => 'varchar2(3000)',
47 'TEXT' => 'clob',
48 'MTEXT' => 'clob',
49 'XSTEXT_UNI'=> 'varchar2(300)',
50 'STEXT_UNI' => 'varchar2(765)',
51 'TEXT_UNI' => 'clob',
52 'MTEXT_UNI' => 'clob',
53 'TIMESTAMP' => 'number(11)',
54 'DECIMAL' => 'number(5, 2)',
55 'DECIMAL:' => 'number(%d, 2)',
56 'PDECIMAL' => 'number(6, 3)',
57 'PDECIMAL:' => 'number(%d, 3)',
58 'VCHAR_UNI' => 'varchar2(255)',
59 'VCHAR_UNI:'=> array('varchar2(%d)', 'limit' => array('mult', 3, 765, 'clob')),
60 'VARBINARY' => 'raw(255)',
63 /**
64 * @var string Last query executed. We need this for sql_nextid()
66 var $last_query_text = '';
68 /**
69 * Connect to server. See {@link phpbb_dbal::sql_connect() sql_connect()} for details.
71 public function sql_connect($server, $user, $password, $database, $port = false, $persistency = false , $new_link = false)
73 $this->persistency = $persistency;
74 $this->user = $user;
75 $this->server = $server . (($port) ? ':' . $port : '');
76 $this->dbname = $database;
77 $this->port = $port;
79 $connect = $database;
81 // support for "easy connect naming"
82 if ($server !== '' && $server !== '/')
84 if (substr($server, -1, 1) == '/')
86 $server == substr($sqlserver, 0, -1);
88 $connect = $server . (($port) ? ':' . $port : '') . '/' . $database;
91 $this->db_connect_id = ($new_link) ? @oci_new_connect($this->user, $password, $connect, 'AL32UTF8') : (($this->persistency) ? @oci_pconnect($this->user, $password, $connect, 'AL32UTF8') : @oci_connect($this->user, $password, $connect, 'AL32UTF8'));
93 return ($this->db_connect_id) ? $this->db_connect_id : $this->sql_error('');
96 /**
97 * Version information about used database. See {@link phpbb_dbal::sql_server_info() sql_server_info()} for details.
99 public function sql_server_info($raw = false)
101 if (!phpbb::registered('acm') || ($this->sql_server_version = phpbb::$acm->get('#oracle_version')) === false)
103 $sql = "SELECT value
104 FROM NLS_DATABASE_PARAMETERS
105 WHERE PARAMETER = 'NLS_RDBMS_VERSION'";
106 $result = @ociparse($this->db_connect_id, $sql);
107 @ociexecute($result, OCI_DEFAULT);
108 @ocicommit($this->db_connect_id);
110 $row = array();
111 @ocifetchinto($result, $row, OCI_ASSOC + OCI_RETURN_NULLS);
112 @ocifreestatement($result);
114 $this->sql_server_version = (isset($row['VALUE'])) ? trim($row['VALUE']) : 0;
116 if (phpbb::registered('acm'))
118 phpbb::$acm->put('#oracle_version', $this->sql_server_version);
122 return ($raw) ? $this->sql_server_version : @oci_server_version($this->db_connect_id);
126 * DB-specific base query method. See {@link phpbb_dbal::_sql_query() _sql_query()} for details.
128 protected function _sql_query($query)
130 $this->last_query_text = $query;
132 $in_transaction = false;
133 if (!$this->transaction)
135 $this->sql_transaction('begin');
137 else
139 $in_transaction = true;
142 $array = array();
144 // We overcome Oracle's 4000 char limit by binding vars
145 if (strlen($query) > 4000)
147 if (preg_match('/^(INSERT INTO[^(]++)\\(([^()]+)\\) VALUES[^(]++\\((.*?)\\)$/s', $query, $regs))
149 if (strlen($regs[3]) > 4000)
151 $cols = explode(', ', $regs[2]);
152 preg_match_all('/\'(?:[^\']++|\'\')*+\'|[\d-.]+/', $regs[3], $vals, PREG_PATTERN_ORDER);
154 $inserts = $vals[0];
155 unset($vals);
157 foreach ($inserts as $key => $value)
159 // check to see if this thing is greater than the max + 'x2
160 if (!empty($value) && $value[0] === "'" && strlen($value) > 4002)
162 $inserts[$key] = ':' . strtoupper($cols[$key]);
163 $array[$inserts[$key]] = str_replace("''", "'", substr($value, 1, -1));
167 $query = $regs[1] . '(' . $regs[2] . ') VALUES (' . implode(', ', $inserts) . ')';
170 else if (preg_match_all('/^(UPDATE [\\w_]++\\s+SET )([\\w_]++\\s*=\\s*(?:\'(?:[^\']++|\'\')*+\'|[\d-.]+)(?:,\\s*[\\w_]++\\s*=\\s*(?:\'(?:[^\']++|\'\')*+\'|[\d-.]+))*+)\\s+(WHERE.*)$/s', $query, $data, PREG_SET_ORDER))
172 if (strlen($data[0][2]) > 4000)
174 $update = $data[0][1];
175 $where = $data[0][3];
176 preg_match_all('/([\\w_]++)\\s*=\\s*(\'(?:[^\']++|\'\')*+\'|[\d-.]++)/', $data[0][2], $temp, PREG_SET_ORDER);
177 unset($data);
179 $cols = array();
180 foreach ($temp as $value)
182 // check to see if this thing is greater than the max + 'x2
183 if (!empty($value[2]) && $value[2][0] === "'" && strlen($value[2]) > 4002)
185 $cols[] = $value[1] . '=:' . strtoupper($value[1]);
186 $array[$value[1]] = str_replace("''", "'", substr($value[2], 1, -1));
188 else
190 $cols[] = $value[1] . '=' . $value[2];
194 $query = $update . implode(', ', $cols) . ' ' . $where;
195 unset($cols);
200 switch (substr($query, 0, 6))
202 case 'DELETE':
203 if (preg_match('/^(DELETE FROM [\w_]++ WHERE)((?:\s*(?:AND|OR)?\s*[\w_]+\s*(?:(?:=|<>)\s*(?>\'(?>[^\']++|\'\')*+\'|[\d-.]+)|(?:NOT )?IN\s*\((?>\'(?>[^\']++|\'\')*+\',? ?|[\d-.]+,? ?)*+\)))*+)$/', $query, $regs))
205 $query = $regs[1] . $this->_rewrite_where($regs[2]);
206 unset($regs);
208 break;
210 case 'UPDATE':
211 if (preg_match('/^(UPDATE [\\w_]++\\s+SET [\\w_]+\s*=\s*(?:\'(?:[^\']++|\'\')*+\'|[\d-.]++|:\w++)(?:, [\\w_]+\s*=\s*(?:\'(?:[^\']++|\'\')*+\'|[\d-.]++|:\w++))*+\\s+WHERE)(.*)$/s', $query, $regs))
213 $query = $regs[1] . $this->_rewrite_where($regs[2]);
214 unset($regs);
216 break;
218 case 'SELECT':
219 $query = preg_replace_callback('/([\w_.]++)\s*(?:(=|<>)\s*(?>\'(?>[^\']++|\'\')*+\'|[\d-.]++|([\w_.]++))|(?:NOT )?IN\s*\((?>\'(?>[^\']++|\'\')*+\',? ?|[\d-.]++,? ?)*+\))/', array($this, '_rewrite_col_compare'), $query);
220 break;
223 $result = @oci_parse($this->db_connect_id, $query);
225 if (!$result)
227 return false;
230 foreach ($array as $key => $value)
232 @oci_bind_by_name($result, $key, $array[$key], -1);
235 $success = @oci_execute($result, OCI_DEFAULT);
237 if (!$success)
239 return false;
242 if (!$in_transaction)
244 $this->sql_transaction('commit');
247 return $result;
251 * Build LIMIT query and run it. See {@link phpbb_dbal::_sql_query_limit() _sql_query_limit()} for details.
253 protected function _sql_query_limit($query, $total, $offset, $cache_ttl)
255 $query = 'SELECT * FROM (SELECT /*+ FIRST_ROWS */ rownum AS xrownum, a.* FROM (' . $query . ') a WHERE rownum <= ' . ($offset + $total) . ') WHERE xrownum >= ' . $offset;
256 return $this->sql_query($query, $cache_ttl);
260 * Close sql connection. See {@link phpbb_dbal::_sql_close() _sql_close()} for details.
262 protected function _sql_close()
264 return @oci_close($this->db_connect_id);
268 * SQL Transaction. See {@link phpbb_dbal::_sql_transaction() _sql_transaction()} for details.
270 protected function _sql_transaction($status)
272 switch ($status)
274 case 'begin':
275 return true;
276 break;
278 case 'commit':
279 return @oci_commit($this->db_connect_id);
280 break;
282 case 'rollback':
283 return @oci_rollback($this->db_connect_id);
284 break;
287 return true;
291 * Return number of affected rows. See {@link phpbb_dbal::sql_affectedrows() sql_affectedrows()} for details.
293 public function sql_affectedrows()
295 return ($this->query_result) ? @oci_num_rows($this->query_result) : false;
299 * Get last inserted id after insert statement. See {@link phpbb_dbal::sql_nextid() sql_nextid()} for details.
301 public function sql_nextid()
303 if (!$this->query_result || !$this->last_query_text)
305 return false;
308 if (preg_match('#^INSERT[\t\n ]+INTO[\t\n ]+([a-z0-9\_\-]+)#is', $this->last_query_text, $tablename))
310 $query = 'SELECT ' . $tablename[1] . '_seq.currval FROM DUAL';
311 $stmt = @oci_parse($this->db_connect_id, $query);
312 @oci_execute($stmt, OCI_DEFAULT);
314 $temp_array = @oci_fetch_array($stmt, OCI_ASSOC + OCI_RETURN_NULLS);
315 @oci_free_statement($stmt);
317 return (isset($temp_array['CURRVAL'])) ? $temp_array['CURRVAL'] : false;
320 return false;
324 * Fetch current row. See {@link phpbb_dbal::_sql_fetchrow() _sql_fetchrow()} for details.
326 protected function _sql_fetchrow($query_id)
328 $row = @oci_fetch_array($query_id, OCI_ASSOC + OCI_RETURN_NULLS);
330 if (!$row)
332 return false;
335 $result_row = array();
336 foreach ($row as $key => $value)
338 // Oracle treats empty strings as null
339 if (is_null($value))
341 $value = '';
344 // OCI->CLOB?
345 if (is_object($value))
347 $value = $value->load();
350 $result_row[strtolower($key)] = $value;
353 return $result_row;
357 * Free query result. See {@link phpbb_dbal::_sql_freeresult() _sql_freeresult()} for details.
359 protected function _sql_freeresult($query_id)
361 return @oci_free_statement($query_id);
365 * Correctly adjust LIKE expression for special characters. See {@link phpbb_dbal::_sql_like_expression() _sql_like_expression()} for details.
367 protected function _sql_like_expression($expression)
369 return $expression . " ESCAPE '\\'";
373 * Escape string used in sql query. See {@link phpbb_dbal::sql_escape() sql_escape()} for details.
375 public function sql_escape($msg)
377 return str_replace(array("'", "\0"), array("''", ''), $msg);
381 * Expose a DBMS specific function. See {@link phpbb_dbal::sql_function() sql_function()} for details.
383 public function sql_function($type, $col)
385 switch ($type)
387 case 'length_varchar':
388 return 'LENGTH(' . $col . ')';
389 break;
391 case 'length_text':
392 return 'dbms_lob.getlength(' . $col . ')';
393 break;
398 * Handle data by using prepared statements. See {@link phpbb_dbal::sql_handle_data() sql_handle_data()} for details.
399 public function sql_handle_data($type, $table, $data, $where = '')
401 if ($type === 'INSERT')
403 $stmt = oci_parse($this->db_connect_id, "INSERT INTO $table (". implode(', ', array_keys($data)) . ") VALUES (:" . implode(', :', array_keys($data)) . ')');
405 else
407 $query = "UPDATE $table SET ";
409 $set = array();
410 foreach (array_keys($data) as $key)
412 $set[] = "$key = :$key";
414 $query .= implode(', ', $set);
416 if ($where !== '')
418 $query .= $where;
421 $stmt = oci_parse($this->db_connect_id, $query);
424 foreach ($data as $column => $value)
426 oci_bind_by_name($stmt, ":$column", $data[$column], -1);
429 oci_execute($stmt);
434 * Build DB-specific query bits. See {@link phpbb_dbal::_sql_custom_build() _sql_custom_build()} for details.
436 protected function _sql_custom_build($stage, $data)
438 return $data;
442 * return sql error array. See {@link phpbb_dbal::_sql_error() _sql_error()} for details.
444 protected function _sql_error()
446 $error = @oci_error();
447 $error = (empty($error)) ? @oci_error($this->query_result) : $error;
448 $error = (empty($error)) ? @oci_error($this->db_connect_id) : $error;
450 if (empty($error))
452 $error = array(
453 'message' => '',
454 'code' => '',
458 return $error;
462 * Run DB-specific code to build SQL Report to explain queries, show statistics and runtime information. See {@link phpbb_dbal::_sql_report() _sql_report()} for details.
464 protected function _sql_report($mode, $query = '')
466 switch ($mode)
468 case 'start':
469 $html_table = false;
471 // Grab a plan table, any will do
472 $sql = "SELECT table_name
473 FROM USER_TABLES
474 WHERE table_name LIKE '%PLAN_TABLE%'";
475 $stmt = @oci_parse($this->db_connect_id, $sql);
476 @oci_execute($stmt);
477 $result = array();
479 if ($result = @oci_fetch_array($stmt, OCI_ASSOC + OCI_RETURN_NULLS))
481 $table = $result['TABLE_NAME'];
483 // This is the statement_id that will allow us to track the plan
484 $statement_id = substr(md5($query), 0, 30);
486 // Remove any stale plans
487 $stmt2 = @oci_parse($this->db_connect_id, "DELETE FROM $table WHERE statement_id='$statement_id'");
488 @oci_execute($stmt2);
489 @oci_free_statement($stmt2);
491 // Explain the plan
492 $sql = "EXPLAIN PLAN
493 SET STATEMENT_ID = '$statement_id'
494 FOR $query";
495 $stmt2 = @ociparse($this->db_connect_id, $sql);
496 @oci_execute($stmt2);
497 @oci_free_statement($stmt2);
499 // Get the data from the plan
500 $sql = "SELECT operation, options, object_name, object_type, cardinality, cost
501 FROM plan_table
502 START WITH id = 0 AND statement_id = '$statement_id'
503 CONNECT BY PRIOR id = parent_id
504 AND statement_id = '$statement_id'";
505 $stmt2 = @oci_parse($this->db_connect_id, $sql);
506 @oci_execute($stmt2);
508 $row = array();
509 while ($row = @oci_fetch_array($stmt2, OCI_ASSOC + OCI_RETURN_NULLS))
511 $html_table = $this->sql_report('add_select_row', $query, $html_table, $row);
513 @oci_free_statement($stmt2);
515 // Remove the plan we just made, we delete them on request anyway
516 $stmt2 = @oci_parse($this->db_connect_id, "DELETE FROM $table WHERE statement_id='$statement_id'");
517 @oci_execute($stmt2);
518 @oci_free_statement($stmt2);
521 @oci_free_statement($stmt);
523 if ($html_table)
525 $this->html_hold .= '</table>';
528 break;
530 case 'fromcache':
531 $endtime = explode(' ', microtime());
532 $endtime = $endtime[0] + $endtime[1];
534 $result = @oci_parse($this->db_connect_id, $query);
535 $success = @oci_execute($result, OCI_DEFAULT);
536 $row = array();
538 while ($void = @oci_fetch_array($result, OCI_ASSOC + OCI_RETURN_NULLS))
540 // Take the time spent on parsing rows into account
542 @oci_free_statement($result);
544 $splittime = explode(' ', microtime());
545 $splittime = $splittime[0] + $splittime[1];
547 $this->sql_report('record_fromcache', $query, $endtime, $splittime);
549 break;
554 * Oracle specific code to handle the fact that it does not compare columns properly
555 * @access private
557 private function _rewrite_col_compare($args)
559 if (sizeof($args) == 4)
561 if ($args[2] == '=')
563 return '(' . $args[0] . ' OR (' . $args[1] . ' is NULL AND ' . $args[3] . ' is NULL))';
565 else if ($args[2] == '<>')
567 // really just a fancy way of saying foo <> bar or (foo is NULL XOR bar is NULL) but SQL has no XOR :P
568 return '(' . $args[0] . ' OR ((' . $args[1] . ' is NULL AND ' . $args[3] . ' is NOT NULL) OR (' . $args[1] . ' is NOT NULL AND ' . $args[3] . ' is NULL)))';
571 else
573 return $this->_rewrite_where($args[0]);
578 * Oracle specific code to handle it's lack of sanity
579 * @access private
581 private function _rewrite_where($where_clause)
583 preg_match_all('/\s*(AND|OR)?\s*([\w_.]++)\s*(?:(=|<[=>]?|>=?)\s*((?>\'(?>[^\']++|\'\')*+\'|[\d-.]+))|((NOT )?IN\s*\((?>\'(?>[^\']++|\'\')*+\',? ?|[\d-.]+,? ?)*+\)))/', $where_clause, $result, PREG_SET_ORDER);
584 $out = '';
586 foreach ($result as $val)
588 if (!isset($val[5]))
590 if ($val[4] !== "''")
592 $out .= $val[0];
594 else
596 $out .= ' ' . $val[1] . ' ' . $val[2];
597 if ($val[3] == '=')
599 $out .= ' is NULL';
601 else if ($val[3] == '<>')
603 $out .= ' is NOT NULL';
607 else
609 $in_clause = array();
610 $sub_exp = substr($val[5], strpos($val[5], '(') + 1, -1);
611 $extra = false;
612 preg_match_all('/\'(?>[^\']++|\'\')*+\'|[\d-.]++/', $sub_exp, $sub_vals, PREG_PATTERN_ORDER);
613 $i = 0;
615 foreach ($sub_vals[0] as $sub_val)
617 // two things:
618 // 1) This determines if an empty string was in the IN clausing, making us turn it into a NULL comparison
619 // 2) This fixes the 1000 list limit that Oracle has (ORA-01795)
620 if ($sub_val !== "''")
622 $in_clause[(int) $i++/1000][] = $sub_val;
624 else
626 $extra = true;
630 if (!$extra && $i < 1000)
632 $out .= $val[0];
634 else
636 $out .= ' ' . $val[1] . '(';
637 $in_array = array();
639 // constuct each IN() clause
640 foreach ($in_clause as $in_values)
642 $in_array[] = $val[2] . ' ' . (isset($val[6]) ? $val[6] : '') . 'IN(' . implode(', ', $in_values) . ')';
645 // Join the IN() clauses against a few ORs (IN is just a nicer OR anyway)
646 $out .= implode(' OR ', $in_array);
648 // handle the empty string case
649 if ($extra)
651 $out .= ' OR ' . $val[2] . ' is ' . (isset($val[6]) ? $val[6] : '') . 'NULL';
653 $out .= ')';
655 unset($in_array, $in_clause);
660 return $out;