Native SQL
You may also express queries in the native SQL dialect of your database. This is useful if you
want to utilize database specific features such as query hints or the CONNECT
keyword in Oracle. It also provides a clean migration path from a direct SQL/JDBC based
application to Hibernate.
Hibernate3 allows you to specify handwritten SQL (including stored procedures) for
all create, update, delete, and load operations.
Creating a native SQL Query
SQL queries are controlled via the SQLQuery interface, which
is obtained by calling Session.createSQLQuery().
This query specified:
the SQL query string, with a placeholder for Hibernate to inject the column aliases
the entity returned by the query, and its SQL table alias
The addEntity() method associates SQL table aliases with entity classes,
and determines the shape of the query result set.
The addJoin() method may be used to load associations to other entities
and collections. TODO: examples!
A native SQL query might return a simple scalar value or a combination of scalars and
entities.
Alias and property references
The {cat.*} notation used above is a shorthand for "all properties".
Alternatively, you may list the columns explicity, but even then you must let Hibernate
inject the SQL column aliases for each property. The placeholder for a column alias is
just the property name qualified by the table alias. In the following example, we retrieve
Cats from a different table (cat_log) to the one
declared in the mapping metadata. Notice that we may even use the property aliases in the
where clause if we like.
The {}-syntax is not required for named queries. See more in
Note: if you list each property explicitly, you must include all
properties of the class and its subclasses!
Named SQL queries
Named SQL queries may be defined in the mapping document and called in exactly the same way
as a named HQL query. In this case, we do not need to call
addEntity().
SELECT person.NAME AS {person.name},
person.AGE AS {person.age},
person.SEX AS {person.sex}
FROM PERSON person WHERE person.NAME LIKE 'Hiber%'
]]>
A named SQL query may return a scalar value. You must specfy the column alias
and Hibernate type using the <return-scalar> element:
SELECT p.NAME AS name,
p.AGE AS age,
FROM PERSON p WHERE p.NAME LIKE 'Hiber%'
]]>
The <return-join> and <load-collection>
elements are used to join associations and define queries which initialize collections,
respectively. TODO!
Using return-property to explicitly specify column/alias names
With <return-property> you can explicitly tell Hibernate what columns
to use as opposed to use {}-syntax to let Hibernate inject its own aliases.
SELECT person.NAME AS myName,
person.AGE AS myAge,
person.SEX AS mySex,
FROM PERSON person WHERE person.NAME LIKE :name
]]>
<return-property> also works with multiple columns. This solves a limitation with
the {}-syntax which can not allow fine grained control of multi-column properties.
SELECT EMPLOYEE AS {emp.employee}, EMPLOYER AS {emp.employer},
STARTDATE AS {emp.startDate}, ENDDATE AS {emp.endDate},
REGIONCODE as {emp.regionCode}, EID AS {emp.id}, VALUE, CURRENCY
FROM EMPLOYMENT
WHERE EMPLOYER = :id AND ENDDATE IS NULL
ORDER BY STARTDATE ASC
]]>
Notice that in this example we used <return-property> in combination
with the {}-syntax for injection. Allowing users to choose
how they want to refer column and properties.
If your mapping has a discriminator you must use <discriminator-result> to specify the discriminators column.
Using stored procedures for querying
Hibernate 3 introduces support for queries via stored procedures.
The stored procedures must return a resultset as the first out-parameter to be able to work with Hibernate.
An example of such a stored procedure in Oracle 9 and higher is as follows:
To use this query in Hibernate you need to map it via a named query.
{ ? = call selectAllEmployments() }
]]>
Notice stored procedures currently only return scalars and entities.
<return-join> and <load-collection>
are not supported.
TODO: make the "rules" visually nicer and understandable ,)
Rules/Limitations for using stored procedures
To use stored procedures with Hibernate the procedures have to follow some rules.
If they do not follow those rules they are not usable with Hibernate. If you still
want to use these procedures you have to execute them via session.connection().
The rules are different per database since database vendors have different stored procedure
semantics/syntax.
For Oracle the following rules apply:
It must return a result set. This is done by returning a SYS_REFCURSOR in Oracle 9 or 10.
In Oracle you need to define a REF CURSOR type.
It should be on the form { ? = call procName(<parameters>) } or
{ ? = call procName } (This is more an Oracle rule than a Hibernate rule.)
For Sybase or MS SQL server the following rules apply:
It must return a result set. Note that since these servers can/will return multiple result
sets and update count Hibernate will iterate the results and take the first result that is
a result set as its return value. Everything else will be discarded.
If you can enable SET NOCOUNT ON in your procedure it will probably be the most efficient, but
it is not a requirement.
Custom SQL for create, update and delete
Hibernate3 can use custom SQL statements for create, update, and delete operations.
The class and collection persisters in Hibernate already contain a set of configuration
time generated strings (insertsql, deletesql, updatesql etc.). The mapping tags
<sql-insert>, <sql-delete>, and
<sql-update> override these strings:
INSERT INTO PERSON (NAME, ID) VALUES ( UPPER(?), ? )
UPDATE PERSON SET NAME=UPPER(?) WHERE ID=?
DELETE FROM PERSON WHERE ID=?
]]>
The SQL is directly executed in your database, so you are free to use any dialect
you like. This will of course reduce the portability of your mapping if you use database
specific SQL.
Stored procedures are supported if the callable attribute is set:
{call createPerson (?, ?)}
{? = call deletePerson (?)}
{? = call updatePerson (?, ?)}
]]>
The order of the positional parameters are currently vital, as they must be in
the same sequence as Hibernate expects them.
You can see the expected order by enabling debug logging for the org.hiberante.persister.entity
level. With this level enabled Hibernate will print out the static SQL that is used to create, update, delete etc. entities.
To see the expected sequence, remember to not include your custom SQL in the mapping files as that will override the Hibernate generated static sql.
The stored procedures are in most cases (read: better do it than not) required to
return the number of rows inserted/updated/deleted, as Hibernate has some runtime
checks for the success of the statement. Hibernate always registers the first statement
parameter as a numeric output parameter for the CUD operations:
Custom SQL for loading
You may also declare your own SQL (or HQL) queries for entity loading:
SELECT NAME AS {p.name}, ID AS {p.id} FROM PERSON WHERE ID=? FOR UPDATE
]]>
This is just a named query declaration, as discussed earlier. You may
reference this named query in a class mapping:
]]>
And this also works with stored procedures.
TODO: Document the following example for collection loader.
SELECT {empcol.*}
FROM EMPLOYMENT empcol
WHERE EMPLOYER = :id
ORDER BY STARTDATE ASC, EMPLOYEE ASC
SELECT EMPLOYEE AS {emp.employee}, EMPLOYER AS {emp.employer},
STARTDATE AS {emp.startDate}, ENDDATE AS {emp.endDate},
REGIONCODE as {emp.regionCode}, ID AS {emp.id}
FROM EMPLOYMENT
WHERE EMPLOYER = :id AND ENDDATE IS NULL
ORDER BY STARTDATE ASC
]]>