Fixes: #12016
**Description**
This PR adds support for specifying the `TABLESPACE` in table definitions in SQLAlchemy, specifically for Oracle. This feature is particularly useful for Oracle users who need to specify the tablespace where the table data will be stored.
**Changes Made**
1. Updated `construct_arguments` in `OracleDialect`:
- The `construct_arguments` list in the `OracleDialect` class has been updated to include the `tablespace` argument for the `Table` class.
```Python
construct_arguments = [
(
sa_schema.Table,
# old
{"resolve_synonyms": False, "on_commit": None, "compress": False},
# new
{"resolve_synonyms": False, "on_commit": None, "compress": False, "tablespace": None},
),
(sa_schema.Index, {"bitmap": False, "compress": False}),
]
```
**Path**: `lib/sqlalchemy/dialects/oracle/base.py`
2. Modified OracleDDLCompiler to Include TABLESPACE in post_create_table:
- The OracleDDLCompiler class has been modified to include the TABLESPACE clause at the end of the CREATE TABLE statement if the tablespace option is provided.
```Python
if opts["tablespace"]:
tablespace_name = opts["tablespace"]
table_opts.append(
"\n TABLESPACE %s" % self.preparer.quote(tablespace_name)
)
```
**Path**: `lib/sqlalchemy/dialects/oracle/base.py`
3. Added tablespace Argument to the Table Class:
- A new tablespace argument has been added to the Table class to allow specifying the tablespace in the table definition.
4. Documentation Update:
- The documentation has been updated to reflect the new feature and provide usage examples.
**Usage Example**
```Python
from sqlalchemy import create_engine, Table, Column, Integer, String, MetaData
engine = create_engine('oracle+cx_oracle://user:password@dsn')
metadata = MetaData()
users = Table('users', metadata,
Column('id', Integer, primary_key=True),
Column('name', String),
Column('email', String, unique=True),
oracle_tablespace='my_tablespace' # New tablespace argument optional
)
metadata.create_all(engine)
```
<!-- Provide a general summary of your proposed changes in the Title field above -->
### Description
<!-- Describe your changes in detail -->
### Checklist
<!-- go over following points. check them with an `x` if they do apply, (they turn into clickable checkboxes once the PR is submitted, so no need to do everything at once)
-->
This pull request is:
- [ ] A documentation / typographical / small typing error fix
- Good to go, no issue or tests are needed
- [ ] A short code fix
- please include the issue number, and create an issue if none exists, which
must include a complete example of the issue. one line code fixes without an
issue and demonstration will not be accepted.
- Please include: `Fixes: #<issue number>` in the commit message
- please include tests. one line code fixes without tests will not be accepted.
- [x] A new feature implementation
- please include the issue number, and create an issue if none exists, which must
include a complete example of how the feature would look.
- Please include: `Fixes: #<issue number>` in the commit message
- please include tests.
**Have a nice day!**
Closes: #12013
Pull-request: https://github.com/sqlalchemy/sqlalchemy/pull/12013
Pull-request-sha:
e542dea6ced269cb188b06cbd04cecf1c400e29a
Change-Id: I4733b466f9486289e13dd7503d18b3b5c866e836
(cherry picked from commit
44fa4a55bad2bc1bd20047275c366385ba3d4b1f)
--- /dev/null
+.. change::
+ :tags: feature, oracle
+ :ticket: 12016
+
+ Added new table option `oracle_tablespace` to specify the `TABLESPACE` option
+ when creating a table in Oracle. This allows users to define the tablespace in
+ which the table should be created. Pull request courtesy of Miguel Grillo.
The ``oracle_compress`` parameter accepts either an integer compression
level, or ``True`` to use the default compression level.
+* ``TABLESPACE``::
+
+ Table('mytable', metadata, ...,
+ oracle_tablespace="EXAMPLE_TABLESPACE")
+
+ The ``oracle_tablespace`` parameter specifies the tablespace in which the
+ table is to be created. This is useful when you want to create a table in a
+ tablespace other than the default tablespace of the user.
+
+ .. versionadded:: 2.0.37
+
.. _oracle_index_options:
Oracle Specific Index Options
table_opts.append("\n COMPRESS")
else:
table_opts.append("\n COMPRESS FOR %s" % (opts["compress"]))
-
+ if opts["tablespace"]:
+ table_opts.append(
+ "\n TABLESPACE %s" % self.preparer.quote(opts["tablespace"])
+ )
return "".join(table_opts)
def get_identity_options(self, identity_options):
construct_arguments = [
(
sa_schema.Table,
- {"resolve_synonyms": False, "on_commit": None, "compress": False},
+ {
+ "resolve_synonyms": False,
+ "on_commit": None,
+ "compress": False,
+ "tablespace": None,
+ },
),
(sa_schema.Index, {"bitmap": False, "compress": False}),
]
if self._supports_table_compress_for
else sql.null().label("compress_for")
),
+ dictionary.all_tables.c.tablespace_name,
).where(dictionary.all_tables.c.owner == owner)
if has_filter_names:
query = query.where(
connection, query, dblink, returns_long=False, params=params
)
- for table, compression, compress_for in result:
+ for table, compression, compress_for, tablespace in result:
+ data = default()
if compression == "ENABLED":
- data = {"oracle_compress": compress_for}
- else:
- data = default()
+ data["oracle_compress"] = compress_for
+ if tablespace:
+ data["oracle_tablespace"] = tablespace
options[(schema, self.normalize_name(table))] = data
if ObjectKind.VIEW in kind and ObjectScope.DEFAULT in scope:
# add the views (no temporary views)
cast(column("foo"), d1), "CAST(foo AS DOUBLE PRECISION)"
)
+ @testing.combinations(
+ ("TEST_TABLESPACE", 'TABLESPACE "TEST_TABLESPACE"'),
+ ("test_tablespace", "TABLESPACE test_tablespace"),
+ ("TestTableSpace", 'TABLESPACE "TestTableSpace"'),
+ argnames="tablespace, expected_sql",
+ )
+ def test_table_tablespace(self, tablespace, expected_sql):
+ m = MetaData()
+
+ t = Table(
+ "table1",
+ m,
+ Column("x", Integer),
+ oracle_tablespace=tablespace,
+ )
+ self.assert_compile(
+ schema.CreateTable(t),
+ f"CREATE TABLE table1 (x INTEGER) {expected_sql}",
+ )
+
class SequenceTest(fixtures.TestBase, AssertsCompiledSQL):
def test_basic(self):
def test_limit_offset_for_update(self, metadata, connection):
# oracle can't actually do the ROWNUM thing with FOR UPDATE
# very well.
+ # Seems to be fixed in 23.
t = Table(
"t1",
# as of #8221, this fails also. limit w/o order by is useless
# in any case.
stmt = t.select().with_for_update().limit(2)
- if testing.against("oracle>=12"):
+ if testing.against("oracle>=12") and testing.against("oracle<23"):
with expect_raises_message(exc.DatabaseError, "ORA-02014"):
connection.execute(stmt).fetchall()
else:
finally:
conn.exec_driver_sql("DROP TABLE my_table")
+ def test_tablespace(self, connection, metadata):
+ tbl = Table(
+ "test_tablespace",
+ metadata,
+ Column("data", Integer),
+ oracle_tablespace="temp",
+ )
+ metadata.create_all(connection)
+
+ m2 = MetaData()
+
+ tbl = Table("test_tablespace", m2, autoload_with=connection)
+ assert tbl.dialect_options["oracle"]["tablespace"] == "TEMP"
+
class ViewReflectionTest(fixtures.TestBase):
__only_on__ = "oracle"
(schema, "parent"): [],
}
self.options[schema] = {
- (schema, "my_table"): {},
- (schema, "parent"): {},
+ (schema, "my_table"): {"oracle_tablespace": "USERS"},
+ (schema, "parent"): {"oracle_tablespace": "USERS"},
}
def test_tables(self, connection):