Ecto 3.0 gets us easy access to partitions and the windowing function
`lag`. `lag` is able to keep track of the previous row without a self
join. Importantly, the new query with `lag` and no more
`generate_series` completes in ~2.5 seconds on Ethereum mainnet
using `:timer.tc(Explorer.Chain, :missing_block_number_ranges, [6889126..0])`
on ETH Mainnet Test DB 40 while the old version doesn't return after 5+
minutes.
I've heavily commented the new version of the query since this took
awhile to figure out and most importantly finding the proper terminology:
"gaps and islands" was key to find the starting query using `lag`.
The query in SQL is as follows:
```sql
SELECT island.last_number + 1,
island.next_number - 1
FROM (
SELECT lag(land.number) OVER "w" AS last_number,
land.number AS next_number
FROM (
SELECT blocks.number AS number
FROM blocks
WHERE blocks.consensus = TRUE
UNION ALL (
SELECT LEAST(min_blocks.number, before_range_min)
FROM (
SELECT min(blocks.number) AS number
FROM blocks
WHERE blocks.consensus = TRUE)
) AS min_blocks
WHERE min_blocks.number IS NULL OR
min_blocks.number != before_range_min
)
UNION ALL (
SELECT GREATEST(max_blocks.number, after_range_max)
FROM (
SELECT max(blocks.number) AS number
FROM blocks
WHERE blocks.consensus = TRUE
) AS max_blocks
WHERE max_blocks.number IS NULL OR
max_blocks.number != after_range_max
) AS land
WINDOW "w" AS (ORDER BY land.number)
) AS islands
WHERE islands.last_number != islands.next_number - 1
ORDER BY islands.last_number
```