forked from moodle/moodle
-
Notifications
You must be signed in to change notification settings - Fork 0
/
oci_native_moodle_database.php
1834 lines (1619 loc) · 73.5 KB
/
oci_native_moodle_database.php
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
260
261
262
263
264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
285
286
287
288
289
290
291
292
293
294
295
296
297
298
299
300
301
302
303
304
305
306
307
308
309
310
311
312
313
314
315
316
317
318
319
320
321
322
323
324
325
326
327
328
329
330
331
332
333
334
335
336
337
338
339
340
341
342
343
344
345
346
347
348
349
350
351
352
353
354
355
356
357
358
359
360
361
362
363
364
365
366
367
368
369
370
371
372
373
374
375
376
377
378
379
380
381
382
383
384
385
386
387
388
389
390
391
392
393
394
395
396
397
398
399
400
401
402
403
404
405
406
407
408
409
410
411
412
413
414
415
416
417
418
419
420
421
422
423
424
425
426
427
428
429
430
431
432
433
434
435
436
437
438
439
440
441
442
443
444
445
446
447
448
449
450
451
452
453
454
455
456
457
458
459
460
461
462
463
464
465
466
467
468
469
470
471
472
473
474
475
476
477
478
479
480
481
482
483
484
485
486
487
488
489
490
491
492
493
494
495
496
497
498
499
500
501
502
503
504
505
506
507
508
509
510
511
512
513
514
515
516
517
518
519
520
521
522
523
524
525
526
527
528
529
530
531
532
533
534
535
536
537
538
539
540
541
542
543
544
545
546
547
548
549
550
551
552
553
554
555
556
557
558
559
560
561
562
563
564
565
566
567
568
569
570
571
572
573
574
575
576
577
578
579
580
581
582
583
584
585
586
587
588
589
590
591
592
593
594
595
596
597
598
599
600
601
602
603
604
605
606
607
608
609
610
611
612
613
614
615
616
617
618
619
620
621
622
623
624
625
626
627
628
629
630
631
632
633
634
635
636
637
638
639
640
641
642
643
644
645
646
647
648
649
650
651
652
653
654
655
656
657
658
659
660
661
662
663
664
665
666
667
668
669
670
671
672
673
674
675
676
677
678
679
680
681
682
683
684
685
686
687
688
689
690
691
692
693
694
695
696
697
698
699
700
701
702
703
704
705
706
707
708
709
710
711
712
713
714
715
716
717
718
719
720
721
722
723
724
725
726
727
728
729
730
731
732
733
734
735
736
737
738
739
740
741
742
743
744
745
746
747
748
749
750
751
752
753
754
755
756
757
758
759
760
761
762
763
764
765
766
767
768
769
770
771
772
773
774
775
776
777
778
779
780
781
782
783
784
785
786
787
788
789
790
791
792
793
794
795
796
797
798
799
800
801
802
803
804
805
806
807
808
809
810
811
812
813
814
815
816
817
818
819
820
821
822
823
824
825
826
827
828
829
830
831
832
833
834
835
836
837
838
839
840
841
842
843
844
845
846
847
848
849
850
851
852
853
854
855
856
857
858
859
860
861
862
863
864
865
866
867
868
869
870
871
872
873
874
875
876
877
878
879
880
881
882
883
884
885
886
887
888
889
890
891
892
893
894
895
896
897
898
899
900
901
902
903
904
905
906
907
908
909
910
911
912
913
914
915
916
917
918
919
920
921
922
923
924
925
926
927
928
929
930
931
932
933
934
935
936
937
938
939
940
941
942
943
944
945
946
947
948
949
950
951
952
953
954
955
956
957
958
959
960
961
962
963
964
965
966
967
968
969
970
971
972
973
974
975
976
977
978
979
980
981
982
983
984
985
986
987
988
989
990
991
992
993
994
995
996
997
998
999
1000
<?php
// This file is part of Moodle - http://moodle.org/
//
// Moodle is free software: you can redistribute it and/or modify
// it under the terms of the GNU General Public License as published by
// the Free Software Foundation, either version 3 of the License, or
// (at your option) any later version.
//
// Moodle is distributed in the hope that it will be useful,
// but WITHOUT ANY WARRANTY; without even the implied warranty of
// MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the
// GNU General Public License for more details.
//
// You should have received a copy of the GNU General Public License
// along with Moodle. If not, see <http://www.gnu.org/licenses/>.
/**
* Native oci class representing moodle database interface.
*
* @package core_dml
* @copyright 2008 Petr Skoda (http://skodak.org)
* @license http://www.gnu.org/copyleft/gpl.html GNU GPL v3 or later
*/
defined('MOODLE_INTERNAL') || die();
require_once(__DIR__.'/moodle_database.php');
require_once(__DIR__.'/oci_native_moodle_recordset.php');
require_once(__DIR__.'/oci_native_moodle_temptables.php');
/**
* Native oci class representing moodle database interface.
*
* One complete reference for PHP + OCI:
* http://www.oracle.com/technology/tech/php/underground-php-oracle-manual.html
*
* @package core_dml
* @copyright 2008 Petr Skoda (http://skodak.org)
* @license http://www.gnu.org/copyleft/gpl.html GNU GPL v3 or later
*/
class oci_native_moodle_database extends moodle_database {
protected $oci = null;
/** @var To store stmt errors and enable get_last_error() to detect them.*/
private $last_stmt_error = null;
/** @var Default value initialised in connect method, we need the driver to be present.*/
private $commit_status = null;
/** @var To handle oci driver default verbosity.*/
private $last_error_reporting;
/** @var To store unique_session_id. Needed for temp tables unique naming.*/
private $unique_session_id;
/**
* Detects if all needed PHP stuff installed.
* Note: can be used before connect()
* @return mixed true if ok, string if something
*/
public function driver_installed() {
if (!extension_loaded('oci8')) {
return get_string('ociextensionisnotpresentinphp', 'install');
}
return true;
}
/**
* Returns database family type - describes SQL dialect
* Note: can be used before connect()
* @return string db family name (mysql, postgres, mssql, oracle, etc.)
*/
public function get_dbfamily() {
return 'oracle';
}
/**
* Returns more specific database driver type
* Note: can be used before connect()
* @return string db type mysqli, pgsql, oci, mssql, sqlsrv
*/
protected function get_dbtype() {
return 'oci';
}
/**
* Returns general database library name
* Note: can be used before connect()
* @return string db type pdo, native
*/
protected function get_dblibrary() {
return 'native';
}
/**
* Returns localised database type name
* Note: can be used before connect()
* @return string
*/
public function get_name() {
return get_string('nativeoci', 'install');
}
/**
* Returns localised database configuration help.
* Note: can be used before connect()
* @return string
*/
public function get_configuration_help() {
return get_string('nativeocihelp', 'install');
}
/**
* Diagnose database and tables, this function is used
* to verify database and driver settings, db engine types, etc.
*
* @return string null means everything ok, string means problem found.
*/
public function diagnose() {
return null;
}
/**
* Connect to db
* Must be called before other methods.
* @param string $dbhost The database host.
* @param string $dbuser The database username.
* @param string $dbpass The database username's password.
* @param string $dbname The name of the database being connected to.
* @param mixed $prefix string means moodle db prefix, false used for external databases where prefix not used
* @param array $dboptions driver specific options
* @return bool true
* @throws dml_connection_exception if error
*/
public function connect($dbhost, $dbuser, $dbpass, $dbname, $prefix, array $dboptions=null) {
if ($prefix == '' and !$this->external) {
//Enforce prefixes for everybody but mysql
throw new dml_exception('prefixcannotbeempty', $this->get_dbfamily());
}
if (!$this->external and strlen($prefix) > 2) {
//Max prefix length for Oracle is 2cc
$a = (object)array('dbfamily'=>'oracle', 'maxlength'=>2);
throw new dml_exception('prefixtoolong', $a);
}
$driverstatus = $this->driver_installed();
if ($driverstatus !== true) {
throw new dml_exception('dbdriverproblem', $driverstatus);
}
// Autocommit ON by default.
// Switching to OFF (OCI_DEFAULT), when playing with transactions
// please note this thing is not defined if oracle driver not present in PHP
// which means it can not be used as default value of object property!
$this->commit_status = OCI_COMMIT_ON_SUCCESS;
$this->store_settings($dbhost, $dbuser, $dbpass, $dbname, $prefix, $dboptions);
unset($this->dboptions['dbsocket']);
// NOTE: use of ', ", / and \ is very problematic, even native oracle tools seem to have
// problems with these, so just forget them and do not report problems into tracker...
if (empty($this->dbhost)) {
// old style full address (TNS)
$dbstring = $this->dbname;
} else {
if (empty($this->dboptions['dbport'])) {
$this->dboptions['dbport'] = 1521;
}
$dbstring = '//'.$this->dbhost.':'.$this->dboptions['dbport'].'/'.$this->dbname;
}
ob_start();
if (empty($this->dboptions['dbpersist'])) {
$this->oci = oci_new_connect($this->dbuser, $this->dbpass, $dbstring, 'AL32UTF8');
} else {
$this->oci = oci_pconnect($this->dbuser, $this->dbpass, $dbstring, 'AL32UTF8');
}
$dberr = ob_get_contents();
ob_end_clean();
if ($this->oci === false) {
$this->oci = null;
$e = oci_error();
if (isset($e['message'])) {
$dberr = $e['message'];
}
throw new dml_connection_exception($dberr);
}
// Make sure moodle package is installed - now required.
if (!$this->oci_package_installed()) {
try {
$this->attempt_oci_package_install();
} catch (Exception $e) {
// Ignore problems, only the result counts,
// admins have to fix it manually if necessary.
}
if (!$this->oci_package_installed()) {
throw new dml_exception('dbdriverproblem', 'Oracle PL/SQL Moodle support package MOODLELIB is not installed! Database administrator has to execute /lib/dml/oci_native_moodle_package.sql script.');
}
}
// get unique session id, to be used later for temp tables stuff
$sql = 'SELECT DBMS_SESSION.UNIQUE_SESSION_ID() FROM DUAL';
$this->query_start($sql, null, SQL_QUERY_AUX);
$stmt = $this->parse_query($sql);
$result = oci_execute($stmt, $this->commit_status);
$this->query_end($result, $stmt);
$records = null;
oci_fetch_all($stmt, $records, 0, -1, OCI_FETCHSTATEMENT_BY_ROW);
oci_free_statement($stmt);
$this->unique_session_id = reset($records[0]);
//note: do not send "ALTER SESSION SET NLS_NUMERIC_CHARACTERS='.,'" !
// instead fix our PHP code to convert "," to "." properly!
// Connection stabilised and configured, going to instantiate the temptables controller
$this->temptables = new oci_native_moodle_temptables($this, $this->unique_session_id);
return true;
}
/**
* Close database connection and release all resources
* and memory (especially circular memory references).
* Do NOT use connect() again, create a new instance if needed.
*/
public function dispose() {
parent::dispose(); // Call parent dispose to write/close session and other common stuff before closing connection
if ($this->oci) {
oci_close($this->oci);
$this->oci = null;
}
}
/**
* Called before each db query.
* @param string $sql
* @param array array of parameters
* @param int $type type of query
* @param mixed $extrainfo driver specific extra information
* @return void
*/
protected function query_start($sql, array $params=null, $type, $extrainfo=null) {
parent::query_start($sql, $params, $type, $extrainfo);
// oci driver tents to send debug to output, we do not need that ;-)
$this->last_error_reporting = error_reporting(0);
}
/**
* Called immediately after each db query.
* @param mixed db specific result
* @return void
*/
protected function query_end($result, $stmt=null) {
// reset original debug level
error_reporting($this->last_error_reporting);
if ($stmt and $result === false) {
// Look for stmt error and store it
if (is_resource($stmt)) {
$e = oci_error($stmt);
if ($e !== false) {
$this->last_stmt_error = $e['message'];
}
}
oci_free_statement($stmt);
}
parent::query_end($result);
}
/**
* Returns database server info array
* @return array Array containing 'description' and 'version' info
*/
public function get_server_info() {
static $info = null; // TODO: move to real object property
if (is_null($info)) {
$this->query_start("--oci_server_version()", null, SQL_QUERY_AUX);
$description = oci_server_version($this->oci);
$this->query_end(true);
preg_match('/(\d+\.)+\d+/', $description, $matches);
$info = array('description'=>$description, 'version'=>$matches[0]);
}
return $info;
}
/**
* Converts short table name {tablename} to real table name
* supporting temp tables ($this->unique_session_id based) if detected
*
* @param string sql
* @return string sql
*/
protected function fix_table_names($sql) {
if (preg_match_all('/\{([a-z][a-z0-9_]*)\}/', $sql, $matches)) {
foreach($matches[0] as $key=>$match) {
$name = $matches[1][$key];
if ($this->temptables && $this->temptables->is_temptable($name)) {
$sql = str_replace($match, $this->temptables->get_correct_name($name), $sql);
} else {
$sql = str_replace($match, $this->prefix.$name, $sql);
}
}
}
return $sql;
}
/**
* Returns supported query parameter types
* @return int bitmask of accepted SQL_PARAMS_*
*/
protected function allowed_param_types() {
return SQL_PARAMS_NAMED;
}
/**
* Returns last error reported by database engine.
* @return string error message
*/
public function get_last_error() {
$error = false;
// First look for any previously saved stmt error
if (!empty($this->last_stmt_error)) {
$error = $this->last_stmt_error;
$this->last_stmt_error = null;
} else { // Now try connection error
$e = oci_error($this->oci);
if ($e !== false) {
$error = $e['message'];
}
}
return $error;
}
/**
* Prepare the statement for execution
* @throws dml_connection_exception
* @param string $sql
* @return resource
*/
protected function parse_query($sql) {
$stmt = oci_parse($this->oci, $sql);
if ($stmt == false) {
throw new dml_connection_exception('Can not parse sql query'); //TODO: maybe add better info
}
return $stmt;
}
/**
* Make sure there are no reserved words in param names...
* @param string $sql
* @param array $params
* @return array ($sql, $params) updated query and parameters
*/
protected function tweak_param_names($sql, array $params) {
if (empty($params)) {
return array($sql, $params);
}
$newparams = array();
$searcharr = array(); // search => replace pairs
foreach ($params as $name => $value) {
// Keep the name within the 30 chars limit always (prefixing/replacing)
if (strlen($name) <= 28) {
$newname = 'o_' . $name;
} else {
$newname = 'o_' . substr($name, 2);
}
$newparams[$newname] = $value;
$searcharr[':' . $name] = ':' . $newname;
}
// sort by length desc to avoid potential str_replace() overlap
uksort($searcharr, array('oci_native_moodle_database', 'compare_by_length_desc'));
$sql = str_replace(array_keys($searcharr), $searcharr, $sql);
return array($sql, $newparams);
}
/**
* Return tables in database WITHOUT current prefix
* @param bool $usecache if true, returns list of cached tables.
* @return array of table names in lowercase and without prefix
*/
public function get_tables($usecache=true) {
if ($usecache and $this->tables !== null) {
return $this->tables;
}
$this->tables = array();
$prefix = str_replace('_', "\\_", strtoupper($this->prefix));
$sql = "SELECT TABLE_NAME
FROM CAT
WHERE TABLE_TYPE='TABLE'
AND TABLE_NAME NOT LIKE 'BIN\$%'
AND TABLE_NAME LIKE '$prefix%' ESCAPE '\\'";
$this->query_start($sql, null, SQL_QUERY_AUX);
$stmt = $this->parse_query($sql);
$result = oci_execute($stmt, $this->commit_status);
$this->query_end($result, $stmt);
$records = null;
oci_fetch_all($stmt, $records, 0, -1, OCI_ASSOC);
oci_free_statement($stmt);
$records = array_map('strtolower', $records['TABLE_NAME']);
foreach ($records as $tablename) {
if ($this->prefix !== false && $this->prefix !== '') {
if (strpos($tablename, $this->prefix) !== 0) {
continue;
}
$tablename = substr($tablename, strlen($this->prefix));
}
$this->tables[$tablename] = $tablename;
}
// Add the currently available temptables
$this->tables = array_merge($this->tables, $this->temptables->get_temptables());
return $this->tables;
}
/**
* Return table indexes - everything lowercased.
* @param string $table The table we want to get indexes from.
* @return array An associative array of indexes containing 'unique' flag and 'columns' being indexed
*/
public function get_indexes($table) {
$indexes = array();
$tablename = strtoupper($this->prefix.$table);
$sql = "SELECT i.INDEX_NAME, i.UNIQUENESS, c.COLUMN_POSITION, c.COLUMN_NAME, ac.CONSTRAINT_TYPE
FROM ALL_INDEXES i
JOIN ALL_IND_COLUMNS c ON c.INDEX_NAME=i.INDEX_NAME
LEFT JOIN ALL_CONSTRAINTS ac ON (ac.TABLE_NAME=i.TABLE_NAME AND ac.CONSTRAINT_NAME=i.INDEX_NAME AND ac.CONSTRAINT_TYPE='P')
WHERE i.TABLE_NAME = '$tablename'
ORDER BY i.INDEX_NAME, c.COLUMN_POSITION";
$stmt = $this->parse_query($sql);
$result = oci_execute($stmt, $this->commit_status);
$this->query_end($result, $stmt);
$records = null;
oci_fetch_all($stmt, $records, 0, -1, OCI_FETCHSTATEMENT_BY_ROW);
oci_free_statement($stmt);
foreach ($records as $record) {
if ($record['CONSTRAINT_TYPE'] === 'P') {
//ignore for now;
continue;
}
$indexname = strtolower($record['INDEX_NAME']);
if (!isset($indexes[$indexname])) {
$indexes[$indexname] = array('primary' => ($record['CONSTRAINT_TYPE'] === 'P'),
'unique' => ($record['UNIQUENESS'] === 'UNIQUE'),
'columns' => array());
}
$indexes[$indexname]['columns'][] = strtolower($record['COLUMN_NAME']);
}
return $indexes;
}
/**
* Returns detailed information about columns in table. This information is cached internally.
* @param string $table name
* @param bool $usecache
* @return array array of database_column_info objects indexed with column names
*/
public function get_columns($table, $usecache=true) {
if ($usecache) {
$properties = array('dbfamily' => $this->get_dbfamily(), 'settings' => $this->get_settings_hash());
$cache = cache::make('core', 'databasemeta', $properties);
if ($data = $cache->get($table)) {
return $data;
}
}
if (!$table) { // table not specified, return empty array directly
return array();
}
$structure = array();
// We give precedence to CHAR_LENGTH for VARCHAR2 columns over WIDTH because the former is always
// BYTE based and, for cross-db operations, we want CHAR based results. See MDL-29415
// Instead of guessing sequence based exclusively on name, check tables against user_triggers to
// ensure the table has a 'before each row' trigger to assume 'id' is auto_increment. MDL-32365
$sql = "SELECT CNAME, COLTYPE, nvl(CHAR_LENGTH, WIDTH) AS WIDTH, SCALE, PRECISION, NULLS, DEFAULTVAL,
DECODE(NVL(TRIGGER_NAME, '0'), '0', '0', '1') HASTRIGGER
FROM COL c
LEFT JOIN USER_TAB_COLUMNS u ON (u.TABLE_NAME = c.TNAME AND u.COLUMN_NAME = c.CNAME AND u.DATA_TYPE = 'VARCHAR2')
LEFT JOIN USER_TRIGGERS t ON (t.TABLE_NAME = c.TNAME AND TRIGGER_TYPE = 'BEFORE EACH ROW' AND c.CNAME = 'ID')
WHERE TNAME = UPPER('{" . $table . "}')
ORDER BY COLNO";
list($sql, $params, $type) = $this->fix_sql_params($sql, null);
$this->query_start($sql, null, SQL_QUERY_AUX);
$stmt = $this->parse_query($sql);
$result = oci_execute($stmt, $this->commit_status);
$this->query_end($result, $stmt);
$records = null;
oci_fetch_all($stmt, $records, 0, -1, OCI_FETCHSTATEMENT_BY_ROW);
oci_free_statement($stmt);
if (!$records) {
return array();
}
foreach ($records as $rawcolumn) {
$rawcolumn = (object)$rawcolumn;
$info = new stdClass();
$info->name = strtolower($rawcolumn->CNAME);
$info->auto_increment = ((int)$rawcolumn->HASTRIGGER) ? true : false;
$matches = null;
if ($rawcolumn->COLTYPE === 'VARCHAR2'
or $rawcolumn->COLTYPE === 'VARCHAR'
or $rawcolumn->COLTYPE === 'NVARCHAR2'
or $rawcolumn->COLTYPE === 'NVARCHAR'
or $rawcolumn->COLTYPE === 'CHAR'
or $rawcolumn->COLTYPE === 'NCHAR') {
$info->type = $rawcolumn->COLTYPE;
$info->meta_type = 'C';
$info->max_length = $rawcolumn->WIDTH;
$info->scale = null;
$info->not_null = ($rawcolumn->NULLS === 'NOT NULL');
$info->has_default = !is_null($rawcolumn->DEFAULTVAL);
if ($info->has_default) {
// this is hacky :-(
if ($rawcolumn->DEFAULTVAL === 'NULL') {
$info->default_value = null;
} else if ($rawcolumn->DEFAULTVAL === "' ' ") { // Sometimes it's stored with trailing space
$info->default_value = "";
} else if ($rawcolumn->DEFAULTVAL === "' '") { // Sometimes it's stored without trailing space
$info->default_value = "";
} else {
$info->default_value = trim($rawcolumn->DEFAULTVAL); // remove trailing space
$info->default_value = substr($info->default_value, 1, strlen($info->default_value)-2); //trim ''
}
} else {
$info->default_value = null;
}
$info->primary_key = false;
$info->binary = false;
$info->unsigned = null;
$info->unique = null;
} else if ($rawcolumn->COLTYPE === 'NUMBER') {
$info->type = $rawcolumn->COLTYPE;
$info->max_length = $rawcolumn->PRECISION;
$info->binary = false;
if (!is_null($rawcolumn->SCALE) && $rawcolumn->SCALE == 0) { // null in oracle scale allows decimals => not integer
// integer
if ($info->name === 'id') {
$info->primary_key = true;
$info->meta_type = 'R';
$info->unique = true;
$info->has_default = false;
} else {
$info->primary_key = false;
$info->meta_type = 'I';
$info->unique = null;
}
$info->scale = 0;
} else {
//float
$info->meta_type = 'N';
$info->primary_key = false;
$info->unsigned = null;
$info->unique = null;
$info->scale = $rawcolumn->SCALE;
}
$info->not_null = ($rawcolumn->NULLS === 'NOT NULL');
$info->has_default = !is_null($rawcolumn->DEFAULTVAL);
if ($info->has_default) {
$info->default_value = trim($rawcolumn->DEFAULTVAL); // remove trailing space
} else {
$info->default_value = null;
}
} else if ($rawcolumn->COLTYPE === 'FLOAT') {
$info->type = $rawcolumn->COLTYPE;
$info->max_length = (int)($rawcolumn->PRECISION * 3.32193);
$info->primary_key = false;
$info->meta_type = 'N';
$info->unique = null;
$info->not_null = ($rawcolumn->NULLS === 'NOT NULL');
$info->has_default = !is_null($rawcolumn->DEFAULTVAL);
if ($info->has_default) {
$info->default_value = trim($rawcolumn->DEFAULTVAL); // remove trailing space
} else {
$info->default_value = null;
}
} else if ($rawcolumn->COLTYPE === 'CLOB'
or $rawcolumn->COLTYPE === 'NCLOB') {
$info->type = $rawcolumn->COLTYPE;
$info->meta_type = 'X';
$info->max_length = -1;
$info->scale = null;
$info->scale = null;
$info->not_null = ($rawcolumn->NULLS === 'NOT NULL');
$info->has_default = !is_null($rawcolumn->DEFAULTVAL);
if ($info->has_default) {
// this is hacky :-(
if ($rawcolumn->DEFAULTVAL === 'NULL') {
$info->default_value = null;
} else if ($rawcolumn->DEFAULTVAL === "' ' ") { // Sometimes it's stored with trailing space
$info->default_value = "";
} else if ($rawcolumn->DEFAULTVAL === "' '") { // Other times it's stored without trailing space
$info->default_value = "";
} else {
$info->default_value = trim($rawcolumn->DEFAULTVAL); // remove trailing space
$info->default_value = substr($info->default_value, 1, strlen($info->default_value)-2); //trim ''
}
} else {
$info->default_value = null;
}
$info->primary_key = false;
$info->binary = false;
$info->unsigned = null;
$info->unique = null;
} else if ($rawcolumn->COLTYPE === 'BLOB') {
$info->type = $rawcolumn->COLTYPE;
$info->meta_type = 'B';
$info->max_length = -1;
$info->scale = null;
$info->scale = null;
$info->not_null = ($rawcolumn->NULLS === 'NOT NULL');
$info->has_default = !is_null($rawcolumn->DEFAULTVAL);
if ($info->has_default) {
// this is hacky :-(
if ($rawcolumn->DEFAULTVAL === 'NULL') {
$info->default_value = null;
} else if ($rawcolumn->DEFAULTVAL === "' ' ") { // Sometimes it's stored with trailing space
$info->default_value = "";
} else if ($rawcolumn->DEFAULTVAL === "' '") { // Sometimes it's stored without trailing space
$info->default_value = "";
} else {
$info->default_value = trim($rawcolumn->DEFAULTVAL); // remove trailing space
$info->default_value = substr($info->default_value, 1, strlen($info->default_value)-2); //trim ''
}
} else {
$info->default_value = null;
}
$info->primary_key = false;
$info->binary = true;
$info->unsigned = null;
$info->unique = null;
} else {
// unknown type - sorry
$info->type = $rawcolumn->COLTYPE;
$info->meta_type = '?';
}
$structure[$info->name] = new database_column_info($info);
}
if ($usecache) {
$cache->set($table, $structure);
}
return $structure;
}
/**
* Normalise values based in RDBMS dependencies (booleans, LOBs...)
*
* @param database_column_info $column column metadata corresponding with the value we are going to normalise
* @param mixed $value value we are going to normalise
* @return mixed the normalised value
*/
protected function normalise_value($column, $value) {
$this->detect_objects($value);
if (is_bool($value)) { // Always, convert boolean to int
$value = (int)$value;
} else if ($column->meta_type == 'B') { // BLOB detected, we return 'blob' array instead of raw value to allow
if (!is_null($value)) { // binding/executing code later to know about its nature
$value = array('blob' => $value);
}
} else if ($column->meta_type == 'X' && strlen($value) > 4000) { // CLOB detected (>4000 optimisation), we return 'clob'
if (!is_null($value)) { // array instead of raw value to allow binding/
$value = array('clob' => (string)$value); // executing code later to know about its nature
}
} else if ($value === '') {
if ($column->meta_type == 'I' or $column->meta_type == 'F' or $column->meta_type == 'N') {
$value = 0; // prevent '' problems in numeric fields
}
}
return $value;
}
/**
* Transforms the sql and params in order to emulate the LIMIT clause available in other DBs
*
* @param string $sql the SQL select query to execute.
* @param array $params array of sql parameters
* @param int $limitfrom return a subset of records, starting at this point (optional, required if $limitnum is set).
* @param int $limitnum return a subset comprising this many records (optional, required if $limitfrom is set).
* @return array with the transformed sql and params updated
*/
private function get_limit_sql($sql, array $params = null, $limitfrom=0, $limitnum=0) {
list($limitfrom, $limitnum) = $this->normalise_limit_from_num($limitfrom, $limitnum);
// TODO: Add the /*+ FIRST_ROWS */ hint if there isn't another hint
if ($limitfrom and $limitnum) {
$sql = "SELECT oracle_o.*
FROM (SELECT oracle_i.*, rownum AS oracle_rownum
FROM ($sql) oracle_i
WHERE rownum <= :oracle_num_rows
) oracle_o
WHERE oracle_rownum > :oracle_skip_rows";
$params['oracle_num_rows'] = $limitfrom + $limitnum;
$params['oracle_skip_rows'] = $limitfrom;
} else if ($limitfrom and !$limitnum) {
$sql = "SELECT oracle_o.*
FROM (SELECT oracle_i.*, rownum AS oracle_rownum
FROM ($sql) oracle_i
) oracle_o
WHERE oracle_rownum > :oracle_skip_rows";
$params['oracle_skip_rows'] = $limitfrom;
} else if (!$limitfrom and $limitnum) {
$sql = "SELECT *
FROM ($sql)
WHERE rownum <= :oracle_num_rows";
$params['oracle_num_rows'] = $limitnum;
}
return array($sql, $params);
}
/**
* This function will handle all the column values before being inserted/updated to DB for Oracle
* installations. This is because the "special feature" of Oracle where the empty string is
* equal to NULL and this presents a problem with all our currently NOT NULL default '' fields.
* (and with empties handling in general)
*
* Note that this function is 100% private and should be used, exclusively by DML functions
* in this file. Also, this is considered a DIRTY HACK to be removed when possible.
*
* This function is private and must not be used outside this driver at all
*
* @param $table string the table where the record is going to be inserted/updated (without prefix)
* @param $field string the field where the record is going to be inserted/updated
* @param $value mixed the value to be inserted/updated
*/
private function oracle_dirty_hack ($table, $field, $value) {
// General bound parameter, just hack the spaces and pray it will work.
if (!$table) {
if ($value === '') {
return ' ';
} else if (is_bool($value)) {
return (int)$value;
} else {
return $value;
}
}
// Get metadata
$columns = $this->get_columns($table);
if (!isset($columns[$field])) {
if ($value === '') {
return ' ';
} else if (is_bool($value)) {
return (int)$value;
} else {
return $value;
}
}
$column = $columns[$field];
// !! This paragraph explains behaviour before Moodle 2.0:
//
// For Oracle DB, empty strings are converted to NULLs in DB
// and this breaks a lot of NOT NULL columns currently Moodle. In the future it's
// planned to move some of them to NULL, if they must accept empty values and this
// piece of code will become less and less used. But, for now, we need it.
// What we are going to do is to examine all the data being inserted and if it's
// an empty string (NULL for Oracle) and the field is defined as NOT NULL, we'll modify
// such data in the best form possible ("0" for booleans and numbers and " " for the
// rest of strings. It isn't optimal, but the only way to do so.
// In the opposite, when retrieving records from Oracle, we'll decode " " back to
// empty strings to allow everything to work properly. DIRTY HACK.
// !! These paragraphs explain the rationale about the change for Moodle 2.5:
//
// Before Moodle 2.0, we only used to apply this DIRTY HACK to NOT NULL columns, as
// stated above, but it causes one problem in NULL columns where both empty strings
// and real NULLs are stored as NULLs, being impossible to differentiate them when
// being retrieved from DB.
//
// So, starting with Moodle 2.0, we are going to apply the DIRTY HACK to all the
// CHAR/CLOB columns no matter of their nullability. That way, when retrieving
// NULLABLE fields we'll get proper empties and NULLs differentiated, so we'll be able
// to rely in NULL/empty/content contents without problems, until now that wasn't
// possible at all.
//
// One space DIRTY HACK is now applied automatically for all query parameters
// and results. The only problem is string concatenation where the glue must
// be specified as "' '" sql fragment.
//
// !! Conclusions:
//
// From Moodle 2.5 onwards, ALL empty strings in Oracle DBs will be stored as
// 1-whitespace char, ALL NULLs as NULLs and, obviously, content as content. And
// those 1-whitespace chars will be converted back to empty strings by all the
// get_field/record/set() functions transparently and any SQL needing direct handling
// of empties will have to use placeholders or sql_isempty() helper function.
// If the field isn't VARCHAR or CLOB, skip
if ($column->meta_type != 'C' and $column->meta_type != 'X') {
return $value;
}
// If the value isn't empty, skip
if (!empty($value)) {
return $value;
}
// Now, we have one empty value, going to be inserted to one VARCHAR2 or CLOB field
// Try to get the best value to be inserted
// The '0' string doesn't need any transformation, skip
if ($value === '0') {
return $value;
}
// Transformations start
if (gettype($value) == 'boolean') {
return '0'; // Transform false to '0' that evaluates the same for PHP
} else if (gettype($value) == 'integer') {
return '0'; // Transform 0 to '0' that evaluates the same for PHP
} else if ($value === '') {
return ' '; // Transform '' to ' ' that DON'T EVALUATE THE SAME
// (we'll transform back again on get_records_XXX functions and others)!!
}
// Fail safe to original value
return $value;
}
/**
* Helper function to order by string length desc
*
* @param $a string first element to compare
* @param $b string second element to compare
* @return int < 0 $a goes first (is less), 0 $b goes first, 0 doesn't matter
*/
private function compare_by_length_desc($a, $b) {
return strlen($b) - strlen($a);
}
/**
* Is db in unicode mode?
* @return bool
*/
public function setup_is_unicodedb() {
$sql = "SELECT VALUE
FROM NLS_DATABASE_PARAMETERS
WHERE PARAMETER = 'NLS_CHARACTERSET'";
$this->query_start($sql, null, SQL_QUERY_AUX);
$stmt = $this->parse_query($sql);
$result = oci_execute($stmt, $this->commit_status);
$this->query_end($result, $stmt);
$records = null;
oci_fetch_all($stmt, $records, 0, -1, OCI_FETCHSTATEMENT_BY_COLUMN);
oci_free_statement($stmt);
return (isset($records['VALUE'][0]) and $records['VALUE'][0] === 'AL32UTF8');
}
/**
* Do NOT use in code, to be used by database_manager only!
* @param string|array $sql query
* @return bool true
* @throws ddl_change_structure_exception A DDL specific exception is thrown for any errors.
*/
public function change_database_structure($sql) {
$this->get_manager(); // Includes DDL exceptions classes ;-)
$sqls = (array)$sql;
try {
foreach ($sqls as $sql) {
$this->query_start($sql, null, SQL_QUERY_STRUCTURE);
$stmt = $this->parse_query($sql);
$result = oci_execute($stmt, $this->commit_status);
$this->query_end($result, $stmt);
oci_free_statement($stmt);
}
} catch (ddl_change_structure_exception $e) {
$this->reset_caches();
throw $e;
}
$this->reset_caches();
return true;
}
protected function bind_params($stmt, array $params=null, $tablename=null) {
$descriptors = array();
if ($params) {
$columns = array();
if ($tablename) {
$columns = $this->get_columns($tablename);
}
foreach($params as $key => $value) {
// Decouple column name and param name as far as sometimes they aren't the same
if ($key == 'o_newfieldtoset') { // found case where column and key diverge, handle that
$columnname = key($value); // columnname is the key of the array
$params[$key] = $value[$columnname]; // set the proper value in the $params array and
$value = $value[$columnname]; // set the proper value in the $value variable
} else {
$columnname = preg_replace('/^o_/', '', $key); // Default columnname (for DB introspecting is key), but...
}
// Continue processing
// Now, handle already detected LOBs
if (is_array($value)) { // Let's go to bind special cases (lob descriptors)
if (isset($value['clob'])) {
$lob = oci_new_descriptor($this->oci, OCI_DTYPE_LOB);
oci_bind_by_name($stmt, $key, $lob, -1, SQLT_CLOB);
$lob->writeTemporary($this->oracle_dirty_hack($tablename, $columnname, $params[$key]['clob']), OCI_TEMP_CLOB);
$descriptors[] = $lob;
continue; // Column binding finished, go to next one
} else if (isset($value['blob'])) {
$lob = oci_new_descriptor($this->oci, OCI_DTYPE_LOB);
oci_bind_by_name($stmt, $key, $lob, -1, SQLT_BLOB);
$lob->writeTemporary($params[$key]['blob'], OCI_TEMP_BLOB);
$descriptors[] = $lob;
continue; // Column binding finished, go to next one
}
} else {
// If, at this point, the param value > 4000 (bytes), let's assume it's a clob
// passed in an arbitrary sql (not processed by normalise_value() ever,
// and let's handle it as such. This will provide proper binding of CLOBs in
// conditions and other raw SQLs not covered by the above function.
if (strlen($value) > 4000) {
$lob = oci_new_descriptor($this->oci, OCI_DTYPE_LOB);
oci_bind_by_name($stmt, $key, $lob, -1, SQLT_CLOB);
$lob->writeTemporary($this->oracle_dirty_hack($tablename, $columnname, $params[$key]), OCI_TEMP_CLOB);
$descriptors[] = $lob;
continue; // Param binding finished, go to next one.
}
}
// TODO: Put proper types and length is possible (enormous speedup)
// Arrived here, continue with standard processing, using metadata if possible
if (isset($columns[$columnname])) {
$type = $columns[$columnname]->meta_type;
$maxlength = $columns[$columnname]->max_length;
} else {
$type = '?';
$maxlength = -1;
}
switch ($type) {
case 'I':
case 'R':
// TODO: Optimise
oci_bind_by_name($stmt, $key, $params[$key]);
break;
case 'N':
case 'F':
// TODO: Optimise
oci_bind_by_name($stmt, $key, $params[$key]);
break;
case 'B':
// TODO: Only arrive here if BLOB is null: Bind if so, else exception!
// don't break here
case 'X':
// TODO: Only arrive here if CLOB is null or <= 4000 cc, else exception
// don't break here
default: // Bind as CHAR (applying dirty hack)
// TODO: Optimise
$params[$key] = $this->oracle_dirty_hack($tablename, $columnname, $params[$key]);
oci_bind_by_name($stmt, $key, $params[$key]);
}
}
}
return $descriptors;
}