9.8 KiB
灵活的 QueryWrapper
在 增删改 和 查询和分页 章节中,我们随时能看到 QueryWrapper 的身影,QueryWrapper 是用于构造 Sql 的 强有力工具,也是 Mybatis-Flex 的亮点和特色。
::: tip 提示
QueryWrapper 可以被序列化通过 RPC 进行传输,因此,在微服务项目中,我们可以在客户端(网关、Controller 层等)构造出 QueryWrapper,传给 Provider 层进行查询返回数据。 :::
QueryWrapper 的使用
以下代码是一个完整 Spring Controller 的示例:
@RestController
public class AccountController {
@Autowired
AccountMapper accountMapper;
@GetMapping("/accounts")
List<Account> selectList() {
//构造 QueryWrapper
QueryWrapper query = new QueryWrapper();
query.where(ACCOUNT.ID.ge(100));
//通过 query 查询数据列表返回
return accountMapper.selectListByQuery(query);
}
}
在以上的示例中,其核心代码如下所示:
//构造 QueryWrapper
QueryWrapper query = new QueryWrapper();
query.where(ACCOUNT.ID.ge(100));
//通过 query 查询数据列表
accountMapper.selectListByQuery(query);
以上代码执行的 Sql 如下:
select * from tb_account
where id >= 100
select *
QueryWrapper query=new QueryWrapper();
query.select(ACCOUNT.ID, ACCOUNT.USER_NAME)
.from(ACCOUNT)
其查询生成的 Sql 如下:
SELECT id, user_name FROM tb_account
select ... as
QueryWrapper query = new QueryWrapper()
.select(
ACCOUNT.ID.as("accountId")
, ACCOUNT.USER_NAME
.from(ACCOUNT.as("a"));
其查询生成的 Sql 如下:
SELECT a.id as accountId, a.user_name
FROM tb_account AS a
select 多张表
QueryWrapper query = new QueryWrapper()
.select(
ACCOUNT.ID
, ACCOUNT.USER_NAME
, ARTICLE.ID.as("articleId")
, ARTICLE.TITLE)
.from(ACCOUNT.as("a"), ARTICLE.as("b"))
.where(ACCOUNT.ID.eq(ARTICLE.ACCOUNT_ID));
其查询生成的 Sql 如下:
SELECT a.id, a.user_name, b.id AS articleId, b.title
FROM tb_account AS a, tb_article AS b
WHERE a.id = b.account_id
select function
QueryWrapper query=new QueryWrapper()
.select(
ACCOUNT.ID,
ACCOUNT.USER_NAME,
max(ACCOUNT.BIRTHDAY),
avg(ACCOUNT.SEX).as("sex_avg")
).from(ACCOUNT);
其查询生成的 Sql 如下:
SELECT id, user_name, MAX(birthday), AVG(sex) AS sex_avg
FROM tb_account
where
QueryWrapper queryWrapper=QueryWrapper.create()
.select()
.from(ACCOUNT)
.where(ACCOUNT.ID.ge(100))
.and(ACCOUNT.USER_NAME.like("michael"));
其查询生成的 Sql 如下:
SELECT * FROM tb_account
WHERE id >= ?
AND user_name LIKE ?
where 动态条件 1
boolean flag = false;
QueryWrapper queryWrapper = QueryWrapper.create()
.select().from(ACCOUNT)
.where(flag ? ACCOUNT.ID.ge(100) : noCondition())
.and(ACCOUNT.USER_NAME.like("michael"));
其查询生成的 Sql 如下:
SELECT * FROM tb_account
WHERE user_name LIKE ?
where 动态条件 2
boolean flag = false;
QueryWrapper queryWrapper = QueryWrapper.create()
.select().from(ACCOUNT)
.where(ACCOUNT.ID.ge(100).when(flag)) // when....
.and(ACCOUNT.USER_NAME.like("michael"));
其查询生成的 Sql 如下:
SELECT * FROM tb_account
WHERE user_name LIKE ?
where select
QueryWrapper queryWrapper = QueryWrapper.create()
.select()
.from(ACCOUNT)
.where(ACCOUNT.ID.ge(
select(ARTICLE.ACCOUNT_ID).from(ARTICLE).where(ARTICLE.ID.ge(100))
));
其查询生成的 Sql 如下:
SELECT * FROM tb_account
WHERE id >=
(SELECT account_id FROM tb_article WHERE id >= ? )
where exists, not exists
QueryWrapper queryWrapper=QueryWrapper.create()
.select()
.from(ACCOUNT)
.where(ACCOUNT.ID.ge(100))
.and(
exist( // or notExist(...)
selectOne().from(ARTICLE).where(ARTICLE.ID.ge(100))
)
);
其查询生成的 Sql 如下:
SELECT * FROM tb_account
WHERE id >= ?
AND EXIST (
SELECT 1 FROM tb_article WHERE id >= ?
)
and (...) or (...)
QueryWrapper queryWrapper=QueryWrapper.create()
.select()
.from(ACCOUNT)
.where(ACCOUNT.ID.ge(100))
.and(ACCOUNT.SEX.eq(1).or(ACCOUNT.SEX.eq(2)))
.or(ACCOUNT.AGE.in(18,19,20).and(ACCOUNT.USER_NAME.like("michael")));
其查询生成的 Sql 如下:
SELECT * FROM tb_account
WHERE id >= ?
AND (sex = ? OR sex = ? )
OR (age IN (?,?,?) AND user_name LIKE ? )
group by
QueryWrapper queryWrapper=QueryWrapper.create()
.select()
.from(ACCOUNT)
.groupBy(ACCOUNT.USER_NAME);
其查询生成的 Sql 如下:
SELECT * FROM tb_account
GROUP BY user_name
having
QueryWrapper queryWrapper=QueryWrapper.create()
.select()
.from(ACCOUNT)
.groupBy(ACCOUNT.USER_NAME)
.having(ACCOUNT.AGE.between(18,25));
其查询生成的 Sql 如下:
SELECT * FROM tb_account
GROUP BY user_name
HAVING age BETWEEN ? AND ?
orderBy
QueryWrapper queryWrapper=QueryWrapper.create()
.select()
.from(ACCOUNT)
.orderBy(ACCOUNT.AGE.asc(), ACCOUNT.USER_NAME.desc().nullsLast());
其查询生成的 Sql 如下:
SELECT * FROM tb_account
ORDER BY age ASC, user_name DESC NULLS LAST
join(left join,inner join...)
QueryWrapper queryWrapper=QueryWrapper.create()
.select()
.from(ACCOUNT)
.leftJoin(ARTICLE).on(ACCOUNT.ID.eq(ARTICLE.ACCOUNT_ID))
.innerJoin(ARTICLE).on(ACCOUNT.ID.eq(ARTICLE.ACCOUNT_ID))
.where(ACCOUNT.AGE.ge(10));
其查询生成的 Sql 如下:
SELECT * FROM tb_account
LEFT JOIN tb_article ON tb_account.id = tb_article.account_id
INNER JOIN tb_article ON tb_account.id = tb_article.account_id
WHERE tb_account.age >= ?
join on 多个条件
QueryWrapper queryWrapper = QueryWrapper.create()
.select()
.from(ACCOUNT)
.leftJoin(ARTICLE).on(
ACCOUNT.ID.eq(ARTICLE.ACCOUNT_ID).and(ACCOUNT.AGE.eq(18))
)
.where(ACCOUNT.AGE.ge(10));
其查询生成的 Sql 如下:
SELECT * FROM tb_account LEFT JOIN tb_article
ON tb_account.id = tb_article.account_id AND tb_account.age = ?
WHERE tb_account.age >= ?
join select
QueryWrapper queryWrapper = QueryWrapper.create()
.select()
.from(ACCOUNT)
.leftJoin(
select().from(ARTICLE).where(ARTICLE.ID.ge(100))
).as("a").on(
ACCOUNT.ID.eq(raw("a.id"))
)
.where(ACCOUNT.AGE.ge(10));
其查询生成的 Sql 如下:
SELECT * FROM tb_account
LEFT JOIN (SELECT * FROM tb_article WHERE id >= ? ) AS a
ON tb_account.id = a.id
WHERE tb_account.age >= ?
union, union all
QueryWrapper query = new QueryWrapper()
.select(ACCOUNT.ID)
.from(ACCOUNT)
.orderBy(ACCOUNT.ID.desc())
.union(select(ARTICLE.ID).from(ARTICLE))
.unionAll(select(ARTICLE.ID).from(ARTICLE));
其查询生成的 Sql 如下:
(SELECT id FROM tb_account ORDER BY id DESC)
UNION (SELECT id FROM tb_article)
UNION ALL (SELECT id FROM tb_article)
limit... offset
::: tip 提示 在 "limit... offset" 的示例中,Mybatis-Flex 能够自动识别当前数据库👍,并根据数据库的类型生成不同的 SQL,用户也可以很轻易的通过 DialectFactory 注册(新增或改写)自己的实现方言。 :::
QueryWrapper queryWrapper = QueryWrapper.create()
.select()
.from(ACCOUNT)
.orderBy(ACCOUNT.ID.desc())
.limit(10)
.offset(20);
MySql 下执行的代码如下:
SELECT * FROM `tb_account` ORDER BY `id` DESC LIMIT 20, 10
PostgreSQL 下执行的代码如下:
SELECT * FROM "tb_account" ORDER BY "id" DESC LIMIT 20 OFFSET 10
Informix 下执行的代码如下:
SELECT SKIP 20 FIRST 10 * FROM "tb_account" ORDER BY "id" DESC
Oracle 下执行的代码如下:
SELECT * FROM (SELECT TEMP_DATAS.*,
ROWNUM RN FROM (
SELECT * FROM "tb_account" ORDER BY "id" DESC)
TEMP_DATAS WHERE ROWNUM <=30)
WHERE RN >20
Db2 下执行的代码如下:
SELECT * FROM "tb_account" ORDER BY "id" DESC
OFFSET 20 ROWS FETCH NEXT 10 ROWS ONLY
Sybase 下执行的代码如下:
SELECT TOP 10 START AT 21 * FROM "tb_account" ORDER BY "id" DESC
Firebird 下执行的代码如下:
SELECT * FROM "tb_account" ORDER BY "id" DESC ROWS 20 TO 30
存在疑问?
疑问1:示例代码中的 QueryWrapper 所需要的 "ACCOUNT" 从哪里来的?
答:Mybatis-Flex 使用了 APT(Annotation Processing Tool)在项目编译的时候,
会自动根据 Entity 类定义的字段生成 "ACCOUNT" 类以及 Entity 对应的 Mapper 类, 通过开发工具构建项目(如下图),
或者执行 maven 编译命令: mvn clean package 都可以自动生成。这个原理和 lombok 一致。
更多关于 APT 的配置,请进入 APT 配置章节 了解。
特别注意事项!!!
在 QueryWrapper 的条件构建中,如果传入 null 值,则自动忽略该条件,这有许多的好处,不需要额外的通过 when() 方法判断。但是也带来一些额外的知识记忆点,
因此,正对这一点需要特别注意一下。
例如:
String userName = null;
Integer id = null;
QueryWrapper query1 = QueryWrapper.create()
.where(ACCOUNT.AGE.ge(18))
.and(ACCOUNT.USER_NAME.like(userName))
.and(ACCOUNT.ID.ge(id));
QueryWrapper query2 = QueryWrapper.create()
.where(ACCOUNT.AGE.ge(18));
在以上的 query1 和 query2 中,它们构建出来的 SQL 条件是完全一致的,因为 Mybatis-Flex 会自动忽略 null 值的条件。
