Closes#3687 .
Previously, the `try_fold_expr_to_i64` function casted `NULL` as `0`
when evaluating expressions in `LIMIT` or `OFFSET` clauses. I removed
this function since evaluating the expression directly and relying on
the MustBeInt operation for casting seems to handle everything.
Closes#3695
Closes#2600
## Problem
Every btree has a key it is sorted by - this is the integer `rowid` for
tables and an arbitrary-sized, potentially multi-column key for indexes.
Executing an UPDATE in a loop is not safe if the update modifies any
part of the key of the btree that is used for iterating the rows in said
loop. For example:
- Using the table itself to iterate rows is not safe if the UPDATE
modifies the rowid (or rowid alias) of a row, because since it modifies
the iteration order itself, it may cause rows to be skipped:
```sql
CREATE TABLE t(x INTEGER PRIMARY KEY, y);
INSERT <something>
UPDATE t SET y = RANDOM() where x > 100; // safe to iterate 't', 'y' is not being modified
UPDATE t SET x = RANDOM() where x > 100; // not safe to iterate 't', 'x' is being modified
```
- Using an index to iterate rows is not safe if the UPDATE modifies any
of the columns in the index key
```sql
CREATE TABLE t(x, y, z);
CREATE INDEX txy ON t (x,y);
INSERT <something>
UPDATE t SET z = RANDOM() where x = 100 and y > 0; // safe to iterate txy, neither x or y is being modified
UPDATE t SET x = RANDOM() where x = 100 and y > 0; // not safe to iterate txy, 'x' is being modified
UPDATE t SET y = RANDOM() where x = 100 and y > 0; // not safe to iterate txy, 'y' is being modified
```
## Current solution in tursodb
Our current `main` code recognizes this issue and adopts this pseudocode
algorithm from SQLite:
- open a table or index for reading the rows of the source table,
- for each row that matches the condition in the UPDATE statement, write
the row into a temporary table
- then use that temporary table for iteration in the UPDATE loop.
This guarantees that the iteration order will not be affected by the
UPDATEs because the ephemeral table is not under modification.
## Problem with current solution
Our `main` code specialcases the ephemeral table solution to rowids /
rowid aliases only. Using indexes for UPDATE iteration was disabled in
an earlier PR (#2599) due to the safety issue mentioned above, which
means that many UPDATE statements become full table scans:
```sql
turso> create table t(x PRIMARY KEY);
turso> insert into t select value from generate_series(1,10000);
turso> explain update t set x = x + 100000 where x > 50 and x < 60;
addr opcode p1 p2 p3 p4 p5 comment
---- ----------------- ---- ---- ---- ------------- -- -------
0 Init 0 28 0 0 Start at 28
1 OpenWrite 0 2 0 0 root=2; iDb=0
2 OpenWrite 1 3 0 0 root=3; iDb=0
-- scan entire 't' despite very narrow update range!
3 Rewind 0 27 0 0 Rewind table t
...
```
## Solution
We move the ephemeral table logic to _after_ the optimizer has selected
the best access path for the table, and then, if the UPDATE modifies the
key of the chosen access path (table or index; whichever was selected by
the optimizer), we change the plan to include the ephemeral table
prepopulation. Hence, the same query from above becomes:
```sql
turso> explain update t set x = x + 100000 where x > 50 and x < 60;
addr opcode p1 p2 p3 p4 p5 comment
---- ----------------- ---- ---- ---- ------------- -- -------
0 Init 0 35 0 0 Start at 35
1 OpenEphemeral 0 1 0 0 cursor=0 is_table=true
2 OpenRead 1 3 0 0 index=sqlite_autoindex_t_1, root=3, iDb=0
3 Integer 50 2 0 0 r[2]=50
-- index seek on PRIMARY KEY index
4 SeekGT 1 10 2 0 key=[2..2]
5 Integer 60 2 0 0 r[2]=60
6 IdxGE 1 10 2 0 key=[2..2]
7 IdxRowId 1 1 0 0 r[1]=cursor 1 for index sqlite_autoindex_t_1.rowid
8 Insert 0 3 1 ephemeral_scratch 2 intkey=r[1] data=r[3]
9 Next 1 6 0 0
10 OpenWrite 2 2 0 0 root=2; iDb=0
11 OpenWrite 3 3 0 0 root=3; iDb=0
-- only scan rows that were inserted to ephemeral index
12 Rewind 0 34 0 0 Rewind table ephemeral_scratch
13 RowId 0 5 0 0 r[5]=ephemeral_scratch.rowid
```
Note that an ephemeral index does not have to be used if the index is
not affected:
```sql
turso> create table t(x PRIMARY KEY, data);
turso> explain update t set data = 'some_data' where x > 50 and x < 60;
addr opcode p1 p2 p3 p4 p5 comment
---- ----------------- ---- ---- ---- ------------- -- -------
0 Init 0 15 0 0 Start at 15
1 OpenWrite 0 2 0 0 root=2; iDb=0
2 OpenWrite 1 3 0 0 root=3; iDb=0
3 Integer 50 1 0 0 r[1]=50
-- direct index seek
4 SeekGT 1 14 1 0 key=[1..1]
```
Reviewed-by: Preston Thorpe <preston@turso.tech>
Closes#3728
When populating an ephemeral table for UPDATE, it may open a cursor
on the (permanent) table - in this case we don't need to open it
again in the UPDATE loop
- Encode information about ephemeral source table in OperationMode::UPDATE
if present
- Use OperationMode information to correctly resolve cursors in UPDATE
the decision to use an ephemeral table in UPDATE will be made after
the optimizer has made the decision about which index to use. this will
be implemented in a later commit.