hibernate-orm/reference/en/modules/query_sql.xml

758 lines
29 KiB
XML

<?xml version="1.0" encoding="ISO-8859-1"?>
<chapter id="querysql" revision="2">
<title>Native SQL</title>
<para>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 <literal>CONNECT</literal> keyword in Oracle. It
also provides a clean migration path from a direct SQL/JDBC based
application to Hibernate.</para>
<para>Hibernate3 allows you to specify handwritten SQL (including stored
procedures) for all create, update, delete, and load operations.</para>
<sect1 id="querysql-creating" revision="4">
<title>Using a <literal>SQLQuery</literal></title>
<para>Execution of native SQL queries is controlled via the
<literal>SQLQuery</literal> interface, which is obtained by calling
<literal>Session.createSQLQuery()</literal>. The following describes how
to use this API for querying.</para>
<sect2>
<title>Scalar queries</title>
<para>The most basic SQL query is to get a list of scalars
(values).</para>
<programlisting><![CDATA[sess.createSQLQuery("SELECT * FROM CATS").list();
sess.createSQLQuery("SELECT ID, NAME, BIRTHDATE FROM CATS").list();
]]></programlisting>
<para>These will both return a List of Object arrays (Object[]) with
scalar values for each column in the CATS table. Hibernate will use
ResultSetMetadata to deduce the actual order and types of the returned
scalar values.</para>
<para>To avoid the overhead of using
<literal>ResultSetMetadata</literal> or simply to be more explicit in
what is returned one can use <literal>addScalar()</literal>.</para>
<programlisting><![CDATA[sess.createSQLQuery("SELECT * FROM CATS")
.addScalar("ID", Hibernate.LONG)
.addScalar("NAME", Hibernate.STRING)
.addScalar("BIRTHDATE", Hibernate.DATE)
]]></programlisting>
<para>This query specified:</para>
<itemizedlist>
<listitem>
<para>the SQL query string</para>
</listitem>
<listitem>
<para>the columns and types to return</para>
</listitem>
</itemizedlist>
<para>This will still return Object arrays, but now it will not use
<literal>ResultSetMetdata</literal> but will instead explicitly get the
ID, NAME and BIRTHDATE column as respectively a Long, String and a Short
from the underlying resultset. This also means that only these three
columns will be returned, even though the query is using
<literal>*</literal> and could return more than the three listed
columns.</para>
<para>It is possible to leave out the type information for all or some
of the scalars.</para>
<programlisting><![CDATA[sess.createSQLQuery("SELECT * FROM CATS")
.addScalar("ID", Hibernate.LONG)
.addScalar("NAME")
.addScalar("BIRTHDATE")
]]></programlisting>
<para>This is essentially the same query as before, but now
<literal>ResultSetMetaData</literal> is used to decide the type of NAME
and BIRTHDATE where as the type of ID is explicitly specified.</para>
<para>How the java.sql.Types returned from ResultSetMetaData is mapped
to Hibernate types is controlled by the Dialect. If a specific type is
not mapped or does not result in the expected type it is possible to
customize it via calls to <literal>registerHibernateType</literal> in
the Dialect.</para>
</sect2>
<sect2>
<title>Entity queries</title>
<para>The above queries were all about returning scalar values,
basically returning the "raw" values from the resultset. The following
shows how to get entity objects from a native sql query via
<literal>addEntity()</literal>.</para>
<programlisting><![CDATA[sess.createSQLQuery("SELECT * FROM CATS").addEntity(Cat.class);
sess.createSQLQuery("SELECT ID, NAME, BIRTHDATE FROM CATS").addEntity(Cat.class);
]]></programlisting>
<para>This query specified:</para>
<itemizedlist>
<listitem>
<para>the SQL query string</para>
</listitem>
<listitem>
<para>the entity returned by the query</para>
</listitem>
</itemizedlist>
<para>Assuming that Cat is mapped as a class with the columns ID, NAME
and BIRTHDATE the above queries will both return a List where each
element is a Cat entity.</para>
<para>If the entity is mapped with a <literal>many-to-one</literal> to
another entity it is required to also return this when performing the
native query, otherwise a database specific "column not found" error
will occur. The additional columns will automatically be returned when
using the * notation, but we prefer to be explicit as in the following
example for a <literal>many-to-one</literal> to a
<literal>Dog</literal>:</para>
<programlisting><![CDATA[sess.createSQLQuery("SELECT ID, NAME, BIRTHDATE, DOG_ID FROM CATS").addEntity(Cat.class);
]]></programlisting>
<para>This will allow cat.getDog() to function properly.</para>
</sect2>
<sect2>
<title>Handling associations and collections</title>
<para>It is possible to eagerly join in the <literal>Dog</literal> to
avoid the possible extra roundtrip for initializing the proxy. This is
done via the <literal>addJoin()</literal> method, which allows you to
join in an association or collection.</para>
<programlisting><![CDATA[sess.createSQLQuery("SELECT c.ID, NAME, BIRTHDATE, DOG_ID, D_ID, D_NAME FROM CATS c, DOGS d WHERE c.DOG_ID = d.D_ID")
.addEntity("cat", Cat.class)
.addJoin("cat.dog");
]]></programlisting>
<para>In this example the returned <literal>Cat</literal>'s will have
their <literal>dog</literal> property fully initialized without any
extra roundtrip to the database. Notice that we added a alias name
("cat") to be able to specify the target property path of the join. It
is possible to do the same eager joining for collections, e.g. if the
<literal>Cat</literal> had a one-to-many to <literal>Dog</literal>
instead.</para>
<programlisting><![CDATA[sess.createSQLQuery("SELECT ID, NAME, BIRTHDATE, D_ID, D_NAME, CAT_ID FROM CATS c, DOGS d WHERE c.ID = d.CAT_ID")
.addEntity("cat", Cat.class)
.addJoin("cat.dogs");
]]></programlisting>
<p>At this stage we are reaching the limits of what is possible with
native queries without starting to enhance the sql queries to make them
usable in Hibernate; the problems starts to arise when returning
multiple entities of the same type or when the default alias/column
names are not enough.</p>
</sect2>
<sect2>
<title>Returning multiple entities</title>
<para>Until now 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.</para>
<para>Column alias injection is needed in the following query (which
most likely will fail):</para>
<programlisting><![CDATA[sess.createSQLQuery("SELECT c.*, m.* FROM CATS c, CATS m WHERE c.MOTHER_ID = c.ID")
.addEntity("cat", Cat.class)
.addEntity("mother", Cat.class)
]]></programlisting>
<para>The intention for this query is to return two Cat instances per
row, a cat and its mother. This will fail since there is a conflict of
names since they are mapped to the same column names and on some
databases the returned column aliases will most likely be on the form
"c.ID", "c.NAME", etc. which are not equal to the columns specificed in
the mappings ("ID" and "NAME").</para>
<para>The following form is not vulnerable to column name
duplication:</para>
<programlisting><![CDATA[sess.createSQLQuery("SELECT {cat.*}, {mother.*} FROM CATS c, CATS m WHERE c.MOTHER_ID = c.ID")
.addEntity("cat", Cat.class)
.addEntity("mother", Cat.class)
]]></programlisting>
<para>This query specified:</para>
<itemizedlist>
<listitem>
<para>the SQL query string, with placeholders for Hibernate to
inject column aliases</para>
</listitem>
<listitem>
<para>the entities returned by the query</para>
</listitem>
</itemizedlist>
<para>The {cat.*} and {mother.*} notation used above is a shorthand for
"all properties". Alternatively, you may list the columns explicity, but
even in 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 and their mothers 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.</para>
<programlisting><![CDATA[String sql = "SELECT ID as {c.id}, NAME as {c.name}, " +
"BIRTHDATE as {c.birthDate}, MOTHER_ID as {c.mother}, {mother.*} " +
"FROM CAT_LOG c, CAT_LOG m WHERE {c.mother} = c.ID";
List loggedCats = sess.createSQLQuery(sql)
.addEntity("cat", Cat.class)
.addEntity("mother", Cat.class).list()
]]></programlisting>
<sect3 id="querysql-aliasreferences" revision="2">
<title>Alias and property references</title>
<para>For most cases the above alias injection is needed, but for
queries relating to more complex mappings like composite properties,
inheritance discriminators, collections etc. there are some specific
aliases to use to allow Hibernate to inject the proper aliases.</para>
<para>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.</para>
<table frame="topbot" id="aliasinjection-summary">
<title>Alias injection names</title>
<tgroup cols="3">
<colspec colwidth="1*" />
<colspec colwidth="1*" />
<colspec colwidth="2.5*" />
<thead>
<row>
<entry>Description</entry>
<entry>Syntax</entry>
<entry>Example</entry>
</row>
</thead>
<tbody>
<row>
<entry>A simple property</entry>
<entry><literal>{[aliasname].[propertyname]</literal></entry>
<entry><literal>A_NAME as {item.name}</literal></entry>
</row>
<row>
<entry>A composite property</entry>
<entry><literal>{[aliasname].[componentname].[propertyname]}</literal></entry>
<entry><literal>CURRENCY as {item.amount.currency}, VALUE as
{item.amount.value}</literal></entry>
</row>
<row>
<entry>Discriminator of an entity</entry>
<entry><literal>{[aliasname].class}</literal></entry>
<entry><literal>DISC as {item.class}</literal></entry>
</row>
<row>
<entry>All properties of an entity</entry>
<entry><literal>{[aliasname].*}</literal></entry>
<entry><literal>{item.*}</literal></entry>
</row>
<row>
<entry>A collection key</entry>
<entry><literal>{[aliasname].key}</literal></entry>
<entry><literal>ORGID as {coll.key}</literal></entry>
</row>
<row>
<entry>The id of an collection</entry>
<entry><literal>{[aliasname].id}</literal></entry>
<entry><literal>EMPID as {coll.id}</literal></entry>
</row>
<row>
<entry>The element of an collection</entry>
<entry><literal>{[aliasname].element}</literal></entry>
<entry><literal>XID as {coll.element}</literal></entry>
</row>
<row>
<entry>roperty of the element in the collection</entry>
<entry><literal>{[aliasname].element.[propertyname]}</literal></entry>
<entry><literal>NAME as {coll.element.name}</literal></entry>
</row>
<row>
<entry>All properties of the element in the collection</entry>
<entry><literal>{[aliasname].element.*}</literal></entry>
<entry><literal>{coll.element.*}</literal></entry>
</row>
<row>
<entry>All properties of the the collection</entry>
<entry><literal>{[aliasname].*}</literal></entry>
<entry><literal>{coll.*}</literal></entry>
</row>
</tbody>
</tgroup>
</table>
</sect3>
</sect2>
<sect2>
<title>Returning non-managed entities</title>
<para>It is possible to apply a ResultTransformer to native sql queries. Allowing it to e.g. return non-managed entities.</para>
<programlisting><![CDATA[sess.createSQLQuery("SELECT NAME, BIRTHDATE FROM CATS")
.setResultTransformer(Transformers.aliasToBean(CatDTO.class))]]></programlisting>
<para>This query specified:</para>
<itemizedlist>
<listitem>
<para>the SQL query string</para>
</listitem>
<listitem>
<para>a result transformer</para>
</listitem>
</itemizedlist>
<para>
The above query will return a list of <literal>CatDTO</literal> which has been instantiated and injected the values of NAME and BIRTHNAME into its corresponding
properties or fields.
</para>
</sect2>
<sect2>
<title>Handling inheritance</title>
<para>Native sql queries which query for entities that is mapped as part
of an inheritance must include all properties for the baseclass and all
it subclasses.</para>
</sect2>
<sect2>
<title>Parameters</title>
<para>Native sql queries support positional as well as named
parameters:</para>
<programlisting><![CDATA[Query query = sess.createSQLQuery("SELECT * FROM CATS WHERE NAME like ?").addEntity(Cat.class);
List pusList = query.setString(0, "Pus%").list();
query = sess.createSQLQuery("SELECT * FROM CATS WHERE NAME like :name").addEntity(Cat.class);
List pusList = query.setString("name", "Pus%").list(); ]]></programlisting>
</sect2>
</sect1>
<sect1 id="querysql-namedqueries" revision="3">
<title>Named SQL queries</title>
<para>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
<emphasis>not</emphasis> need to call
<literal>addEntity()</literal>.</para>
<programlisting><![CDATA[<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>]]></programlisting>
<programlisting><![CDATA[List people = sess.getNamedQuery("persons")
.setString("namePattern", namePattern)
.setMaxResults(50)
.list();]]></programlisting>
<para>The <literal>&lt;return-join&gt;</literal> and
<literal>&lt;load-collection&gt;</literal> elements are used to join
associations and define queries which initialize collections,
respectively.</para>
<programlisting><![CDATA[<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>]]></programlisting>
<para>A named SQL query may return a scalar value. You must declare the
column alias and Hibernate type using the
<literal>&lt;return-scalar&gt;</literal> element:</para>
<programlisting><![CDATA[<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>]]></programlisting>
<para>You can externalize the resultset mapping informations in a
<literal>&lt;resultset&gt;</literal> element to either reuse them accross
several named queries or through the
<literal>setResultSetMapping()</literal> API.</para>
<programlisting><![CDATA[<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>]]></programlisting>
<para>You can alternatively use the resultset mapping information in your
hbm files directly in java code.</para>
<programlisting><![CDATA[List cats = sess.createSQLQuery(
"select {cat.*}, {kitten.*} from cats cat, cats kitten where kitten.mother = cat.id"
)
.setResultSetMapping("catAndKitten")
.list();]]></programlisting>
<sect2 id="propertyresults">
<title>Using return-property to explicitly specify column/alias
names</title>
<para>With <literal>&lt;return-property&gt;</literal> you can explicitly
tell Hibernate what column aliases to use, instead of using the
<literal>{}</literal>-syntax to let Hibernate inject its own
aliases.</para>
<programlisting><![CDATA[<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>
]]></programlisting>
<para><literal>&lt;return-property&gt;</literal> also works with
multiple columns. This solves a limitation with the
<literal>{}</literal>-syntax which can not allow fine grained control of
multi-column properties.</para>
<programlisting><![CDATA[<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>]]></programlisting>
<para>Notice that in this example we used
<literal>&lt;return-property&gt;</literal> in combination with the
<literal>{}</literal>-syntax for injection. Allowing users to choose how
they want to refer column and properties.</para>
<para>If your mapping has a discriminator you must use
<literal>&lt;return-discriminator&gt;</literal> to specify the
discriminator column.</para>
</sect2>
<sect2 id="sp_query" revision="1">
<title>Using stored procedures for querying</title>
<para>Hibernate 3 introduces support for queries via stored procedures
and functions. Most of the following documentation is equivalent for
both. The stored procedure/function must return a resultset as the first
out-parameter to be able to work with Hibernate. An example of such a
stored function in Oracle 9 and higher is as follows:</para>
<programlisting><![CDATA[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;]]></programlisting>
<para>To use this query in Hibernate you need to map it via a named
query.</para>
<programlisting><![CDATA[<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>]]></programlisting>
<para>Notice stored procedures currently only return scalars and
entities. <literal>&lt;return-join&gt;</literal> and
<literal>&lt;load-collection&gt;</literal> are not supported.</para>
<sect3 id="querysql-limits-storedprocedures" revision="1">
<title>Rules/limitations for using stored procedures</title>
<para>To use stored procedures with Hibernate the procedures/functions
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 <literal>session.connection()</literal>.
The rules are different for each database, since database vendors have
different stored procedure semantics/syntax.</para>
<para>Stored procedure queries can't be paged with
<literal>setFirstResult()/setMaxResults()</literal>.</para>
<para>Recommended call form is standard SQL92: <literal>{ ? = call
functionName(&lt;parameters&gt;) }</literal> or <literal>{ ? = call
procedureName(&lt;parameters&gt;}</literal>. Native call syntax is not
supported.</para>
<para>For Oracle the following rules apply:</para>
<itemizedlist spacing="compact">
<listitem>
<para>A function must return a result set. The first parameter of
a procedure must be an <literal>OUT</literal> that returns a
result set. This is done by using a
<literal>SYS_REFCURSOR</literal> type in Oracle 9 or 10. In Oracle
you need to define a <literal>REF CURSOR</literal> type, see
Oracle literature.</para>
</listitem>
</itemizedlist>
<para>For Sybase or MS SQL server the following rules apply:</para>
<itemizedlist spacing="compact">
<listitem>
<para>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.</para>
</listitem>
<listitem>
<para>If you can enable <literal>SET NOCOUNT ON</literal> in your
procedure it will probably be more efficient, but this is not a
requirement.</para>
</listitem>
</itemizedlist>
</sect3>
</sect2>
</sect1>
<sect1 id="querysql-cud">
<title>Custom SQL for create, update and delete</title>
<para>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
<literal>&lt;sql-insert&gt;</literal>,
<literal>&lt;sql-delete&gt;</literal>, and
<literal>&lt;sql-update&gt;</literal> override these strings:</para>
<programlisting><![CDATA[<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>]]></programlisting>
<para>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.</para>
<para>Stored procedures are supported if the <literal>callable</literal>
attribute is set:</para>
<programlisting><![CDATA[<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>]]></programlisting>
<para>The order of the positional parameters are currently vital, as they
must be in the same sequence as Hibernate expects them.</para>
<para>You can see the expected order by enabling debug logging for the
<literal>org.hibernate.persister.entity</literal> 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.)</para>
<para>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:</para>
<programlisting><![CDATA[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;]]></programlisting>
</sect1>
<sect1 id="querysql-load">
<title>Custom SQL for loading</title>
<para>You may also declare your own SQL (or HQL) queries for entity
loading:</para>
<programlisting><![CDATA[<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>]]></programlisting>
<para>This is just a named query declaration, as discussed earlier. You
may reference this named query in a class mapping:</para>
<programlisting><![CDATA[<class name="Person">
<id name="id">
<generator class="increment"/>
</id>
<property name="name" not-null="true"/>
<loader query-ref="person"/>
</class>]]></programlisting>
<para>This even works with stored procedures.</para>
<para>You may even define a query for collection loading:</para>
<programlisting><![CDATA[<set name="employments" inverse="true">
<key/>
<one-to-many class="Employment"/>
<loader query-ref="employments"/>
</set>]]></programlisting>
<programlisting><![CDATA[<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>]]></programlisting>
<para>You could even define an entity loader that loads a collection by
join fetching:</para>
<programlisting><![CDATA[<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>]]></programlisting>
</sect1>
</chapter>