select.inc 19 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137138139140141142143144145146147148149150151152153154155156157158159160161162163164165166167168169170171172173174175176177178179180181182183184185186187188189190191192193194195196197198199200201202203204205206207208209210211212213214215216217218219220221222223224225226227228229230231232233234235236237238239240241242243244245246247248249250251252253254255256257258259260261262263264265266267268269270271272273274275276277278279280281282283284285286287288289290291292293294295296297298299300301302303304305306307308309310311312313314315316317318319320321322323324325326327328329330331332333334335336337338339340341342343344345346347348349350351352353354355356357358359360361362363364365366367368369370371372373374375376377378379380381382383384385386387388389390391392393394395396397398399400401402403404405406407408409410411412413414415416417418419420421422423424425426427428429430431432433434435436437438439440441442443444445446447448449450451452453454455456457458459460461462463464465466467468469470471472473474475476477478479480481482483484485486487488489490491492493494495496497498499500501502503504505506507508509510511512513514515516517518519520521522523524525526527528529530531532533534535536537538539540541542543544545546547548549550551552
  1. <?php
  2. class SelectQuery_sqlsrv extends SelectQuery {
  3. /**
  4. * Overriden with an aditional exclude parameter that tells not to include this expression (by default)
  5. * in the select list.
  6. *
  7. * @param string $expression
  8. *
  9. * @param string $alias
  10. *
  11. * @param string $arguments
  12. *
  13. * @param string $exclude
  14. * If set to TRUE, this expression will not be added to the select list. Useful
  15. * when you want to reuse expressions in the WHERE part.
  16. * @param string $expand
  17. * If this expression will be expanded as a CROSS_JOIN so it can be consumed
  18. * from other parts of the query. TRUE by default. It attempts to detect expressions
  19. * that cannot be cross joined (aggregates).
  20. * @return string
  21. */
  22. public function addExpression($expression, $alias = NULL, $arguments = array(), $exclude = FALSE, $expand = TRUE) {
  23. $alias = parent::addExpression($expression, $alias, $arguments);
  24. $this->expressions[$alias]['exclude'] = $exclude;
  25. $this->expressions[$alias]['expand'] = $expand;
  26. return $alias;
  27. }
  28. /**
  29. * Override for SelectQuery::preExecute().
  30. *
  31. * Ensure that all the fields in ORDER BY and GROUP BY are part of the
  32. * main query.
  33. */
  34. public function preExecute(SelectQueryInterface $query = NULL) {
  35. // If no query object is passed in, use $this.
  36. if (!isset($query)) {
  37. $query = $this;
  38. }
  39. // Only execute this once.
  40. if ($this->isPrepared()) {
  41. return TRUE;
  42. }
  43. // Execute standard pre-execution first.
  44. parent::preExecute($query);
  45. if ($this->distinct || $this->group) {
  46. // When the query is DISTINCT or contains GROUP BY fields, all the fields
  47. // in the GROUP BY and ORDER BY clauses must appear in the returned
  48. // columns.
  49. $columns = $this->order + array_flip($this->group);
  50. $counter = 0;
  51. foreach ($columns as $field => $dummy) {
  52. $found = FALSE;
  53. foreach($this->fields as $f) {
  54. if (!isset($f['table']) || !isset($f['field'])) {
  55. continue;
  56. }
  57. $alias = "{$f['table']}.{$f['field']}";
  58. if ($alias == $field) {
  59. $found = TRUE;
  60. break;
  61. }
  62. }
  63. if (!isset($this->fields[$field]) && !isset($this->expressions[$field]) && !$found) {
  64. $alias = '_field_' . ($counter++);
  65. $this->addExpression($field, $alias, array(), FALSE, FALSE);
  66. $this->queryOptions['sqlsrv_drop_columns'][] = $alias;
  67. }
  68. }
  69. // The other way round is also true, if using aggregates, all the fields in the SELECT
  70. // must be present in the GROUP BY.
  71. if (!empty($this->group)) {
  72. foreach ($this->fields as $field) {
  73. $spec = $field['table'] . '.' . $field['field'];
  74. $alias = $field['alias'];
  75. if (!isset($this->group[$spec]) && !isset($this->group[$alias])) {
  76. $this->group[$spec] = $spec;
  77. }
  78. }
  79. }
  80. // More over, GROUP BY columns cannot use aliases, so expand them to
  81. // their full expressions.
  82. foreach ($this->group as $key => &$group_field) {
  83. // Expand an alias on a field.
  84. if (isset($this->fields[$group_field])) {
  85. $field = $this->fields[$group_field];
  86. $group_field = (isset($field['table']) ? $this->connection->escapeTable($field['table']) . '.' : '') . $this->connection->escapeField($field['field']);
  87. }
  88. // Expand an alias on an expression.
  89. else if (isset($this->expressions[$group_field])) {
  90. $expression = $this->expressions[$group_field];
  91. $group_field = $expression['expression'];
  92. // If the expression has arguments, we now
  93. // have duplicate placeholders. Run as insecure.
  94. if (is_array($expression['arguments'])) {
  95. $this->queryOptions['insecure'] = TRUE;
  96. }
  97. }
  98. }
  99. }
  100. // Verify type bindings in the conditions, and throw the Exception
  101. // now to prevent a bug in MSSQLPDO where transactions are f**** UP
  102. // when the driver throws a PDOException().
  103. // @see https://github.com/Azure/msphpsql/issues/50
  104. //
  105. // TODO: Remove when the issue is fixed in the PDO driver.
  106. if (DatabaseUtils::GetConfigBoolean('MSSQL_VERIFY_NUMERIC_BINDINGS')) {
  107. foreach($this->where->conditions() as $condition) {
  108. if (!isset($condition['field']) || !is_string($condition['field'])) {
  109. continue;
  110. }
  111. // Make sure we have a valid $table.$field format.
  112. $parts = explode('.', $condition['field']);
  113. if (count($parts) !== 2) {
  114. continue;
  115. }
  116. list($table, $field_alias) = $parts;
  117. // Fin the real field name if this was an alias.
  118. $fields = $this->getFields();
  119. $field = $field_alias;
  120. if (isset($fields[$field_alias])) {
  121. $field = $fields[$field_alias]['field'];
  122. }
  123. // Get the real table name.
  124. $tables = $this->getTables();
  125. if (!isset($tables[$table])) {
  126. continue;
  127. }
  128. $real_table = $tables[$table]['table'];
  129. /** @var DatabaseSchema_sqlsrv **/
  130. $schema = $this->connection->schema();
  131. $spec = $schema->queryColumnInformation($real_table);
  132. if (!isset($spec['columns'][$field])) {
  133. continue;
  134. }
  135. $col_spec = $spec['columns'][$field];
  136. $values = $condition['value'];
  137. if (!is_array($values)) {
  138. $values = array($values);
  139. }
  140. foreach($values as $value) {
  141. if (!is_numeric($value) && !is_bool($value)) {
  142. if (in_array($col_spec['type'], array('int', 'bigint'))) {
  143. // This is anyways going to throw an exception when running the query against the PDO driver.
  144. throw new \PDOException('Invalid type binding!');
  145. }
  146. }
  147. }
  148. }
  149. }
  150. return $this->prepared;
  151. }
  152. /**
  153. * Override for SelectQuery::compile().
  154. *
  155. * Detect when this query is prepared for use in a sub-query.
  156. */
  157. public function compile(DatabaseConnection $connection, QueryPlaceholderInterface $queryPlaceholder) {
  158. $this->inSubQuery = $queryPlaceholder != $this;
  159. return parent::compile($connection, $queryPlaceholder);
  160. }
  161. /* strpos that takes an array of values to match against a string
  162. * note the stupid argument order (to match strpos)
  163. */
  164. private function stripos_arr($haystack, $needle) {
  165. if(!is_array($needle)) {
  166. $needle = array($needle);
  167. }
  168. foreach($needle as $what) {
  169. if(($pos = stripos($haystack, $what)) !== false) {
  170. return $pos;
  171. }
  172. }
  173. return FALSE;
  174. }
  175. const RESERVED_REGEXP_BASE = '/\G
  176. # Everything that follows a boundary that is not ":" or "_" or ".".
  177. \b(?<![:\[_\[.])(?:
  178. # Any reserved words, followed by a boundary that is not an opening parenthesis.
  179. ({0})
  180. (?!\()
  181. |
  182. # Or a normal word.
  183. ([a-z]+)
  184. )\b
  185. |
  186. \b(
  187. [^a-z\'"\\\\]+
  188. )\b
  189. |
  190. (?=[\'"])
  191. (
  192. " [^\\\\"] * (?: \\\\. [^\\\\"] *) * "
  193. |
  194. \' [^\\\\\']* (?: \\\\. [^\\\\\']*) * \'
  195. )
  196. /Six';
  197. // Aliases for expressions that should
  198. // be replaced.
  199. private $cross_apply_aliases;
  200. // A subset of $cross_apply_aliases that
  201. // only contains the the cross-join expanded
  202. // expressions.
  203. private $cross_apply_aliases_non_aggregates;
  204. protected function replaceReservedAliases($matches) {
  205. if ($matches[1] !== '') {
  206. // Replace reserved words.
  207. return $this->cross_apply_aliases[$matches[1]];
  208. }
  209. // Let other value passthru.
  210. // by the logic of the regex above, this will always be the last match.
  211. return end($matches);
  212. }
  213. /**
  214. * This function needs some work....
  215. *
  216. * @param mixed $statement
  217. * @return mixed
  218. */
  219. protected function replaceExpressionAliases($statement) {
  220. // References to expressions in cross-apply need to be updated.
  221. // Now we need to update all references to the expression aliases
  222. // and point them to the CROSS APPLY alias.
  223. if (!empty($this->cross_apply_aliases)) {
  224. $regex = str_replace('{0}', implode('|', array_keys($this->cross_apply_aliases)), self::RESERVED_REGEXP_BASE);
  225. // Add and then remove the SELECT
  226. // keyword. Do this to use the exact same
  227. // regex that we have in DatabaseConnection_sqlrv.
  228. $statement = 'SELECT ' . $statement;
  229. $statement = preg_replace_callback($regex, array($this, 'replaceReservedAliases'), $statement);
  230. $statement = substr($statement, 7, strlen($statement) - 7);
  231. }
  232. return $statement;
  233. }
  234. /**
  235. * Verify in an expression has an aggregate.
  236. *
  237. * Needs some more work.
  238. *
  239. * @param mixed $expression
  240. * @return bool|int
  241. */
  242. protected function expressionContainsAggregate($expression) {
  243. return $this->stripos_arr($expression, array('AVG(', 'GROUP_CONCAT(', 'COUNT(', 'MAX(', 'GROUPING(', 'GROUPING_ID(', 'COUNT_BIG(', 'CHECKSUM_AGG(', 'MIN(', 'SUM(', 'VAR(', 'VARP(', 'STDEV(', 'STDEVP(')) !== FALSE;
  244. }
  245. public function __toString() {
  246. // For convenience, we compile the query ourselves if the caller forgot
  247. // to do it. This allows constructs like "(string) $query" to work. When
  248. // the query will be executed, it will be recompiled using the proper
  249. // placeholder generator anyway.
  250. if (!$this->compiled()) {
  251. $this->compile($this->connection, $this);
  252. }
  253. // Create a sanitized comment string to prepend to the query.
  254. $comments = $this->connection->makeComment($this->comments);
  255. // SELECT
  256. $query = $comments . 'SELECT ';
  257. if ($this->distinct) {
  258. $query .= 'DISTINCT ';
  259. }
  260. // FIELDS and EXPRESSIONS
  261. $fields = array();
  262. foreach ($this->tables as $alias => $table) {
  263. // Table might be a subquery, so nothing to do really.
  264. if (is_string($table['table']) && !empty($table['all_fields'])) {
  265. // Temporary tables are not supported here.
  266. if ($table['table'][0] == '#') {
  267. $fields[] = $this->connection->escapeTable($alias) . '.*';
  268. }
  269. else {
  270. $info = $this->connection->schema()->queryColumnInformation($table['table']);
  271. // Some fields need to be "transparent" to Drupal, including technical primary keys
  272. // or custom computed columns.
  273. foreach ($info['columns_clean'] as $column) {
  274. $fields[] = $this->connection->escapeTable($alias) . '.' . $column['name'];
  275. }
  276. }
  277. }
  278. }
  279. foreach ($this->fields as $alias => $field) {
  280. // Always use the AS keyword for field aliases, as some
  281. // databases require it (e.g., PostgreSQL).
  282. $fields[] = (isset($field['table']) ? $this->connection->escapeTable($field['table']) . '.' : '') . $this->connection->escapeField($field['field']) . ' AS ' . $this->connection->escapeField($field['alias']);
  283. }
  284. // In MySQL you can reuse expressions present in SELECT
  285. // from WHERE.
  286. // The way to emulate that behaviour in SQL Server is to
  287. // fit all that in a CROSS_APPLY with an alias and then consume
  288. // it from WHERE or AGGREGATE.
  289. $cross_apply = array();
  290. $this->cross_apply_aliases = array();
  291. $this->cross_apply_aliases_non_aggregates = array();
  292. foreach ($this->expressions as $alias => $expression) {
  293. // Only use CROSS_APPLY for non-aggregate expresions. This trick
  294. // will not work, and does not make sense, for aggregates.
  295. // If the alias is 'expression' this is Drupal's default
  296. // meaning that more than probably this expression
  297. // is never reused in a WHERE.
  298. $aggregate_expression = $this->expressionContainsAggregate($expression['expression']);
  299. if ($expression['expand'] !== FALSE && $expression['alias'] != 'expression' && !$aggregate_expression) {
  300. // What we are doing here is using a CROSS APPLY to
  301. // generate an expression that can be used in the select and where
  302. // but we need to give this expression a new name.
  303. $cross_apply[] = "\nCROSS APPLY (SELECT " . $expression['expression'] . ' cross_sqlsrv) cross_' . $expression['alias'];
  304. $new_alias = 'cross_' . $expression['alias'] . '.cross_sqlsrv';
  305. // We might not want an expression to appear in the select list.
  306. if ($expression['exclude'] !== TRUE) {
  307. $fields[] = $new_alias . ' AS ' . $expression['alias'];
  308. }
  309. // Store old expression and new representation.
  310. $this->cross_apply_aliases[$expression['alias']] = $new_alias;
  311. $this->cross_apply_aliases_non_aggregates[$expression['alias']] = $new_alias;
  312. }
  313. else {
  314. if ($aggregate_expression) {
  315. // Use the expression itself...
  316. $this->cross_apply_aliases[$expression['alias']] = $expression['expression'];
  317. }
  318. // We might not want an expression to appear in the select list.
  319. if ($expression['exclude'] !== TRUE) {
  320. $fields[] = $expression['expression'] . ' AS ' . $expression['alias'];
  321. }
  322. }
  323. }
  324. $query .= implode(', ', $fields);
  325. // FROM - We presume all queries have a FROM, as any query that doesn't won't need the query builder anyway.
  326. $query .= "\nFROM ";
  327. foreach ($this->tables as $alias => $table) {
  328. $query .= "\n";
  329. if (isset($table['join type'])) {
  330. $query .= $table['join type'] . ' JOIN ';
  331. }
  332. // If the table is a subquery, compile it and integrate it into this query.
  333. if ($table['table'] instanceof SelectQueryInterface) {
  334. // Run preparation steps on this sub-query before converting to string.
  335. $subquery = $table['table'];
  336. $subquery->preExecute();
  337. $table_string = '(' . (string) $subquery . ')';
  338. }
  339. else {
  340. $table_string = '{' . $this->connection->escapeTable($table['table']) . '}';
  341. }
  342. // Don't use the AS keyword for table aliases, as some
  343. // databases don't support it (e.g., Oracle).
  344. $query .= $table_string . ' ' . $this->connection->escapeTable($table['alias']);
  345. if ($this->nolock) {
  346. $query .= ' WITH(NOLOCK)';
  347. }
  348. if (!empty($table['condition'])) {
  349. $query .= ' ON ' . $table['condition'];
  350. }
  351. }
  352. // CROSS APPLY
  353. $query .= implode($cross_apply);
  354. // WHERE
  355. if (count($this->where)) {
  356. // There is an implicit string cast on $this->condition.
  357. $where = $this->where->__toString();
  358. $where = $this->replaceExpressionAliases($where);
  359. $query .= "\nWHERE ( " . $where . " )";
  360. }
  361. // GROUP BY
  362. if ($this->group) {
  363. $group = $this->group;
  364. // You named it, if the newly expanded expression
  365. // is added to the select list, then it must
  366. // also be present in the aggregate expression.
  367. $group = array_merge($group, $this->cross_apply_aliases_non_aggregates);
  368. $query .= "\nGROUP BY " . implode(', ', $group);
  369. }
  370. // HAVING
  371. if (count($this->having)) {
  372. // There is an implicit string cast on $this->having.
  373. $having = $this->replaceExpressionAliases($this->having);
  374. $query .= "\nHAVING " . $having;
  375. }
  376. // ORDER BY
  377. // The ORDER BY clause is invalid in views, inline functions, derived
  378. // tables, subqueries, and common table expressions, unless TOP or FOR XML
  379. // is also specified.
  380. $sorted = FALSE;
  381. if ($this->order && (empty($this->inSubQuery) || !empty($this->range))) {
  382. $query .= "\nORDER BY ";
  383. $fields = array();
  384. foreach ($this->order as $field => $direction) {
  385. $fields[] = $field . ' ' . $direction;
  386. }
  387. $query .= implode(', ', $fields);
  388. $sorted = TRUE;
  389. }
  390. // RANGE
  391. if (!empty($this->range)) {
  392. // To get OFFSET FETCH to work the query needs
  393. // to have an order by. Use the recommended sort.
  394. if (!$sorted) {
  395. $query .= "\nORDER BY 1";
  396. }
  397. $query = $this->connection->addRangeToQuery($query, $this->range['start'], $this->range['length']);
  398. }
  399. // UNION is a little odd, as the select queries to combine are passed into
  400. // this query, but syntactically they all end up on the same level.
  401. if ($this->union) {
  402. foreach ($this->union as $union) {
  403. $query .= ' ' . $union['type'] . ' ' . (string) $union['query'];
  404. }
  405. }
  406. return $query;
  407. }
  408. /**
  409. * Override of SelectQuery::orderRandom() for SQL Server.
  410. *
  411. * It seems that sorting by RAND() doesn't actually work, this is a less then
  412. * elegant workaround.
  413. *
  414. * @status tested
  415. */
  416. public function orderRandom() {
  417. $alias = $this->addExpression('NEWID()', 'random_field');
  418. $this->orderBy($alias);
  419. return $this;
  420. }
  421. private function GetUsedAliases(\DatabaseCondition $condition, array &$aliases = array()) {
  422. foreach($condition->conditions() as $key => $c) {
  423. if (is_string($key) && substr($key, 0, 1) == '#') {
  424. continue;
  425. }
  426. if (is_a($c['field'], 'DatabaseCondition')) {
  427. $this->GetUsedAliases($c['field'], $aliases);
  428. }
  429. else {
  430. $aliases[$c['field']] = TRUE;
  431. }
  432. }
  433. }
  434. private $nolock = FALSE;
  435. /**
  436. * Add a hint that is appended to all tables
  437. * in the query.
  438. * @param mixed $hint
  439. * @throws Exception
  440. */
  441. public function WithNoLock() {
  442. $this->nolock = TRUE;
  443. }
  444. /**
  445. * This is like the default countQuery, but does not optimize field (or expressions)
  446. * that are being used in conditions.
  447. */
  448. public function countQuery() {
  449. // Create our new query object that we will mutate into a count query.
  450. $count = clone($this);
  451. $group_by = $count->getGroupBy();
  452. $having = $count->havingConditions();
  453. if (!$count->distinct && !isset($having[0])) {
  454. $used_aliases = array();
  455. $this->GetUsedAliases($count->where, $used_aliases);
  456. // When not executing a distinct query, we can zero-out existing fields
  457. // and expressions that are not used by a GROUP BY or HAVING. Fields
  458. // listed in a GROUP BY or HAVING clause need to be present in the
  459. // query.
  460. $fields =& $count->getFields();
  461. foreach ($fields as $field => $value) {
  462. if (empty($group_by[$field]) && !isset($used_aliases[$value['alias']])) {
  463. unset($fields[$field]);
  464. }
  465. }
  466. $expressions =& $count->getExpressions();
  467. foreach ($expressions as $field => $value) {
  468. if (empty($group_by[$field]) && !isset($used_aliases[$value['alias']])) {
  469. unset($expressions[$field]);
  470. }
  471. }
  472. // Also remove 'all_fields' statements, which are expanded into tablename.*
  473. // when the query is executed.
  474. foreach ($count->tables as $alias => &$table) {
  475. unset($table['all_fields']);
  476. }
  477. }
  478. // If we've just removed all fields from the query, make sure there is at
  479. // least one so that the query still runs.
  480. $count->addExpression('1');
  481. // Ordering a count query is a waste of cycles, and breaks on some
  482. // databases anyway.
  483. $orders = &$count->getOrderBy();
  484. $orders = array();
  485. if ($count->distinct && !empty($group_by)) {
  486. // If the query is distinct and contains a GROUP BY, we need to remove the
  487. // distinct because SQL99 does not support counting on distinct multiple fields.
  488. $count->distinct = FALSE;
  489. }
  490. $query = $this->connection->select($count);
  491. $query->addExpression('COUNT(*)');
  492. return $query;
  493. }
  494. }