Merge 'Restructure optimizer to support join reordering' from Jussi Saurio

Closes #1283
In lieu of a better description, I will just copypaste the contents of
the new `OPTIMIZER.MD` here:
# Overview of the current state of the query optimizer in Limbo
Query optimization is obviously an important part of any SQL-based
database engine. This document is an overview of what we currently do.
## Structure of the optimizer directory
1. `mod.rs`
   - Provides the high-level optimization interface through
`optimize_plan()`
2. `access_method.rs`
   - Determines what is the best index to use when joining a table to a
set of preceding tables
3. `constraints.rs` - Manages query constraints:
   - Extracts constraints from the WHERE clause
   - Determines which constraints are usable with indexes
4. `cost.rs`
   - Calculates the cost of doing a seek vs a scan, for example
5. `join.rs`
   - Implements the System R style dynamic programming join ordering
algorithm
6. `order.rs`
   - Determines if sort operations can be eliminated based on the chosen
access methods and join order
## Join reordering and optimal index selection
**The goals of query optimization are at least the following:**
1. Do as little page I/O as possible
2. Do as little CPU work as possible
3. Retain query correctness.
**The most important ways to achieve no. 1 and no. 2 are:**
1. Choose the optimal access method for each table (e.g. an index or a
rowid-based seek, or a full table scan if all else fails).
2. Choose the best or near-best way to reorder the tables in the query
so that those optimal access methods can be used.
3. Also factor in whether the chosen join order and indexes allow
removal of any sort operations that are necessary for query correctness.
## Limbo's optimizer
Limbo's optimizer is an implementation of an extremely traditional [IBM
System R](https://www.cs.cmu.edu/~15721-f24/slides/02-Selinger-SystemR-
opt.pdf) style optimizer,
i.e. straight from the 70s! The DP algorithm is explained below.
### Current high level flow of the optimizer
1. **SQL rewriting**
  - Rewrite certain SQL expressions to another form (not a lot
currently; e.g. rewrite BETWEEN as two comparisons)
  - Eliminate constant conditions: e.g. `WHERE 1` is removed, `WHERE 0`
short-circuits the whole query because it is trivially false.
2. **Check whether there is an "interesting order"** that we should
consider when evaluating indexes and join orders
    - Is there a GROUP BY? an ORDER BY? Both?
3. **Convert WHERE clause conjucts to Constraints**
    - E.g. in `WHERE t.x = 5`, the expression `5` _constrains_  table
`t` to values of `x` that are exactly `5`.
    - E.g. in `Where t.x = u.x`, the expression `u.x` constrains `t`,
AND `t.x` constrains `u`.
    - Per table, each constraint has an estimated _selectivity_ (how
much it filters the result set); this affects join order calculations,
see the paragraph on _Estimation_  below.
    - Per table, constraints are also analyzed for whether one or
multiple of them can be used as an index seek key to avoid a full scan.
4. **Compute the best join order using a dynamic programming
algorithm:**
  - `n` = number of tables considered
  - `n=1`: find the lowest _cost_ way to access each single table, given
the constraints of the query. Memoize the result.
  - `n=2`: for each table found in the `n=1` step, find the best way to
join that table with each other table. Memoize the result.
  - `n=3`: for each 2-table subset found, find the best way to join that
result to each other table. Memoize the result.
  - `n=m`: for each `m-1` table subset found, find the best way to join
that result to the `m'th` table
  - **Use pruning to reduce search space:**
    - Compute the literal query order first, and store its _cost_  as an
upper threshold
    - If at any point a considered join order exceeds the upper
threshold, discard that search path since it cannot be better than the
current best.
      - For example, we have `SELECT * FROM a JOIN b JOIN c JOIN d`.
Compute `JOIN(a,b,c,d)` first. If `JOIN (b,a)` is already worse than
`JOIN(a,b,c,d)`, we don't have to even try `JOIN(b,a,c)`.
    - Also keep track of the best plan per _subset_:
      - If we find that `JOIN(b,a,c)` is better than any other
permutation of the same tables, e.g. `JOIN(a,b,c)`, then we can discard
_ALL_ of the other permutations for that subset. For example, we don't
need to consider `JOIN(a,b,c,d)` because we know it's worse than
`JOIN(b,a,c,d)`.
      - This is possible due to the associativity and commutativity of
INNER JOINs.
  - Also keep track of the best _ordered plan_ , i.e. one that provides
the "interesting order" mentioned above.
  - At the end, apply a cost penalty to the best overall plan
    - If it is now worse than the best sorted plan, then choose the
sorted plan as the best plan for the query.
      - This allows us to eliminate a sorting operation.
    - If the best overall plan is still best even with the sorting
penalty, then keep it. A sorting operation is later applied to sort the
rows according to the desired order.
5. **Mutate the plan's `join_order` and `Operation`s to match the
computed best plan.**
### Estimation of cost and cardinalities + a note on table statistics
Currently, in the absence of `ANALYZE`, `sqlite_stat1` etc. we assume
the following:
1. Each table has `1,000,000` rows.
2. Each equality (`=`) filter will filter out some percentage of the
result set.
3. Each nonequality (e.g. `>`) will filter out some smaller percentage
of the result set.
4. Each `4096` byte database page holds `50` rows, i.e. roughly `80`
bytes per row
5. Sort operations have some CPU cost dependent on the number of input
rows to the sort operation.
From the above, we derive the following formula for estimating the cost
of joining `t1` with `t2`
```
JOIN_COST = PAGE_IO(t1.rows) + t1.rows * PAGE_IO(t2.rows)
```
For example, let's take the query `SELECT * FROM t1 JOIN t2 USING(foo)
WHERE t2.foo > 10`. Let's assume the following:
- `t1` has `6400` rows and `t2` has `8000` rows
- there are no indexes at all
- let's ignore the CPU cost from the equation for simplicity.
The best access method for both is a full table scan. The output
cardinality of `t1` is the full table, because nothing is filtering it.
Hence, the cost of `t1 JOIN t2` becomes:
```
JOIN_COST = PAGE_IO(t1.input_rows) + t1.output_rows * PAGE_IO(t2.input_rows)

// plugging in the values:

JOIN_COST = PAGE_IO(6400) + 6400 * PAGE_IO(8000)
JOIN_COST = 80 + 6400 * 100 = 640080
```
Now let's consider `t2 JOIN t1`. The best access method for both is
still a full scan, but since we can filter on `t2.foo > 10`, its output
cardinality decreases. Let's assume only 1/4 of the rows of `t2` match
the condition `t2.foo > 10`. Hence, the cost of `t2 join t1` becomes:
```
JOIN_COST = PAGE_IO(t2.input_rows) + t2.output_rows * PAGE_IO(t1.input_rows)

// plugging in the values:

JOIN_COST = PAGE_IO(8000) + 1/4 * 8000 * PAGE_IO(6400)
JOIN_COST = 100 + 2000 * 80 = 160100
```
Even though `t2` is a larger table, because we were able to reduce the
input set to the join operation, it's dramatically cheaper.
#### Statistics
Since we don't support `ANALYZE`, nor can we assume that users will call
`ANALYZE` anyway, we use simple magic constants to estimate the
selectivity of join predicates, row count of tables, and so on. When we
have support for `ANALYZE`, we should plug the statistics from
`sqlite_stat1` and friends into the optimizer to make more informed
decisions.
### Estimating the output cardinality of a join
The output cardinality (output row count) of an operation is as follows:
```
OUTPUT_CARDINALITY_JOIN = INPUT_CARDINALITY_RHS * OUTPUT_CARDINALITY_RHS

where

INPUT_CARDINALITY_RHS = OUTPUT_CARDINALITY_LHS
```
example:
```
SELECT * FROM products p JOIN order_lines o ON p.id = o.product_id
```
Assuming there are 100 products, i.e. just selecting all products would
yield 100 rows:
```
OUTPUT_CARDINALITY_LHS = 100
INPUT_CARDINALITY_RHS = 100
```
Assuming p.id = o.product_id will return three orders per each product:
```
OUTPUT_CARDINALITY_RHS = 3

OUTPUT_CARDINALITY_JOIN = 100 * 3 = 300
```
i.e. the join is estimated to return 300 rows, 3 for each product.
Again, in the absence of statistics, we use magic constants to estimate
these cardinalities.
Estimating them is important because in multi-way joins the output
cardinality of the previous join becomes the input cardinality of the
next one.

Reviewed-by: Pere Diaz Bou <pere-altea@homail.com>

Closes #1462
This commit is contained in:
Jussi Saurio
2025-05-14 14:02:33 +03:00
12 changed files with 2821 additions and 887 deletions

View File

@@ -2579,3 +2579,38 @@ pub fn maybe_apply_affinity(col_type: Type, target_register: usize, program: &mu
pub fn sanitize_string(input: &str) -> String {
input[1..input.len() - 1].replace("''", "'").to_string()
}
/// Returns the components of a binary expression
/// e.g. t.x = 5 -> Some((t.x, =, 5))
pub fn as_binary_components(
expr: &ast::Expr,
) -> Result<Option<(&ast::Expr, ast::Operator, &ast::Expr)>> {
match unwrap_parens(expr)? {
ast::Expr::Binary(lhs, operator, rhs)
if matches!(
operator,
ast::Operator::Equals
| ast::Operator::Greater
| ast::Operator::Less
| ast::Operator::GreaterEquals
| ast::Operator::LessEquals
) =>
{
Ok(Some((lhs.as_ref(), *operator, rhs.as_ref())))
}
_ => Ok(None),
}
}
/// Recursively unwrap parentheses from an expression
/// e.g. (((t.x > 5))) -> t.x > 5
fn unwrap_parens(expr: &ast::Expr) -> Result<&ast::Expr> {
match expr {
ast::Expr::Column { .. } => Ok(expr),
ast::Expr::Parenthesized(exprs) => match exprs.len() {
1 => unwrap_parens(exprs.first().unwrap()),
_ => crate::bail_parse_error!("expected single expression in parentheses"),
},
_ => Ok(expr),
}
}

View File

@@ -131,9 +131,7 @@ pub fn init_loop(
program.emit_insn(Insn::VOpen { cursor_id });
}
}
_ => {
unimplemented!()
}
_ => {}
},
Operation::Search(search) => {
match mode {
@@ -435,13 +433,7 @@ pub fn open_loop(
// Rowid equality point lookups are handled with a SeekRowid instruction which does not loop, since it is a single row lookup.
if let Search::RowidEq { cmp_expr } = search {
let src_reg = program.alloc_register();
translate_expr(
program,
Some(tables),
&cmp_expr.expr,
src_reg,
&t_ctx.resolver,
)?;
translate_expr(program, Some(tables), cmp_expr, src_reg, &t_ctx.resolver)?;
program.emit_insn(Insn::SeekRowid {
cursor_id: table_cursor_id
.expect("Search::RowidEq requires a table cursor"),

View File

@@ -0,0 +1,162 @@
# Overview of the current state of the query optimizer in Limbo
Query optimization is obviously an important part of any SQL-based database engine. This document is an overview of what we currently do.
## Structure of the optimizer directory
1. `mod.rs`
- Provides the high-level optimization interface through `optimize_plan()`
2. `access_method.rs`
- Determines what is the best index to use when joining a table to a set of preceding tables
3. `constraints.rs` - Manages query constraints:
- Extracts constraints from the WHERE clause
- Determines which constraints are usable with indexes
4. `cost.rs`
- Calculates the cost of doing a seek vs a scan, for example
5. `join.rs`
- Implements the System R style dynamic programming join ordering algorithm
6. `order.rs`
- Determines if sort operations can be eliminated based on the chosen access methods and join order
## Join reordering and optimal index selection
**The goals of query optimization are at least the following:**
1. Do as little page I/O as possible
2. Do as little CPU work as possible
3. Retain query correctness.
**The most important ways to achieve no. 1 and no. 2 are:**
1. Choose the optimal access method for each table (e.g. an index or a rowid-based seek, or a full table scan if all else fails).
2. Choose the best or near-best way to reorder the tables in the query so that those optimal access methods can be used.
3. Also factor in whether the chosen join order and indexes allow removal of any sort operations that are necessary for query correctness.
## Limbo's optimizer
Limbo's optimizer is an implementation of an extremely traditional [IBM System R](https://www.cs.cmu.edu/~15721-f24/slides/02-Selinger-SystemR-opt.pdf) style optimizer,
i.e. straight from the 70s! The DP algorithm is explained below.
### Current high level flow of the optimizer
1. **SQL rewriting**
- Rewrite certain SQL expressions to another form (not a lot currently; e.g. rewrite BETWEEN as two comparisons)
- Eliminate constant conditions: e.g. `WHERE 1` is removed, `WHERE 0` short-circuits the whole query because it is trivially false.
2. **Check whether there is an "interesting order"** that we should consider when evaluating indexes and join orders
- Is there a GROUP BY? an ORDER BY? Both?
3. **Convert WHERE clause conjucts to Constraints**
- E.g. in `WHERE t.x = 5`, the expression `5` _constrains_ table `t` to values of `x` that are exactly `5`.
- E.g. in `Where t.x = u.x`, the expression `u.x` constrains `t`, AND `t.x` constrains `u`.
- Per table, each constraint has an estimated _selectivity_ (how much it filters the result set); this affects join order calculations, see the paragraph on _Estimation_ below.
- Per table, constraints are also analyzed for whether one or multiple of them can be used as an index seek key to avoid a full scan.
4. **Compute the best join order using a dynamic programming algorithm:**
- `n` = number of tables considered
- `n=1`: find the lowest _cost_ way to access each single table, given the constraints of the query. Memoize the result.
- `n=2`: for each table found in the `n=1` step, find the best way to join that table with each other table. Memoize the result.
- `n=3`: for each 2-table subset found, find the best way to join that result to each other table. Memoize the result.
- `n=m`: for each `m-1` table subset found, find the best way to join that result to the `m'th` table
- **Use pruning to reduce search space:**
- Compute the literal query order first, and store its _cost_ as an upper threshold
- If at any point a considered join order exceeds the upper threshold, discard that search path since it cannot be better than the current best.
- For example, we have `SELECT * FROM a JOIN b JOIN c JOIN d`. Compute `JOIN(a,b,c,d)` first. If `JOIN (b,a)` is already worse than `JOIN(a,b,c,d)`, we don't have to even try `JOIN(b,a,c)`.
- Also keep track of the best plan per _subset_:
- If we find that `JOIN(b,a,c)` is better than any other permutation of the same tables, e.g. `JOIN(a,b,c)`, then we can discard _ALL_ of the other permutations for that subset. For example, we don't need to consider `JOIN(a,b,c,d)` because we know it's worse than `JOIN(b,a,c,d)`.
- This is possible due to the associativity and commutativity of INNER JOINs.
- Also keep track of the best _ordered plan_ , i.e. one that provides the "interesting order" mentioned above.
- At the end, apply a cost penalty to the best overall plan
- If it is now worse than the best sorted plan, then choose the sorted plan as the best plan for the query.
- This allows us to eliminate a sorting operation.
- If the best overall plan is still best even with the sorting penalty, then keep it. A sorting operation is later applied to sort the rows according to the desired order.
5. **Mutate the plan's `join_order` and `Operation`s to match the computed best plan.**
### Estimation of cost and cardinalities + a note on table statistics
Currently, in the absence of `ANALYZE`, `sqlite_stat1` etc. we assume the following:
1. Each table has `1,000,000` rows.
2. Each equality (`=`) filter will filter out some percentage of the result set.
3. Each nonequality (e.g. `>`) will filter out some smaller percentage of the result set.
4. Each `4096` byte database page holds `50` rows, i.e. roughly `80` bytes per row
5. Sort operations have some CPU cost dependent on the number of input rows to the sort operation.
From the above, we derive the following formula for estimating the cost of joining `t1` with `t2`
```
JOIN_COST = PAGE_IO(t1.rows) + t1.rows * PAGE_IO(t2.rows)
```
For example, let's take the query `SELECT * FROM t1 JOIN t2 USING(foo) WHERE t2.foo > 10`. Let's assume the following:
- `t1` has `6400` rows and `t2` has `8000` rows
- there are no indexes at all
- let's ignore the CPU cost from the equation for simplicity.
The best access method for both is a full table scan. The output cardinality of `t1` is the full table, because nothing is filtering it. Hence, the cost of `t1 JOIN t2` becomes:
```
JOIN_COST = PAGE_IO(t1.input_rows) + t1.output_rows * PAGE_IO(t2.input_rows)
// plugging in the values:
JOIN_COST = PAGE_IO(6400) + 6400 * PAGE_IO(8000)
JOIN_COST = 80 + 6400 * 100 = 640080
```
Now let's consider `t2 JOIN t1`. The best access method for both is still a full scan, but since we can filter on `t2.foo > 10`, its output cardinality decreases. Let's assume only 1/4 of the rows of `t2` match the condition `t2.foo > 10`. Hence, the cost of `t2 join t1` becomes:
```
JOIN_COST = PAGE_IO(t2.input_rows) + t2.output_rows * PAGE_IO(t1.input_rows)
// plugging in the values:
JOIN_COST = PAGE_IO(8000) + 1/4 * 8000 * PAGE_IO(6400)
JOIN_COST = 100 + 2000 * 80 = 160100
```
Even though `t2` is a larger table, because we were able to reduce the input set to the join operation, it's dramatically cheaper.
#### Statistics
Since we don't support `ANALYZE`, nor can we assume that users will call `ANALYZE` anyway, we use simple magic constants to estimate the selectivity of join predicates, row count of tables, and so on. When we have support for `ANALYZE`, we should plug the statistics from `sqlite_stat1` and friends into the optimizer to make more informed decisions.
### Estimating the output cardinality of a join
The output cardinality (output row count) of an operation is as follows:
```
OUTPUT_CARDINALITY_JOIN = INPUT_CARDINALITY_RHS * OUTPUT_CARDINALITY_RHS
where
INPUT_CARDINALITY_RHS = OUTPUT_CARDINALITY_LHS
```
example:
```
SELECT * FROM products p JOIN order_lines o ON p.id = o.product_id
```
Assuming there are 100 products, i.e. just selecting all products would yield 100 rows:
```
OUTPUT_CARDINALITY_LHS = 100
INPUT_CARDINALITY_RHS = 100
```
Assuming p.id = o.product_id will return three orders per each product:
```
OUTPUT_CARDINALITY_RHS = 3
OUTPUT_CARDINALITY_JOIN = 100 * 3 = 300
```
i.e. the join is estimated to return 300 rows, 3 for each product.
Again, in the absence of statistics, we use magic constants to estimate these cardinalities.
Estimating them is important because in multi-way joins the output cardinality of the previous join becomes the input cardinality of the next one.

View File

@@ -0,0 +1,148 @@
use std::sync::Arc;
use limbo_sqlite3_parser::ast::SortOrder;
use crate::{
schema::Index,
translate::plan::{IterationDirection, JoinOrderMember, TableReference},
Result,
};
use super::{
constraints::{usable_constraints_for_join_order, ConstraintRef, TableConstraints},
cost::{estimate_cost_for_scan_or_seek, Cost, IndexInfo},
order::OrderTarget,
};
#[derive(Debug, Clone)]
/// Represents a way to access a table.
pub struct AccessMethod<'a> {
/// The estimated number of page fetches.
/// We are ignoring CPU cost for now.
pub cost: Cost,
/// The direction of iteration for the access method.
/// Typically this is backwards only if it helps satisfy an [OrderTarget].
pub iter_dir: IterationDirection,
/// The index that is being used, if any. For rowid based searches (and full table scans), this is None.
pub index: Option<Arc<Index>>,
/// The constraint references that are being used, if any.
/// An empty list of constraint refs means a scan (full table or index);
/// a non-empty list means a search.
pub constraint_refs: &'a [ConstraintRef],
}
impl<'a> AccessMethod<'a> {
pub fn is_scan(&self) -> bool {
self.constraint_refs.is_empty()
}
pub fn new_table_scan(input_cardinality: f64, iter_dir: IterationDirection) -> Self {
Self {
cost: estimate_cost_for_scan_or_seek(None, &[], &[], input_cardinality),
iter_dir,
index: None,
constraint_refs: &[],
}
}
}
/// Return the best [AccessMethod] for a given join order.
pub fn find_best_access_method_for_join_order<'a>(
rhs_table: &TableReference,
rhs_constraints: &'a TableConstraints,
join_order: &[JoinOrderMember],
maybe_order_target: Option<&OrderTarget>,
input_cardinality: f64,
) -> Result<AccessMethod<'a>> {
let table_no = join_order.last().unwrap().table_no;
let mut best_access_method =
AccessMethod::new_table_scan(input_cardinality, IterationDirection::Forwards);
let rowid_column_idx = rhs_table.columns().iter().position(|c| c.is_rowid_alias);
// Estimate cost for each candidate index (including the rowid index) and replace best_access_method if the cost is lower.
for candidate in rhs_constraints.candidates.iter() {
let index_info = match candidate.index.as_ref() {
Some(index) => IndexInfo {
unique: index.unique,
covering: rhs_table.index_is_covering(index),
column_count: index.columns.len(),
},
None => IndexInfo {
unique: true, // rowids are always unique
covering: false,
column_count: 1,
},
};
let usable_constraint_refs = usable_constraints_for_join_order(
&rhs_constraints.constraints,
&candidate.refs,
join_order,
);
let cost = estimate_cost_for_scan_or_seek(
Some(index_info),
&rhs_constraints.constraints,
&usable_constraint_refs,
input_cardinality,
);
// All other things being equal, prefer an access method that satisfies the order target.
let (iter_dir, order_satisfiability_bonus) = if let Some(order_target) = maybe_order_target
{
// If the index delivers rows in the same direction (or the exact reverse direction) as the order target, then it
// satisfies the order target.
let mut all_same_direction = true;
let mut all_opposite_direction = true;
for i in 0..order_target.0.len().min(index_info.column_count) {
let correct_table = order_target.0[i].table_no == table_no;
let correct_column = {
match &candidate.index {
Some(index) => index.columns[i].pos_in_table == order_target.0[i].column_no,
None => {
rowid_column_idx.map_or(false, |idx| idx == order_target.0[i].column_no)
}
}
};
if !correct_table || !correct_column {
all_same_direction = false;
all_opposite_direction = false;
break;
}
let correct_order = {
match &candidate.index {
Some(index) => order_target.0[i].order == index.columns[i].order,
None => order_target.0[i].order == SortOrder::Asc,
}
};
if correct_order {
all_opposite_direction = false;
} else {
all_same_direction = false;
}
}
if all_same_direction || all_opposite_direction {
(
if all_same_direction {
IterationDirection::Forwards
} else {
IterationDirection::Backwards
},
Cost(1.0),
)
} else {
(IterationDirection::Forwards, Cost(0.0))
}
} else {
(IterationDirection::Forwards, Cost(0.0))
};
if cost < best_access_method.cost + order_satisfiability_bonus {
best_access_method = AccessMethod {
cost,
index: candidate.index.clone(),
iter_dir,
constraint_refs: &usable_constraint_refs,
};
}
}
Ok(best_access_method)
}

View File

@@ -0,0 +1,418 @@
use std::{cmp::Ordering, collections::HashMap, sync::Arc};
use crate::{
schema::{Column, Index},
translate::{
expr::as_binary_components,
plan::{JoinOrderMember, TableReference, WhereTerm},
planner::{table_mask_from_expr, TableMask},
},
Result,
};
use limbo_sqlite3_parser::ast::{self, SortOrder};
use super::cost::ESTIMATED_HARDCODED_ROWS_PER_TABLE;
/// Represents a single condition derived from a `WHERE` clause term
/// that constrains a specific column of a table.
///
/// Constraints are precomputed for each table involved in a query. They are used
/// during query optimization to estimate the cost of different access paths (e.g., using an index)
/// and to determine the optimal join order. A constraint can only be applied if all tables
/// referenced in its expression (other than the constrained table itself) are already
/// available in the current join context, i.e. on the left side in the join order
/// relative to the table.
#[derive(Debug, Clone)]
///
pub struct Constraint {
/// The position of the original `WHERE` clause term this constraint derives from,
/// and which side of the [ast::Expr::Binary] comparison contains the expression
/// that constrains the column.
/// E.g. in SELECT * FROM t WHERE t.x = 10, the constraint is (0, BinaryExprSide::Rhs)
/// because the RHS '10' is the constraining expression.
///
/// This is tracked so we can:
///
/// 1. Extract the constraining expression for use in an index seek key, and
/// 2. Remove the relevant binary expression from the WHERE clause, if used as an index seek key.
pub where_clause_pos: (usize, BinaryExprSide),
/// The comparison operator (e.g., `=`, `>`, `<`) used in the constraint.
pub operator: ast::Operator,
/// The zero-based index of the constrained column within the table's schema.
pub table_col_pos: usize,
/// A bitmask representing the set of tables that appear on the *constraining* side
/// of the comparison expression. For example, in SELECT * FROM t1,t2,t3 WHERE t1.x = t2.x + t3.x,
/// the lhs_mask contains t2 and t3. Thus, this constraint can only be used if t2 and t3
/// have already been joined (i.e. are on the left side of the join order relative to t1).
pub lhs_mask: TableMask,
/// An estimated selectivity factor (0.0 to 1.0) indicating the fraction of rows
/// expected to satisfy this constraint. Used for cost and cardinality estimation.
pub selectivity: f64,
}
#[derive(Debug, Clone, Copy, PartialEq)]
pub enum BinaryExprSide {
Lhs,
Rhs,
}
impl Constraint {
/// Get the constraining expression, e.g. '2+3' from 't.x = 2+3'
pub fn get_constraining_expr(&self, where_clause: &[WhereTerm]) -> ast::Expr {
let (idx, side) = self.where_clause_pos;
let where_term = &where_clause[idx];
let Ok(Some((lhs, _, rhs))) = as_binary_components(&where_term.expr) else {
panic!("Expected a valid binary expression");
};
if side == BinaryExprSide::Lhs {
lhs.clone()
} else {
rhs.clone()
}
}
}
#[derive(Debug, Clone)]
/// A reference to a [Constraint] in a [TableConstraints].
///
/// This is used to track which constraints may be used as an index seek key.
pub struct ConstraintRef {
/// The position of the constraint in the [TableConstraints::constraints] vector.
pub constraint_vec_pos: usize,
/// The position of the constrained column in the index. Always 0 for rowid indices.
pub index_col_pos: usize,
/// The sort order of the constrained column in the index. Always ascending for rowid indices.
pub sort_order: SortOrder,
}
impl ConstraintRef {
/// Convert the constraint to a column usable in a [crate::translate::plan::SeekDef::key].
pub fn as_seek_key_column(
&self,
constraints: &[Constraint],
where_clause: &[WhereTerm],
) -> (ast::Expr, SortOrder) {
let constraint = &constraints[self.constraint_vec_pos];
let constraining_expr = constraint.get_constraining_expr(where_clause);
(constraining_expr, self.sort_order)
}
}
/// A collection of [ConstraintRef]s for a given index, or if index is None, for the table's rowid index.
/// For example, given a table `T (x,y,z)` with an index `T_I (y desc,z)`, take the following query:
/// ```sql
/// SELECT * FROM T WHERE y = 10 AND z = 20;
/// ```
///
/// This will produce the following [ConstraintUseCandidate]:
///
/// ConstraintUseCandidate {
/// index: Some(T_I)
/// refs: [
/// ConstraintRef {
/// constraint_vec_pos: 0, // y = 10
/// index_col_pos: 0, // y
/// sort_order: SortOrder::Desc,
/// },
/// ConstraintRef {
/// constraint_vec_pos: 1, // z = 20
/// index_col_pos: 1, // z
/// sort_order: SortOrder::Asc,
/// },
/// ],
/// }
///
#[derive(Debug)]
pub struct ConstraintUseCandidate {
/// The index that may be used to satisfy the constraints. If none, the table's rowid index is used.
pub index: Option<Arc<Index>>,
/// References to the constraints that may be used as an access path for the index.
pub refs: Vec<ConstraintRef>,
}
#[derive(Debug)]
/// A collection of [Constraint]s and their potential [ConstraintUseCandidate]s for a given table.
pub struct TableConstraints {
pub table_no: usize,
/// The constraints for the table, i.e. any [WhereTerm]s that reference columns from this table.
pub constraints: Vec<Constraint>,
/// Candidates for indexes that may use the constraints to perform a lookup.
pub candidates: Vec<ConstraintUseCandidate>,
}
/// In lieu of statistics, we estimate that an equality filter will reduce the output set to 1% of its size.
const SELECTIVITY_EQ: f64 = 0.01;
/// In lieu of statistics, we estimate that a range filter will reduce the output set to 40% of its size.
const SELECTIVITY_RANGE: f64 = 0.4;
/// In lieu of statistics, we estimate that other filters will reduce the output set to 90% of its size.
const SELECTIVITY_OTHER: f64 = 0.9;
const SELECTIVITY_UNIQUE_EQUALITY: f64 = 1.0 / ESTIMATED_HARDCODED_ROWS_PER_TABLE as f64;
/// Estimate the selectivity of a constraint based on the operator and the column type.
fn estimate_selectivity(column: &Column, op: ast::Operator) -> f64 {
match op {
ast::Operator::Equals => {
if column.is_rowid_alias || column.primary_key {
SELECTIVITY_UNIQUE_EQUALITY
} else {
SELECTIVITY_EQ
}
}
ast::Operator::Greater => SELECTIVITY_RANGE,
ast::Operator::GreaterEquals => SELECTIVITY_RANGE,
ast::Operator::Less => SELECTIVITY_RANGE,
ast::Operator::LessEquals => SELECTIVITY_RANGE,
_ => SELECTIVITY_OTHER,
}
}
/// Precompute all potentially usable [Constraints] from a WHERE clause.
/// The resulting list of [TableConstraints] is then used to evaluate the best access methods for various join orders.
pub fn constraints_from_where_clause(
where_clause: &[WhereTerm],
table_references: &[TableReference],
available_indexes: &HashMap<String, Vec<Arc<Index>>>,
) -> Result<Vec<TableConstraints>> {
let mut constraints = Vec::new();
// For each table, collect all the Constraints and all potential index candidates that may use them.
for (table_no, table_reference) in table_references.iter().enumerate() {
let rowid_alias_column = table_reference
.columns()
.iter()
.position(|c| c.is_rowid_alias);
let mut cs = TableConstraints {
table_no,
constraints: Vec::new(),
candidates: available_indexes
.get(table_reference.table.get_name())
.map_or(Vec::new(), |indexes| {
indexes
.iter()
.map(|index| ConstraintUseCandidate {
index: Some(index.clone()),
refs: Vec::new(),
})
.collect()
}),
};
// Add a candidate for the rowid index, which is always available when the table has a rowid alias.
cs.candidates.push(ConstraintUseCandidate {
index: None,
refs: Vec::new(),
});
for (i, term) in where_clause.iter().enumerate() {
let Some((lhs, operator, rhs)) = as_binary_components(&term.expr)? else {
continue;
};
// Constraints originating from a LEFT JOIN must always be evaluated in that join's RHS table's loop,
// regardless of which tables the constraint references.
if let Some(outer_join_tbl) = term.from_outer_join {
if outer_join_tbl != table_no {
continue;
}
}
// If either the LHS or RHS of the constraint is a column from the table, add the constraint.
match lhs {
ast::Expr::Column { table, column, .. } => {
if *table == table_no {
let table_column = &table_reference.table.columns()[*column];
cs.constraints.push(Constraint {
where_clause_pos: (i, BinaryExprSide::Rhs),
operator,
table_col_pos: *column,
lhs_mask: table_mask_from_expr(rhs)?,
selectivity: estimate_selectivity(table_column, operator),
});
}
}
ast::Expr::RowId { table, .. } => {
// A rowid alias column must exist for the 'rowid' keyword to be considered a valid reference.
// This should be a parse error at an earlier stage of the query compilation, but nevertheless,
// we check it here.
if *table == table_no && rowid_alias_column.is_some() {
let table_column =
&table_reference.table.columns()[rowid_alias_column.unwrap()];
cs.constraints.push(Constraint {
where_clause_pos: (i, BinaryExprSide::Rhs),
operator,
table_col_pos: rowid_alias_column.unwrap(),
lhs_mask: table_mask_from_expr(rhs)?,
selectivity: estimate_selectivity(table_column, operator),
});
}
}
_ => {}
};
match rhs {
ast::Expr::Column { table, column, .. } => {
if *table == table_no {
let table_column = &table_reference.table.columns()[*column];
cs.constraints.push(Constraint {
where_clause_pos: (i, BinaryExprSide::Lhs),
operator: opposite_cmp_op(operator),
table_col_pos: *column,
lhs_mask: table_mask_from_expr(lhs)?,
selectivity: estimate_selectivity(table_column, operator),
});
}
}
ast::Expr::RowId { table, .. } => {
if *table == table_no && rowid_alias_column.is_some() {
let table_column =
&table_reference.table.columns()[rowid_alias_column.unwrap()];
cs.constraints.push(Constraint {
where_clause_pos: (i, BinaryExprSide::Lhs),
operator: opposite_cmp_op(operator),
table_col_pos: rowid_alias_column.unwrap(),
lhs_mask: table_mask_from_expr(lhs)?,
selectivity: estimate_selectivity(table_column, operator),
});
}
}
_ => {}
};
}
// sort equalities first so that index keys will be properly constructed.
// see e.g.: https://www.solarwinds.com/blog/the-left-prefix-index-rule
cs.constraints.sort_by(|a, b| {
if a.operator == ast::Operator::Equals {
Ordering::Less
} else if b.operator == ast::Operator::Equals {
Ordering::Greater
} else {
Ordering::Equal
}
});
// For each constraint we found, add a reference to it for each index that may be able to use it.
for (i, constraint) in cs.constraints.iter().enumerate() {
if rowid_alias_column.map_or(false, |idx| constraint.table_col_pos == idx) {
let rowid_candidate = cs
.candidates
.iter_mut()
.find_map(|candidate| {
if candidate.index.is_none() {
Some(candidate)
} else {
None
}
})
.unwrap();
rowid_candidate.refs.push(ConstraintRef {
constraint_vec_pos: i,
index_col_pos: 0,
sort_order: SortOrder::Asc,
});
}
for index in available_indexes
.get(table_reference.table.get_name())
.unwrap_or(&Vec::new())
{
if let Some(position_in_index) =
index.column_table_pos_to_index_pos(constraint.table_col_pos)
{
let index_candidate = cs
.candidates
.iter_mut()
.find_map(|candidate| {
if candidate
.index
.as_ref()
.map_or(false, |i| Arc::ptr_eq(index, i))
{
Some(candidate)
} else {
None
}
})
.unwrap();
index_candidate.refs.push(ConstraintRef {
constraint_vec_pos: i,
index_col_pos: position_in_index,
sort_order: index.columns[position_in_index].order,
});
}
}
}
for candidate in cs.candidates.iter_mut() {
// Sort by index_col_pos, ascending -- index columns must be consumed in contiguous order.
candidate.refs.sort_by_key(|cref| cref.index_col_pos);
// Deduplicate by position, keeping first occurrence (which will be equality if one exists, since the constraints vec is sorted that way)
candidate.refs.dedup_by_key(|cref| cref.index_col_pos);
// Truncate at first gap in positions -- again, index columns must be consumed in contiguous order.
let mut last_pos = 0;
let mut i = 0;
for cref in candidate.refs.iter() {
if cref.index_col_pos != last_pos {
if cref.index_col_pos != last_pos + 1 {
break;
}
last_pos = cref.index_col_pos;
}
i += 1;
}
candidate.refs.truncate(i);
// Truncate after the first inequality, since the left-prefix rule of indexes requires that all constraints but the last one must be equalities;
// again see: https://www.solarwinds.com/blog/the-left-prefix-index-rule
if let Some(first_inequality) = candidate.refs.iter().position(|cref| {
cs.constraints[cref.constraint_vec_pos].operator != ast::Operator::Equals
}) {
candidate.refs.truncate(first_inequality + 1);
}
}
constraints.push(cs);
}
Ok(constraints)
}
/// Find which [Constraint]s are usable for a given join order.
/// Returns a slice of the references to the constraints that are usable.
/// A constraint is considered usable for a given table if all of the other tables referenced by the constraint
/// are on the left side in the join order relative to the table.
pub fn usable_constraints_for_join_order<'a>(
constraints: &'a [Constraint],
refs: &'a [ConstraintRef],
join_order: &[JoinOrderMember],
) -> &'a [ConstraintRef] {
let table_no = join_order.last().unwrap().table_no;
let mut usable_until = 0;
for cref in refs.iter() {
let constraint = &constraints[cref.constraint_vec_pos];
let other_side_refers_to_self = constraint.lhs_mask.contains_table(table_no);
if other_side_refers_to_self {
break;
}
let lhs_mask = TableMask::from_table_number_iter(
join_order
.iter()
.take(join_order.len() - 1)
.map(|j| j.table_no),
);
let all_required_tables_are_on_left_side = lhs_mask.contains_all(&constraint.lhs_mask);
if !all_required_tables_are_on_left_side {
break;
}
usable_until += 1;
}
&refs[..usable_until]
}
fn opposite_cmp_op(op: ast::Operator) -> ast::Operator {
match op {
ast::Operator::Equals => ast::Operator::Equals,
ast::Operator::Greater => ast::Operator::Less,
ast::Operator::GreaterEquals => ast::Operator::LessEquals,
ast::Operator::Less => ast::Operator::Greater,
ast::Operator::LessEquals => ast::Operator::GreaterEquals,
_ => panic!("unexpected operator: {:?}", op),
}
}

View File

@@ -0,0 +1,72 @@
use super::constraints::{Constraint, ConstraintRef};
/// A simple newtype wrapper over a f64 that represents the cost of an operation.
///
/// This is used to estimate the cost of scans, seeks, and joins.
#[derive(Debug, Clone, Copy, PartialEq, PartialOrd)]
pub struct Cost(pub f64);
impl std::ops::Add for Cost {
type Output = Cost;
fn add(self, other: Cost) -> Cost {
Cost(self.0 + other.0)
}
}
impl std::ops::Deref for Cost {
type Target = f64;
fn deref(&self) -> &f64 {
&self.0
}
}
#[derive(Debug, Clone, Copy, PartialEq, Eq)]
pub struct IndexInfo {
pub unique: bool,
pub column_count: usize,
pub covering: bool,
}
pub const ESTIMATED_HARDCODED_ROWS_PER_TABLE: usize = 1000000;
pub const ESTIMATED_HARDCODED_ROWS_PER_PAGE: usize = 50; // roughly 80 bytes per 4096 byte page
pub fn estimate_page_io_cost(rowcount: f64) -> Cost {
Cost((rowcount as f64 / ESTIMATED_HARDCODED_ROWS_PER_PAGE as f64).ceil())
}
/// Estimate the cost of a scan or seek operation.
///
/// This is a very simple model that estimates the number of pages read
/// based on the number of rows read, ignoring any CPU costs.
pub fn estimate_cost_for_scan_or_seek(
index_info: Option<IndexInfo>,
constraints: &[Constraint],
usable_constraint_refs: &[ConstraintRef],
input_cardinality: f64,
) -> Cost {
let Some(index_info) = index_info else {
return estimate_page_io_cost(
input_cardinality * ESTIMATED_HARDCODED_ROWS_PER_TABLE as f64,
);
};
let selectivity_multiplier: f64 = usable_constraint_refs
.iter()
.map(|cref| {
let constraint = &constraints[cref.constraint_vec_pos];
constraint.selectivity
})
.product();
// little cheeky bonus for covering indexes
let covering_multiplier = if index_info.covering { 0.9 } else { 1.0 };
estimate_page_io_cost(
selectivity_multiplier
* ESTIMATED_HARDCODED_ROWS_PER_TABLE as f64
* input_cardinality
* covering_multiplier,
)
}

File diff suppressed because it is too large Load Diff

File diff suppressed because it is too large Load Diff

View File

@@ -0,0 +1,217 @@
use std::cell::RefCell;
use limbo_sqlite3_parser::ast::{self, SortOrder};
use crate::{
translate::plan::{GroupBy, IterationDirection, TableReference},
util::exprs_are_equivalent,
};
use super::{access_method::AccessMethod, join::JoinN};
#[derive(Debug, PartialEq, Clone)]
/// A convenience struct for representing a (table_no, column_no, [SortOrder]) tuple.
pub struct ColumnOrder {
pub table_no: usize,
pub column_no: usize,
pub order: SortOrder,
}
#[derive(Debug, PartialEq, Clone)]
/// If an [OrderTarget] is satisfied, then [EliminatesSort] describes which part of the query no longer requires sorting.
pub enum EliminatesSort {
GroupBy,
OrderBy,
GroupByAndOrderBy,
}
#[derive(Debug, PartialEq, Clone)]
/// An [OrderTarget] is considered in join optimization and index selection,
/// so that if a given join ordering and its access methods satisfy the [OrderTarget],
/// then the join ordering and its access methods are preferred, all other things being equal.
pub struct OrderTarget(pub Vec<ColumnOrder>, pub EliminatesSort);
impl OrderTarget {
fn maybe_from_iterator<'a>(
list: impl Iterator<Item = (&'a ast::Expr, SortOrder)> + Clone,
eliminates_sort: EliminatesSort,
) -> Option<Self> {
if list.clone().count() == 0 {
return None;
}
if list
.clone()
.any(|(expr, _)| !matches!(expr, ast::Expr::Column { .. }))
{
return None;
}
Some(OrderTarget(
list.map(|(expr, order)| {
let ast::Expr::Column { table, column, .. } = expr else {
unreachable!();
};
ColumnOrder {
table_no: *table,
column_no: *column,
order,
}
})
.collect(),
eliminates_sort,
))
}
}
/// Compute an [OrderTarget] for the join optimizer to use.
/// Ideally, a join order is both efficient in joining the tables
/// but also returns the results in an order that minimizes the amount of
/// sorting that needs to be done later (either in GROUP BY, ORDER BY, or both).
///
/// TODO: this does not currently handle the case where we definitely cannot eliminate
/// the ORDER BY sorter, but we could still eliminate the GROUP BY sorter.
pub fn compute_order_target(
order_by: &Option<Vec<(ast::Expr, SortOrder)>>,
group_by: Option<&mut GroupBy>,
) -> Option<OrderTarget> {
match (order_by, group_by) {
// No ordering demands - we don't care what order the joined result rows are in
(None, None) => None,
// Only ORDER BY - we would like the joined result rows to be in the order specified by the ORDER BY
(Some(order_by), None) => OrderTarget::maybe_from_iterator(
order_by.iter().map(|(expr, order)| (expr, *order)),
EliminatesSort::OrderBy,
),
// Only GROUP BY - we would like the joined result rows to be in the order specified by the GROUP BY
(None, Some(group_by)) => OrderTarget::maybe_from_iterator(
group_by.exprs.iter().map(|expr| (expr, SortOrder::Asc)),
EliminatesSort::GroupBy,
),
// Both ORDER BY and GROUP BY:
// If the GROUP BY does not contain all the expressions in the ORDER BY,
// then we must separately sort the result rows for ORDER BY anyway.
// However, in that case we can use the GROUP BY expressions as the target order for the join,
// so that we don't have to sort twice.
//
// If the GROUP BY contains all the expressions in the ORDER BY,
// then we again can use the GROUP BY expressions as the target order for the join;
// however in this case we must take the ASC/DESC from ORDER BY into account.
(Some(order_by), Some(group_by)) => {
// Does the group by contain all expressions in the order by?
let group_by_contains_all = group_by.exprs.iter().all(|expr| {
order_by
.iter()
.any(|(order_by_expr, _)| exprs_are_equivalent(expr, order_by_expr))
});
// If not, let's try to target an ordering that matches the group by -- we don't care about ASC/DESC
if !group_by_contains_all {
return OrderTarget::maybe_from_iterator(
group_by.exprs.iter().map(|expr| (expr, SortOrder::Asc)),
EliminatesSort::GroupBy,
);
}
// If yes, let's try to target an ordering that matches the GROUP BY columns,
// but the ORDER BY orderings. First, we need to reorder the GROUP BY columns to match the ORDER BY columns.
group_by.exprs.sort_by_key(|expr| {
order_by
.iter()
.position(|(order_by_expr, _)| exprs_are_equivalent(expr, order_by_expr))
.map_or(usize::MAX, |i| i)
});
// Iterate over GROUP BY, but take the ORDER BY orderings into account.
OrderTarget::maybe_from_iterator(
group_by
.exprs
.iter()
.zip(
order_by
.iter()
.map(|(_, dir)| dir)
.chain(std::iter::repeat(&SortOrder::Asc)),
)
.map(|(expr, dir)| (expr, *dir)),
EliminatesSort::GroupByAndOrderBy,
)
}
}
}
/// Check if the plan's row iteration order matches the [OrderTarget]'s column order.
/// If yes, and this plan is selected, then a sort operation can be eliminated.
pub fn plan_satisfies_order_target(
plan: &JoinN,
access_methods_arena: &RefCell<Vec<AccessMethod>>,
table_references: &[TableReference],
order_target: &OrderTarget,
) -> bool {
let mut target_col_idx = 0;
let num_cols_in_order_target = order_target.0.len();
for (table_no, access_method_index) in plan.data.iter() {
let target_col = &order_target.0[target_col_idx];
let table_ref = &table_references[*table_no];
let correct_table = target_col.table_no == *table_no;
if !correct_table {
return false;
}
// Check if this table has an access method that provides the right ordering.
let access_method = &access_methods_arena.borrow()[*access_method_index];
let iter_dir = access_method.iter_dir;
let index = access_method.index.as_ref();
match index {
None => {
// No index, so the next required column must be the rowid alias column.
let rowid_alias_col = table_ref
.table
.columns()
.iter()
.position(|c| c.is_rowid_alias);
let Some(rowid_alias_col) = rowid_alias_col else {
return false;
};
let correct_column = target_col.column_no == rowid_alias_col;
if !correct_column {
return false;
}
// Btree table rows are always in ascending order of rowid.
let correct_order = if iter_dir == IterationDirection::Forwards {
target_col.order == SortOrder::Asc
} else {
target_col.order == SortOrder::Desc
};
if !correct_order {
return false;
}
target_col_idx += 1;
// All order columns matched.
if target_col_idx == num_cols_in_order_target {
return true;
}
}
Some(index) => {
// All of the index columns must match the next required columns in the order target.
for index_col in index.columns.iter() {
let target_col = &order_target.0[target_col_idx];
let correct_column = target_col.column_no == index_col.pos_in_table;
if !correct_column {
return false;
}
let correct_order = if iter_dir == IterationDirection::Forwards {
target_col.order == index_col.order
} else {
target_col.order != index_col.order
};
if !correct_order {
return false;
}
target_col_idx += 1;
// All order columns matched.
if target_col_idx == num_cols_in_order_target {
return true;
}
}
}
}
}
false
}

View File

@@ -64,9 +64,10 @@ impl ResultSetColumn {
#[derive(Debug, Clone)]
pub struct GroupBy {
pub exprs: Vec<ast::Expr>,
/// sort order, if a sorter is required (= the columns aren't already in the correct order)
pub sort_order: Option<Vec<SortOrder>>,
/// having clause split into a vec at 'AND' boundaries.
pub having: Option<Vec<ast::Expr>>,
pub sort_order: Option<Vec<SortOrder>>,
}
/// In a query plan, WHERE clause conditions and JOIN conditions are all folded into a vector of WhereTerm.
@@ -781,7 +782,7 @@ pub struct TerminationKey {
#[derive(Clone, Debug)]
pub enum Search {
/// A rowid equality point lookup. This is a special case that uses the SeekRowid bytecode instruction and does not loop.
RowidEq { cmp_expr: WhereTerm },
RowidEq { cmp_expr: ast::Expr },
/// A search on a table btree (via `rowid`) or a secondary index search. Uses bytecode instructions like SeekGE, SeekGT etc.
Seek {
index: Option<Arc<Index>>,

View File

@@ -581,13 +581,236 @@ pub fn determine_where_to_eval_term(
join_order
.iter()
.position(|t| t.table_no == table_no)
.unwrap(),
.unwrap_or(usize::MAX),
));
}
return determine_where_to_eval_expr(&term.expr, join_order);
}
/// A bitmask representing a set of tables in a query plan.
/// Tables are numbered by their index in [SelectPlan::table_references].
/// In the bitmask, the first bit is unused so that a mask with all zeros
/// can represent "no tables".
///
/// E.g. table 0 is represented by bit index 1, table 1 by bit index 2, etc.
///
/// Usage in Join Optimization
///
/// In join optimization, [TableMask] is used to:
/// - Generate subsets of tables for dynamic programming in join optimization
/// - Ensure tables are joined in valid orders (e.g., respecting LEFT JOIN order)
///
/// Usage with constraints (WHERE clause)
///
/// [TableMask] helps determine:
/// - Which tables are referenced in a constraint
/// - When a constraint can be applied as a join condition (all referenced tables must be on the left side of the table being joined)
#[derive(Debug, Clone, Copy, PartialEq, Eq, Hash)]
pub struct TableMask(pub u128);
impl std::ops::BitOrAssign for TableMask {
fn bitor_assign(&mut self, rhs: Self) {
self.0 |= rhs.0;
}
}
impl TableMask {
/// Creates a new empty table mask.
///
/// The initial mask represents an empty set of tables.
pub fn new() -> Self {
Self(0)
}
/// Returns true if the mask represents an empty set of tables.
pub fn is_empty(&self) -> bool {
self.0 == 0
}
/// Creates a new mask that is the same as this one but without the specified table.
pub fn without_table(&self, table_no: usize) -> Self {
assert!(table_no < 127, "table_no must be less than 127");
Self(self.0 ^ (1 << (table_no + 1)))
}
/// Creates a table mask from raw bits.
///
/// The bits are shifted left by 1 to maintain the convention that table 0 is at bit 1.
pub fn from_bits(bits: u128) -> Self {
Self(bits << 1)
}
/// Creates a table mask from an iterator of table numbers.
pub fn from_table_number_iter(iter: impl Iterator<Item = usize>) -> Self {
iter.fold(Self::new(), |mut mask, table_no| {
assert!(table_no < 127, "table_no must be less than 127");
mask.add_table(table_no);
mask
})
}
/// Adds a table to the mask.
pub fn add_table(&mut self, table_no: usize) {
assert!(table_no < 127, "table_no must be less than 127");
self.0 |= 1 << (table_no + 1);
}
/// Returns true if the mask contains the specified table.
pub fn contains_table(&self, table_no: usize) -> bool {
assert!(table_no < 127, "table_no must be less than 127");
self.0 & (1 << (table_no + 1)) != 0
}
/// Returns true if this mask contains all tables in the other mask.
pub fn contains_all(&self, other: &TableMask) -> bool {
self.0 & other.0 == other.0
}
/// Returns the number of tables in the mask.
pub fn table_count(&self) -> usize {
self.0.count_ones() as usize
}
/// Returns true if this mask shares any tables with the other mask.
pub fn intersects(&self, other: &TableMask) -> bool {
self.0 & other.0 != 0
}
}
/// Returns a [TableMask] representing the tables referenced in the given expression.
/// Used in the optimizer for constraint analysis.
pub fn table_mask_from_expr(expr: &Expr) -> Result<TableMask> {
let mut mask = TableMask::new();
match expr {
Expr::Binary(e1, _, e2) => {
mask |= table_mask_from_expr(e1)?;
mask |= table_mask_from_expr(e2)?;
}
Expr::Column { table, .. } | Expr::RowId { table, .. } => {
mask.add_table(*table);
}
Expr::Between {
lhs,
not: _,
start,
end,
} => {
mask |= table_mask_from_expr(lhs)?;
mask |= table_mask_from_expr(start)?;
mask |= table_mask_from_expr(end)?;
}
Expr::Case {
base,
when_then_pairs,
else_expr,
} => {
if let Some(base) = base {
mask |= table_mask_from_expr(base)?;
}
for (when, then) in when_then_pairs {
mask |= table_mask_from_expr(when)?;
mask |= table_mask_from_expr(then)?;
}
if let Some(else_expr) = else_expr {
mask |= table_mask_from_expr(else_expr)?;
}
}
Expr::Cast { expr, .. } => {
mask |= table_mask_from_expr(expr)?;
}
Expr::Collate(expr, _) => {
mask |= table_mask_from_expr(expr)?;
}
Expr::DoublyQualified(_, _, _) => {
crate::bail_parse_error!(
"DoublyQualified should be resolved to a Column before resolving table mask"
);
}
Expr::Exists(_) => {
todo!();
}
Expr::FunctionCall {
args,
order_by,
filter_over: _,
..
} => {
if let Some(args) = args {
for arg in args.iter() {
mask |= table_mask_from_expr(arg)?;
}
}
if let Some(order_by) = order_by {
for term in order_by.iter() {
mask |= table_mask_from_expr(&term.expr)?;
}
}
}
Expr::FunctionCallStar { .. } => {}
Expr::Id(_) => panic!("Id should be resolved to a Column before resolving table mask"),
Expr::InList { lhs, not: _, rhs } => {
mask |= table_mask_from_expr(lhs)?;
if let Some(rhs) = rhs {
for rhs_expr in rhs.iter() {
mask |= table_mask_from_expr(rhs_expr)?;
}
}
}
Expr::InSelect { .. } => todo!(),
Expr::InTable {
lhs,
not: _,
rhs: _,
args,
} => {
mask |= table_mask_from_expr(lhs)?;
if let Some(args) = args {
for arg in args.iter() {
mask |= table_mask_from_expr(arg)?;
}
}
}
Expr::IsNull(expr) => {
mask |= table_mask_from_expr(expr)?;
}
Expr::Like {
lhs,
not: _,
op: _,
rhs,
escape,
} => {
mask |= table_mask_from_expr(lhs)?;
mask |= table_mask_from_expr(rhs)?;
if let Some(escape) = escape {
mask |= table_mask_from_expr(escape)?;
}
}
Expr::Literal(_) => {}
Expr::Name(_) => {}
Expr::NotNull(expr) => {
mask |= table_mask_from_expr(expr)?;
}
Expr::Parenthesized(exprs) => {
for expr in exprs.iter() {
mask |= table_mask_from_expr(expr)?;
}
}
Expr::Qualified(_, _) => {
panic!("Qualified should be resolved to a Column before resolving table mask");
}
Expr::Raise(_, _) => todo!(),
Expr::Subquery(_) => todo!(),
Expr::Unary(_, expr) => {
mask |= table_mask_from_expr(expr)?;
}
Expr::Variable(_) => {}
}
Ok(mask)
}
pub fn determine_where_to_eval_expr<'a>(
expr: &'a Expr,
join_order: &[JoinOrderMember],
@@ -602,7 +825,7 @@ pub fn determine_where_to_eval_expr<'a>(
let join_idx = join_order
.iter()
.position(|t| t.table_no == *table)
.unwrap();
.unwrap_or(usize::MAX);
eval_at = eval_at.max(EvalAt::Loop(join_idx));
}
ast::Expr::Id(_) => {

View File

@@ -192,3 +192,9 @@ do_execsql_test groupby_orderby_removal_regression_test {
} {1|Foster|1
2|Salazar|1
3|Perry|1}
do_execsql_test group_by_no_sorting_required {
select age, count(1) from users group by age limit 3;
} {1|112
2|113
3|97}