Skip to content

Commit

Permalink
fix(db-query): use join instead of nested query for FRI prover extrac…
Browse files Browse the repository at this point in the history
…ting (#364)

# What ❔
use join instead of nested query for FRI prover extracting jobs

## Why ❔
This is expected to make the `SELECT` faster as per discussion with DBA.


## Checklist

<!-- Check your PR fulfills the following items. -->
<!-- For draft PRs check the boxes as you complete them. -->

- [* ] PR title corresponds to the body of PR (we generate changelog
entries from PRs).
- [ *] Tests for the changes have been added / updated.
- [ *] Documentation comments have been added / updated.
- [ *] Code has been formatted via `zk fmt` and `zk lint`.
  • Loading branch information
akash-chandrakar committed Nov 2, 2023
1 parent 568bf5e commit f9cc831
Show file tree
Hide file tree
Showing 2 changed files with 68 additions and 66 deletions.
118 changes: 59 additions & 59 deletions core/lib/dal/sqlx-data.json
Original file line number Diff line number Diff line change
Expand Up @@ -4660,6 +4660,65 @@
},
"query": "INSERT INTO events_queue (l1_batch_number, serialized_events_queue) VALUES ($1, $2)"
},
"62aaa047e3da5bd966608fec421ddad1b8afa04aaf35e946219d703bbe6ac9c5": {
"describe": {
"columns": [
{
"name": "id",
"ordinal": 0,
"type_info": "Int8"
},
{
"name": "l1_batch_number",
"ordinal": 1,
"type_info": "Int8"
},
{
"name": "circuit_id",
"ordinal": 2,
"type_info": "Int2"
},
{
"name": "aggregation_round",
"ordinal": 3,
"type_info": "Int2"
},
{
"name": "sequence_number",
"ordinal": 4,
"type_info": "Int4"
},
{
"name": "depth",
"ordinal": 5,
"type_info": "Int4"
},
{
"name": "is_node_final_proof",
"ordinal": 6,
"type_info": "Bool"
}
],
"nullable": [
false,
false,
false,
false,
false,
false,
false
],
"parameters": {
"Left": [
"Int2Array",
"Int2Array",
"Int4Array",
"Text"
]
}
},
"query": "\n UPDATE prover_jobs_fri\n SET status = 'in_progress', attempts = attempts + 1,\n updated_at = now(), processing_started_at = now(),\n picked_by = $4\n WHERE id = (\n SELECT pj.id\n FROM prover_jobs_fri AS pj\n JOIN (\n SELECT * FROM unnest($1::smallint[], $2::smallint[])\n )\n AS tuple (circuit_id, round)\n ON tuple.circuit_id = pj.circuit_id AND tuple.round = pj.aggregation_round\n WHERE pj.status = 'queued'\n AND pj.protocol_version = ANY($3)\n ORDER BY pj.l1_batch_number ASC, pj.aggregation_round DESC, pj.id ASC\n LIMIT 1\n FOR UPDATE\n SKIP LOCKED\n )\n RETURNING prover_jobs_fri.id, prover_jobs_fri.l1_batch_number, prover_jobs_fri.circuit_id,\n prover_jobs_fri.aggregation_round, prover_jobs_fri.sequence_number, prover_jobs_fri.depth,\n prover_jobs_fri.is_node_final_proof\n "
},
"62e8b4afd4df9e30bfa08cb30c74ba4566fa2e9f4934b7a2777f9e90b49e8fce": {
"describe": {
"columns": [],
Expand Down Expand Up @@ -4737,65 +4796,6 @@
},
"query": "\n SELECT status, error, compilation_errors FROM contract_verification_requests\n WHERE id = $1\n "
},
"654e133230ee435e95cfda5bc4d72c8dd26412fe9d364e218e95eb4fe64559e9": {
"describe": {
"columns": [
{
"name": "id",
"ordinal": 0,
"type_info": "Int8"
},
{
"name": "l1_batch_number",
"ordinal": 1,
"type_info": "Int8"
},
{
"name": "circuit_id",
"ordinal": 2,
"type_info": "Int2"
},
{
"name": "aggregation_round",
"ordinal": 3,
"type_info": "Int2"
},
{
"name": "sequence_number",
"ordinal": 4,
"type_info": "Int4"
},
{
"name": "depth",
"ordinal": 5,
"type_info": "Int4"
},
{
"name": "is_node_final_proof",
"ordinal": 6,
"type_info": "Bool"
}
],
"nullable": [
false,
false,
false,
false,
false,
false,
false
],
"parameters": {
"Left": [
"Int2Array",
"Int2Array",
"Int4Array",
"Text"
]
}
},
"query": "\n UPDATE prover_jobs_fri\n SET status = 'in_progress', attempts = attempts + 1,\n updated_at = now(), processing_started_at = now(),\n picked_by = $4\n WHERE id = (\n SELECT id\n FROM prover_jobs_fri\n WHERE status = 'queued'\n AND (circuit_id, aggregation_round) IN (\n SELECT * FROM UNNEST($1::smallint[], $2::smallint[])\n )\n AND protocol_version = ANY($3)\n ORDER BY aggregation_round DESC, l1_batch_number ASC, id ASC\n LIMIT 1\n FOR UPDATE\n SKIP LOCKED\n )\n RETURNING prover_jobs_fri.id, prover_jobs_fri.l1_batch_number, prover_jobs_fri.circuit_id,\n prover_jobs_fri.aggregation_round, prover_jobs_fri.sequence_number, prover_jobs_fri.depth,\n prover_jobs_fri.is_node_final_proof\n "
},
"65a31949cd7f8890e9448d26a0efee852ddf59bfbbc858b51fba10048d47d27b": {
"describe": {
"columns": [
Expand Down
16 changes: 9 additions & 7 deletions core/lib/dal/src/fri_prover_dal.rs
Original file line number Diff line number Diff line change
Expand Up @@ -112,14 +112,16 @@ impl FriProverDal<'_, '_> {
updated_at = now(), processing_started_at = now(),
picked_by = $4
WHERE id = (
SELECT id
FROM prover_jobs_fri
WHERE status = 'queued'
AND (circuit_id, aggregation_round) IN (
SELECT * FROM UNNEST($1::smallint[], $2::smallint[])
SELECT pj.id
FROM prover_jobs_fri AS pj
JOIN (
SELECT * FROM unnest($1::smallint[], $2::smallint[])
)
AND protocol_version = ANY($3)
ORDER BY aggregation_round DESC, l1_batch_number ASC, id ASC
AS tuple (circuit_id, round)
ON tuple.circuit_id = pj.circuit_id AND tuple.round = pj.aggregation_round
WHERE pj.status = 'queued'
AND pj.protocol_version = ANY($3)
ORDER BY pj.l1_batch_number ASC, pj.aggregation_round DESC, pj.id ASC
LIMIT 1
FOR UPDATE
SKIP LOCKED
Expand Down

0 comments on commit f9cc831

Please sign in to comment.