216 lines
7.7 KiB
XML
216 lines
7.7 KiB
XML
<chapter id="querysql" revision="1">
|
|
<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 the CONNECT keyword in Oracle.
|
|
This also allows for a cleaner migration path from a direct SQL/JDBC based application to
|
|
Hibernate.
|
|
</para>
|
|
|
|
<para>
|
|
Hibernate3 also supports native SQL statements for all create, update, delete, and load
|
|
operations.
|
|
</para>
|
|
|
|
<sect1 id="querysql-creating">
|
|
<title>Creating a SQL based <literal>Query</literal></title>
|
|
|
|
<para>
|
|
SQL queries are exposed through the same <literal>Query</literal> interface, just like ordinary
|
|
HQL queries. The only difference is the use of <literal>Session.createSQLQuery()</literal>.
|
|
</para>
|
|
|
|
<programlisting><![CDATA[Query sqlQuery = sess.createSQLQuery("select {cat.*} from cats {cat}", "cat", Cat.class);
|
|
sqlQuery.setMaxResults(50);
|
|
List cats = sqlQuery.list();]]></programlisting>
|
|
|
|
<para>
|
|
The three parameters provided to <literal>createSQLQuery()</literal> are:
|
|
</para>
|
|
|
|
<itemizedlist>
|
|
<listitem>
|
|
<para>
|
|
the SQL query string
|
|
</para>
|
|
</listitem>
|
|
<listitem>
|
|
<para>
|
|
a table alias name
|
|
</para>
|
|
</listitem>
|
|
<listitem>
|
|
<para>
|
|
the persistent class returned by the query
|
|
</para>
|
|
</listitem>
|
|
</itemizedlist>
|
|
|
|
<para>
|
|
The alias name is used inside the sql string to refer to the properties of the mapped class
|
|
(in this case <literal>Cat</literal>). You may retrieve multiple objects per row by supplying
|
|
a <literal>String</literal> array of alias names and a <literal>Class</literal> array of
|
|
corresponding classes.
|
|
</para>
|
|
|
|
</sect1>
|
|
|
|
<sect1 id="querysql-aliasreferences">
|
|
<title>Alias and property references</title>
|
|
|
|
<para>
|
|
The <literal>{cat.*}</literal> notation used above is a shorthand for "all properties". You
|
|
may even list the properties explicity, but you must let Hibernate provide SQL column aliases
|
|
for each property. The placeholders for these column aliases are the property name qualified by
|
|
the table alias. In the following example, we retrieve <literal>Cat</literal>s from a different
|
|
table (<literal>cat_log</literal>) to the one declared in the mapping metadata. Notice that we
|
|
may even use the property aliases in the where clause.
|
|
</para>
|
|
|
|
<programlisting><![CDATA[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, "cat", Cat.class)
|
|
.setLong("catId", catId)
|
|
.list();
|
|
]]></programlisting>
|
|
|
|
<para>
|
|
<emphasis>Note:</emphasis> if you list each property explicitly, you must include all
|
|
properties of the class <emphasis>and its subclasses</emphasis>!
|
|
</para>
|
|
|
|
</sect1>
|
|
|
|
<sect1 id="querysql-namedqueries" revision="1">
|
|
<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.
|
|
</para>
|
|
|
|
<programlisting><![CDATA[List people = sess.getNamedQuery("mySqlQuery")
|
|
.setMaxResults(50)
|
|
.list();]]></programlisting>
|
|
|
|
<programlisting><![CDATA[<sql-query name="mySqlQuery">
|
|
<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 'Hiber%'
|
|
</sql-query>]]></programlisting>
|
|
|
|
<para>
|
|
Using named SQL queries, you may also query for scalar values. To do this, use the type attribute
|
|
of the <literal><scalar-return></literal> element and specify a type there:
|
|
</para>
|
|
|
|
<programlisting><![CDATA[<sql-query name="mySqlQuery">
|
|
<scalar-return column="name" type="string"/>
|
|
<scalar-return column="age" type="long"/>
|
|
SELECT p.NAME AS name,
|
|
p.AGE AS age,
|
|
FROM PERSON p WHERE p.NAME LIKE 'Hiber%'
|
|
</sql-query>]]></programlisting>
|
|
|
|
</sect1>
|
|
|
|
<sect1 id="querysql-cud">
|
|
<title>Custom SQL for CUD</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><sql-insert></literal>, <literal><sql-delete></literal>, and
|
|
<literal><sql-update></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 execute in your database, so you are free to use any dialect
|
|
you like.
|
|
</para>
|
|
|
|
<para>
|
|
Stored procedures are support 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 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="p" class="Person" lock-mode="upgrade"/>
|
|
SELECT NAME AS {p.name}, ID AS {p.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>
|
|
TODO: Document synchronized mapping element in named queries
|
|
</para>
|
|
|
|
</sect1>
|
|
|
|
</chapter> |