|
| 1 | +# NopORM 集合操作增强设计说明 |
| 2 | + |
| 3 | +## 概述 |
| 4 | + |
| 5 | +为了提供更强大、更直观的集合操作能力,NopORM 在现有 `_some` 和 `_all` 操作符基础上,引入新的集合操作语法:`collection[filter].function()` 元素访问操作符。 |
| 6 | + |
| 7 | +## 1. 集合过滤聚合语法 |
| 8 | + |
| 9 | +### 1.1 基础语法 |
| 10 | + |
| 11 | +```javascript |
| 12 | +// 三种使用方式: |
| 13 | +o.collection[filter_conditions] // 只有过滤条件 |
| 14 | +o.collection[order by sort_spec] // 只有排序条件 |
| 15 | +o.collection[filter_conditions order by sort_spec] // 过滤 + 排序 |
| 16 | +``` |
| 17 | + |
| 18 | +### 1.2 支持的聚合函数 |
| 19 | + |
| 20 | +#### 计数操作 |
| 21 | +```javascript |
| 22 | +// 简单计数 |
| 23 | +o.roles[status = 1].count() >= 2 |
| 24 | + |
| 25 | +// 带条件计数 |
| 26 | +o.orders[status = 'COMPLETED' and amount > 100].count() >= 5 |
| 27 | +``` |
| 28 | + |
| 29 | +#### 求和操作 |
| 30 | +```javascript |
| 31 | +// 字段求和 |
| 32 | +o.orders[status = 'COMPLETED'].sum(amount) > 10000 |
| 33 | + |
| 34 | +// 数值计算 |
| 35 | +o.items[category = 'ELECTRONICS'].sum(price * quantity) > 5000 |
| 36 | +``` |
| 37 | + |
| 38 | +#### 平均值操作 |
| 39 | +```javascript |
| 40 | +o.scores[examType = 'FINAL'].avg(score) >= 60 |
| 41 | +o.products[price > 0].avg(rating) > 4.0 |
| 42 | +``` |
| 43 | + |
| 44 | +#### 极值操作 |
| 45 | +```javascript |
| 46 | +o.transactions[year = 2024].max(amount) < 5000 |
| 47 | +o.products[category = 'A'].min(price) > 100 |
| 48 | +``` |
| 49 | + |
| 50 | +#### 存在性判断 |
| 51 | +```javascript |
| 52 | +o.roles[roleType = 'SPECIAL'].exists() |
| 53 | +// 等价于 o.roles[roleType = 'SPECIAL'].count() >= 1 |
| 54 | +// 返回布尔值,可直接在逻辑表达式中使用 |
| 55 | +``` |
| 56 | + |
| 57 | +### 1.3 复杂过滤条件 |
| 58 | + |
| 59 | +#### 逻辑组合 |
| 60 | +```javascript |
| 61 | +// AND 条件 |
| 62 | +o.orders[status = 'COMPLETED' and amount > 100 and createTime > '2024-01-01'] |
| 63 | + |
| 64 | +// OR 条件 |
| 65 | +o.roles[roleName = 'admin' or roleName = 'manager' or level >= 3] |
| 66 | + |
| 67 | +// 复杂逻辑 |
| 68 | +o.products[(category = 'A' or category = 'B') and (price > 100 or hasDiscount = true)] |
| 69 | +``` |
| 70 | + |
| 71 | +#### 嵌套属性访问 |
| 72 | +```javascript |
| 73 | +o.orders[customer.age > 18 and customer.region = 'North'].sum(amount) |
| 74 | +o.roles[department.budget > 100000].count() |
| 75 | +``` |
| 76 | + |
| 77 | +### 1.4 多级集合操作 |
| 78 | + |
| 79 | +```javascript |
| 80 | +// 嵌套集合过滤 |
| 81 | +o.departments[employees[salary > 10000].count() > 5].count() >= 1 |
| 82 | + |
| 83 | +// 复杂聚合链 |
| 84 | +o.companies[ |
| 85 | + departments[budget > 100000].count() >= 2 |
| 86 | + and departments[employees.count() > 50].sum(budget) > 500000 |
| 87 | +].exists() |
| 88 | +``` |
| 89 | + |
| 90 | +## 2. 集合元素访问语法 |
| 91 | + |
| 92 | +### 2.1 基础元素访问操作符 |
| 93 | + |
| 94 | +#### 首元素访问 |
| 95 | +```javascript |
| 96 | +// 只有排序 |
| 97 | +o.orders[order by createTime desc].first().amount > 1000 |
| 98 | + |
| 99 | +// 过滤 + 单字段排序 |
| 100 | +o.orders[status = 'PENDING' order by createTime desc].first().amount > 1000 |
| 101 | + |
| 102 | +// 过滤 + 多字段排序 |
| 103 | +o.orders[priority = 'HIGH' order by priority desc, createTime asc].first().status = 'URGENT' |
| 104 | + |
| 105 | +// 复杂过滤 + 排序 |
| 106 | +o.orders[status = 'COMPLETED' and amount > 100 order by createTime desc].first().customer.name = 'John' |
| 107 | +``` |
| 108 | + |
| 109 | +#### 末元素访问 |
| 110 | +```javascript |
| 111 | +o.orders[status = 'PROCESSING' order by createTime asc].last().status = 'COMPLETED' |
| 112 | +``` |
| 113 | + |
| 114 | +### 2.2 排序规格语法 |
| 115 | + |
| 116 | +#### 方向说明符 |
| 117 | +```javascript |
| 118 | +// 降序 |
| 119 | +[order by createTime desc] |
| 120 | +[order by amount desc, id asc] |
| 121 | + |
| 122 | +// 升序(可省略,默认) |
| 123 | +[order by createTime] |
| 124 | +[order by createTime asc] |
| 125 | +``` |
| 126 | + |
| 127 | +#### 复杂排序表达式 |
| 128 | +```javascript |
| 129 | +// 函数表达式排序 |
| 130 | +[order by lower(name) asc, length(description) desc] |
| 131 | + |
| 132 | +// 计算字段排序 |
| 133 | +[order by year(createTime) desc, month(createTime) asc] |
| 134 | + |
| 135 | +// 嵌套属性排序 |
| 136 | +[order by customer.age desc, customer.name asc] |
| 137 | +``` |
| 138 | + |
| 139 | +## 3. 边界情况和空集合处理 |
| 140 | + |
| 141 | +### 3.1 空集合返回值(与SQL语义一致) |
| 142 | + |
| 143 | +```javascript |
| 144 | +// 聚合函数在空集合时返回(与SQL标准一致): |
| 145 | +o.orders[status = 'INVALID'].count() // 返回 0 |
| 146 | +o.orders[status = 'INVALID'].sum(amount) // 返回 null |
| 147 | +o.orders[status = 'INVALID'].avg(score) // 返回 null |
| 148 | +o.orders[status = 'INVALID'].max(amount) // 返回 null |
| 149 | +o.orders[status = 'INVALID'].min(amount) // 返回 null |
| 150 | + |
| 151 | +// 元素访问在空集合时返回: |
| 152 | +o.orders[status = 'INVALID'].first() // 返回 null |
| 153 | +o.orders[status = 'INVALID'].last() // 返回 null |
| 154 | +``` |
| 155 | + |
| 156 | +### 3.2 空值处理说明 |
| 157 | + |
| 158 | +```javascript |
| 159 | +// 当聚合函数返回null时,比较操作自然返回false |
| 160 | +o.orders[status = 'INVALID'].sum(amount) > 1000 // 返回false |
| 161 | + |
| 162 | +// 如果需要显式处理null值,可以使用$nvl函数 |
| 163 | +o.orders[status = 'COMPLETED'].sum(amount).$nvl(0) > 10000 |
| 164 | +``` |
| 165 | + |
| 166 | +## 4. 与Collection Operator语法的兼容性 |
| 167 | + |
| 168 | +### 4.1 与 `_some` / `_all` 的对应关系 |
| 169 | + |
| 170 | +```javascript |
| 171 | +// _some 的等价表达 |
| 172 | +o.roles._some.status = 1 |
| 173 | +⇔ o.roles[status = 1].exists() |
| 174 | + |
| 175 | +// _all 的等价表达 |
| 176 | +o.roles._all.status = 1 |
| 177 | +⇔ o.roles[status != 1].count() = 0 |
| 178 | +⇔ !o.roles[status != 1].exists() |
| 179 | + |
| 180 | +// 复杂条件 |
| 181 | +o.roles._some.roleName = 'admin' or o.roles._some.status = 1 |
| 182 | +⇔ o.roles[roleName = 'admin' or status = 1].exists() |
| 183 | +``` |
| 184 | + |
| 185 | +### 4.2 混合使用 |
| 186 | + |
| 187 | +```javascript |
| 188 | +// 与_some/_all语法可以混合使用 |
| 189 | +o.roles._some.status = 1 and o.orders[amount > 100].count() >= 5 |
| 190 | + |
| 191 | +// 组合使用存在性判断和计数 |
| 192 | +o.roles[roleType = 'ADMIN'].exists() and o.orders[status = 'PENDING'].count() < 10 |
| 193 | +``` |
| 194 | + |
| 195 | +## 5. SQL 转换策略 |
| 196 | + |
| 197 | +### 5.1 基础转换规则 |
| 198 | + |
| 199 | +#### 过滤聚合转换(保持SQL语义) |
| 200 | +```javascript |
| 201 | +// EQL: o.orders[status = 'COMPLETED'].sum(amount) > 10000 |
| 202 | + |
| 203 | +// SQL: |
| 204 | +(select sum(amount) from Order ord |
| 205 | + where ord.user_id = o.id and ord.status = 'COMPLETED') > 10000 |
| 206 | + |
| 207 | +// 注意:空集合时返回null,与SQL标准一致 |
| 208 | +``` |
| 209 | + |
| 210 | +#### 存在性判断转换 |
| 211 | +```javascript |
| 212 | +// EQL: o.roles[roleType = 'SPECIAL'].exists() |
| 213 | + |
| 214 | +// SQL: |
| 215 | +exists ( |
| 216 | + select 1 from Role r |
| 217 | + where r.user_id = o.id and r.role_type = 'SPECIAL' |
| 218 | +) |
| 219 | +``` |
| 220 | + |
| 221 | +#### 元素访问转换(同时过滤和排序) |
| 222 | +```javascript |
| 223 | +// EQL: o.orders[status = 'PENDING' order by createTime desc].first().amount > 1000 |
| 224 | + |
| 225 | +// SQL: |
| 226 | +exists ( |
| 227 | + select 1 from Order ord |
| 228 | + where ord.user_id = o.id |
| 229 | + and ord.amount > 1000 |
| 230 | + and ord.status = 'PENDING' |
| 231 | + and ord.id = ( |
| 232 | + select ord2.id from Order ord2 |
| 233 | + where ord2.user_id = o.id and ord2.status = 'PENDING' |
| 234 | + order by ord2.createTime desc |
| 235 | + limit 1 |
| 236 | + ) |
| 237 | +) |
| 238 | +``` |
| 239 | + |
| 240 | +#### $nvl 函数转换 |
| 241 | +```javascript |
| 242 | +// EQL: o.orders[status = 'COMPLETED'].sum(amount).$nvl(0) > 10000 |
| 243 | + |
| 244 | +// SQL: |
| 245 | +coalesce(( |
| 246 | + select sum(amount) from Order ord |
| 247 | + where ord.user_id = o.id and ord.status = 'COMPLETED' |
| 248 | +), 0) > 10000 |
| 249 | +``` |
| 250 | + |
| 251 | +### 5.2 优化转换策略 |
| 252 | + |
| 253 | +#### Group Join 优化 |
| 254 | +```javascript |
| 255 | +// 多个集合条件自动优化 |
| 256 | +o.roles[roleType = 'A'].count() >= 2 |
| 257 | +and o.roles[roleType = 'B'].count() = 0 |
| 258 | + |
| 259 | +// 优化为 Group Join: |
| 260 | +select o from User o left join ( |
| 261 | + select user_id, |
| 262 | + count(case when role_type = 'A' then 1 else null end) as count_a, |
| 263 | + count(case when role_type = 'B' then 1 else null end) as count_b |
| 264 | + from Role group by user_id |
| 265 | +) t on o.id = t.user_id |
| 266 | +where t.count_a >= 2 and t.count_b = 0 |
| 267 | +``` |
| 268 | + |
| 269 | +#### 窗口函数优化 |
| 270 | +```javascript |
| 271 | +// 多个元素访问操作 |
| 272 | +o.orders[status = 'PENDING' order by createTime desc].first().amount > 1000 |
| 273 | +and o.orders[status = 'COMPLETED' order by createTime asc].first().customerName = 'John' |
| 274 | + |
| 275 | +// 优化为: |
| 276 | +select o from User o |
| 277 | +where o.id in ( |
| 278 | + select user_id from ( |
| 279 | + select user_id, |
| 280 | + first_value(amount) over ( |
| 281 | + partition by user_id |
| 282 | + order by case when status = 'PENDING' then createTime end desc |
| 283 | + ) as pending_first_amount, |
| 284 | + first_value(customer_name) over ( |
| 285 | + partition by user_id |
| 286 | + order by case when status = 'COMPLETED' then createTime end asc |
| 287 | + ) as completed_first_customer |
| 288 | + from Order |
| 289 | + ) t |
| 290 | + where t.pending_first_amount > 1000 |
| 291 | + and t.completed_first_customer = 'John' |
| 292 | + and t.pending_first_amount is not null |
| 293 | + and t.completed_first_customer is not null |
| 294 | +) |
| 295 | +``` |
| 296 | + |
| 297 | +## 6. 性能优化提示 |
| 298 | + |
| 299 | +### 6.1 优化器提示语法 |
| 300 | + |
| 301 | +```sql |
| 302 | +-- 强制使用 Group Join 优化 |
| 303 | +select o from User o |
| 304 | +/*@group_join(o.roles) */ |
| 305 | +where o.roles[roleType = 'A'].count() >= 2 |
| 306 | + |
| 307 | +-- 禁用特定优化 |
| 308 | +select o from User o |
| 309 | +/*@no_window_function */ |
| 310 | +where o.orders[status = 'PENDING' order by createTime desc].first().amount > 1000 |
| 311 | + |
| 312 | +-- 建议使用索引 |
| 313 | +select o from User o |
| 314 | +/*@index(orders.createTime) */ |
| 315 | +where o.orders[order by createTime desc].first().amount > 1000 |
| 316 | +``` |
| 317 | + |
| 318 | +### 6.2 最佳实践 |
| 319 | + |
| 320 | +```javascript |
| 321 | +// 推荐:使用 exists() 进行存在性判断 |
| 322 | +o.roles[roleType = 'SPECIAL'].exists() |
| 323 | + |
| 324 | +// 推荐:在复杂逻辑中合理组合使用 |
| 325 | +o.orders[status = 'COMPLETED'].count() >= 5 |
| 326 | +and o.orders[status = 'PENDING'].exists() |
| 327 | + |
| 328 | +// 推荐:同时使用过滤和排序 |
| 329 | +o.orders[status = 'PENDING' and priority = 'HIGH' order by createTime asc].first().assignee = 'currentUser' |
| 330 | + |
| 331 | +// 注意:聚合函数返回null时比较结果为false,通常不需要$nvl |
| 332 | +o.orders[status = 'COMPLETED'].sum(amount) > 10000 // 空集合时返回false |
| 333 | + |
| 334 | +// 避免:不必要的复杂表达式 |
| 335 | +// o.roles[roleType = 'SPECIAL'].exists() == true // 冗余 |
| 336 | +``` |
| 337 | + |
| 338 | +## 7. 错误处理和验证 |
| 339 | + |
| 340 | +### 7.1 编译时验证 |
| 341 | + |
| 342 | +```javascript |
| 343 | +// 无效字段名 - 编译时报错 |
| 344 | +o.orders[invalidField = 1].count() // 错误:字段 invalidField 不存在 |
| 345 | + |
| 346 | +// 类型不匹配 - 编译时报错 |
| 347 | +o.orders[status = 123].count() // 错误:status 字段类型为字符串,不能与数字比较 |
| 348 | + |
| 349 | +// 无效聚合函数 - 编译时报错 |
| 350 | +o.orders[status = 'COMPLETED'].invalidFunc() // 错误:函数 invalidFunc 不存在 |
| 351 | +``` |
| 352 | + |
| 353 | +## 8. 语法规范总结 |
| 354 | + |
| 355 | +- **所有集合操作**统一使用函数调用形式:`collection[filter order by ...].function()` |
| 356 | +- **语法组合灵活**:过滤和排序都是可选的,可以单独或组合使用 |
| 357 | +- **无参数函数**:`count()`, `exists()` |
| 358 | +- **有参数函数**:`sum(field)`, `avg(field)`, `max(field)`, `min(field)` |
| 359 | +- **元素访问**:`first()`, `last()` 返回单个元素,可继续访问属性 |
| 360 | +- **布尔表达式**:`exists()` 直接作为布尔值使用,无需 `== true` |
| 361 | +- **SQL语义一致**:聚合函数在空集合时的行为与SQL标准完全一致 |
| 362 | +- **空值处理**:聚合函数返回null时,比较操作自然返回false |
| 363 | +- **默认值处理**:特殊情况下可使用 `$nvl` 函数提供默认值 |
| 364 | +- **一致性**:所有操作符遵循统一的语法模式和调用约定 |
0 commit comments