2
0

operations.py 24 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137138139140141142143144145146147148149150151152153154155156157158159160161162163164165166167168169170171172173174175176177178179180181182183184185186187188189190191192193194195196197198199200201202203204205206207208209210211212213214215216217218219220221222223224225226227228229230231232233234235236237238239240241242243244245246247248249250251252253254255256257258259260261262263264265266267268269270271272273274275276277278279280281282283284285286287288289290291292293294295296297298299300301302303304305306307308309310311312313314315316317318319320321322323324325326327328329330331332333334335336337338339340341342343344345346347348349350351352353354355356357358359360361362363364365366367368369370371372373374375376377378379380381382383384385386387388389390391392393394395396397398399400401402403404405406407408409410411412413414415416417418419420421422423424425426427428429430431432433434435436437438439440441442443444445446447448449450451452453454455456457458459460461462463464465466467468469470471472473474475476477478479480481482483484485486487488489490491492493494495496497498499500501502503504505506507508509510511512513514515516517518519520521522523524525526527528529530531532533534535536537538539540541542543544545546547548549550551552553554555556557558559560561562563564565566567568569570571572573574575
  1. import datetime
  2. import re
  3. import uuid
  4. from django.conf import settings
  5. from django.db.backends.base.operations import BaseDatabaseOperations
  6. from django.db.backends.utils import strip_quotes, truncate_name
  7. from django.db.utils import DatabaseError
  8. from django.utils import timezone
  9. from django.utils.encoding import force_bytes
  10. from .base import Database
  11. from .utils import BulkInsertMapper, InsertIdVar, Oracle_datetime
  12. class DatabaseOperations(BaseDatabaseOperations):
  13. # Oracle uses NUMBER(11) and NUMBER(19) for integer fields.
  14. integer_field_ranges = {
  15. 'SmallIntegerField': (-99999999999, 99999999999),
  16. 'IntegerField': (-99999999999, 99999999999),
  17. 'BigIntegerField': (-9999999999999999999, 9999999999999999999),
  18. 'PositiveSmallIntegerField': (0, 99999999999),
  19. 'PositiveIntegerField': (0, 99999999999),
  20. }
  21. set_operators = {**BaseDatabaseOperations.set_operators, 'difference': 'MINUS'}
  22. # TODO: colorize this SQL code with style.SQL_KEYWORD(), etc.
  23. _sequence_reset_sql = """
  24. DECLARE
  25. table_value integer;
  26. seq_value integer;
  27. seq_name user_tab_identity_cols.sequence_name%%TYPE;
  28. BEGIN
  29. BEGIN
  30. SELECT sequence_name INTO seq_name FROM user_tab_identity_cols
  31. WHERE table_name = '%(table_name)s' AND
  32. column_name = '%(column_name)s';
  33. EXCEPTION WHEN NO_DATA_FOUND THEN
  34. seq_name := '%(no_autofield_sequence_name)s';
  35. END;
  36. SELECT NVL(MAX(%(column)s), 0) INTO table_value FROM %(table)s;
  37. SELECT NVL(last_number - cache_size, 0) INTO seq_value FROM user_sequences
  38. WHERE sequence_name = seq_name;
  39. WHILE table_value > seq_value LOOP
  40. EXECUTE IMMEDIATE 'SELECT "'||seq_name||'".nextval FROM DUAL'
  41. INTO seq_value;
  42. END LOOP;
  43. END;
  44. /"""
  45. # Oracle doesn't support string without precision; use the max string size.
  46. cast_char_field_without_max_length = 'NVARCHAR2(2000)'
  47. def cache_key_culling_sql(self):
  48. return """
  49. SELECT cache_key
  50. FROM (SELECT cache_key, rank() OVER (ORDER BY cache_key) AS rank FROM %s)
  51. WHERE rank = %%s + 1
  52. """
  53. def date_extract_sql(self, lookup_type, field_name):
  54. if lookup_type == 'week_day':
  55. # TO_CHAR(field, 'D') returns an integer from 1-7, where 1=Sunday.
  56. return "TO_CHAR(%s, 'D')" % field_name
  57. elif lookup_type == 'week':
  58. # IW = ISO week number
  59. return "TO_CHAR(%s, 'IW')" % field_name
  60. elif lookup_type == 'quarter':
  61. return "TO_CHAR(%s, 'Q')" % field_name
  62. else:
  63. # https://docs.oracle.com/database/121/SQLRF/functions067.htm#SQLRF00639
  64. return "EXTRACT(%s FROM %s)" % (lookup_type.upper(), field_name)
  65. def date_trunc_sql(self, lookup_type, field_name):
  66. # https://docs.oracle.com/database/121/SQLRF/functions271.htm#SQLRF52058
  67. if lookup_type in ('year', 'month'):
  68. return "TRUNC(%s, '%s')" % (field_name, lookup_type.upper())
  69. elif lookup_type == 'quarter':
  70. return "TRUNC(%s, 'Q')" % field_name
  71. elif lookup_type == 'week':
  72. return "TRUNC(%s, 'IW')" % field_name
  73. else:
  74. return "TRUNC(%s)" % field_name
  75. # Oracle crashes with "ORA-03113: end-of-file on communication channel"
  76. # if the time zone name is passed in parameter. Use interpolation instead.
  77. # https://groups.google.com/forum/#!msg/django-developers/zwQju7hbG78/9l934yelwfsJ
  78. # This regexp matches all time zone names from the zoneinfo database.
  79. _tzname_re = re.compile(r'^[\w/:+-]+$')
  80. def _convert_field_to_tz(self, field_name, tzname):
  81. if not settings.USE_TZ:
  82. return field_name
  83. if not self._tzname_re.match(tzname):
  84. raise ValueError("Invalid time zone name: %s" % tzname)
  85. # Convert from UTC to local time, returning TIMESTAMP WITH TIME ZONE
  86. # and cast it back to TIMESTAMP to strip the TIME ZONE details.
  87. return "CAST((FROM_TZ(%s, '0:00') AT TIME ZONE '%s') AS TIMESTAMP)" % (field_name, tzname)
  88. def datetime_cast_date_sql(self, field_name, tzname):
  89. field_name = self._convert_field_to_tz(field_name, tzname)
  90. return 'TRUNC(%s)' % field_name
  91. def datetime_cast_time_sql(self, field_name, tzname):
  92. # Since `TimeField` values are stored as TIMESTAMP where only the date
  93. # part is ignored, convert the field to the specified timezone.
  94. return self._convert_field_to_tz(field_name, tzname)
  95. def datetime_extract_sql(self, lookup_type, field_name, tzname):
  96. field_name = self._convert_field_to_tz(field_name, tzname)
  97. return self.date_extract_sql(lookup_type, field_name)
  98. def datetime_trunc_sql(self, lookup_type, field_name, tzname):
  99. field_name = self._convert_field_to_tz(field_name, tzname)
  100. # https://docs.oracle.com/database/121/SQLRF/functions271.htm#SQLRF52058
  101. if lookup_type in ('year', 'month'):
  102. sql = "TRUNC(%s, '%s')" % (field_name, lookup_type.upper())
  103. elif lookup_type == 'quarter':
  104. sql = "TRUNC(%s, 'Q')" % field_name
  105. elif lookup_type == 'week':
  106. sql = "TRUNC(%s, 'IW')" % field_name
  107. elif lookup_type == 'day':
  108. sql = "TRUNC(%s)" % field_name
  109. elif lookup_type == 'hour':
  110. sql = "TRUNC(%s, 'HH24')" % field_name
  111. elif lookup_type == 'minute':
  112. sql = "TRUNC(%s, 'MI')" % field_name
  113. else:
  114. sql = "CAST(%s AS DATE)" % field_name # Cast to DATE removes sub-second precision.
  115. return sql
  116. def time_trunc_sql(self, lookup_type, field_name):
  117. # The implementation is similar to `datetime_trunc_sql` as both
  118. # `DateTimeField` and `TimeField` are stored as TIMESTAMP where
  119. # the date part of the later is ignored.
  120. if lookup_type == 'hour':
  121. sql = "TRUNC(%s, 'HH24')" % field_name
  122. elif lookup_type == 'minute':
  123. sql = "TRUNC(%s, 'MI')" % field_name
  124. elif lookup_type == 'second':
  125. sql = "CAST(%s AS DATE)" % field_name # Cast to DATE removes sub-second precision.
  126. return sql
  127. def get_db_converters(self, expression):
  128. converters = super().get_db_converters(expression)
  129. internal_type = expression.output_field.get_internal_type()
  130. if internal_type == 'TextField':
  131. converters.append(self.convert_textfield_value)
  132. elif internal_type == 'BinaryField':
  133. converters.append(self.convert_binaryfield_value)
  134. elif internal_type in ['BooleanField', 'NullBooleanField']:
  135. converters.append(self.convert_booleanfield_value)
  136. elif internal_type == 'DateTimeField':
  137. if settings.USE_TZ:
  138. converters.append(self.convert_datetimefield_value)
  139. elif internal_type == 'DateField':
  140. converters.append(self.convert_datefield_value)
  141. elif internal_type == 'TimeField':
  142. converters.append(self.convert_timefield_value)
  143. elif internal_type == 'UUIDField':
  144. converters.append(self.convert_uuidfield_value)
  145. # Oracle stores empty strings as null. If the field accepts the empty
  146. # string, undo this to adhere to the Django convention of using
  147. # the empty string instead of null.
  148. if expression.field.empty_strings_allowed:
  149. converters.append(
  150. self.convert_empty_bytes
  151. if internal_type == 'BinaryField' else
  152. self.convert_empty_string
  153. )
  154. return converters
  155. def convert_textfield_value(self, value, expression, connection):
  156. if isinstance(value, Database.LOB):
  157. value = value.read()
  158. return value
  159. def convert_binaryfield_value(self, value, expression, connection):
  160. if isinstance(value, Database.LOB):
  161. value = force_bytes(value.read())
  162. return value
  163. def convert_booleanfield_value(self, value, expression, connection):
  164. if value in (0, 1):
  165. value = bool(value)
  166. return value
  167. # cx_Oracle always returns datetime.datetime objects for
  168. # DATE and TIMESTAMP columns, but Django wants to see a
  169. # python datetime.date, .time, or .datetime.
  170. def convert_datetimefield_value(self, value, expression, connection):
  171. if value is not None:
  172. value = timezone.make_aware(value, self.connection.timezone)
  173. return value
  174. def convert_datefield_value(self, value, expression, connection):
  175. if isinstance(value, Database.Timestamp):
  176. value = value.date()
  177. return value
  178. def convert_timefield_value(self, value, expression, connection):
  179. if isinstance(value, Database.Timestamp):
  180. value = value.time()
  181. return value
  182. def convert_uuidfield_value(self, value, expression, connection):
  183. if value is not None:
  184. value = uuid.UUID(value)
  185. return value
  186. @staticmethod
  187. def convert_empty_string(value, expression, connection):
  188. return '' if value is None else value
  189. @staticmethod
  190. def convert_empty_bytes(value, expression, connection):
  191. return b'' if value is None else value
  192. def deferrable_sql(self):
  193. return " DEFERRABLE INITIALLY DEFERRED"
  194. def fetch_returned_insert_id(self, cursor):
  195. try:
  196. return int(cursor._insert_id_var.getvalue())
  197. except TypeError:
  198. raise DatabaseError(
  199. 'The database did not return a new row id. Probably "ORA-1403: '
  200. 'no data found" was raised internally but was hidden by the '
  201. 'Oracle OCI library (see https://code.djangoproject.com/ticket/28859).'
  202. )
  203. def field_cast_sql(self, db_type, internal_type):
  204. if db_type and db_type.endswith('LOB'):
  205. return "DBMS_LOB.SUBSTR(%s)"
  206. else:
  207. return "%s"
  208. def no_limit_value(self):
  209. return None
  210. def limit_offset_sql(self, low_mark, high_mark):
  211. fetch, offset = self._get_limit_offset_params(low_mark, high_mark)
  212. return '%s%s' % (
  213. (' OFFSET %d ROWS' % offset) if offset else '',
  214. (' FETCH FIRST %d ROWS ONLY' % fetch) if fetch else '',
  215. )
  216. def last_executed_query(self, cursor, sql, params):
  217. # https://cx-oracle.readthedocs.io/en/latest/cursor.html#Cursor.statement
  218. # The DB API definition does not define this attribute.
  219. statement = cursor.statement
  220. # Unlike Psycopg's `query` and MySQLdb`'s `_last_executed`, CxOracle's
  221. # `statement` doesn't contain the query parameters. refs #20010.
  222. return super().last_executed_query(cursor, statement, params)
  223. def last_insert_id(self, cursor, table_name, pk_name):
  224. sq_name = self._get_sequence_name(cursor, strip_quotes(table_name), pk_name)
  225. cursor.execute('"%s".currval' % sq_name)
  226. return cursor.fetchone()[0]
  227. def lookup_cast(self, lookup_type, internal_type=None):
  228. if lookup_type in ('iexact', 'icontains', 'istartswith', 'iendswith'):
  229. return "UPPER(%s)"
  230. return "%s"
  231. def max_in_list_size(self):
  232. return 1000
  233. def max_name_length(self):
  234. return 30
  235. def pk_default_value(self):
  236. return "NULL"
  237. def prep_for_iexact_query(self, x):
  238. return x
  239. def process_clob(self, value):
  240. if value is None:
  241. return ''
  242. return value.read()
  243. def quote_name(self, name):
  244. # SQL92 requires delimited (quoted) names to be case-sensitive. When
  245. # not quoted, Oracle has case-insensitive behavior for identifiers, but
  246. # always defaults to uppercase.
  247. # We simplify things by making Oracle identifiers always uppercase.
  248. if not name.startswith('"') and not name.endswith('"'):
  249. name = '"%s"' % truncate_name(name.upper(), self.max_name_length())
  250. # Oracle puts the query text into a (query % args) construct, so % signs
  251. # in names need to be escaped. The '%%' will be collapsed back to '%' at
  252. # that stage so we aren't really making the name longer here.
  253. name = name.replace('%', '%%')
  254. return name.upper()
  255. def random_function_sql(self):
  256. return "DBMS_RANDOM.RANDOM"
  257. def regex_lookup(self, lookup_type):
  258. if lookup_type == 'regex':
  259. match_option = "'c'"
  260. else:
  261. match_option = "'i'"
  262. return 'REGEXP_LIKE(%%s, %%s, %s)' % match_option
  263. def return_insert_id(self):
  264. return "RETURNING %s INTO %%s", (InsertIdVar(),)
  265. def savepoint_create_sql(self, sid):
  266. return "SAVEPOINT " + self.quote_name(sid)
  267. def savepoint_rollback_sql(self, sid):
  268. return "ROLLBACK TO SAVEPOINT " + self.quote_name(sid)
  269. def _foreign_key_constraints(self, table_name, recursive=False):
  270. with self.connection.cursor() as cursor:
  271. if recursive:
  272. cursor.execute("""
  273. SELECT
  274. user_tables.table_name, rcons.constraint_name
  275. FROM
  276. user_tables
  277. JOIN
  278. user_constraints cons
  279. ON (user_tables.table_name = cons.table_name AND cons.constraint_type = ANY('P', 'U'))
  280. LEFT JOIN
  281. user_constraints rcons
  282. ON (user_tables.table_name = rcons.table_name AND rcons.constraint_type = 'R')
  283. START WITH user_tables.table_name = UPPER(%s)
  284. CONNECT BY NOCYCLE PRIOR cons.constraint_name = rcons.r_constraint_name
  285. GROUP BY
  286. user_tables.table_name, rcons.constraint_name
  287. HAVING user_tables.table_name != UPPER(%s)
  288. ORDER BY MAX(level) DESC
  289. """, (table_name, table_name))
  290. else:
  291. cursor.execute("""
  292. SELECT
  293. cons.table_name, cons.constraint_name
  294. FROM
  295. user_constraints cons
  296. WHERE
  297. cons.constraint_type = 'R'
  298. AND cons.table_name = UPPER(%s)
  299. """, (table_name,))
  300. return cursor.fetchall()
  301. def sql_flush(self, style, tables, sequences, allow_cascade=False):
  302. if tables:
  303. truncated_tables = {table.upper() for table in tables}
  304. constraints = set()
  305. # Oracle's TRUNCATE CASCADE only works with ON DELETE CASCADE
  306. # foreign keys which Django doesn't define. Emulate the
  307. # PostgreSQL behavior which truncates all dependent tables by
  308. # manually retrieving all foreign key constraints and resolving
  309. # dependencies.
  310. for table in tables:
  311. for foreign_table, constraint in self._foreign_key_constraints(table, recursive=allow_cascade):
  312. if allow_cascade:
  313. truncated_tables.add(foreign_table)
  314. constraints.add((foreign_table, constraint))
  315. sql = [
  316. "%s %s %s %s %s %s %s %s;" % (
  317. style.SQL_KEYWORD('ALTER'),
  318. style.SQL_KEYWORD('TABLE'),
  319. style.SQL_FIELD(self.quote_name(table)),
  320. style.SQL_KEYWORD('DISABLE'),
  321. style.SQL_KEYWORD('CONSTRAINT'),
  322. style.SQL_FIELD(self.quote_name(constraint)),
  323. style.SQL_KEYWORD('KEEP'),
  324. style.SQL_KEYWORD('INDEX'),
  325. ) for table, constraint in constraints
  326. ] + [
  327. "%s %s %s;" % (
  328. style.SQL_KEYWORD('TRUNCATE'),
  329. style.SQL_KEYWORD('TABLE'),
  330. style.SQL_FIELD(self.quote_name(table)),
  331. ) for table in truncated_tables
  332. ] + [
  333. "%s %s %s %s %s %s;" % (
  334. style.SQL_KEYWORD('ALTER'),
  335. style.SQL_KEYWORD('TABLE'),
  336. style.SQL_FIELD(self.quote_name(table)),
  337. style.SQL_KEYWORD('ENABLE'),
  338. style.SQL_KEYWORD('CONSTRAINT'),
  339. style.SQL_FIELD(self.quote_name(constraint)),
  340. ) for table, constraint in constraints
  341. ]
  342. # Since we've just deleted all the rows, running our sequence
  343. # ALTER code will reset the sequence to 0.
  344. sql.extend(self.sequence_reset_by_name_sql(style, sequences))
  345. return sql
  346. else:
  347. return []
  348. def sequence_reset_by_name_sql(self, style, sequences):
  349. sql = []
  350. for sequence_info in sequences:
  351. no_autofield_sequence_name = self._get_no_autofield_sequence_name(sequence_info['table'])
  352. table = self.quote_name(sequence_info['table'])
  353. column = self.quote_name(sequence_info['column'] or 'id')
  354. query = self._sequence_reset_sql % {
  355. 'no_autofield_sequence_name': no_autofield_sequence_name,
  356. 'table': table,
  357. 'column': column,
  358. 'table_name': strip_quotes(table),
  359. 'column_name': strip_quotes(column),
  360. }
  361. sql.append(query)
  362. return sql
  363. def sequence_reset_sql(self, style, model_list):
  364. from django.db import models
  365. output = []
  366. query = self._sequence_reset_sql
  367. for model in model_list:
  368. for f in model._meta.local_fields:
  369. if isinstance(f, models.AutoField):
  370. no_autofield_sequence_name = self._get_no_autofield_sequence_name(model._meta.db_table)
  371. table = self.quote_name(model._meta.db_table)
  372. column = self.quote_name(f.column)
  373. output.append(query % {
  374. 'no_autofield_sequence_name': no_autofield_sequence_name,
  375. 'table': table,
  376. 'column': column,
  377. 'table_name': strip_quotes(table),
  378. 'column_name': strip_quotes(column),
  379. })
  380. # Only one AutoField is allowed per model, so don't
  381. # continue to loop
  382. break
  383. for f in model._meta.many_to_many:
  384. if not f.remote_field.through:
  385. no_autofield_sequence_name = self._get_no_autofield_sequence_name(f.m2m_db_table())
  386. table = self.quote_name(f.m2m_db_table())
  387. column = self.quote_name('id')
  388. output.append(query % {
  389. 'no_autofield_sequence_name': no_autofield_sequence_name,
  390. 'table': table,
  391. 'column': column,
  392. 'table_name': strip_quotes(table),
  393. 'column_name': 'ID',
  394. })
  395. return output
  396. def start_transaction_sql(self):
  397. return ''
  398. def tablespace_sql(self, tablespace, inline=False):
  399. if inline:
  400. return "USING INDEX TABLESPACE %s" % self.quote_name(tablespace)
  401. else:
  402. return "TABLESPACE %s" % self.quote_name(tablespace)
  403. def adapt_datefield_value(self, value):
  404. """
  405. Transform a date value to an object compatible with what is expected
  406. by the backend driver for date columns.
  407. The default implementation transforms the date to text, but that is not
  408. necessary for Oracle.
  409. """
  410. return value
  411. def adapt_datetimefield_value(self, value):
  412. """
  413. Transform a datetime value to an object compatible with what is expected
  414. by the backend driver for datetime columns.
  415. If naive datetime is passed assumes that is in UTC. Normally Django
  416. models.DateTimeField makes sure that if USE_TZ is True passed datetime
  417. is timezone aware.
  418. """
  419. if value is None:
  420. return None
  421. # Expression values are adapted by the database.
  422. if hasattr(value, 'resolve_expression'):
  423. return value
  424. # cx_Oracle doesn't support tz-aware datetimes
  425. if timezone.is_aware(value):
  426. if settings.USE_TZ:
  427. value = timezone.make_naive(value, self.connection.timezone)
  428. else:
  429. raise ValueError("Oracle backend does not support timezone-aware datetimes when USE_TZ is False.")
  430. return Oracle_datetime.from_datetime(value)
  431. def adapt_timefield_value(self, value):
  432. if value is None:
  433. return None
  434. # Expression values are adapted by the database.
  435. if hasattr(value, 'resolve_expression'):
  436. return value
  437. if isinstance(value, str):
  438. return datetime.datetime.strptime(value, '%H:%M:%S')
  439. # Oracle doesn't support tz-aware times
  440. if timezone.is_aware(value):
  441. raise ValueError("Oracle backend does not support timezone-aware times.")
  442. return Oracle_datetime(1900, 1, 1, value.hour, value.minute,
  443. value.second, value.microsecond)
  444. def combine_expression(self, connector, sub_expressions):
  445. lhs, rhs = sub_expressions
  446. if connector == '%%':
  447. return 'MOD(%s)' % ','.join(sub_expressions)
  448. elif connector == '&':
  449. return 'BITAND(%s)' % ','.join(sub_expressions)
  450. elif connector == '|':
  451. return 'BITAND(-%(lhs)s-1,%(rhs)s)+%(lhs)s' % {'lhs': lhs, 'rhs': rhs}
  452. elif connector == '<<':
  453. return '(%(lhs)s * POWER(2, %(rhs)s))' % {'lhs': lhs, 'rhs': rhs}
  454. elif connector == '>>':
  455. return 'FLOOR(%(lhs)s / POWER(2, %(rhs)s))' % {'lhs': lhs, 'rhs': rhs}
  456. elif connector == '^':
  457. return 'POWER(%s)' % ','.join(sub_expressions)
  458. return super().combine_expression(connector, sub_expressions)
  459. def _get_no_autofield_sequence_name(self, table):
  460. """
  461. Manually created sequence name to keep backward compatibility for
  462. AutoFields that aren't Oracle identity columns.
  463. """
  464. name_length = self.max_name_length() - 3
  465. return '%s_SQ' % truncate_name(strip_quotes(table), name_length).upper()
  466. def _get_sequence_name(self, cursor, table, pk_name):
  467. cursor.execute("""
  468. SELECT sequence_name
  469. FROM user_tab_identity_cols
  470. WHERE table_name = UPPER(%s)
  471. AND column_name = UPPER(%s)""", [table, pk_name])
  472. row = cursor.fetchone()
  473. return self._get_no_autofield_sequence_name(table) if row is None else row[0]
  474. def bulk_insert_sql(self, fields, placeholder_rows):
  475. query = []
  476. for row in placeholder_rows:
  477. select = []
  478. for i, placeholder in enumerate(row):
  479. # A model without any fields has fields=[None].
  480. if fields[i]:
  481. internal_type = getattr(fields[i], 'target_field', fields[i]).get_internal_type()
  482. placeholder = BulkInsertMapper.types.get(internal_type, '%s') % placeholder
  483. # Add columns aliases to the first select to avoid "ORA-00918:
  484. # column ambiguously defined" when two or more columns in the
  485. # first select have the same value.
  486. if not query:
  487. placeholder = '%s col_%s' % (placeholder, i)
  488. select.append(placeholder)
  489. query.append('SELECT %s FROM DUAL' % ', '.join(select))
  490. # Bulk insert to tables with Oracle identity columns causes Oracle to
  491. # add sequence.nextval to it. Sequence.nextval cannot be used with the
  492. # UNION operator. To prevent incorrect SQL, move UNION to a subquery.
  493. return 'SELECT * FROM (%s)' % ' UNION ALL '.join(query)
  494. def subtract_temporals(self, internal_type, lhs, rhs):
  495. if internal_type == 'DateField':
  496. lhs_sql, lhs_params = lhs
  497. rhs_sql, rhs_params = rhs
  498. return "NUMTODSINTERVAL(%s - %s, 'DAY')" % (lhs_sql, rhs_sql), lhs_params + rhs_params
  499. return super().subtract_temporals(internal_type, lhs, rhs)
  500. def bulk_batch_size(self, fields, objs):
  501. """Oracle restricts the number of parameters in a query."""
  502. if fields:
  503. return self.connection.features.max_query_params // len(fields)
  504. return len(objs)