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. Using a <literal>SQLQuery</literal> Execution of native SQL queries is controlled via the SQLQuery interface, which is obtained by calling Session.createSQLQuery(). In extremely simple cases, we can use the following form: List cats = sess.createSQLQuery("select * from cats") .addEntity(Cat.class) .list(); This query specified: the SQL query string the entity returned by the query Here, the result set column names are assumed to be the same as the column names specified in the mapping document. This can be problematic for SQL queries which join multiple tables, since the same column names may appear in more than one table. The following form is not vulnerable to column name duplication: List cats = sess.createSQLQuery("select {cat.*} from cats cat") .addEntity("cat", Cat.class) .list(); 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 the SQL table alias with the returned entity class, and determines the shape of the query result set. The addJoin() method may be used to load associations to other entities and collections. List cats = sess.createSQLQuery( "select {cat.*}, {kitten.*} from cats cat, cats kitten where kitten.mother = cat.id" ) .addEntity("cat", Cat.class) .addJoin("kitten", "cat.kittens") .list(); A native SQL query might return a simple scalar value or a combination of scalars and entities. Double max = (Double) sess.createSQLQuery("select max(cat.weight) as maxWeight from cats cat") .addScalar("maxWeight", Hibernate.DOUBLE); .uniqueResult(); You can alternatively describe the resultset mapping informations in your hbm files and use them for your queries List cats = sess.createSQLQuery( "select {cat.*}, {kitten.*} from cats cat, cats kitten where kitten.mother = cat.id" ) .setResultSetMapping("catAndKitten") .list(); Alias and property references The {cat.*} notation used above is a shorthand for "all properties". Alternatively, you may list the columns explicity, but even this case we 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 String sql = "select cat.originalId as {cat.id}, " + "cat.mateid as {cat.mate}, cat.sex as {cat.sex}, " + "cat.weight*10 as {cat.weight}, cat.name as {cat.name} " + "from cat_log cat where {cat.mate} = :catId" List loggedCats = sess.createSQLQuery(sql) .addEntity("cat", Cat.class) .setLong("catId", catId) .list(); Note: if you list each property explicitly, you must include all properties of the class and its subclasses! The following table shows the different possibilities of using the alias injection. Note: the alias names in the result are examples, each alias will have a unique and probably different name when used. Alias injection names Description Syntax Example A simple property {[aliasname].[propertyname] A_NAME as {item.name} A composite property {[aliasname].[componentname].[propertyname]} CURRENCY as {item.amount.currency}, VALUE as {item.amount.value} Discriminator of an entity {[aliasname].class} DISC as {item.class} All properties of an entity {[aliasname].*} {item.*} A collection key {[aliasname].key} ORGID as {coll.key} The id of an collection {[aliasname].id} EMPID as {coll.id} The element of an collection {[aliasname].element} XID as {coll.element} Property of the element in the collection {[aliasname].element.[propertyname]} NAME as {coll.element.name} All properties of the element in the collection {[aliasname].element.*} {coll.element.*} All properties of the the collection {[aliasname].*} {coll.*}
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(). <sql-query name="persons"> <return alias="person" class="eg.Person"/> SELECT person.NAME AS {person.name}, person.AGE AS {person.age}, person.SEX AS {person.sex} FROM PERSON person WHERE person.NAME LIKE :namePattern </sql-query> List people = sess.getNamedQuery("persons") .setString("namePattern", namePattern) .setMaxResults(50) .list(); The <return-join> and <load-collection> elements are used to join associations and define queries which initialize collections, respectively. <sql-query name="personsWith"> <return alias="person" class="eg.Person"/> <return-join alias="address" property="person.mailingAddress"/> SELECT person.NAME AS {person.name}, person.AGE AS {person.age}, person.SEX AS {person.sex}, adddress.STREET AS {address.street}, adddress.CITY AS {address.city}, adddress.STATE AS {address.state}, adddress.ZIP AS {address.zip} FROM PERSON person JOIN ADDRESS adddress ON person.ID = address.PERSON_ID AND address.TYPE='MAILING' WHERE person.NAME LIKE :namePattern </sql-query> A named SQL query may return a scalar value. You must specfy the column alias and Hibernate type using the <return-scalar> element: <sql-query name="mySqlQuery"> <return-scalar column="name" type="string"/> <return-scalar column="age" type="long"/> SELECT p.NAME AS name, p.AGE AS age, FROM PERSON p WHERE p.NAME LIKE 'Hiber%' </sql-query> You can externalize the resultset mapping informations in a <resultset> element to either reuse them accross several named queries or through the setResultSetMapping() API. <resultset name="personAddress"> <return alias="person" class="eg.Person"/> <return-join alias="address" property="person.mailingAddress"/> </resultset> <sql-query name="personsWith" resultset-ref="personAddress"> SELECT person.NAME AS {person.name}, person.AGE AS {person.age}, person.SEX AS {person.sex}, adddress.STREET AS {address.street}, adddress.CITY AS {address.city}, adddress.STATE AS {address.state}, adddress.ZIP AS {address.zip} FROM PERSON person JOIN ADDRESS adddress ON person.ID = address.PERSON_ID AND address.TYPE='MAILING' WHERE person.NAME LIKE :namePattern </sql-query> Using return-property to explicitly specify column/alias names With <return-property> you can explicitly tell Hibernate what column aliases to use, instead of using the {}-syntax to let Hibernate inject its own aliases. <sql-query name="mySqlQuery"> <return alias="person" class="eg.Person"> <return-property name="name" column="myName"/> <return-property name="age" column="myAge"/> <return-property name="sex" column="mySex"/> </return> SELECT person.NAME AS myName, person.AGE AS myAge, person.SEX AS mySex, FROM PERSON person WHERE person.NAME LIKE :name </sql-query> <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. <sql-query name="organizationCurrentEmployments"> <return alias="emp" class="Employment"> <return-property name="salary"> <return-column name="VALUE"/> <return-column name="CURRENCY"/> </return-property> <return-property name="endDate" column="myEndDate"/> </return> 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 </sql-query> 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 <return-discriminator> to specify the discriminator 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: CREATE OR REPLACE FUNCTION selectAllEmployments RETURN SYS_REFCURSOR AS st_cursor SYS_REFCURSOR; BEGIN OPEN st_cursor FOR SELECT EMPLOYEE, EMPLOYER, STARTDATE, ENDDATE, REGIONCODE, EID, VALUE, CURRENCY FROM EMPLOYMENT; RETURN st_cursor; END; To use this query in Hibernate you need to map it via a named query. <sql-query name="selectAllEmployees_SP" callable="true"> <return alias="emp" class="Employment"> <return-property name="employee" column="EMPLOYEE"/> <return-property name="employer" column="EMPLOYER"/> <return-property name="startDate" column="STARTDATE"/> <return-property name="endDate" column="ENDDATE"/> <return-property name="regionCode" column="REGIONCODE"/> <return-property name="id" column="EID"/> <return-property name="salary"> <return-column name="VALUE"/> <return-column name="CURRENCY"/> </return-property> </return> { ? = call selectAllEmployments() } </sql-query> Notice stored procedures currently only return scalars and entities. <return-join> and <load-collection> are not supported. 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 for each database, since database vendors have different stored procedure semantics/syntax. Stored procedure queries can't be paged with setFirstResult()/setMaxResults(). For Oracle the following rules apply: The procedure 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. Recommended form is { ? = 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: The procedure must return a result set. Note that since these servers can/will return multiple result sets and update counts, 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 more efficient, but this 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: <class name="Person"> <id name="id"> <generator class="increment"/> </id> <property name="name" not-null="true"/> <sql-insert>INSERT INTO PERSON (NAME, ID) VALUES ( UPPER(?), ? )</sql-insert> <sql-update>UPDATE PERSON SET NAME=UPPER(?) WHERE ID=?</sql-update> <sql-delete>DELETE FROM PERSON WHERE ID=?</sql-delete> </class> 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: <class name="Person"> <id name="id"> <generator class="increment"/> </id> <property name="name" not-null="true"/> <sql-insert callable="true">{call createPerson (?, ?)}</sql-insert> <sql-delete callable="true">{? = call deletePerson (?)}</sql-delete> <sql-update callable="true">{? = call updatePerson (?, ?)}</sql-update> </class> 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.hibernate.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: CREATE OR REPLACE FUNCTION updatePerson (uid IN NUMBER, uname IN VARCHAR2) RETURN NUMBER IS BEGIN update PERSON set NAME = uname, where ID = uid; return SQL%ROWCOUNT; END updatePerson; Custom SQL for loading You may also declare your own SQL (or HQL) queries for entity loading: <sql-query name="person"> <return alias="pers" class="Person" lock-mode="upgrade"/> SELECT NAME AS {pers.name}, ID AS {pers.id} FROM PERSON WHERE ID=? FOR UPDATE </sql-query> This is just a named query declaration, as discussed earlier. You may reference this named query in a class mapping: <class name="Person"> <id name="id"> <generator class="increment"/> </id> <property name="name" not-null="true"/> <loader query-ref="person"/> </class> This even works with stored procedures. You may even define a query for collection loading: <set name="employments" inverse="true"> <key/> <one-to-many class="Employment"/> <loader query-ref="employments"/> </set> <sql-query name="employments"> <load-collection alias="emp" role="Person.employments"/> SELECT {emp.*} FROM EMPLOYMENT emp WHERE EMPLOYER = :id ORDER BY STARTDATE ASC, EMPLOYEE ASC </sql-query> You could even define an entity loader that loads a collection by join fetching: <sql-query name="person"> <return alias="pers" class="Person"/> <return-join alias="emp" property="pers.employments"/> SELECT NAME AS {pers.*}, {emp.*} FROM PERSON pers LEFT OUTER JOIN EMPLOYMENT emp ON pers.ID = emp.PERSON_ID WHERE ID=? </sql-query>