When developing most applications, you end up having to interact with a database. If you’re application is large enough and warrants the design and effort, it will no doubt be tiered as well. If your application is tiered, one of your layers will probably include a database API. A database API is used to restrict access to the database, a funnel which all requests from your application must pass through. Implementing this additional layer of abstraction normally yields in higher performance, increased security and easier maintenance.
In most cases, you’re application code will require a fairly standard interface into your database to retrieve information. A simple way to achieve that consistent interface is using the DECODE
function in your PL/SQL procedures and functions. There are always cases where you need to do something special, and in those cases it is probably a perfect scenario for this methods counter-part – the string building technique.
For a simple but practical example, consider the following table definition:
CREATE TABLE MyTable (
PrimaryKeyID NUMBER NOT NULL,
ForeignKeyID NUMBER NOT NULL,
Name VARCHAR2 (255) NOT NULL
)
As I have mentioned before, the Oracle DECODE function provides similar functionality to an IF-THEN-ELSE
code block. Lets examine an example which relates to MyTable
above.
PROCEDURE Get
(pDetails OUT grcDetails,
pPrimaryKeyID IN MyTable.PrimaryKeyID%TYPE DEFAULT NULL,
pForeignKeyID IN MyTable.ForeignKeyID%TYPE DEFAULT NULL,
pName IN MyTable.Name%TYPE DEFAULT NULL)
IS
BEGIN
OPEN pDetails FOR
SELECT *
FROM MyTable
WHERE PrimaryKeyID = DECODE(pPrimaryKeyID, NULL, PrimaryKeyID, 0, PrimaryKeyID, pPrimaryKeyID)
AND ForeignKeyID = DECODE(pForeignKeyID, NULL, ForeignKeyID, 0, ForeignKeyID, pForeignKeyID)
AND LOWER(Name) LIKE DECODE(pName, NULL, LOWER(Name), '%'||LOWER(pName)||'%');
END;
Working top down, the second line declares pDetails
(the parameter name) as being an OUT
parameter. As the name suggests, an OUT
parameter is a way for you to pass information out of your procedure. In some aspects it would be similar to returning a value out of a typical programming function. The difference to an OUT
parameter is that you can have many OUT
parameters in a single procedure, where as a typical programming function can only return a single value at a time.
The next thing you’ve probably noticed is this weird thing in there, grcDetails
. Just as the IN
parameters below it, grcDetails
is the type of the parameter. It would be akin to defining a paramter in a traditional function as accepting an integer or string type. In this case, grcDetails
is declared in the package header:
TYPE grcDetails IS REF CURSOR RETURN MyTable%ROWTYPE;
The important thing to notice about grcDetails
is that it is a REF CURSOR
and its type is the ROWTYPE
of MyTable
. The benefit of defining it as a ROWTYPE
is that if tomorrow the definition of the table changed in some way, you don’t have to worry about changing any code to match the new table definition – it simply continues to work. This is the same reason why the INPUT
parameters above have their type defined against the field that they represent. Of course, if you are passing in or out a value which isn’t based on a field – you would simply define it as a standard PL/SQL type.
Next, you have probably noticed that each IN
parameter has a DEFAULT
value. As with most programming languages, providing a DEFAULT
value allows the programmer to optionally supply that parameter. For our example, this is a pivotal point as it simplifies the use of this method; more on that later.
Moving on to the actual SQL statement, the flexibility of the DECODE
function starts to show. Since the DECODE
function acts like an IF-THEN-ELSE
block, you’re actually seeing an inline IF-THEN-ELSE IF-ELSE
block per field. Lets take a practical example of that statement and assume we passed in pPrimaryKeyID
with a value of 1, while the other two input parameter’s are not passed in (thus taking their default value of NULL
). The SQL statement would be parsed and executed as follows:
SELECT *
FROM MyTable
WHERE PrimaryKeyID = 1
AND ForeignKeyID = ForeignKeyID
AND LOWER(Name) LIKE LOWER(Name);
Of course, the net effect of that SQL statement is that the first WHERE
condition is used, while the second and third conditions are nullified as the left and right half of each expression are equivalent. So by passing in a NULL
value for the pForeignKeyID
and pName
parameters, they are effectively removed from the SQL statement by evaluating to themselves. Of course, you could also pass in two, three or none of the parameters to the procedure as well. In which case you would get either a restricted set from the statement or all records in the table.
As mentioned above, the DEFAULT
value of each IN
parameter is critical to this methods success. By providing a default value, the programmer no longer needs to call the procedure with all parameters; all, some or none are also perfectly valid combinations. Since the input parameter’s default value is NULL
, the following DECODE
function call is all that is required to negate the parameter in the WHERE
clause:
PrimaryKeyID = DECODE(pPrimaryKeyID, NULL, PrimaryKeyID, pPrimaryKeyID)
By now, you have probably noticed some extra parameters in the example GET
procedure listed above. The additional values are used to exclude any other ‘not important’ values from the statement. In the example procedure, NULL
and the value 0
are considered unimportant; whilst all other values are considered useful.
If you’re wondering why you’d want to exclude other values, it might be to make another section of your application simpler. Some programming languages don’t support nullable primitive types. If you use such a language and you intend to pass in all parameters to your procedure in all circumstances (this is the ‘simpler’ above); then all values will have a value of some sort. In the case of a primitive such as an integer, you might find that its default uninitialised value is zero. If that is the case and you don’t require the ability to filter on a zero value, then excluding it within the DECODE
function makes things simpler.
Don’t think you’re limited to using this method on SELECT
statements, it will work a treat on DELETE
too. Consider the following DEL
procedure:
PROCEDURE Del
(pRowCount OUT NUMBER,
pRoomTypeID IN RoomTypes.ROOMTYPEID%TYPE DEFAULT NULL,
pBuildingID IN RoomTypes.BUILDINGID%TYPE DEFAULT NULL)
IS
BEGIN
IF (pRoomTypeID IS NOT NULL OR pBuildingID IS NOT NULL) THEN
DELETE
FROM RoomTypes
WHERE RoomTypeID = DECODE(pRoomTypeID, NULL, RoomTypeID, 0, RoomTypeID, pRoomTypeID)
AND BuildingID = DECODE(pBuildingID, NULL, BuildingID, 0, BuildingID, pBuildingID);
ELSE
RAISE_APPLICATION_ERROR(-20001, 'At least one parameter must be supplied');
END IF;
pRowCount := SQL%ROWCOUNT;
END;
There is a caveat to using this method for building dynamic SQL within Oracle, it cannot handle columns which are nullable. If you consider the use of the DEFAULT
value on all of the input parameters, it will become clear. Within Orcale PL/SQL, it is not possible to use an equality (=
) operator to compare a NULL
value. As a simple example, take the two simple SQL statements:
SELECT * FROM DUAL
SELECT * FROM DUAL WHERE NULL = NULL
The first SQL statement above will return the expected row from the DUAL
table, while the second statement will return no results as you cannot compare the NULL
value in that manner. If a comparison against a NULL
is required, it must be handled using the IS NULL
clause.
Other than not being able to use this method against columns which are nullable, its a really convenient way to write dynamic SQL in Oracle. Next time you need a little flexibility and you don’t want to go down the string building path, try using the Oracle DECODE
function to produce your dynamic SQL.