1: <?php
2: 3: 4: 5: 6: 7: 8: 9: 10: 11: 12: 13: 14: 15: 16: 17:
18:
19: App::uses('DboSource', 'Model/Datasource');
20:
21: 22: 23: 24: 25: 26: 27: 28: 29: 30:
31: class Sqlserver extends DboSource {
32:
33: 34: 35: 36: 37:
38: public $description = "SQL Server DBO Driver";
39:
40: 41: 42: 43: 44:
45: public $startQuote = "[";
46:
47: 48: 49: 50: 51:
52: public $endQuote = "]";
53:
54: 55: 56: 57: 58: 59:
60: protected $_fieldMappings = array();
61:
62: 63: 64: 65: 66:
67: protected $_lastAffected = false;
68:
69: 70: 71: 72: 73:
74: protected $_baseConfig = array(
75: 'persistent' => true,
76: 'host' => 'localhost\SQLEXPRESS',
77: 'login' => '',
78: 'password' => '',
79: 'database' => 'cake',
80: 'schema' => '',
81: 'flags' => array()
82: );
83:
84: 85: 86: 87: 88:
89: public $columns = array(
90: 'primary_key' => array('name' => 'IDENTITY (1, 1) NOT NULL'),
91: 'string' => array('name' => 'nvarchar', 'limit' => '255'),
92: 'text' => array('name' => 'nvarchar', 'limit' => 'MAX'),
93: 'integer' => array('name' => 'int', 'formatter' => 'intval'),
94: 'biginteger' => array('name' => 'bigint'),
95: 'numeric' => array('name' => 'decimal', 'formatter' => 'floatval'),
96: 'decimal' => array('name' => 'decimal', 'formatter' => 'floatval'),
97: 'float' => array('name' => 'float', 'formatter' => 'floatval'),
98: 'real' => array('name' => 'float', 'formatter' => 'floatval'),
99: 'datetime' => array('name' => 'datetime', 'format' => 'Y-m-d H:i:s', 'formatter' => 'date'),
100: 'timestamp' => array('name' => 'timestamp', 'format' => 'Y-m-d H:i:s', 'formatter' => 'date'),
101: 'time' => array('name' => 'datetime', 'format' => 'H:i:s', 'formatter' => 'date'),
102: 'date' => array('name' => 'datetime', 'format' => 'Y-m-d', 'formatter' => 'date'),
103: 'binary' => array('name' => 'varbinary'),
104: 'boolean' => array('name' => 'bit')
105: );
106:
107: 108: 109: 110: 111: 112:
113: const ROW_COUNTER = '_cake_page_rownum_';
114:
115: 116: 117: 118: 119: 120:
121: public function connect() {
122: $config = $this->config;
123: $this->connected = false;
124:
125: $flags = $config['flags'] + array(
126: PDO::ATTR_PERSISTENT => $config['persistent'],
127: PDO::ATTR_ERRMODE => PDO::ERRMODE_EXCEPTION
128: );
129:
130: if (!empty($config['encoding'])) {
131: $flags[PDO::SQLSRV_ATTR_ENCODING] = $config['encoding'];
132: }
133:
134: try {
135: $this->_connection = new PDO(
136: "sqlsrv:server={$config['host']};Database={$config['database']}",
137: $config['login'],
138: $config['password'],
139: $flags
140: );
141: $this->connected = true;
142: if (!empty($config['settings'])) {
143: foreach ($config['settings'] as $key => $value) {
144: $this->_execute("SET $key $value");
145: }
146: }
147: } catch (PDOException $e) {
148: throw new MissingConnectionException(array(
149: 'class' => get_class($this),
150: 'message' => $e->getMessage()
151: ));
152: }
153:
154: return $this->connected;
155: }
156:
157: 158: 159: 160: 161:
162: public function enabled() {
163: return in_array('sqlsrv', PDO::getAvailableDrivers());
164: }
165:
166: 167: 168: 169: 170: 171:
172: public function listSources($data = null) {
173: $cache = parent::listSources();
174: if ($cache !== null) {
175: return $cache;
176: }
177: $result = $this->_execute("SELECT TABLE_NAME FROM INFORMATION_SCHEMA.TABLES");
178:
179: if (!$result) {
180: $result->closeCursor();
181: return array();
182: }
183: $tables = array();
184:
185: while ($line = $result->fetch(PDO::FETCH_NUM)) {
186: $tables[] = $line[0];
187: }
188:
189: $result->closeCursor();
190: parent::listSources($tables);
191: return $tables;
192: }
193:
194: 195: 196: 197: 198: 199: 200:
201: public function describe($model) {
202: $table = $this->fullTableName($model, false, false);
203: $fulltable = $this->fullTableName($model, false, true);
204:
205: $cache = parent::describe($fulltable);
206: if ($cache) {
207: return $cache;
208: }
209:
210: $fields = array();
211: $schema = is_object($model) ? $model->schemaName : false;
212:
213: $cols = $this->_execute(
214: "SELECT
215: COLUMN_NAME as Field,
216: DATA_TYPE as Type,
217: COL_LENGTH('" . ($schema ? $fulltable : $table) . "', COLUMN_NAME) as Length,
218: IS_NULLABLE As [Null],
219: COLUMN_DEFAULT as [Default],
220: COLUMNPROPERTY(OBJECT_ID('" . ($schema ? $fulltable : $table) . "'), COLUMN_NAME, 'IsIdentity') as [Key],
221: NUMERIC_SCALE as Size
222: FROM INFORMATION_SCHEMA.COLUMNS
223: WHERE TABLE_NAME = '" . $table . "'" . ($schema ? " AND TABLE_SCHEMA = '" . $schema . "'" : '')
224: );
225:
226: if (!$cols) {
227: throw new CakeException(__d('cake_dev', 'Could not describe table for %s', $table));
228: }
229:
230: while ($column = $cols->fetch(PDO::FETCH_OBJ)) {
231: $field = $column->Field;
232: $fields[$field] = array(
233: 'type' => $this->column($column),
234: 'null' => ($column->Null === 'YES' ? true : false),
235: 'default' => $column->Default,
236: 'length' => $this->length($column),
237: 'key' => ($column->Key == '1') ? 'primary' : false
238: );
239:
240: if ($fields[$field]['default'] === 'null') {
241: $fields[$field]['default'] = null;
242: }
243: if ($fields[$field]['default'] !== null) {
244: $fields[$field]['default'] = preg_replace(
245: "/^[(]{1,2}'?([^')]*)?'?[)]{1,2}$/",
246: "$1",
247: $fields[$field]['default']
248: );
249: $this->value($fields[$field]['default'], $fields[$field]['type']);
250: }
251:
252: if ($fields[$field]['key'] !== false && $fields[$field]['type'] === 'integer') {
253: $fields[$field]['length'] = 11;
254: } elseif ($fields[$field]['key'] === false) {
255: unset($fields[$field]['key']);
256: }
257: if (in_array($fields[$field]['type'], array('date', 'time', 'datetime', 'timestamp'))) {
258: $fields[$field]['length'] = null;
259: }
260: if ($fields[$field]['type'] === 'float' && !empty($column->Size)) {
261: $fields[$field]['length'] = $fields[$field]['length'] . ',' . $column->Size;
262: }
263: }
264: $this->_cacheDescription($table, $fields);
265: $cols->closeCursor();
266: return $fields;
267: }
268:
269: 270: 271: 272: 273: 274: 275: 276: 277:
278: public function fields(Model $model, $alias = null, $fields = array(), $quote = true) {
279: if (empty($alias)) {
280: $alias = $model->alias;
281: }
282: $fields = parent::fields($model, $alias, $fields, false);
283: $count = count($fields);
284:
285: if ($count >= 1 && strpos($fields[0], 'COUNT(*)') === false) {
286: $result = array();
287: for ($i = 0; $i < $count; $i++) {
288: $prepend = '';
289:
290: if (strpos($fields[$i], 'DISTINCT') !== false && strpos($fields[$i], 'COUNT') === false) {
291: $prepend = 'DISTINCT ';
292: $fields[$i] = trim(str_replace('DISTINCT', '', $fields[$i]));
293: }
294:
295: if (!preg_match('/\s+AS\s+/i', $fields[$i])) {
296: if (substr($fields[$i], -1) === '*') {
297: if (strpos($fields[$i], '.') !== false && $fields[$i] != $alias . '.*') {
298: $build = explode('.', $fields[$i]);
299: $AssociatedModel = $model->{$build[0]};
300: } else {
301: $AssociatedModel = $model;
302: }
303:
304: $_fields = $this->fields($AssociatedModel, $AssociatedModel->alias, array_keys($AssociatedModel->schema()));
305: $result = array_merge($result, $_fields);
306: continue;
307: }
308:
309: if (strpos($fields[$i], '.') === false) {
310: $this->_fieldMappings[$alias . '__' . $fields[$i]] = $alias . '.' . $fields[$i];
311: $fieldName = $this->name($alias . '.' . $fields[$i]);
312: $fieldAlias = $this->name($alias . '__' . $fields[$i]);
313: } else {
314: $build = explode('.', $fields[$i]);
315: $build[0] = trim($build[0], '[]');
316: $build[1] = trim($build[1], '[]');
317: $name = $build[0] . '.' . $build[1];
318: $alias = $build[0] . '__' . $build[1];
319:
320: $this->_fieldMappings[$alias] = $name;
321: $fieldName = $this->name($name);
322: $fieldAlias = $this->name($alias);
323: }
324: if ($model->getColumnType($fields[$i]) === 'datetime') {
325: $fieldName = "CONVERT(VARCHAR(20), {$fieldName}, 20)";
326: }
327: $fields[$i] = "{$fieldName} AS {$fieldAlias}";
328: }
329: $result[] = $prepend . $fields[$i];
330: }
331: return $result;
332: }
333: return $fields;
334: }
335:
336: 337: 338: 339: 340: 341: 342: 343: 344: 345:
346: public function create(Model $model, $fields = null, $values = null) {
347: if (!empty($values)) {
348: $fields = array_combine($fields, $values);
349: }
350: $primaryKey = $this->_getPrimaryKey($model);
351:
352: if (array_key_exists($primaryKey, $fields)) {
353: if (empty($fields[$primaryKey])) {
354: unset($fields[$primaryKey]);
355: } else {
356: $this->_execute('SET IDENTITY_INSERT ' . $this->fullTableName($model) . ' ON');
357: }
358: }
359: $result = parent::create($model, array_keys($fields), array_values($fields));
360: if (array_key_exists($primaryKey, $fields) && !empty($fields[$primaryKey])) {
361: $this->_execute('SET IDENTITY_INSERT ' . $this->fullTableName($model) . ' OFF');
362: }
363: return $result;
364: }
365:
366: 367: 368: 369: 370: 371: 372: 373: 374: 375:
376: public function update(Model $model, $fields = array(), $values = null, $conditions = null) {
377: if (!empty($values)) {
378: $fields = array_combine($fields, $values);
379: }
380: if (isset($fields[$model->primaryKey])) {
381: unset($fields[$model->primaryKey]);
382: }
383: if (empty($fields)) {
384: return true;
385: }
386: return parent::update($model, array_keys($fields), array_values($fields), $conditions);
387: }
388:
389: 390: 391: 392: 393: 394: 395:
396: public function limit($limit, $offset = null) {
397: if ($limit) {
398: $rt = '';
399: if (!strpos(strtolower($limit), 'top') || strpos(strtolower($limit), 'top') === 0) {
400: $rt = ' TOP';
401: }
402: $rt .= sprintf(' %u', $limit);
403: if (is_int($offset) && $offset > 0) {
404: $rt = sprintf(' OFFSET %u ROWS FETCH FIRST %u ROWS ONLY', $offset, $limit);
405: }
406: return $rt;
407: }
408: return null;
409: }
410:
411: 412: 413: 414: 415: 416: 417:
418: public function column($real) {
419: $limit = null;
420: $col = $real;
421: if (is_object($real) && isset($real->Field)) {
422: $limit = $real->Length;
423: $col = $real->Type;
424: }
425:
426: if ($col === 'datetime2') {
427: return 'datetime';
428: }
429: if (in_array($col, array('date', 'time', 'datetime', 'timestamp'))) {
430: return $col;
431: }
432: if ($col === 'bit') {
433: return 'boolean';
434: }
435: if (strpos($col, 'bigint') !== false) {
436: return 'biginteger';
437: }
438: if (strpos($col, 'int') !== false) {
439: return 'integer';
440: }
441: if (strpos($col, 'char') !== false && $limit == -1) {
442: return 'text';
443: }
444: if (strpos($col, 'char') !== false) {
445: return 'string';
446: }
447: if (strpos($col, 'text') !== false) {
448: return 'text';
449: }
450: if (strpos($col, 'binary') !== false || $col === 'image') {
451: return 'binary';
452: }
453: if (in_array($col, array('float', 'real'))) {
454: return 'float';
455: }
456: if (in_array($col, array('decimal', 'numeric'))) {
457: return 'decimal';
458: }
459: return 'text';
460: }
461:
462: 463: 464: 465: 466: 467: 468:
469: public function length($length) {
470: if (is_object($length) && isset($length->Length)) {
471: if ($length->Length == -1 && strpos($length->Type, 'char') !== false) {
472: return null;
473: }
474: if (in_array($length->Type, array('nchar', 'nvarchar'))) {
475: return floor($length->Length / 2);
476: }
477: return $length->Length;
478: }
479: return parent::length($length);
480: }
481:
482: 483: 484: 485: 486: 487:
488: public function resultSet($results) {
489: $this->map = array();
490: $numFields = $results->columnCount();
491: $index = 0;
492:
493: while ($numFields-- > 0) {
494: $column = $results->getColumnMeta($index);
495: $name = $column['name'];
496:
497: if (strpos($name, '__')) {
498: if (isset($this->_fieldMappings[$name]) && strpos($this->_fieldMappings[$name], '.')) {
499: $map = explode('.', $this->_fieldMappings[$name]);
500: } elseif (isset($this->_fieldMappings[$name])) {
501: $map = array(0, $this->_fieldMappings[$name]);
502: } else {
503: $map = array(0, $name);
504: }
505: } else {
506: $map = array(0, $name);
507: }
508: $map[] = ($column['sqlsrv:decl_type'] === 'bit') ? 'boolean' : $column['native_type'];
509: $this->map[$index++] = $map;
510: }
511: }
512:
513: 514: 515: 516: 517: 518: 519:
520: public function renderStatement($type, $data) {
521: switch (strtolower($type)) {
522: case 'select':
523: extract($data);
524: $fields = trim($fields);
525:
526: if (strpos($limit, 'TOP') !== false && strpos($fields, 'DISTINCT ') === 0) {
527: $limit = 'DISTINCT ' . trim($limit);
528: $fields = substr($fields, 9);
529: }
530:
531:
532: if ($limit && !$order) {
533: $order = 'ORDER BY (SELECT NULL)';
534: }
535:
536:
537: if (version_compare($this->getVersion(), '11', '<') && preg_match('/FETCH\sFIRST\s+([0-9]+)/i', $limit, $offset)) {
538: preg_match('/OFFSET\s*(\d+)\s*.*?(\d+)\s*ROWS/', $limit, $limitOffset);
539:
540: $limit = 'TOP ' . (int)$limitOffset[2];
541: $page = (int)($limitOffset[1] / $limitOffset[2]);
542: $offset = (int)($limitOffset[2] * $page);
543:
544: $rowCounter = self::ROW_COUNTER;
545: $sql = "SELECT {$limit} * FROM (
546: SELECT {$fields}, ROW_NUMBER() OVER ({$order}) AS {$rowCounter}
547: FROM {$table} {$alias} {$joins} {$conditions} {$group}
548: ) AS _cake_paging_
549: WHERE _cake_paging_.{$rowCounter} > {$offset}
550: ORDER BY _cake_paging_.{$rowCounter}
551: ";
552: return trim($sql);
553: }
554: if (strpos($limit, 'FETCH') !== false) {
555: return trim("SELECT {$fields} FROM {$table} {$alias} {$joins} {$conditions} {$group} {$order} {$limit}");
556: }
557: return trim("SELECT {$limit} {$fields} FROM {$table} {$alias} {$joins} {$conditions} {$group} {$order}");
558: case "schema":
559: extract($data);
560:
561: foreach ($indexes as $i => $index) {
562: if (preg_match('/PRIMARY KEY/', $index)) {
563: unset($indexes[$i]);
564: break;
565: }
566: }
567:
568: foreach (array('columns', 'indexes') as $var) {
569: if (is_array(${$var})) {
570: ${$var} = "\t" . implode(",\n\t", array_filter(${$var}));
571: }
572: }
573: return trim("CREATE TABLE {$table} (\n{$columns});\n{$indexes}");
574: default:
575: return parent::renderStatement($type, $data);
576: }
577: }
578:
579: 580: 581: 582: 583: 584: 585:
586: public function value($data, $column = null) {
587: if ($data === null || is_array($data) || is_object($data)) {
588: return parent::value($data, $column);
589: }
590: if (in_array($data, array('{$__cakeID__$}', '{$__cakeForeignKey__$}'), true)) {
591: return $data;
592: }
593:
594: if (empty($column)) {
595: $column = $this->introspectType($data);
596: }
597:
598: switch ($column) {
599: case 'string':
600: case 'text':
601: return 'N' . $this->_connection->quote($data, PDO::PARAM_STR);
602: default:
603: return parent::value($data, $column);
604: }
605: }
606:
607: 608: 609: 610: 611: 612: 613: 614: 615:
616: public function read(Model $model, $queryData = array(), $recursive = null) {
617: $results = parent::read($model, $queryData, $recursive);
618: $this->_fieldMappings = array();
619: return $results;
620: }
621:
622: 623: 624: 625: 626: 627:
628: public function fetchResult() {
629: if ($row = $this->_result->fetch(PDO::FETCH_NUM)) {
630: $resultRow = array();
631: foreach ($this->map as $col => $meta) {
632: list($table, $column, $type) = $meta;
633: if ($table === 0 && $column === self::ROW_COUNTER) {
634: continue;
635: }
636: $resultRow[$table][$column] = $row[$col];
637: if ($type === 'boolean' && $row[$col] !== null) {
638: $resultRow[$table][$column] = $this->boolean($resultRow[$table][$column]);
639: }
640: }
641: return $resultRow;
642: }
643: $this->_result->closeCursor();
644: return false;
645: }
646:
647: 648: 649: 650: 651: 652: 653: 654:
655: public function insertMulti($table, $fields, $values) {
656: $primaryKey = $this->_getPrimaryKey($table);
657: $hasPrimaryKey = $primaryKey && (
658: (is_array($fields) && in_array($primaryKey, $fields)
659: || (is_string($fields) && strpos($fields, $this->startQuote . $primaryKey . $this->endQuote) !== false))
660: );
661:
662: if ($hasPrimaryKey) {
663: $this->_execute('SET IDENTITY_INSERT ' . $this->fullTableName($table) . ' ON');
664: }
665:
666: parent::insertMulti($table, $fields, $values);
667:
668: if ($hasPrimaryKey) {
669: $this->_execute('SET IDENTITY_INSERT ' . $this->fullTableName($table) . ' OFF');
670: }
671: }
672:
673: 674: 675: 676: 677: 678: 679: 680:
681: public function buildColumn($column) {
682: $result = parent::buildColumn($column);
683: $result = preg_replace('/(bigint|int|integer)\([0-9]+\)/i', '$1', $result);
684: $result = preg_replace('/(bit)\([0-9]+\)/i', '$1', $result);
685: if (strpos($result, 'DEFAULT NULL') !== false) {
686: if (isset($column['default']) && $column['default'] === '') {
687: $result = str_replace('DEFAULT NULL', "DEFAULT ''", $result);
688: } else {
689: $result = str_replace('DEFAULT NULL', 'NULL', $result);
690: }
691: } elseif (array_keys($column) === array('type', 'name')) {
692: $result .= ' NULL';
693: } elseif (strpos($result, "DEFAULT N'")) {
694: $result = str_replace("DEFAULT N'", "DEFAULT '", $result);
695: }
696: return $result;
697: }
698:
699: 700: 701: 702: 703: 704: 705:
706: public function buildIndex($indexes, $table = null) {
707: $join = array();
708:
709: foreach ($indexes as $name => $value) {
710: if ($name === 'PRIMARY') {
711: $join[] = 'PRIMARY KEY (' . $this->name($value['column']) . ')';
712: } elseif (isset($value['unique']) && $value['unique']) {
713: $out = "ALTER TABLE {$table} ADD CONSTRAINT {$name} UNIQUE";
714:
715: if (is_array($value['column'])) {
716: $value['column'] = implode(', ', array_map(array(&$this, 'name'), $value['column']));
717: } else {
718: $value['column'] = $this->name($value['column']);
719: }
720: $out .= "({$value['column']});";
721: $join[] = $out;
722: }
723: }
724: return $join;
725: }
726:
727: 728: 729: 730: 731: 732:
733: protected function _getPrimaryKey($model) {
734: $schema = $this->describe($model);
735: foreach ($schema as $field => $props) {
736: if (isset($props['key']) && $props['key'] === 'primary') {
737: return $field;
738: }
739: }
740: return null;
741: }
742:
743: 744: 745: 746: 747: 748: 749:
750: public function lastAffected($source = null) {
751: $affected = parent::lastAffected();
752: if ($affected === null && $this->_lastAffected !== false) {
753: return $this->_lastAffected;
754: }
755: return $affected;
756: }
757:
758: 759: 760: 761: 762: 763: 764: 765: 766: 767:
768: protected function _execute($sql, $params = array(), $prepareOptions = array()) {
769: $this->_lastAffected = false;
770: $sql = trim($sql);
771: if (strncasecmp($sql, 'SELECT', 6) === 0 || preg_match('/^EXEC(?:UTE)?\s/mi', $sql) > 0) {
772: $prepareOptions += array(PDO::ATTR_CURSOR => PDO::CURSOR_SCROLL);
773: return parent::_execute($sql, $params, $prepareOptions);
774: }
775: try {
776: $this->_lastAffected = $this->_connection->exec($sql);
777: if ($this->_lastAffected === false) {
778: $this->_results = null;
779: $error = $this->_connection->errorInfo();
780: $this->error = $error[2];
781: return false;
782: }
783: return true;
784: } catch (PDOException $e) {
785: if (isset($query->queryString)) {
786: $e->queryString = $query->queryString;
787: } else {
788: $e->queryString = $sql;
789: }
790: throw $e;
791: }
792: }
793:
794: 795: 796: 797: 798: 799:
800: protected function _dropTable($table) {
801: return "IF OBJECT_ID('" . $this->fullTableName($table, false) . "', 'U') IS NOT NULL DROP TABLE " . $this->fullTableName($table) . ";";
802: }
803:
804: 805: 806: 807: 808:
809: public function getSchemaName() {
810: return $this->config['schema'];
811: }
812:
813: }
814: