Skip to content

Commit bd85bb7

Browse files
committed
[ADD] util/bulk_update_table
A recurrent challenge in writing upgrade scripts is that of updating values in a table based on some form of already available mapping from the id (or another identifier) to the new value, this is often addressed with an iterative solution in the form: ```python for key, value in mapping.items(): cr.execute( """ UPDATE table SET col = %s WHERE key_col = %s """, [value, key], ) ``` or in a more efficient (only issuing a single query) but hacky way: ```python cr.execute( """ UPDATE table SET col = (%s::jsonb)->>(key_col::text) WHERE key_col = ANY(%s) """, [json.dumps(mapping), list(mapping)], ) ``` With the former being ineffective for big mappings and the latter often requiring some comments at review time to get it right. This commit introduces a util meant to make it easier to efficiently perform such updates. closes #297 Signed-off-by: Christophe Simonis (chs) <chs@odoo.com>
1 parent a09edbd commit bd85bb7

File tree

2 files changed

+183
-0
lines changed

2 files changed

+183
-0
lines changed

src/base/tests/test_util.py

Lines changed: 109 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -881,6 +881,115 @@ def test_parallel_execute_retry_on_serialization_failure(self):
881881
cr.execute(util.format_query(cr, "SELECT 1 FROM {}", TEST_TABLE_NAME))
882882
self.assertFalse(cr.rowcount)
883883

884+
def test_update_one_col_from_dict(self):
885+
TEST_TABLE_NAME = "_upgrade_bulk_update_one_col_test_table"
886+
N_ROWS = 10
887+
888+
cr = self._get_cr()
889+
890+
cr.execute(
891+
util.format_query(
892+
cr,
893+
"""
894+
DROP TABLE IF EXISTS {table};
895+
896+
CREATE TABLE {table} (
897+
id SERIAL PRIMARY KEY,
898+
col1 INTEGER,
899+
col2 INTEGER
900+
);
901+
902+
INSERT INTO {table} (col1, col2) SELECT v, v FROM GENERATE_SERIES(1, %s) as v;
903+
""",
904+
table=TEST_TABLE_NAME,
905+
),
906+
[N_ROWS],
907+
)
908+
mapping = {id: id * 2 for id in range(1, N_ROWS + 1, 2)}
909+
util.bulk_update_table(cr, TEST_TABLE_NAME, "col1", mapping)
910+
911+
cr.execute(
912+
util.format_query(
913+
cr,
914+
"SELECT id FROM {table} WHERE col2 != id",
915+
table=TEST_TABLE_NAME,
916+
)
917+
)
918+
self.assertFalse(cr.rowcount, "unintended column 'col2' is affected")
919+
920+
cr.execute(
921+
util.format_query(
922+
cr,
923+
"SELECT id FROM {table} WHERE col1 != id AND MOD(id, 2) = 0",
924+
table=TEST_TABLE_NAME,
925+
)
926+
)
927+
self.assertFalse(cr.rowcount, "unintended rows are affected")
928+
929+
cr.execute(
930+
util.format_query(
931+
cr,
932+
"SELECT id FROM {table} WHERE col1 != 2 * id AND MOD(id, 2) = 1",
933+
table=TEST_TABLE_NAME,
934+
)
935+
)
936+
self.assertFalse(cr.rowcount, "partial/incorrect updates are performed")
937+
938+
def test_update_multiple_cols_from_dict(self):
939+
TEST_TABLE_NAME = "_upgrade_bulk_update_multiple_cols_test_table"
940+
N_ROWS = 10
941+
942+
cr = self._get_cr()
943+
944+
cr.execute(
945+
util.format_query(
946+
cr,
947+
"""
948+
DROP TABLE IF EXISTS {table};
949+
950+
CREATE TABLE {table} (
951+
id SERIAL PRIMARY KEY,
952+
col1 INTEGER,
953+
col2 INTEGER,
954+
col3 INTEGER
955+
);
956+
957+
INSERT INTO {table} (col1, col2, col3) SELECT v, v, v FROM GENERATE_SERIES(1, %s) as v;
958+
""",
959+
table=TEST_TABLE_NAME,
960+
),
961+
[N_ROWS],
962+
)
963+
mapping = {id: [id * 2, id * 3] for id in range(1, N_ROWS + 1, 2)}
964+
util.bulk_update_table(cr, TEST_TABLE_NAME, ["col1", "col2"], mapping)
965+
966+
cr.execute(
967+
util.format_query(
968+
cr,
969+
"SELECT id FROM {table} WHERE col3 != id",
970+
table=TEST_TABLE_NAME,
971+
)
972+
)
973+
self.assertFalse(cr.rowcount, "unintended column 'col3' is affected")
974+
975+
cr.execute(
976+
util.format_query(
977+
cr,
978+
"SELECT id FROM {table} WHERE col1 != id AND MOD(id, 2) = 0",
979+
table=TEST_TABLE_NAME,
980+
)
981+
)
982+
self.assertFalse(cr.rowcount, "unintended rows are affected")
983+
984+
cr.execute(
985+
util.format_query(
986+
cr,
987+
"SELECT id FROM {table} WHERE (col1 != 2 * id OR col2 != 3 * id) AND MOD(id, 2) = 1",
988+
table=TEST_TABLE_NAME,
989+
)
990+
)
991+
self.assertFalse(cr.rowcount, "partial/incorrect updates are performed")
992+
884993
def test_create_column_with_fk(self):
885994
cr = self.env.cr
886995
self.assertFalse(util.column_exists(cr, "res_partner", "_test_lang_id"))

src/util/pg.py

Lines changed: 74 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -32,6 +32,7 @@
3232
import psycopg2
3333
from psycopg2 import errorcodes, sql
3434
from psycopg2.extensions import quote_ident
35+
from psycopg2.extras import Json
3536

3637
try:
3738
from odoo.modules import module as odoo_module
@@ -1621,3 +1622,76 @@ def create_id_sequence(cr, table, set_as_default=True):
16211622
table=table_sql,
16221623
)
16231624
)
1625+
1626+
1627+
def bulk_update_table(cr, table, columns, mapping, key_col="id"):
1628+
"""
1629+
Update table based on mapping.
1630+
1631+
Each `mapping` entry defines the new values for the specified `columns` for the row(s)
1632+
whose `key_col` value matches the key.
1633+
1634+
.. example::
1635+
1636+
.. code-block:: python
1637+
1638+
# single column update
1639+
util.bulk_update_table(cr, "res_users", "active", {42: False, 27: True})
1640+
1641+
# multi-column update
1642+
util.bulk_update_table(
1643+
cr,
1644+
"res_users",
1645+
["active", "password"],
1646+
{
1647+
"admin": [True, "1234"],
1648+
"demo": [True, "5678"],
1649+
},
1650+
key_col="login",
1651+
)
1652+
1653+
:param str table: table to update.
1654+
:param str | list(str) columns: columns spec for the update. It could be a single
1655+
column name or a list of column names. The `mapping`
1656+
must match the spec.
1657+
:param dict mapping: values to set, which must match the spec in `columns`,
1658+
following the **same** order
1659+
:param str key_col: column used as key to get the values from `mapping` during the
1660+
update.
1661+
1662+
.. warning::
1663+
1664+
The values in the mapping will be casted to the type of the target column.
1665+
This function is designed to update scalar values, avoid setting arrays or json
1666+
data via the mapping.
1667+
"""
1668+
_validate_table(table)
1669+
if not columns or not mapping:
1670+
return
1671+
1672+
assert isinstance(mapping, dict)
1673+
if isinstance(columns, str):
1674+
columns = [columns]
1675+
else:
1676+
n_columns = len(columns)
1677+
assert all(isinstance(value, (list, tuple)) and len(value) == n_columns for value in mapping.values())
1678+
1679+
query = format_query(
1680+
cr,
1681+
"""
1682+
UPDATE {table} t
1683+
SET ({cols}) = ROW({cols_values})
1684+
FROM JSONB_EACH(%s) m
1685+
WHERE t.{key_col}::text = m.key
1686+
""",
1687+
table=table,
1688+
cols=ColumnList.from_unquoted(cr, columns),
1689+
cols_values=SQLStr(
1690+
", ".join(
1691+
"(m.value->>{:d})::{}".format(col_idx, column_type(cr, table, col_name))
1692+
for col_idx, col_name in enumerate(columns)
1693+
)
1694+
),
1695+
key_col=key_col,
1696+
)
1697+
cr.execute(query, [Json(mapping)])

0 commit comments

Comments
 (0)