From: Mike Bayer Date: Tue, 22 Nov 2011 22:27:35 +0000 (-0500) Subject: - commit the unit tests X-Git-Tag: rel_0_7_4~57 X-Git-Url: http://git.ipfire.org/cgi-bin/gitweb.cgi?a=commitdiff_plain;h=90b6ca30e430a06ed1d1696f3881ae72c6014ecd;p=thirdparty%2Fsqlalchemy%2Fsqlalchemy.git - commit the unit tests - lots of doc updates to all three of update/insert/delete --- diff --git a/doc/build/core/tutorial.rst b/doc/build/core/tutorial.rst index c615167d6d..36fa476954 100644 --- a/doc/build/core/tutorial.rst +++ b/doc/build/core/tutorial.rst @@ -1408,11 +1408,13 @@ indicate ascending or descending. () {stop}[(2, 1, u'jack@msn.com')] +.. _inserts_and_updates: + Inserts and Updates =================== Finally, we're back to INSERT for some more detail. The -:func:`~sqlalchemy.sql.expression.insert` construct provides a ``values()`` +:func:`~sqlalchemy.sql.expression.insert` construct provides a :meth:`~.ValuesBase.values` method which can be used to send any value or clause expression to the VALUES portion of the INSERT:: @@ -1445,7 +1447,8 @@ of bind names:: ] ) -Updates work a lot like INSERTS, except there is an additional WHERE clause +An UPDATE statement is emitted using the :func:`.update` construct. These +work much like an INSERT, except there is an additional WHERE clause that can be specified: .. sourcecode:: pycon+sql @@ -1508,10 +1511,60 @@ table, or the same table: COMMIT {stop} +Multiple Table Updates +---------------------- + +.. note:: This feature is new as of version 0.7.4. + +The Postgresql, Microsoft SQL Server, and MySQL backends all support UPDATE statements +that refer to multiple tables. For PG and MSSQL, this is the "UPDATE FROM" syntax, +which updates one table at a time, but can reference additional tables in an additional +"FROM" clause that can then be referenced in the WHERE clause directly. On MySQL, +multiple tables can be embedded into a single UPDATE statement separated by a comma. +The SQLAlchemy :func:`.update` construct supports both of these modes +implicitly, simply by specifying multiple tables in the WHERE clause:: + + stmt = users.update().\ + values(name='ed wood').\ + where(users.c.id==addresses.c.id).\ + where(addresses.c.email_address.startswith('ed%')) + conn.execute(stmt) + +The resulting SQL from the above statement would render as:: + + UPDATE users SET name=:name FROM addresses + WHERE users.id = addresses.id AND + addresses.email_address LIKE :email_address_1 || '%%' + +When using MySQL, columns from each table can be assigned to in the +SET clause directly, using the dictionary form passed to :meth:`.Update.values`:: + + stmt = users.update().\ + values({ + users.c.name:'ed wood', + addresses.c.email_address:'ed.wood@foo.com' + }).\ + where(users.c.id==addresses.c.id).\ + where(addresses.c.email_address.startswith('ed%')) + +The tables are referenced explicitly in the SET clause:: + + UPDATE users, addresses SET addresses.email_address=%s, + users.name=%s WHERE users.id = addresses.id + AND addresses.email_address LIKE concat(%s, '%%') + +SQLAlchemy doesn't do anything special when these constructs are used on +a non-supporting database. The ``UPDATE FROM`` syntax generates by default +when multiple tables are present, and the statement will simply be rejected +by the database if this syntax is not supported. + +.. _deletes: + Deletes ======== -Finally, a delete. Easy enough: +Finally, a delete. This is accomplished easily enough using the +:func:`~.expression.delete` construct: .. sourcecode:: pycon+sql diff --git a/lib/sqlalchemy/sql/expression.py b/lib/sqlalchemy/sql/expression.py index 0357122b09..6520be202d 100644 --- a/lib/sqlalchemy/sql/expression.py +++ b/lib/sqlalchemy/sql/expression.py @@ -311,14 +311,12 @@ def subquery(alias, *args, **kwargs): return Select(*args, **kwargs).alias(alias) def insert(table, values=None, inline=False, **kwargs): - """Return an :class:`.Insert` clause element. + """Represent an ``INSERT`` statement via the :class:`.Insert` SQL + construct. - Similar functionality is available via the :meth:`~.schema.Table.insert` method on + Similar functionality is available via the :meth:`~.TableClause.insert` method on :class:`~.schema.Table`. - See also: - - :ref:`coretutorial_insert_expressions` - Core Tutorial description of the :func:`.insert` construct. :param table: The table to be inserted into. @@ -352,51 +350,115 @@ def insert(table, values=None, inline=False, **kwargs): ``INSERT`` statement's table, the statement will be correlated against the ``INSERT`` statement. + See also: + + :ref:`coretutorial_insert_expressions` - SQL Expression Tutorial + + :ref:`inserts_and_updates` - SQL Expression Tutorial + """ return Insert(table, values, inline=inline, **kwargs) def update(table, whereclause=None, values=None, inline=False, **kwargs): - """Return an :class:`.Update` clause element. + """Represent an ``UPDATE`` statement via the :class:`.Update` SQL + construct. - Similar functionality is available via the :func:`update()` method on - :class:`~sqlalchemy.schema.Table`. + E.g.:: - :param table: The table to be updated. + from sqlalchemy import update + + stmt = update(users).where(users.c.id==5).\\ + values(name='user #5') - :param whereclause: A :class:`.ClauseElement` describing the ``WHERE`` - condition of the ``UPDATE`` statement. Note that the - :meth:`~Update.where()` generative method may also be used for this. + Similar functionality is available via the :meth:`~.TableClause.update` method on + :class:`.Table`:: + + + stmt = users.update().\\ + where(users.c.id==5).\\ + values(name='user #5') + + :param table: A :class:`.Table` object representing the database + table to be updated. + + :param whereclause: Optional SQL expression describing the ``WHERE`` + condition of the ``UPDATE`` statement. Modern applications + may prefer to use the generative :meth:`~Update.where()` + method to specify the ``WHERE`` clause. + + The WHERE clause can refer to multiple tables as of version 0.7.4. + For databases which support this, an ``UPDATE FROM`` clause will + be generated, or on MySQL, a multi-table update. The statement + will fail on databases that don't have support for multi-table + update statements. A SQL-standard method of referring to + additional tables in the WHERE clause is to use a correlated + subquery:: + + users.update().values(name='ed').where( + users.c.name==select([addresses.c.email_address]).\\ + where(addresses.c.user_id==users.c.id).\\ + as_scalar() + ) :param values: - A dictionary which specifies the ``SET`` conditions of the - ``UPDATE``, and is optional. If left as None, the ``SET`` - conditions are determined from the bind parameters used during - the compile phase of the ``UPDATE`` statement. If the bind - parameters also are None during the compile phase, then the - ``SET`` conditions will be generated from the full list of table - columns. Note that the :meth:`~Update.values()` generative method may - also be used for this. + Optional dictionary which specifies the ``SET`` conditions of the + ``UPDATE``. If left as ``None``, the ``SET`` + conditions are determined from those parameters passed to the + statement during the execution and/or compilation of the + statement. When compiled standalone without any parameters, + the ``SET`` clause generates for all columns. + + Modern applications may prefer to use the generative + :meth:`.Update.values` method to set the values of the + UPDATE statement. :param inline: - if True, SQL defaults will be compiled 'inline' into the statement - and not pre-executed. + if True, SQL defaults present on :class:`.Column` objects via + the ``default`` keyword will be compiled 'inline' into the statement + and not pre-executed. This means that their values will not + be available in the dictionary returned from + :meth:`.ResultProxy.last_updated_params`. - If both `values` and compile-time bind parameters are present, the + If both ``values`` and compile-time bind parameters are present, the compile-time bind parameters override the information specified - within `values` on a per-key basis. - - The keys within `values` can be either :class:`~sqlalchemy.schema.Column` - objects or their - string identifiers. Each key may reference one of: - - * a literal data value (i.e. string, number, etc.); - * a Column object; - * a SELECT statement. + within ``values`` on a per-key basis. + + The keys within ``values`` can be either :class:`.Column` + objects or their string identifiers (specifically the "key" of the + :class:`.Column`, normally but not necessarily equivalent to + its "name"). Normally, the + :class:`.Column` objects used here are expected to be + part of the target :class:`.Table` that is the table + to be updated. However when using MySQL, a multiple-table + UPDATE statement can refer to columns from any of + the tables referred to in the WHERE clause. + + The values referred to in ``values`` are typically: + + * a literal data value (i.e. string, number, etc.) + * a SQL expression, such as a related :class:`.Column`, + a scalar-returning :func:`.select` construct, + etc. + + When combining :func:`.select` constructs within the values + clause of an :func:`.update` construct, + the subquery represented by the :func:`.select` should be + *correlated* to the parent table, that is, providing criterion + which links the table inside the subquery to the outer table + being updated:: + + users.update().values( + name=select([addresses.c.email_address]).\\ + where(addresses.c.user_id==users.c.id).\\ + as_scalar() + ) - If a ``SELECT`` statement is specified which references this - ``UPDATE`` statement's table, the statement will be correlated - against the ``UPDATE`` statement. + See also: + :ref:`inserts_and_updates` - SQL Expression + Language Tutorial + + """ return Update( table, @@ -406,10 +468,11 @@ def update(table, whereclause=None, values=None, inline=False, **kwargs): **kwargs) def delete(table, whereclause = None, **kwargs): - """Return a :class:`.Delete` clause element. + """Represent a ``DELETE`` statement via the :class:`.Delete` SQL + construct. - Similar functionality is available via the :func:`delete()` method on - :class:`~sqlalchemy.schema.Table`. + Similar functionality is available via the :meth:`~.TableClause.delete` method on + :class:`~.schema.Table`. :param table: The table to be updated. @@ -417,6 +480,10 @@ def delete(table, whereclause = None, **kwargs): condition of the ``UPDATE`` statement. Note that the :meth:`~Delete.where()` generative method may be used instead. + See also: + + :ref:`deletes` - SQL Expression Tutorial + """ return Delete(table, whereclause, **kwargs) @@ -4008,18 +4075,45 @@ class TableClause(_Immutable, FromClause): **params) def insert(self, values=None, inline=False, **kwargs): - """Generate an :func:`insert()` construct.""" + """Generate an :func:`.insert` construct against this + :class:`.TableClause`. + + E.g.:: + + table.insert().values(name='foo') + + See :func:`.insert` for argument and usage information. + + """ return insert(self, values=values, inline=inline, **kwargs) def update(self, whereclause=None, values=None, inline=False, **kwargs): - """Generate an :func:`update()` construct.""" + """Generate an :func:`.update` construct against this + :class:`.TableClause`. + + E.g.:: + + table.update().where(table.c.id==7).values(name='foo') + + See :func:`.update` for argument and usage information. + + """ return update(self, whereclause=whereclause, values=values, inline=inline, **kwargs) def delete(self, whereclause=None, **kwargs): - """Generate a :func:`delete()` construct.""" + """Generate a :func:`.delete` construct against this + :class:`.TableClause`. + + E.g.:: + + table.delete().where(table.c.id==7) + + See :func:`.delete` for argument and usage information. + + """ return delete(self, whereclause, **kwargs) @@ -5070,6 +5164,15 @@ class ValuesBase(UpdateBase): users.update().where(users.c.id==5).values({users.c.name : "some name"}) + See also: + + :ref:`inserts_and_updates` - SQL Expression + Language Tutorial + + :func:`~.expression.insert` - produce an ``INSERT`` statement + + :func:`~.expression.update` - produce an ``UPDATE`` statement + """ if args: v = args[0] diff --git a/test/sql/test_update.py b/test/sql/test_update.py new file mode 100644 index 0000000000..87fd6ffd5e --- /dev/null +++ b/test/sql/test_update.py @@ -0,0 +1,218 @@ +from test.lib.testing import eq_, assert_raises_message, assert_raises, AssertsCompiledSQL +import datetime +from sqlalchemy import * +from sqlalchemy import exc, sql, util +from sqlalchemy.engine import default, base +from test.lib import * +from test.lib.schema import Table, Column +from sqlalchemy.dialects import mysql + +class UpdateFromTest(fixtures.TablesTest, AssertsCompiledSQL): + __dialect__ = 'default' + + @classmethod + def define_tables(cls, metadata): + Table('users', metadata, + Column('id', Integer, primary_key=True, + test_needs_autoincrement=True), + Column('name', String(30), nullable=False), + test_needs_acid=True, + test_needs_fk=True + ) + + Table('addresses', metadata, + Column('id', Integer, primary_key=True, + test_needs_autoincrement=True), + Column('user_id', None, ForeignKey('users.id')), + Column('name', String(30), nullable=False), + Column('email_address', String(50), nullable=False), + test_needs_acid=True, + test_needs_fk=True + ) + + Table("dingalings", metadata, + Column('id', Integer, primary_key=True, + test_needs_autoincrement=True), + Column('address_id', None, ForeignKey('addresses.id')), + Column('data', String(30)), + test_needs_acid=True, + test_needs_fk=True + ) + + @classmethod + def fixtures(cls): + return dict( + users = ( + ('id', 'name'), + (7, 'jack'), + (8, 'ed'), + (9, 'fred'), + (10, 'chuck') + ), + + addresses = ( + ('id', 'user_id', 'name', 'email_address'), + (1, 7, 'x', "jack@bean.com"), + (2, 8, 'x', "ed@wood.com"), + (3, 8, 'x', "ed@bettyboop.com"), + (4, 8, 'x', "ed@lala.com"), + (5, 9, 'x', "fred@fred.com") + ), + dingalings = ( + ('id', 'address_id', 'data'), + (1, 2, 'ding 1/2'), + (2, 5, 'ding 2/5') + ), + ) + + def test_render_table(self): + users, addresses = self.tables.users, self.tables.addresses + self.assert_compile( + users.update().\ + values(name='newname').\ + where(users.c.id==addresses.c.user_id).\ + where(addresses.c.email_address=='e1'), + "UPDATE users SET name=:name FROM addresses " + "WHERE users.id = addresses.user_id AND " + "addresses.email_address = :email_address_1", + checkparams={u'email_address_1': 'e1', 'name': 'newname'} + ) + + def test_render_multi_table(self): + users, addresses, dingalings = \ + self.tables.users, \ + self.tables.addresses, \ + self.tables.dingalings + self.assert_compile( + users.update().\ + values(name='newname').\ + where(users.c.id==addresses.c.user_id).\ + where(addresses.c.email_address=='e1').\ + where(addresses.c.id==dingalings.c.address_id).\ + where(dingalings.c.id==2), + "UPDATE users SET name=:name FROM addresses, " + "dingalings WHERE users.id = addresses.user_id " + "AND addresses.email_address = :email_address_1 " + "AND addresses.id = dingalings.address_id AND " + "dingalings.id = :id_1", + checkparams={u'email_address_1': 'e1', u'id_1': 2, + 'name': 'newname'} + ) + + def test_render_table_mysql(self): + users, addresses = self.tables.users, self.tables.addresses + self.assert_compile( + users.update().\ + values(name='newname').\ + where(users.c.id==addresses.c.user_id).\ + where(addresses.c.email_address=='e1'), + "UPDATE users, addresses SET users.name=%s " + "WHERE users.id = addresses.user_id AND " + "addresses.email_address = %s", + checkparams={u'email_address_1': 'e1', 'name': 'newname'}, + dialect=mysql.dialect() + ) + + def test_render_subquery(self): + users, addresses = self.tables.users, self.tables.addresses + subq = select([addresses.c.id, + addresses.c.user_id, + addresses.c.email_address]).\ + where(addresses.c.id==7).alias() + self.assert_compile( + users.update().\ + values(name='newname').\ + where(users.c.id==subq.c.user_id).\ + where(subq.c.email_address=='e1'), + "UPDATE users SET name=:name FROM " + "(SELECT addresses.id AS id, addresses.user_id " + "AS user_id, addresses.email_address AS " + "email_address FROM addresses WHERE addresses.id = " + ":id_1) AS anon_1 WHERE users.id = anon_1.user_id " + "AND anon_1.email_address = :email_address_1", + checkparams={u'email_address_1': 'e1', + u'id_1': 7, 'name': 'newname'} + ) + + @testing.requires.update_from + def test_exec_two_table(self): + users, addresses = self.tables.users, self.tables.addresses + testing.db.execute( + addresses.update().\ + values(email_address=users.c.name).\ + where(users.c.id==addresses.c.user_id).\ + where(users.c.name=='ed') + ) + eq_( + testing.db.execute( + addresses.select().\ + order_by(addresses.c.id)).fetchall(), + [ + (1, 7, 'x', "jack@bean.com"), + (2, 8, 'x', "ed"), + (3, 8, 'x', "ed"), + (4, 8, 'x', "ed"), + (5, 9, 'x', "fred@fred.com") + ] + ) + + @testing.requires.update_from + def test_exec_three_table(self): + users, addresses, dingalings = \ + self.tables.users, \ + self.tables.addresses, \ + self.tables.dingalings + testing.db.execute( + addresses.update().\ + values(email_address=users.c.name).\ + where(users.c.id==addresses.c.user_id).\ + where(users.c.name=='ed'). + where(addresses.c.id==dingalings.c.address_id).\ + where(dingalings.c.id==1), + ) + eq_( + testing.db.execute( + addresses.select().order_by(addresses.c.id) + ).fetchall(), + [ + (1, 7, 'x', "jack@bean.com"), + (2, 8, 'x', "ed"), + (3, 8, 'x', "ed@bettyboop.com"), + (4, 8, 'x', "ed@lala.com"), + (5, 9, 'x', "fred@fred.com") + ] + ) + + @testing.only_on('mysql', 'Multi table update') + def test_exec_multitable(self): + users, addresses = self.tables.users, self.tables.addresses + testing.db.execute( + addresses.update().\ + values({ + addresses.c.email_address:users.c.name, + users.c.name:'ed2' + }).\ + where(users.c.id==addresses.c.user_id).\ + where(users.c.name=='ed') + ) + eq_( + testing.db.execute( + addresses.select().order_by(addresses.c.id)).fetchall(), + [ + (1, 7, 'x', "jack@bean.com"), + (2, 8, 'x', "ed"), + (3, 8, 'x', "ed"), + (4, 8, 'x', "ed"), + (5, 9, 'x', "fred@fred.com") + ] + ) + eq_( + testing.db.execute( + users.select().order_by(users.c.id)).fetchall(), + [ + (7, 'jack'), + (8, 'ed2'), + (9, 'fred'), + (10, 'chuck') + ] + )