[PERF] runbot: remove row_number queries

The row_number window function is quite unoptimized as it requires
reading the whole table.
Using lateral join and / or distinct makes better use of existing
indexes.
This commit is contained in:
William Braeckman 2024-12-05 13:28:23 +01:00
parent 1add8d56f5
commit b659c73856

View File

@ -144,65 +144,55 @@ class Bundle(models.Model):
@api.depends_context('category_id') @api.depends_context('category_id')
def _compute_last_batchs(self): def _compute_last_batchs(self):
batch_ids = defaultdict(list) batches_by_bundle = defaultdict(lambda: self.env['runbot.batch'])
if self.ids: if self.ids:
category_id = self.env.context.get('category_id', self.env['ir.model.data']._xmlid_to_res_id('runbot.default_category')) category_id = self.env.context.get('category_id', self.env['ir.model.data']._xmlid_to_res_id('runbot.default_category'))
self.env.cr.execute(""" self.env.cr.execute("""
SELECT SELECT bundle.id, ARRAY_AGG(batch.id)
id FROM runbot_bundle bundle
FROM ( JOIN LATERAL (
SELECT SELECT b.id
batch.id AS id, FROM runbot_batch b
row_number() OVER (PARTITION BY batch.bundle_id order by batch.id desc) AS row WHERE b.category_id = %s
FROM AND b.bundle_id = bundle.id
runbot_bundle bundle INNER JOIN runbot_batch batch ON bundle.id=batch.bundle_id ORDER BY id desc
WHERE LIMIT 4
bundle.id in %s ) batch ON TRUE
AND batch.category_id = %s WHERE bundle.id in %s
) AS bundle_batch GROUP BY bundle.id;
WHERE """, (category_id, tuple(self.ids)))
row <= 4 for bundle_id, batch_ids in self.env.cr.fetchall():
ORDER BY row, id desc batches_by_bundle[bundle_id] = self.env['runbot.batch'].browse(batch_ids)
""", [tuple(self.ids), category_id]
)
batchs = self.env['runbot.batch'].browse([r[0] for r in self.env.cr.fetchall()])
for batch in batchs:
batch_ids[batch.bundle_id.id].append(batch.id)
for bundle in self: for bundle in self:
bundle.last_batchs = [(6, 0, batch_ids[bundle.id])] if bundle.id in batch_ids else False bundle.last_batchs = batches_by_bundle[bundle.id]
@api.depends_context('category_id') @api.depends_context('category_id')
def _compute_last_done_batch(self): def _compute_last_done_batch(self):
if self: if not self:
self.env['runbot.batch'].flush_model() return
self.env['runbot.bundle'].flush_model() self.env['runbot.batch'].flush_model()
# self.env['runbot.batch'].flush() self.env['runbot.bundle'].flush_model()
for bundle in self: # self.env['runbot.batch'].flush()
bundle.last_done_batch = False self.last_done_batch = False
category_id = self.env.context.get('category_id', self.env['ir.model.data']._xmlid_to_res_id('runbot.default_category')) category_id = self.env.context.get('category_id', self.env['ir.model.data']._xmlid_to_res_id('runbot.default_category'))
self.env.cr.execute(""" # Could be expressed as a subselect but similar enough to `_compute_last_batchs` query to keep them the same.
SELECT self.env.cr.execute("""
id SELECT bundle.id, batch.id
FROM ( FROM runbot_bundle bundle
SELECT JOIN LATERAL (
batch.id AS id, SELECT b.id
row_number() OVER (PARTITION BY batch.bundle_id order by batch.id desc) AS row FROM runbot_batch b
FROM WHERE b.category_id = %s
runbot_bundle bundle INNER JOIN runbot_batch batch ON bundle.id=batch.bundle_id AND b.bundle_id = bundle.id
WHERE AND b.state = 'done'
bundle.id in %s ORDER BY id desc
AND batch.state = 'done' LIMIT 1
AND batch.category_id = %s ) batch ON TRUE
) AS bundle_batch WHERE bundle.id in %s;
WHERE """, [category_id, tuple(self.ids)]
row = 1 )
ORDER BY row, id desc for bundle_id, batch_id in self.env.cr.fetchall():
""", [tuple(self.ids), category_id] self.browse(bundle_id).last_done_batch = self.env['runbot.batch'].browse(batch_id)
)
batchs = self.env['runbot.batch'].browse([r[0] for r in self.env.cr.fetchall()])
for batch in batchs:
batch.bundle_id.last_done_batch = batch
def _url(self): def _url(self):
self.ensure_one() self.ensure_one()