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
<?php
/*
* $Id$
*
* THIS SOFTWARE IS PROVIDED BY THE COPYRIGHT HOLDERS AND CONTRIBUTORS
* "AS IS" AND ANY EXPRESS OR IMPLIED WARRANTIES, INCLUDING, BUT NOT
* LIMITED TO, THE IMPLIED WARRANTIES OF MERCHANTABILITY AND FITNESS FOR
* A PARTICULAR PURPOSE ARE DISCLAIMED. IN NO EVENT SHALL THE COPYRIGHT
* OWNER OR CONTRIBUTORS BE LIABLE FOR ANY DIRECT, INDIRECT, INCIDENTAL,
* SPECIAL, EXEMPLARY, OR CONSEQUENTIAL DAMAGES (INCLUDING, BUT NOT
* LIMITED TO, PROCUREMENT OF SUBSTITUTE GOODS OR SERVICES; LOSS OF USE,
* DATA, OR PROFITS; OR BUSINESS INTERRUPTION) HOWEVER CAUSED AND ON ANY
* THEORY OF LIABILITY, WHETHER IN CONTRACT, STRICT LIABILITY, OR TORT
* (INCLUDING NEGLIGENCE OR OTHERWISE) ARISING IN ANY WAY OUT OF THE USE
* OF THIS SOFTWARE, EVEN IF ADVISED OF THE POSSIBILITY OF SUCH DAMAGE.
*
* This software consists of voluntary contributions made by many individuals
* and is licensed under the LGPL. For more information, see
* <http://www.phpdoctrine.org>.
*/
Doctrine::autoload('Doctrine_Export');
/**
* Doctrine_Export_Oracle
*
* @package Doctrine
* @subpackage Export
* @author Konsta Vesterinen <kvesteri@cc.hut.fi>
* @author Lukas Smith <smith@pooteeweet.org> (PEAR MDB2 library)
* @license http://www.opensource.org/licenses/lgpl-license.php LGPL
* @link www.phpdoctrine.org
* @since 1.0
* @version $Revision$
*/
class Doctrine_Export_Oracle extends Doctrine_Export
{
/**
* create a new database
*
* @param object $db database object that is extended by this class
* @param string $name name of the database that should be created
* @return mixed MDB2_OK on success, a MDB2 error on failure
* @access public
*/
public function createDatabase($name)
{
if ( ! $this->conn->getAttribute(Doctrine::ATTR_EMULATE_DATABASE))
throw new Doctrine_Export_Exception('database creation is only supported if the "emulate_database" attribute is enabled');
$username = sprintf($this->conn->getAttribute(Doctrine::ATTR_DB_NAME_FORMAT), $name);
$password = $this->conn->dsn['password'] ? $this->conn->dsn['password'] : $name;
$tablespace = $this->conn->getAttribute(Doctrine::ATTR_DB_NAME_FORMAT)
? ' DEFAULT TABLESPACE '.$this->conn->options['default_tablespace'] : '';
$query = 'CREATE USER ' . $username . ' IDENTIFIED BY ' . $password . $tablespace;
$result = $this->conn->exec($query);
try {
$query = 'GRANT CREATE SESSION, CREATE TABLE, UNLIMITED TABLESPACE, CREATE SEQUENCE, CREATE TRIGGER TO ' . $username;
$result = $this->conn->exec($query);
} catch (Exception $e) {
$query = 'DROP USER '.$username.' CASCADE';
$result2 = $this->conn->exec($query);
}
return true;
}
/**
* drop an existing database
*
* @param object $this->conn database object that is extended by this class
* @param string $name name of the database that should be dropped
* @return mixed MDB2_OK on success, a MDB2 error on failure
* @access public
*/
public function dropDatabase($name)
{
if ( ! $this->conn->getAttribute(Doctrine::ATTR_EMULATE_DATABASE))
throw new Doctrine_Export_Exception('database dropping is only supported if the
"emulate_database" option is enabled');
$username = sprintf($this->conn->getAttribute(Doctrine::ATTR_DB_NAME_FORMAT), $name);
return $this->conn->exec('DROP USER ' . $username . ' CASCADE');
}
/**
* add an autoincrement sequence + trigger
*
* @param string $name name of the PK field
* @param string $table name of the table
* @param string $start start value for the sequence
* @return mixed MDB2_OK on success, a MDB2 error on failure
* @access private
*/
public function _makeAutoincrement($name, $table, $start = 1)
{
$sql = array();
$table = strtoupper($table);
$indexName = $table . '_AI_PK';
$definition = array(
'primary' => true,
'fields' => array($name => true),
);
$sql[] = $this->createConstraintSql($table, $indexName, $definition);
if (is_null($start)) {
$query = 'SELECT MAX(' . $this->conn->quoteIdentifier($name, true) . ') FROM ' . $this->conn->quoteIdentifier($table, true);
$start = $this->conn->fetchOne($query);
++$start;
}
$sql[] = $this->createSequenceSql($table, $start);
$sequenceName = $this->conn->formatter->getSequenceName($table);
$triggerName = $this->conn->quoteIdentifier($table . '_AI_PK', true);
$table = $this->conn->quoteIdentifier($table, true);
$name = $this->conn->quoteIdentifier($name, true);
$sql[] = 'CREATE TRIGGER ' . $triggerName . '
BEFORE INSERT
ON '.$table.'
FOR EACH ROW
DECLARE
last_Sequence NUMBER;
last_InsertID NUMBER;
BEGIN
SELECT '.$sequenceName.'.NEXTVAL INTO :NEW.'.$name.' FROM DUAL;
IF (:NEW.'.$name.' IS NULL OR :NEW.'.$name.' = 0) THEN
SELECT '.$sequenceName.'.NEXTVAL INTO :NEW.'.$name.' FROM DUAL;
ELSE
SELECT NVL(Last_Number, 0) INTO last_Sequence
FROM User_Sequences
WHERE UPPER(Sequence_Name) = UPPER(\''.$sequenceName.'\');
SELECT :NEW.id INTO last_InsertID FROM DUAL;
WHILE (last_InsertID > last_Sequence) LOOP
SELECT ' . $sequenceName . '.NEXTVAL INTO last_Sequence FROM DUAL;
END LOOP;
END IF;
END;
';
return $sql;
}
/**
* drop an existing autoincrement sequence + trigger
*
* @param string $table name of the table
* @return void
*/
public function dropAutoincrement($table)
{
$table = strtoupper($table);
$triggerName = $table . '_AI_PK';
$trigger_name_quoted = $this->conn->quote($triggerName);
$query = 'SELECT trigger_name FROM user_triggers';
$query.= ' WHERE trigger_name='.$trigger_name_quoted.' OR trigger_name='.strtoupper($trigger_name_quoted);
$trigger = $this->conn->fetchOne($query);
if ($trigger) {
$trigger_name = $this->conn->quoteIdentifier($table . '_AI_PK', true);
$trigger_sql = 'DROP TRIGGER ' . $trigger_name;
// if throws exception, trigger for autoincrement PK could not be dropped
$this->conn->exec($trigger_sql);
// if throws exception, sequence for autoincrement PK could not be dropped
$this->dropSequence($table);
$indexName = $table . '_AI_PK';
// if throws exception, primary key for autoincrement PK could not be dropped
$this->dropConstraint($table, $indexName);
}
}
/**
* A method to return the required SQL string that fits between CREATE ... TABLE
* to create the table as a temporary table.
*
* @return string The string required to be placed between "CREATE" and "TABLE"
* to generate a temporary table, if possible.
*/
public function getTemporaryTableQuery()
{
return 'GLOBAL TEMPORARY';
}
/**
* getAdvancedForeignKeyOptions
* Return the FOREIGN KEY query section dealing with non-standard options
* as MATCH, INITIALLY DEFERRED, ON UPDATE, ...
*
* @param array $definition foreign key definition
* @return string
* @access protected
*/
public function getAdvancedForeignKeyOptions(array $definition)
{
$query = '';
if (isset($definition['onDelete'])) {
$query .= ' ON DELETE ' . $definition['onDelete'];
}
if (isset($definition['deferrable'])) {
$query .= ' DEFERRABLE';
} else {
$query .= ' NOT DEFERRABLE';
}
if (isset($definition['feferred'])) {
$query .= ' INITIALLY DEFERRED';
} else {
$query .= ' INITIALLY IMMEDIATE';
}
return $query;
}
/**
* create a new table
*
* @param string $name Name of the database that should be created
* @param array $fields Associative array that contains the definition of each field of the new table
* The indexes of the array entries are the names of the fields of the table an
* the array entry values are associative arrays like those that are meant to be
* passed with the field definitions to get[Type]Declaration() functions.
*
* Example
* array(
*
* 'id' => array(
* 'type' => 'integer',
* 'unsigned' => 1
* 'notnull' => 1
* 'default' => 0
* ),
* 'name' => array(
* 'type' => 'text',
* 'length' => 12
* ),
* 'password' => array(
* 'type' => 'text',
* 'length' => 12
* )
* );
* @param array $options An associative array of table options:
*
* @return void
*/
public function createTable($name, array $fields, array $options = array())
{
$this->conn->beginTransaction();
foreach ($this->createTableSql($name, $fields, $options) as $sql) {
$this->conn->exec($sql);
}
$this->conn->commit();
}
/**
* create a new table
*
* @param string $name Name of the database that should be created
* @param array $fields Associative array that contains the definition of each field of the new table
* The indexes of the array entries are the names of the fields of the table an
* the array entry values are associative arrays like those that are meant to be
* passed with the field definitions to get[Type]Declaration() functions.
*
* Example
* array(
*
* 'id' => array(
* 'type' => 'integer',
* 'unsigned' => 1
* 'notnull' => 1
* 'default' => 0
* ),
* 'name' => array(
* 'type' => 'text',
* 'length' => 12
* ),
* 'password' => array(
* 'type' => 'text',
* 'length' => 12
* )
* );
* @param array $options An associative array of table options:
*
* @return void
*/
public function createTableSql($name, array $fields, array $options = array())
{
$sql = parent::createTableSql($name, $fields, $options);
foreach ($fields as $fieldName => $field) {
if (isset($field['autoincrement']) && $field['autoincrement'] ||
(isset($field['autoinc']) && $fields['autoinc'])) {
$sql = array_merge($sql, $this->_makeAutoincrement($fieldName, $name));
}
}
return $sql;
}
/**
* drop an existing table
*
* @param string $name name of the table that should be dropped
* @return void
*/
public function dropTable($name)
{
//$this->conn->beginNestedTransaction();
$result = $this->dropAutoincrement($name);
$result = parent::dropTable($name);
//$this->conn->completeNestedTransaction();
return $result;
}
/**
* alter an existing table
*
* @param string $name name of the table that is intended to be changed.
* @param array $changes associative array that contains the details of each type
* of change that is intended to be performed. The types of
* changes that are currently supported are defined as follows:
*
* name
*
* New name for the table.
*
* add
*
* Associative array with the names of fields to be added as
* indexes of the array. The value of each entry of the array
* should be set to another associative array with the properties
* of the fields to be added. The properties of the fields should
* be the same as defined by the MDB2 parser.
*
*
* remove
*
* Associative array with the names of fields to be removed as indexes
* of the array. Currently the values assigned to each entry are ignored.
* An empty array should be used for future compatibility.
*
* rename
*
* Associative array with the names of fields to be renamed as indexes
* of the array. The value of each entry of the array should be set to
* another associative array with the entry named name with the new
* field name and the entry named Declaration that is expected to contain
* the portion of the field declaration already in DBMS specific SQL code
* as it is used in the CREATE TABLE statement.
*
* change
*
* Associative array with the names of the fields to be changed as indexes
* of the array. Keep in mind that if it is intended to change either the
* name of a field and any other properties, the change array entries
* should have the new names of the fields as array indexes.
*
* The value of each entry of the array should be set to another associative
* array with the properties of the fields to that are meant to be changed as
* array entries. These entries should be assigned to the new values of the
* respective properties. The properties of the fields should be the same
* as defined by the MDB2 parser.
*
* Example
* array(
* 'name' => 'userlist',
* 'add' => array(
* 'quota' => array(
* 'type' => 'integer',
* 'unsigned' => 1
* )
* ),
* 'remove' => array(
* 'file_limit' => array(),
* 'time_limit' => array()
* ),
* 'change' => array(
* 'name' => array(
* 'length' => '20',
* 'definition' => array(
* 'type' => 'text',
* 'length' => 20,
* ),
* )
* ),
* 'rename' => array(
* 'sex' => array(
* 'name' => 'gender',
* 'definition' => array(
* 'type' => 'text',
* 'length' => 1,
* 'default' => 'M',
* ),
* )
* )
* )
*
* @param boolean $check indicates whether the function should just check if the DBMS driver
* can perform the requested table alterations if the value is true or
* actually perform them otherwise.
* @return void
*/
public function alterTable($name, array $changes, $check = false)
{
foreach ($changes as $changeName => $change) {
switch ($changeName) {
case 'add':
case 'remove':
case 'change':
case 'name':
case 'rename':
break;
default:
throw new Doctrine_Export_Exception('change type "' . $changeName . '" not yet supported');
}
}
if ($check) {
return false;
}
$name = $this->conn->quoteIdentifier($name, true);
if ( ! empty($changes['add']) && is_array($changes['add'])) {
$fields = array();
foreach ($changes['add'] as $fieldName => $field) {
$fields[] = $this->conn->getDeclaration($fieldName, $field);
}
$result = $this->conn->exec('ALTER TABLE ' . $name . ' ADD (' . implode(', ', $fields) . ')');
}
if ( ! empty($changes['change']) && is_array($changes['change'])) {
$fields = array();
foreach ($changes['change'] as $fieldName => $field) {
$fields[] = $fieldName. ' ' . $this->conn->getDeclaration('', $field['definition']);
}
$result = $this->conn->exec('ALTER TABLE ' . $name . ' MODIFY (' . implode(', ', $fields) . ')');
}
if ( ! empty($changes['rename']) && is_array($changes['rename'])) {
foreach ($changes['rename'] as $fieldName => $field) {
$query = 'ALTER TABLE ' . $name . ' RENAME COLUMN ' . $this->conn->quoteIdentifier($fieldName, true)
. ' TO ' . $this->conn->quoteIdentifier($field['name']);
$result = $this->conn->exec($query);
}
}
if ( ! empty($changes['remove']) && is_array($changes['remove'])) {
$fields = array();
foreach ($changes['remove'] as $fieldName => $field) {
$fields[] = $this->conn->quoteIdentifier($fieldName, true);
}
$result = $this->conn->exec('ALTER TABLE ' . $name . ' DROP COLUMN ' . implode(', ', $fields));
}
if ( ! empty($changes['name'])) {
$changeName = $this->conn->quoteIdentifier($changes['name'], true);
$result = $this->conn->exec('ALTER TABLE ' . $name . ' RENAME TO ' . $changeName);
}
}
/**
* create sequence
*
* @param string $seqName name of the sequence to be created
* @param string $start start value of the sequence; default is 1
* @param array $options An associative array of table options:
* array(
* 'comment' => 'Foo',
* 'charset' => 'utf8',
* 'collate' => 'utf8_unicode_ci',
* );
* @return string
*/
public function createSequenceSql($seqName, $start = 1, array $options = array())
{
$sequenceName = $this->conn->quoteIdentifier($this->conn->formatter->getSequenceName($seqName), true);
$query = 'CREATE SEQUENCE ' . $sequenceName . ' START WITH ' . $start . ' INCREMENT BY 1 NOCACHE';
$query .= ($start < 1 ? ' MINVALUE ' . $start : '');
return $query;
}
/**
* drop existing sequence
*
* @param object $this->conn database object that is extended by this class
* @param string $seqName name of the sequence to be dropped
* @return string
*/
public function dropSequenceSql($seqName)
{
$sequenceName = $this->conn->quoteIdentifier($this->conn->formatter->getSequenceName($seqName), true);
return 'DROP SEQUENCE ' . $sequenceName;
}
}