feat: entgo query .

This commit is contained in:
tx7do
2023-10-25 14:28:29 +08:00
parent 798ccd50d6
commit f8eedb020b
4 changed files with 187 additions and 52 deletions

80
entgo/query/README.md Normal file
View File

@@ -0,0 +1,80 @@
# 列表查询规则
## 通用列表查询请求
| 字段名 | 类型 | 格式 | 字段描述 | 示例 | 备注 |
|----------|-----------|-------------------------------------|---------|----------------------------------------------------------------------------------------------------------|------------------------------------------------------------------|
| page | `number` | | 当前页码 | | 默认为`1`,最小值为`1`。 |
| pageSize | `number` | | 每页的行数 | | 默认为`10`,最小值为`1`。 |
| query | `string` | `json object``json object array` | AND过滤条件 | json字符串: `{"field1":"val1","field2":"val2"}` 或者`[{"field1":"val1"},{"field1":"val2"},{"field2":"val2"}]` | `map``array`都支持,当需要同字段名,不同值的情况下,请使用`array`。具体规则请见:[过滤规则](#过滤规则) |
| or | `string` | `json object``json object array` | OR过滤条件 | 同 AND过滤条件 | |
| orderBy | `string` | `json string array` | 排序条件 | json字符串`["-create_time", "type"]` | json的`string array`,字段名前加`-`是为降序,不加为升序。具体规则请见:[排序规则](#排序规则) |
| nopaging | `boolean` | | 是否不分页 | | 此字段为`true`时,`page``pageSize`字段的传入将无效用。 |
## 排序规则
排序操作本质上是`SQL`里面的`Order By`条件。
| 序列 | 示例 | 备注 |
|----|--------------------|--------------|
| 升序 | `["type"]` | |
| 降序 | `["-create_time"]` | 字段名前加`-`是为降序 |
## 过滤规则
过滤器操作本质上是`SQL`里面的`WHERE`条件。
过滤器的规则遵循了Python的ORM的规则比如
- [Tortoise ORM Filtering](https://tortoise.github.io/query.html#filtering)。
- [Django Field lookups](https://docs.djangoproject.com/en/4.2/ref/models/querysets/#field-lookups)
如果只是普通的查询,只需要传递`字段名`即可,但是如果需要一些特殊的查询,那么就需要加入`操作符`了。
特殊查询的语法规则其实很简单,就是使用双下划线`__`分割字段名和操作符:
```text
{字段名}__{查找类型} : {值}
```
| 查找类型 | 示例 | SQL | 备注 |
|-------------|---------------------------------------------------------|---------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------|---------------------------------------------------------------------------------------------------------------|
| not | `{"name__not" : "tom"}` | `WHERE NOT ("name" = "tom")` | |
| in | `{"name__in" : ["tom", "jimmy"]}` | `WHERE name IN ("tom", "jimmy")` | |
| not_in | `{"name__not_in" : ["tom", "jimmy"]}` | `WHERE name NOT IN ("tom", "jimmy")` | |
| gte | `{"create_time__gte" : "2023-10-25"}` | `WHERE "create_time" >= "2023-10-25"` | |
| gt | `{"create_time__gt" : "2023-10-25"}` | `WHERE "create_time" > "2023-10-25"` | |
| lte | `{"create_time__lte" : "2023-10-25"}` | `WHERE "create_time" <= "2023-10-25"` | |
| lt | `{"create_time__lt" : "2023-10-25"}` | `WHERE "create_time" < "2023-10-25"` | |
| range | `{"create_time__range" : ["2023-10-25", "2024-10-25"]}` | `WHERE "create_time" BETWEEN "2023-10-25" AND "2024-10-25"` <br><br> `WHERE "create_time" >= "2023-10-25" AND "create_time" <= "2024-10-25"` | 需要注意的是: <br>1. 有些数据库的BETWEEN实现的开闭区间可能不一样。<br>2. 日期`2005-01-01`会被隐式转换为:`2005-01-01 00:00:00`,两个日期一致就会导致查询不到数据。 |
| isnull | `{"name__isnull" : "True"}` | `WHERE name IS NULL` | |
| not_isnull | `{"name__not_isnull" : "False"}` | `WHERE name IS NOT NULL` | |
| contains | `{"name__contains" : "L"}` | `WHERE name LIKE '%L%';` | |
| icontains | `{"name__icontains" : "L"}` | `WHERE name ILIKE '%L%';` | |
| startswith | `{"name__startswith" : "La"}` | `WHERE name LIKE 'La%';` | |
| istartswith | `{"name__istartswith" : "La"}` | `WHERE name ILIKE 'La%';` | |
| endswith | `{"name__endswith" : "a"}` | `WHERE name LIKE '%a';` | |
| iendswith | `{"name__iendswith" : "a"}` | `WHERE name ILIKE '%a';` | |
| exact | `{"name__exact" : "a"}` | `WHERE name LIKE 'a';` | |
| iexact | `{"name__iexact" : "a"}` | `WHERE name ILIKE 'a';` | |
| regex | `{"title__regex" : "^(An?\|The) +"}` | MySQL: `WHERE title REGEXP BINARY '^(An?\|The) +'` <br> Oracle: `WHERE REGEXP_LIKE(title, '^(An?\|The) +', 'c');` <br> PostgreSQL: `WHERE title ~ '^(An?\|The) +';` <br> SQLite: `WHERE title REGEXP '^(An?\|The) +';` | |
| iregex | `{"title__iregex" : "^(an?\|the) +"}` | MySQL: `WHERE title REGEXP '^(an?\|the) +'` <br> Oracle: `WHERE REGEXP_LIKE(title, '^(an?\|the) +', 'i');` <br> PostgreSQL: `WHERE title ~* '^(an?\|the) +';` <br> SQLite: `WHERE title REGEXP '(?i)^(an?\|the) +';` | |
| search | | | |
以及将日期提取出来的查找类型:
| 查找类型 | 示例 | SQL | 备注 |
|--------------|--------------------------------------|---------------------------------------------------|----------------------|
| date | `{"pub_date__date" : "2023-01-01"}` | `WHERE DATE(pub_date) = '2023-01-01'` | |
| year | `{"pub_date__year" : "2023"}` | `WHERE EXTRACT('YEAR' FROM pub_date) = '2023'` | 哪一年 |
| iso_year | `{"pub_date__iso_year" : "2023"}` | `WHERE EXTRACT('ISOYEAR' FROM pub_date) = '2023'` | ISO 8601 一年中的周数 |
| month | `{"pub_date__month" : "12"}` | `WHERE EXTRACT('MONTH' FROM pub_date) = '12'` | 月份1-12 |
| day | `{"pub_date__day" : "3"}` | `WHERE EXTRACT('DAY' FROM pub_date) = '3'` | 该月的某天(1-31) |
| week | `{"pub_date__week" : "7"}` | `WHERE EXTRACT('WEEK' FROM pub_date) = '7'` | ISO 8601 周编号 一年中的周数 |
| week_day | `{"pub_date__week_day" : "tom"}` | `` | 星期几 |
| iso_week_day | `{"pub_date__iso_week_day" : "tom"}` | `` | |
| quarter | `{"pub_date__quarter" : "1"}` | `WHERE EXTRACT('QUARTER' FROM pub_date) = '1'` | 一年中的季度 |
| time | `{"pub_date__time" : "12:59:59"}` | `` | |
| hour | `{"pub_date__hour" : "12"}` | `WHERE EXTRACT('HOUR' FROM pub_date) = '12'` | 小时(0-23) |
| minute | `{"pub_date__minute" : "59"}` | `WHERE EXTRACT('MINUTE' FROM pub_date) = '59'` | 分钟 (0-59) |
| second | `{"pub_date__second" : "59"}` | `WHERE EXTRACT('SECOND' FROM pub_date) = '59'` | 秒 (0-59) |

View File

@@ -6,41 +6,49 @@ import (
"entgo.io/ent/dialect/sql"
"github.com/go-kratos/kratos/v2/encoding"
"github.com/tx7do/kratos-utils/stringcase"
"restroom-system/pkg/util/stringcase"
)
const (
FilterNot = "not" // 不
FilterIn = "in" // 检查字段值是否在传递列表中
FilterNot = "not" // 不等于
FilterIn = "in" // 检查值是否在列表中
FilterNotIn = "not_in" // 不在列表中
FilterGTE = "gte" // 大于或等于传递的值
FilterGT = "gt" // 大于传递值
FilterLTE = "lte" // 于或等于传递值
FilterLT = "lt" // 于传递值
FilterRange = "range" // 介于和给定的两个值之间
FilterIsNull = "isnull" // 字段为空
FilterNotIsNull = "not_isnull" // 字段不为空
FilterContains = "contains" // 字段包含指定的子字符串
FilterInsensitiveContains = "icontains" // 不区分大小写,字段包含指定的子字符串
FilterStartsWith = "startswith" // 如果字段以值开头
FilterInsensitiveStartsWith = "istartswith" // 不区分大小写,如果字段以值开头
FilterEndsWith = "endswith" // 如果字段以值结尾
FilterInsensitiveEndsWith = "iendswith" // 不区分大小写,如果字段以值结尾
FilterExact = "exact" // 等于
FilterInsensitiveExact = "iexact" // 不区分大小写等于
FilterLTE = "lte" // 于或等于传递值
FilterLT = "lt" // 于传递值
FilterRange = "range" // 是否介于和给定的两个值之间
FilterIsNull = "isnull" // 是否为空
FilterNotIsNull = "not_isnull" // 是否不为空
FilterContains = "contains" // 是否包含指定的子字符串
FilterInsensitiveContains = "icontains" // 不区分大小写,是否包含指定的子字符串
FilterStartsWith = "startswith" // 以值开头
FilterInsensitiveStartsWith = "istartswith" // 不区分大小写以值开头
FilterEndsWith = "endswith" // 以值结尾
FilterInsensitiveEndsWith = "iendswith" // 不区分大小写以值结尾
FilterExact = "exact" // 精确匹配
FilterInsensitiveExact = "iexact" // 不区分大小写,精确匹配
FilterRegex = "regex" // 正则表达式
FilterInsensitiveRegex = "iregex" // 不区分大小写,正则表达式
FilterSearch = "search" // 全文搜索
)
const (
FilterDatePartYear = "year" //
FilterDatePartQuarter = "quarter" // 季度
FilterDatePartMonth = "month" // 月
FilterDatePartWeek = "week" // 星期
FilterDatePartDay = "day" //
FilterDatePartHour = "hour" // 小时
FilterDatePartMinute = "minute" // 分钟
FilterDatePartSecond = "second" //
FilterDatePartMicrosecond = "microsecond" // 微秒
FilterDatePartDate = "date" // 日期
FilterDatePartYear = "year" //
FilterDatePartISOYear = "iso_year" // ISO 8601 一年中的周数
FilterDatePartQuarter = "quarter" // 季度
FilterDatePartMonth = "month" //
FilterDatePartWeek = "week" // ISO 8601 周编号 一年中的周数
FilterDatePartWeekDay = "week_day" // 星期几
FilterDatePartISOWeekDay = "iso_week_day" // 星期几
FilterDatePartDay = "day" //
FilterDatePartTime = "time" // 小时:分钟:秒
FilterDatePartHour = "hour" // 小时
FilterDatePartMinute = "minute" // 分钟
FilterDatePartSecond = "second" // 秒
FilterDatePartMicrosecond = "microsecond" // 微秒
)
// QueryCommandToWhereConditions 查询命令转换为选择条件
@@ -159,10 +167,14 @@ func oneFieldFilter(s *sql.Selector, keys []string, value string) *sql.Predicate
cond = filterEndsWith(s, field, value)
case FilterInsensitiveEndsWith:
cond = filterInsensitiveEndsWith(s, field, value)
case FilterInsensitiveExact:
cond = filterInsensitiveExact(s, field, value)
case FilterExact:
cond = filterExact(s, field, value)
case FilterInsensitiveExact:
cond = filterInsensitiveExact(s, field, value)
case FilterRegex:
cond = filterRegex(s, field, value)
case FilterInsensitiveRegex:
cond = filterInsensitiveRegex(s, field, value)
case FilterSearch:
cond = filterSearch(s, field, value)
default:
@@ -172,17 +184,22 @@ func oneFieldFilter(s *sql.Selector, keys []string, value string) *sql.Predicate
return cond
}
// filterEqual 相等 WHERE "name" = $1
// filterEqual = 相等操作
// SQL: WHERE "name" = "tom"
func filterEqual(s *sql.Selector, field, value string) *sql.Predicate {
return sql.EQ(s.C(field), value)
}
// filterNot NOT操作 WHERE NOT ("name" = $1 AND "age" = $2)
// filterNot NOT 不相等操作
// SQL: WHERE NOT ("name" = "tom")
// 或者: WHERE "name" <> "tom"
// 用NOT可以过滤出NULL而用<>、!=则不能。
func filterNot(s *sql.Selector, field, value string) *sql.Predicate {
return sql.Not(sql.EQ(s.C(field), value))
}
// filterIn IN操作
// SQL: WHERE name IN ("tom", "jimmy")
func filterIn(s *sql.Selector, field, value string) *sql.Predicate {
var strs []string
if err := json.Unmarshal([]byte(value), &strs); err == nil {
@@ -197,7 +214,8 @@ func filterIn(s *sql.Selector, field, value string) *sql.Predicate {
return nil
}
// filterNotIn 操作
// filterNotIn NOT IN操作
// SQL: WHERE name NOT IN ("tom", "jimmy")`
func filterNotIn(s *sql.Selector, field, value string) *sql.Predicate {
var strs []string
if err := json.Unmarshal([]byte(value), &strs); err == nil {
@@ -212,27 +230,33 @@ func filterNotIn(s *sql.Selector, field, value string) *sql.Predicate {
return nil
}
// filterGTE 操作
// filterGTE GTE (Greater Than or Equal) 大于等于 >=操作
// SQL: WHERE "create_time" >= "2023-10-25"
func filterGTE(s *sql.Selector, field, value string) *sql.Predicate {
return sql.GTE(s.C(field), value)
}
// filterGT 操作
// filterGT GT (Greater than) 大于 >操作
// SQL: WHERE "create_time" > "2023-10-25"
func filterGT(s *sql.Selector, field, value string) *sql.Predicate {
return sql.GT(s.C(field), value)
}
// filterLTE 操作
// filterLTE LTE (Less Than or Equal) 小于等于 <=操作
// SQL: WHERE "create_time" <= "2023-10-25"
func filterLTE(s *sql.Selector, field, value string) *sql.Predicate {
return sql.LTE(s.C(field), value)
}
// filterLT 操作
// filterLT LT (Less than) 小于 <操作
// SQL: WHERE "create_time" < "2023-10-25"
func filterLT(s *sql.Selector, field, value string) *sql.Predicate {
return sql.LT(s.C(field), value)
}
// filterRange 操作
// filterRange 在值域之中 BETWEEN操作
// SQL: WHERE "create_time" BETWEEN "2023-10-25" AND "2024-10-25"
// 或者: WHERE "create_time" >= "2023-10-25" AND "create_time" <= "2024-10-25"
func filterRange(s *sql.Selector, field, value string) *sql.Predicate {
var strs []string
if err := json.Unmarshal([]byte(value), &strs); err == nil {
@@ -261,62 +285,92 @@ func filterRange(s *sql.Selector, field, value string) *sql.Predicate {
return nil
}
// filterIsNull 操作
// filterIsNull 为空 IS NULL操作
// SQL: WHERE name IS NULL
func filterIsNull(s *sql.Selector, field, _ string) *sql.Predicate {
return sql.IsNull(s.C(field))
}
// filterNotIsNull 操作
// filterNotIsNull 不为空 IS NOT NULL操作
// SQL: WHERE name IS NOT NULL
func filterNotIsNull(s *sql.Selector, field, _ string) *sql.Predicate {
return sql.Not(sql.IsNull(s.C(field)))
}
// filterContains 前后模糊查询 WHERE city LIKE '%L%';
// filterContains LIKE 前后模糊查询
// SQL: WHERE name LIKE '%L%';
func filterContains(s *sql.Selector, field, value string) *sql.Predicate {
return sql.Contains(s.C(field), value)
}
// filterInsensitiveContains 前后模糊查询 WHERE city ILIKE '%L%';
// filterInsensitiveContains ILIKE 前后模糊查询
// SQL: WHERE name ILIKE '%L%';
func filterInsensitiveContains(s *sql.Selector, field, value string) *sql.Predicate {
return sql.ContainsFold(s.C(field), value)
}
// filterStartsWith 前缀+模糊查询 WHERE CustomerName LIKE 'La%';
// filterStartsWith LIKE 前缀+模糊查询
// SQL: WHERE name LIKE 'La%';
func filterStartsWith(s *sql.Selector, field, value string) *sql.Predicate {
return sql.HasPrefix(s.C(field), value)
}
// filterInsensitiveStartsWith 前缀+模糊查询 WHERE CustomerName ILIKE 'La%';
// filterInsensitiveStartsWith ILIKE 前缀+模糊查询
// SQL: WHERE name ILIKE 'La%';
func filterInsensitiveStartsWith(s *sql.Selector, field, value string) *sql.Predicate {
return sql.EqualFold(s.C(field), value+"%")
}
// filterEndsWith 后缀+模糊查询 WHERE CustomerName LIKE '%a';
// filterEndsWith LIKE 后缀+模糊查询
// SQL: WHERE name LIKE '%a';
func filterEndsWith(s *sql.Selector, field, value string) *sql.Predicate {
return sql.HasSuffix(s.C(field), value)
}
// filterInsensitiveEndsWith 后缀+模糊查询 WHERE CustomerName ILIKE '%a';
// filterInsensitiveEndsWith ILIKE 后缀+模糊查询
// SQL: WHERE name ILIKE '%a';
func filterInsensitiveEndsWith(s *sql.Selector, field, value string) *sql.Predicate {
return sql.EqualFold(s.C(field), "%"+value)
}
// filterInsensitiveExact 操作 WHERE CustomerName ILIKE 'a';
func filterInsensitiveExact(s *sql.Selector, field, value string) *sql.Predicate {
return sql.EqualFold(s.C(field), value)
}
// filterInsensitiveExact 操作 WHERE CustomerName LIKE 'a';
// filterExact LIKE 操作 精确比对
// SQL: WHERE name LIKE 'a';
func filterExact(s *sql.Selector, field, value string) *sql.Predicate {
return sql.Like(s.C(field), value)
}
// filterInsensitiveExact ILIKE 操作 不区分大小写,精确比对
// SQL: WHERE name ILIKE 'a';
func filterInsensitiveExact(s *sql.Selector, field, value string) *sql.Predicate {
return sql.EqualFold(s.C(field), value)
}
// filterRegex LIKE 操作 精确比对
// MySQL: WHERE title REGEXP BINARY '^(An?|The) +'
// Oracle: WHERE REGEXP_LIKE(title, '^(An?|The) +', 'c');
// PostgreSQL: WHERE title ~ '^(An?|The) +';
// SQLite: WHERE title REGEXP '^(An?|The) +';
func filterRegex(s *sql.Selector, field, value string) *sql.Predicate {
return nil
}
// filterInsensitiveRegex ILIKE 操作 不区分大小写,精确比对
// MySQL: WHERE title REGEXP '^(an?|the) +'
// Oracle: WHERE REGEXP_LIKE(title, '^(an?|the) +', 'i');
// PostgreSQL: WHERE title ~* '^(an?|the) +';
// SQLite: WHERE title REGEXP '(?i)^(an?|the) +';
func filterInsensitiveRegex(s *sql.Selector, field, value string) *sql.Predicate {
return nil
}
// filterSearch 全文搜索
// SQL:
func filterSearch(s *sql.Selector, _, _ string) *sql.Predicate {
return nil
}
// filterDatePart 时间戳提取日期 select extract(quarter from timestamp '2018-08-15 12:10:10');
// SQL:
func filterDatePart(s *sql.Selector, datePart, field, value string) *sql.Predicate {
return nil
}

View File

@@ -3,7 +3,7 @@ package entgo
import (
"entgo.io/ent/dialect/sql"
"github.com/tx7do/kratos-utils/pagination"
paging "restroom-system/pkg/util/pagination"
)
func BuildPaginationSelector(page, pageSize int32, noPaging bool) func(*sql.Selector) {
@@ -20,7 +20,7 @@ func BuildPaginationSelector(page, pageSize int32, noPaging bool) func(*sql.Sele
}
return func(s *sql.Selector) {
s.Offset(pagination.GetPageOffset(page, pageSize)).
s.Offset(paging.GetPageOffset(page, pageSize)).
Limit(int(pageSize))
}
}

View File

@@ -33,7 +33,8 @@ func parseJsonMap(strJson []byte, retMap *map[string]string) error {
}
// BuildQuerySelector 构建分页查询选择器
func BuildQuerySelector(andFilterJsonString, orFilterJsonString string,
func BuildQuerySelector(dbDriverName string,
andFilterJsonString, orFilterJsonString string,
page, pageSize int32, noPaging bool,
orderBys []string, defaultOrderField string) (err error, whereSelectors []func(s *sql.Selector), querySelectors []func(s *sql.Selector)) {
err, whereSelectors = BuildFilterSelector(andFilterJsonString, orFilterJsonString)