Using ADOdb with PHP and Oracle: an advanced tutorial |
(c) 2004-2014 John Lim. All rights reserved.
Oracle is the most popular commercial database used with PHP. There are many ways of accessing Oracle databases in PHP. These include:
The wide range of choices is confusing to someone just starting with Oracle and PHP. I will briefly summarize the differences, and show you the advantages of using ADOdb.
First we have the C extensions which provide low-level access to Oracle functionality. These C extensions are precompiled into PHP, or linked in dynamically when the web server starts up. Just in case you need it, here's a guide to installing Oracle and PHP on Linux.
Oracle extension | Designed for Oracle 7 or earlier. This is obsolete. |
Oci8 extension | Despite it's name, which implies it is only for Oracle 8i, this is the standard method for accessing databases running Oracle 8i, 9i or 10g (and later). |
Here is an example of using the oci8 extension to query the emp table of the scott schema with bind parameters:
$conn = OCILogon("scott","tiger", $tnsName); $stmt = OCIParse($conn,"select * from emp where empno > :emp order by empno"); $emp = 7900; OCIBindByName($stmt, ':emp', $emp); $ok = OCIExecute($stmt); while (OCIFetchInto($stmt,$arr)) { print_r($arr); echo "<hr>"; }
This generates the following output:
We also have many higher level PHP libraries that allow you to simplify the above code. The most popular are PEAR DB and ADOdb. Here are some of the differences between these libraries:
Feature | PEAR DB 1.6 | ADOdb 4.52 |
General Style | Simple, easy to use. Lacks Oracle specific functionality. | Has multi-tier design. Simple high-level design for beginners, and also lower-level advanced Oracle functionality. |
Support for Prepare | Yes, but only on one statement, as the last prepare overwrites previous prepares. | Yes (multiple simultaneous prepare's allowed) |
Support for LOBs | No | Yes, using update semantics |
Support for REF Cursors | No | Yes |
Support for IN Parameters | Yes | Yes |
Support for OUT Parameters | No | Yes |
Schema creation using XML | No | Yes, including ability to define tablespaces and constraints |
Provides database portability features | No | Yes, has some ability to abstract features that differ between databases such as dates, bind parameters, and data types. |
Performance monitoring and tracing | No | Yes. SQL can be traced and linked to web page it was executed on. Explain plan support included. |
Recordset caching for frequently used queries | No | Yes. Provides great speedups for SQL involving complex where, group-by and order-by clauses. |
Popularity | Yes, part of PEAR release | Yes, many open source projects are using this software, including PostNuke, Xaraya, Mambo, Tiki Wiki. |
Speed | Medium speed. | Very high speed. Fastest database abstraction library available for PHP. Benchmarks are available. |
High Speed Extension available | No | Yes. You can install the optional ADOdb extension, which reimplements the most frequently used parts of ADOdb as fast C code. Note that the source code version of ADOdb runs just fine without this extension, and only makes use of the extension if detected. |
PEAR DB is good enough for simple web apps. But if you need more power, you can see ADOdb offers more sophisticated functionality. The rest of this article will concentrate on using ADOdb with Oracle. You can find out more about connecting to Oracle later in this guide.
In ADOdb, the above oci8 example querying the emp table could be written as:
include "/path/to/adodb.inc.php"; $db = NewADOConnection("oci8"); $db->Connect($tnsName, "scott", "tiger"); $rs = $db->Execute("select * from emp where empno>:emp order by empno", array('emp' => 7900)); while ($arr = $rs->FetchRow()) { print_r($arr); echo "<hr>"; }
The Execute( ) function returns a recordset object, and you can retrieve the rows returned using $recordset->FetchRow( ).
If we ignore the initial connection preamble, we can see the ADOdb version is much easier and simpler:
Oci8 | ADOdb |
$stmt = OCIParse($conn, "select * from emp where empno > :emp"); $emp = 7900; OCIBindByName($stmt, ':emp', $emp); $ok = OCIExecute($stmt); while (OCIFetchInto($stmt,$arr)) { print_r($arr); echo "<hr>"; } |
$recordset = $db->Execute("select * from emp where empno>:emp", array('emp' => 7900)); while ($arr = $recordset->FetchRow()) { print_r($arr); echo "<hr>"; } |
You can also query the database using the standard Microsoft ADO MoveNext( ) metaphor. The data array for the current row is stored in the fields property of the recordset object, $rs. MoveNext( ) offers the highest performance among all the techniques for iterating through a recordset:
$rs = $db->Execute("select * from emp where empno>:emp", array('emp' => 7900)); while (!$rs->EOF) { print_r($rs->fields); $rs->MoveNext(); }
And if you are interested in having the data returned in a 2-dimensional array, you can use:
$arr = $db->GetArray("select * from emp where empno>:emp", array('emp' => 7900));
Now to obtain only the first row as an array:
$arr = $db->GetRow("select * from emp where empno=:emp", array('emp' => 7900));
Or to retrieve only the first field of the first row:
$arr = $db->GetOne("select ename from emp where empno=:emp", array('emp' => 7900));
For easy pagination support, we provide the SelectLimit function. The following will perform a select query, limiting it to 100 rows, starting from row 201 (row 1 being the 1st row):
$offset = 200; $limitrows = 100; $rs = $db->SelectLimit('select * from table', $limitrows, $offset);
The $offset parameter is optional.
When data is being returned in an array, you can choose the type of array the data is returned in.
The default is ADODB_FETCH_BOTH for Oracle.
You can define a database cache directory using $ADODB_CACHE_DIR, and cache the results of frequently used queries that rarely change. This is particularly useful for SQL with complex where clauses and group-by's and order-by's. It is also good for relieving heavily-loaded database servers.
This example will cache the following select statement for 3600 seconds (1 hour):
$ADODB_CACHE_DIR = '/var/adodb/tmp'; $rs = $db->CacheExecute(3600, "select names from allcountries order by 1");There are analogous CacheGetArray( ), CacheGetRow( ), CacheGetOne( ) and CacheSelectLimit( ) functions. The first parameter is the number of seconds to cache. You can also pass a bind array as a 3rd parameter (not shown above).
There is an alternative syntax for the caching functions. The first parameter is omitted, and you set the cacheSecs property of the connection object:
$ADODB_CACHE_DIR = '/var/adodb/tmp'; $connection->cacheSecs = 3600; $rs = $connection->CacheExecute($sql, array('id' => 1));
Prepare( ) is for compiling frequently used SQL statement for reuse. For example, suppose we have a large array which needs to be inserted into an Oracle database. The following will result in a massive speedup in query execution (at least 20-40%), as the SQL statement only needs to be compiled once:
$stmt = $db->Prepare('insert into table (field1, field2) values (:f1, :f2)'); foreach ($arrayToInsert as $key => $value) { $db->Execute($stmt, array('f1' => $key, 'f2' => $val); }
Oracle treats data which is more than 4000 bytes in length specially. These are called Large Objects, or LOBs for short. Binary LOBs are BLOBs, and character LOBs are CLOBs. In most Oracle libraries, you need to do a lot of work to process LOBs, probably because Oracle designed it to work in systems with little memory. ADOdb tries to make things easy by assuming the LOB can fit into main memory.
ADOdb will transparently handle LOBs in select statements. The LOBs are automatically converted to PHP variables without any special coding.
For updating records with LOBs, the functions UpdateBlob( ) and UpdateClob( ) are provided. Here's a BLOB example. The parameters should be self-explanatory:
$ok = $db->Execute("insert into aTable (id, name, ablob) values (aSequence.nextVal, 'Name', null)"); if (!$ok) return LogError($db->ErrorMsg()); # params: $tableName, $blobFieldName, $blobValue, $whereClause $db->UpdateBlob('aTable', 'ablob', $blobValue, 'id=aSequence.currVal');
and the analogous CLOB example:
$ok = $db->Execute("insert into aTable (id, name, aclob) values (aSequence.nextVal, 'Name', null)"); if (!$ok) return LogError($db->ErrorMsg()); $db->UpdateClob('aTable', 'aclob', $clobValue, 'id=aSequence.currVal');
Note that LogError( ) is a user-defined function, and not part of ADOdb.
Inserting LOBs is more complicated. Since ADOdb 4.55, we allow you to do this (assuming that the photo field is a BLOB, and we want to store $blob_data into this field, and the primary key is the id field):
$sql = "INSERT INTO photos ( ID, photo) ". "VALUES ( :id, empty_blob() )". " RETURNING photo INTO :xx"; $stmt = $db->PrepareSP($sql); $db->InParameter($stmt, $id, 'id'); $blob = $db->InParameter($stmt, $blob_data, 'xx',-1, OCI_B_BLOB); $db->StartTrans(); $ok = $db->Execute($stmt); $db->CompleteTrans();
Oracle recordsets can be passed around as variables called REF Cursors. For example, in PL/SQL, we could define a function open_tab that returns a REF CURSOR in the first parameter:
TYPE TabType IS REF CURSOR RETURN TAB%ROWTYPE; PROCEDURE open_tab (tabcursor IN OUT TabType,tablenames IN VARCHAR) IS BEGIN OPEN tabcursor FOR SELECT * FROM TAB WHERE tname LIKE tablenames; END open_tab;
In ADOdb, we could access this REF Cursor using the ExecuteCursor() function. The following will find all table names that begin with 'A' in the current schema:
$rs = $db->ExecuteCursor("BEGIN open_tab(:refc,'A%'); END;",'refc'); while ($arr = $rs->FetchRow()) print_r($arr);
The first parameter is the PL/SQL statement, and the second parameter is the name of the REF Cursor.
The following PL/SQL stored procedure requires an input variable, and returns a result into an output variable:
PROCEDURE data_out(input IN VARCHAR, output OUT VARCHAR) IS BEGIN output := 'I love '||input; END;
The following ADOdb code allows you to call the stored procedure:
$stmt = $db->PrepareSP("BEGIN adodb.data_out(:a1, :a2); END;"); $input = 'Sophia Loren'; $db->InParameter($stmt,$input,'a1'); $db->OutParameter($stmt,$output,'a2'); $ok = $db->Execute($stmt); if ($ok) echo ($output == 'I love Sophia Loren') ? 'OK' : 'Failed';
PrepareSP( ) is a special function that knows about bind parameters. The main limitation currently is that IN OUT parameters do not work.
We could also rewrite the REF CURSOR example to use InParameter (requires ADOdb 4.53 or later):
$stmt = $db->PrepareSP("BEGIN adodb.open_tab(:refc,:tabname); END;"); $input = 'A%'; $db->InParameter($stmt,$input,'tabname'); $rs = $db->ExecuteCursor($stmt,'refc'); while ($arr = $rs->FetchRow()) print_r($arr);
You can also operate on LOBs. In this example, we have IN and OUT parameters using CLOBs.
$text = 'test test test'; $sql = "declare rs clob; begin :rs := lobinout(:sa0); end;"; $stmt = $conn -> PrepareSP($sql); $conn -> InParameter($stmt,$text,'sa0', -1, OCI_B_CLOB); # -1 means variable length $rs = ''; $conn -> OutParameter($stmt,$rs,'rs', -1, OCI_B_CLOB); $conn -> Execute($stmt); echo "return = ".$rs."<br>";
Similarly, you can use the constant OCI_B_BLOB to indicate that you are using BLOBs.
Many web programmers do not care to use bind parameters, and prefer to enter the SQL directly. So instead of:
$arr = $db->GetArray("select * from emp where empno>:emp", array('emp' => 7900));
They prefer entering the values inside the SQL:
$arr = $db->GetArray("select * from emp where empno>7900");
This reduces Oracle performance because Oracle will reuse compiled SQL which is identical to previously compiled SQL. The above example with the values inside the SQL is unlikely to be reused. As an optimization, from Oracle 8.1 onwards, you can set the following session parameter after you login:
ALTER SESSION SET CURSOR_SHARING=FORCE
This will force Oracle to convert all such variables (eg. the 7900 value) into constant bind parameters, improving SQL reuse.
More speedup tips.
There are two things you need to know about dates in ADOdb.
First, to ensure cross-database compability, ADOdb assumes that dates are returned in ISO format (YYYY-MM-DD H24:MI:SS).
Secondly, since Oracle treats dates and datetime as the same data type, we decided not to display the time in the default date format. So on login, ADOdb will set the NLS_DATE_FORMAT to 'YYYY-MM-DD'. If you prefer to show the date and time by default, do this:
$db = NewADOConnection('oci8'); $db->NLS_DATE_FORMAT = 'RRRR-MM-DD HH24:MI:SS'; $db->Connect($tns, $user, $pwd);
Or execute:
$sql = quot;ALTER SESSION SET NLS_DATE_FORMAT = 'RRRR-MM-DD HH24:MI:SS'"; $db->Execute($sql);
If you are not concerned about date portability and do not use ADOdb's portability layer, you can use your preferred date format instead.
ADOdb provides the following functions for portably generating SQL functions as strings to be merged into your SQL statements:
Function | Description |
DBDate($date) | Pass in a UNIX timestamp or ISO date and it will convert it to a date string formatted for INSERT/UPDATE |
DBTimeStamp($date) | Pass in a UNIX timestamp or ISO date and it will convert it to a timestamp string formatted for INSERT/UPDATE |
SQLDate($date, $fmt) | Portably generate a date formatted using $fmt mask, for use in SELECT statements. |
OffsetDate($date, $ndays) | Portably generate a $date offset by $ndays. |
Concat($s1, $s2, ...) | Portably concatenate strings. Alternatively, for mssql use mssqlpo driver, which allows || operator. |
IfNull($fld, $replaceNull) | Returns a string that is the equivalent of MySQL IFNULL or Oracle NVL. |
Param($name) | Generates bind placeholders, using ? or named conventions as appropriate. |
$db->sysDate | Property that holds the SQL function that returns today's date |
$db->sysTimeStamp | Property that holds the SQL function that returns the current timestamp (date+time). |
$db->concat_operator | Property that holds the concatenation operator |
$db->length | Property that holds the name of the SQL strlen function. |
$db->upperCase | Property that holds the name of the SQL strtoupper function. |
$db->random | Property that holds the SQL to generate a random number between 0.00 and 1.00. |
$db->substr | Property that holds the name of the SQL substring function. |
ADOdb also provides multiple oracle oci8 drivers for different scenarios:
Driver Name | Description |
oci805 | Specifically for Oracle 8.0.5. This driver has a slower SelectLimit( ). |
oci8 | The default high performance driver. The keys of associative arrays returned in a recordset are upper-case. |
oci8po | The portable Oracle driver. Slightly slower than oci8. This driver uses ? instead of :bindvar for binding variables, which is the standard for other databases. Also the keys of associative arrays are in lower-case like other databases. |
Here's an example of calling the oci8po driver. Note that the bind variables use question-mark:
$db = NewADOConnection('oci8po'); $db->Connect($tns, $user, $pwd); $db->Execute("insert into atable (f1, f2) values (?,?)", array(12, 'abc'));
Before you can use ADOdb, you need to have the Oracle client installed and setup the oci8 extension. This extension comes pre-compiled for Windows (but you still need to enable it in the php.ini file). For information on compiling the oci8 extension for PHP and Apache on Unix, there is an excellent guide at oracle.com.
One question that is frequently asked is should you use persistent connections to Oracle. Persistent connections allow PHP to recycle existing connections, reusing them after the previous web pages have completed. Non-persistent connections close automatically after the web page has completed. Persistent connections are faster because the cost of reconnecting is expensive, but there is additional resource overhead. As an alternative, Oracle allows you to pool and reuse server processes; this is called Shared Server (also known as MTS).
The author's benchmarks suggest that using non-persistent connections and the Shared Server configuration offer the best performance. If Shared Server is not an option, only then consider using persistent connections.
Just in case you are having problems connecting to Oracle, here are some examples:
a. PHP and Oracle reside on the same machine, use default SID, with non-persistent connections:
$conn = NewADOConnection('oci8'); $conn->Connect(false, 'scott', 'tiger');
b. TNS Name defined in tnsnames.ora (or ONAMES or HOSTNAMES), eg. 'myTNS', using persistent connections:
$conn = NewADOConnection('oci8'); $conn->PConnect(false, 'scott', 'tiger', 'myTNS');
or
$conn->PConnect('myTNS', 'scott', 'tiger');
c. Host Address and SID
$conn->connectSID = true; $conn->Connect('192.168.0.1', 'scott', 'tiger', 'SID');
d. Host Address and Service Name
$conn->Connect('192.168.0.1', 'scott', 'tiger', 'servicename');
e. Oracle connection string:
$cstr = "(DESCRIPTION=(ADDRESS=(PROTOCOL=TCP)(HOST=$host)(PORT=$port)) (CONNECT_DATA=(SID=$sid)))"; $conn->Connect($cstr, 'scott', 'tiger');
f. ADOdb data source names (dsn):
$dsn = 'oci8://user:pwd@tnsname/?persist'; # persist is optional $conn = ADONewConnection($dsn); # no need for Connect/PConnect $dsn = 'oci8://user:pwd@host/sid'; $conn = ADONewConnection($dsn); $dsn = 'oci8://user:pwd@/'; # oracle on local machine $conn = ADONewConnection($dsn);
With ADOdb data source names, you don't have to call Connect( ) or PConnect( ).
The examples in this article are easy to read but a bit simplistic because we ignore error-handling. Execute( ) and Connect( ) will return false on error. So a more realistic way to call Connect( ) and Execute( ) is:
function InvokeErrorHandler() {
global $db; ## assume global MyLogFunction($db->ErrorNo(), $db->ErrorMsg()); } if (!$db->Connect($tns, $usr, $pwd)) InvokeErrorHandler(); $rs = $db->Execute("select * from emp where empno>:emp order by empno", array('emp' => 7900)); if (!$rs) return InvokeErrorHandler(); while ($arr = $rs->FetchRow()) { print_r($arr); echo "<hr>"; }
You can retrieve the error message and error number of the last SQL statement executed from ErrorMsg( ) and ErrorNo( ). You can also define a custom error handler function. ADOdb also supports throwing exceptions in PHP5.
This variable is checked every time a query is executed, so you can selectively choose which recordsets to count.
Schema generation. This allows you to define a schema using XML and import it into different RDBMS systems portably.
Performance monitoring and tracing. Highlights of performance monitoring include identification of poor and suspicious SQL, with explain plan support, and identifying which web pages the SQL ran on.
You can download ADOdb from sourceforge. ADOdb uses a BSD style license. That means that it is free for commercial use, and redistribution without source code is allowed.