This chapter describes the query type generation and querying functionality of the SQL module.
Add the following dependencies to your Maven project:
<dependency> <groupId>com.mysema.querydsl</groupId> <artifactId>querydsl-sql</artifactId> <version>${querydsl.version}</version> </dependency> <dependency> <groupId>com.mysema.querydsl</groupId> <artifactId>querydsl-sql-codegen</artifactId> <version>${querydsl.version}</version> <scope>provided</scope> </dependency> <dependency> <groupId>org.slf4j</groupId> <artifactId>slf4j-log4j12</artifactId> <version>1.6.1</version> </dependency>
The querydsl-sql-codegen dependency can be skipped, if code generation happens via Maven or Ant.
This functionality should be primarily used via the Maven plugin. Here is an example:
<plugin> <groupId>com.mysema.querydsl</groupId> <artifactId>querydsl-maven-plugin</artifactId> <version>${querydsl.version}</version> <executions> <execution> <goals> <goal>export</goal> </goals> </execution> </executions> <configuration> <jdbcDriver>org.apache.derby.jdbc.EmbeddedDriver</jdbcDriver> <jdbcUrl>jdbc:derby:target/demoDB;create=true</jdbcUrl> <packageName>com.myproject.domain</packageName> <targetFolder>${project.basedir}/target/generated-sources/java</targetFolder> </configuration> <dependencies> <dependency> <groupId>org.apache.derby</groupId> <artifactId>derby</artifactId> <version>${derby.version}</version> </dependency> </dependencies> </plugin>
Use the goal test-export to add the targetFolder as a test compile source root instead of a compile source root.
Table 2.1. Parameters
Name | Description |
---|---|
jdbcDriver | class name of the JDBC driver |
jdbcUrl | JDBC url |
jdbcUser | JDBC user |
jdbcPassword | JDBC password |
namePrefix | name prefix for generated query classes (default: Q) |
nameSuffix | name suffix for generated query classes (default: ) |
beanPrefix | name prefix for generated bean classes |
beanSuffix | name suffix for generated bean classes |
packageName | package name where source files should be generated |
beanPackageName | package name where bean files should be generated, (default: packageName) |
beanInterfaces | array of interface classnames to add to the bean classes (default: empty) |
beanAddToString | set to true to create a default toString() implementation (default: false) |
beanAddFullConstructor | set to true to create a full constructor in addition to public empty (default: false) |
beanPrintSupertype | set to true to print the supertype as well (default: false) |
schemaPattern | a schema name pattern; must match the schema name as it is stored in the database; (default: null) |
tableNamePattern | a table name pattern; must match the table name as it is stored in the database, multiple can be separated by comma (default: null) |
targetFolder | target folder where source filder should be generated |
namingStrategyClass | class name of the NamingStrategy class (default: DefaultNamingStrategy) |
beanSerializerClass | class name of the BeanSerializer class (default: BeanSerializer) |
serializerClass | class name of the Serializer class (default: MetaDataSerializer) |
exportBeans | set to true to generate beans as well, see section 2.14.13 (default: false) |
innerClassesForKeys | set to true to generate inner classes for keys (default: false) |
validationAnnotations | set to true to enable serialization of validation annotations (default: false) |
columnAnnotations | export column annotations (default: false) |
createScalaSources | whether to export Scala sources instead of Java sources, (default: false) |
schemaToPackage | append schema name to package (default: false) |
lowerCase | lower case transformation of names (default: false) |
exportTables | export tables (default: true) |
exportViews | export views (default: true) |
exportPrimaryKeys | export primary keys (default: true) |
exportForeignKeys | export foreign keys (default: true) |
customTypes | Custom user types (default: none) |
typeMappings | Mappings of table.column to Java type (default: none) |
numericMappings | Mappings of size/digits to Java type (default: none) |
imports | Array of java imports added to generated query classes: com.bar for package (without .* notation), com.bar.Foo for class (default: empty) |
Custom types can be used to register additional Type implementations:
<customTypes> <customType>com.mysema.query.sql.types.InputStreamType</customType> </customTypes>
Type mappings can be used to register table.column specific java types:
<typeMappings> <typeMapping> <table>IMAGE</table> <column>CONTENTS</column> <type>java.io.InputStream</type> </typeMapping> </typeMappings>
Numeric mappings can be used to customize the mappings for the SQL numeric type:
<numericMappings> <numericMapping> <size>1</size> <digits>0</digits> <javaType>java.lang.Byte</javaType> </numericMapping> </numericMappings>
Imports can be used to add cross-schema foreign keys support.
The ANT task com.mysema.query.sql.ant.AntMetaDataExporter
of the querydsl-sql module provides the same functionality as an ANT task.
The configuration parameters of the task are the same as for the Maven plugin.
To get started export your schema into Querydsl query types like this:
java.sql.Connection conn = ...; MetaDataExporter exporter = new MetaDataExporter(); exporter.setPackageName("com.myproject.mydomain"); exporter.setTargetFolder(new File("target/generated-sources/java")); exporter.export(conn.getMetaData());
This declares that the database schema is to be mirrored into the com.myproject.domain package in the target/generated-sources/java folder.
The generated types have the table name transformed to mixed case as the class name and a similar mixed case transformation applied to the columns which are available as property paths in the query type.
In addition to this primary key and foreign key constraints are provided as fields which can be used for compact join declarations.
The configuration is done via the com.mysema.query.sql.Configuration class which takes the Querydsl SQL dialect as an argument. For H2 you would create it like this
SQLTemplates templates = new H2Templates(); Configuration configuration = new Configuration(templates);
Querydsl uses SQL dialects to customize the SQL serialization needed for different relational databases. The available dialects are:
CUBRIDTemplates (tested with 8.4)
DerbyTemplates (tested with 10.8.2.2)
HSQLDBTemplates (tested with 2.2.4)
H2Templates (tested with 1.3.164)
MySQLTemplates (tested with MySQL 5.5)
OracleTemplates (test with Oracle 10 and 11)
PostgresTemplates (tested with 9.1)
SQLiteTemplates (tested with xerial JDBC 3.7.2)
SQLServerTemplates (tested with SQL Server)
SQLServer2005Templates (for SQL Server 2005)
SQLServer2008Templates (for SQL Server 2008)
SQLServer2012Templates (for SQL Server 2012 and later)
TeradataTemplates (tested with Teradata 14)
For customized SQLTemplates instances you can use the builder pattern like this
H2Templates.builder() .printSchema() // to include the schema in the output .quote() // to quote names .newLineToSingleSpace() // to replace new lines with single space in the output .escape(ch) // to set the escape char .build(); // to get the customized SQLTemplates instance
Querying with Querydsl SQL is as simple as this:
QCustomer customer = new QCustomer("c"); SQLQuery query = new SQLQuery(connection, configuration); List<String> lastNames = query.from(customer) .where(customer.firstName.eq("Bob")) .list(customer.lastName);
which is transformed into the following sql query, assuming that the related table name is customer and the columns first_name and last_name:
SELECT c.last_name FROM customer c WHERE c.first_name = 'Bob'
Use the the cascading methods of the SQLQuery class like this
from: Add the query sources here.
innerJoin, join, leftJoin, fullJoin, on: Add join elements using these constructs. For the join methods the first argument is the join source and the second the target (alias).
where: Add query filters, either in varargs form separated via commas or cascaded via the and-operator.
groupBy: Add group by arguments in varargs form.
having: Add having filter of the "group by" grouping as an varags array of Predicate expressions.
orderBy: Add ordering of the result as an varargs array of order expressions. Use asc() and desc() on numeric, string and other comparable expression to access the OrderSpecifier instances.
limit, offset, restrict: Set the paging of the result. Limit for max results, offset for skipping rows and restrict for defining both in one call.
Joins are constructed using the following syntax:
QCustomer customer = QCustomer.customer; QCompany company = QCompany.company; query.from(customer) .innerJoin(customer.company, company) .list(customer.firstName, customer.lastName, company.name);
and for a left join:
query.from(customer) .leftJoin(customer.company, company) .list(customer.firstName, customer.lastName, company.name);
Alternatively the join condition can also be written out:
query.from(customer) .leftJoin(company).on(customer.company.eq(company.id)) .list(customer.firstName, customer.lastName, company.name);
The syntax for declaring ordering is
query.from(customer) .orderBy(customer.lastName.asc(), customer.firstName.asc()) .list(customer.firstName, customer.lastName);
which is equivalent to the following native SQL
SELECT c.first_name, c.last_name FROM customer c ORDER BY c.last_name ASC, c.first_name ASC
Grouping can be done in the following form
query.from(customer) .groupBy(customer.lastName) .list(customer.lastName);
which is equivalent to the following native SQL
SELECT c.last_name FROM customer c GROUP BY c.last_name
To create a subquery you create a SQLSubQuery instance, define the query parameters via from, where etc and use unique or list to create a subquery, which is just a type-safe Querydsl expression for the query. unique is used for a unique (single) result and list for a list result.
QCustomer customer = QCustomer.customer; QCustomer customer2 = new QCustomer("customer2"); query.from(customer).where( customer.status.eq(new SQLSubQuery().from(customer2).unique(customer2.status.max())) .list(customer.all())
Another example
QStatus status = QStatus.status; query.from(customer).where( customer.status.in(new SQLSubQuery().from(status).where(status.level.lt(3)).list(status.id)) .list(customer.all())
To select literals you need to create constant instances for them like this:
query.list(Expressions.constant(1), Expressions.constant("abc"));
The class com.mysema.query.support.Expressions
offers also other useful static methods for
projections, operation and template creation.
Custom query extensions to support engine specific syntax can be created by subclassing AbstractSQLQuery and adding flagging methods like in the given MySQLQuery example:
public class MySQLQuery extends AbstractSQLQuery<MySQLQuery> { public MySQLQuery(Connection conn) { this(conn, new MySQLTemplates(), new DefaultQueryMetadata()); } public MySQLQuery(Connection conn, SQLTemplates templates) { this(conn, templates, new DefaultQueryMetadata()); } protected MySQLQuery(Connection conn, SQLTemplates templates, QueryMetadata metadata) { super(conn, new Configuration(templates), metadata); } public MySQLQuery bigResult(){ return addFlag(Position.AFTER_SELECT, "SQL_BIG_RESULT "); } public MySQLQuery bufferResult(){ return addFlag(Position.AFTER_SELECT, "SQL_BUFFER_RESULT "); } // ... }
The flags are custom SQL snippets that can be inserted at specific points in the
serialization. The supported positions are the enums of the
com.mysema.query.QueryFlag.Position
enum class.
Window functions are supported in Querydsl via the methods in the SQLExpressions
class.
Usage example:
query.from(employee) .list(SQLExpressions.rowNumber() .over() .partitionBy(employee.name) .orderBy(employee.id));
Other SQL expressions are also available from the SQLExpressions
class as static methods.
All the DMLClause implementation in the Querydsl SQL module take three parameters, the Connection, the SQLTemplates instance used in the queries and the main entity the DMLClause is bound to.
With columns
QSurvey survey = QSurvey.survey; new SQLInsertClause(conn, configuration, survey) .columns(survey.id, survey.name) .values(3, "Hello").execute();
Without columns
new SQLInsertClause(conn, configuration, survey) .values(4, "Hello").execute();
With subquery
new SQLInsertClause(conn, configuration, survey) .columns(survey.id, survey.name) .select(new SQLSubQuery().from(survey2).list(survey2.id.add(1), survey2.name)) .execute();
With subquery, without columns
new SQLInsertClause(conn, configuration, survey) .select(new SQLSubQuery().from(survey2).list(survey2.id.add(10), survey2.name)) .execute();
As an alternative to the columns/values usage, Querydsl provides also a set method which can be used like this
QSurvey survey = QSurvey.survey; new SQLInsertClause(conn, configuration, survey) .set(survey.id, 3) .set(survey.name, "Hello").execute();
which is equivalent to the first example. Usage of the set method always expands internally to columns and values.
Beware that
columns(...).select(...)
maps the result set of the given query to be inserted whereas
To get the created keys out instead of modified rows count use one of the executeWithKey/s method.
set(...)
maps single columns and nulls are used for empty subquery results.
To populate a clause instance based on the contents of a bean you can use
new SQLInsertClause(conn, configuration, survey)
.populate(surveyBean).execute();
This will exclude null bindings, if you need also null bindings use
new SQLInsertClause(conn, configuration, survey)
.populate(surveyBean, DefaultMapper.WITH_NULL_BINDINGS).execute();
With where
QSurvey survey = QSurvey.survey; new SQLUpdateClause(conn, configuration, survey) .where(survey.name.eq("XXX")) .set(survey.name, "S") .execute();
Without where
new SQLUpdateClause(conn, configuration, survey) .set(survey.name, "S") .execute();
Using bean population
new SQLUpdateClause(conn, configuration, survey)
.populate(surveyBean)
.execute();
Querydsl SQL supports usage of JDBC batch updates through the DML APIs. If you have consecutive DML calls with a similar structure, you can bundle the the calls via addBatch() usage into one DMLClause. See the examples how it works for UPDATE, DELETE and INSERT.
Update:
QSurvey survey = QSurvey.survey; insert(survey).values(2, "A").execute(); insert(survey).values(3, "B").execute(); SQLUpdateClause update = update(survey); update.set(survey.name, "AA").where(survey.name.eq("A")).addBatch(); update.set(survey.name, "BB").where(survey.name.eq("B")).addBatch();
Delete:
insert(survey).values(2, "A").execute(); insert(survey).values(3, "B").execute(); SQLDeleteClause delete = delete(survey); delete.where(survey.name.eq("A")).addBatch(); delete.where(survey.name.eq("B")).addBatch(); assertEquals(2, delete.execute());
Insert:
SQLInsertClause insert = insert(survey); insert.set(survey.id, 5).set(survey.name, "5").addBatch(); insert.set(survey.id, 6).set(survey.name, "6").addBatch(); assertEquals(2, insert.execute());
To create JavaBean DTO types for the tables of your schema use the MetaDataExporter like this:
java.sql.Connection conn = ...; MetaDataExporter exporter = new MetaDataExporter(); exporter.setPackageName("com.myproject.mydomain"); exporter.setTargetFolder(new File("src/main/java")) ; exporter.setBeanSerializer(new BeanSerializer()); exporter.export(conn.getMetaData());
Now you can use the bean types as arguments to the populate method in DML clauses and you can project directly to bean types in queries. Here is a simple example in JUnit form:
QEmployee e = new QEmployee("e"); // Insert Employee employee = new Employee(); employee.setFirstname("John"); Integer id = insert(e).populate(employee).executeWithKey(e.id); employee.setId(id); // Update employee.setLastname("Smith"); assertEquals(1l, update(e).populate(employee).where(e.id.eq(employee.getId())).execute()); // Query Employee smith = query().from(e).where(e.lastname.eq("Smith")).uniqueResult(e); assertEquals("John", smith.getFirstname()); // Delete assertEquals(1l, delete(e).where(e.id.eq(employee.getId())).execute());
The factory methods used in the previous example are here:
protected SQLUpdateClause update(RelationalPath<?> e){ return new SQLUpdateClause(Connections.getConnection(), templates, e); } protected SQLInsertClause insert(RelationalPath<?> e){ return new SQLInsertClause(Connections.getConnection(), templates, e); } protected SQLDeleteClause delete(RelationalPath<?> e){ return new SQLDeleteClause(Connections.getConnection(), templates, e); } protected SQLMergeClause merge(RelationalPath<?> e){ return new SQLMergeClause(Connections.getConnection(), templates, e); } protected SQLQuery query() { return new SQLQuery(Connections.getConnection(), templates); }
Querydsl SQL provides the possibility to declare custom type mappings for ResultSet/Statement interaction. The custom type mappings can be declared in com.mysema.query.sql.Configuration instances, which are supplied as constructor arguments to the actual queries:
Configuration configuration = new Configuration(new H2Templates()); // overrides the mapping for Types.DATE configuration.register(new UtilDateType());
And for a table column
Configuration configuration = new Configuration(new H2Templates()); // declares a maping for the gender column in the person table configuration.register("person", "gender", new EnumByNameType<Gender>(Gender.class));
To customize a numeric mapping you can use the registerNumeric method like this
configuration.registerNumeric(5,2,Float.class);
This will map the Float type to the NUMERIC(5,2) type.
SQLListener is a listener interface that can be used to listen to queries and DML clause. SQLListener instances can be registered either on the configuration and on the query/clause level via the addListener method.
Use cases for listeners are data synchronization, logging, cacheing and validation.