select nextval('mysql') FROM generate_series(1,...)
sa.Column(
'trip_num',
sa.Integer,
sa.Sequence('trip_num_seq', schema='public', optional=True),
primary_key=True,
)
shared_sequence = Sequence('shared_id__seq')
class ModelA(Base):
shared_id = Column(Integer,
primary_key=True,
default=shared_sequence.next_value(),
server_default=shared_sequence.next_value())
class ModelB(Base):
shared_id = Column(Integer,
primary_key=True,
default=shared_sequence.next_value(),
server_default=shared_sequence.next_value())
--
SQLAlchemy -
The Python SQL Toolkit and Object Relational Mapper
http://www.sqlalchemy.org/
To post example code, please provide an MCVE: Minimal, Complete, and Verifiable Example. See http://stackoverflow.com/help/mcve for a full description.
---
You received this message because you are subscribed to the Google Groups "sqlalchemy" group.
To unsubscribe from this group and stop receiving emails from it, send an email to sqlalchemy+...@googlegroups.com.
To view this discussion on the web visit https://groups.google.com/d/msgid/sqlalchemy/7860f5ab-64a4-481d-8e72-9b40d2ab2527o%40googlegroups.com.
Michael Mulqueen
Method B Ltd
mi...@method-b.uk / +44 (0)330 223 0864
http://www.method-b.uk/
Method
B Limited is registered in England and Wales with the company number
9189496. Registered office: 28-29 Richmond Place, Brighton, East Sussex, England, BN2 9NA
Hi,I've split a table into two tables, for performance reasons. I'd like to insert into both tables using the same sequence. I'm inserting using executemany_mode='values'.My idea is to call nextval() on the sequence before insert and fill in the values client side, before inserting.select nextval('mysql') FROM generate_series(1,...)Everything looks good, except for the default behaviour of SQLAlchemy to turn an integer + pk column into a SERIAL.
As an alternative I'm also looking at using Sequence('myseq') from https://docs.sqlalchemy.org/en/13/dialects/postgresql.html#sequences-serial-identity, but this is broken for issuing "CREATE SEQUENCE myseq" before the table creation, which is missing the IF NOT EXISTS part.
How can I either:- turn off the automatic behaviour of making a pg + int = serial?- add a IF NOT EXISTS to the Sequence()?Or any alternative ideas?
I'm lost in two places:sa.Column(
'trip_num',
sa.Integer,
sa.Sequence('trip_num_seq', schema='public', optional=True),
primary_key=True,
)1. I'm specifying schema='public', yet the sequence gets created under Metadata's schema.
2. I'm trying this optional=True, however all it does is make the Integer back into the Serial, which I'm trying to avoid.On Wednesday, 5 August 2020 14:59:03 UTC+2, Zsolt Ero wrote:Hi,I've split a table into two tables, for performance reasons. I'd like to insert into both tables using the same sequence. I'm inserting using executemany_mode='values'.My idea is to call nextval() on the sequence before insert and fill in the values client side, before inserting.select nextval('mysql') FROM generate_series(1,...)Everything looks good, except for the default behaviour of SQLAlchemy to turn an integer + pk column into a SERIAL.As an alternative I'm also looking at using Sequence('myseq') from https://docs.sqlalchemy.org/en/13/dialects/postgresql.html#sequences-serial-identity, but this is broken for issuing "CREATE SEQUENCE myseq" before the table creation, which is missing the IF NOT EXISTS part.How can I either:- turn off the automatic behaviour of making a pg + int = serial?- add a IF NOT EXISTS to the Sequence()?Or any alternative ideas?
--SQLAlchemy -The Python SQL Toolkit and Object Relational MapperTo post example code, please provide an MCVE: Minimal, Complete, and Verifiable Example. See http://stackoverflow.com/help/mcve for a full description.---You received this message because you are subscribed to the Google Groups "sqlalchemy" group.To unsubscribe from this group and stop receiving emails from it, send an email to sqlalchemy+...@googlegroups.com.
To view this discussion on the web visit https://groups.google.com/d/msgid/sqlalchemy/925b2783-cbf3-491f-b4ab-1bda26eae181o%40googlegroups.com.
But this would create a different id for each table, wouldn't it?
To view this discussion on the web visit https://groups.google.com/d/msgid/sqlalchemy/CAKw-smCTjWL_1qeAKRcZp7ex_ecmgpd_iXx2MEUhGDnei9%2B8MA%40mail.gmail.com.
Thanks for all the answers.> add autoincrement=False to the ColumnThis is actually all I needed, but possibly my findings can help others or provide improvements.I'm not using drop_alll and create_all, but table.create() and this results in the "relation "some_seq" already exists" error.99% your snippet, just using create:from sqlalchemy import Column
from sqlalchemy import Integer
from sqlalchemy import MetaData
from sqlalchemy import Sequence
from sqlalchemy import Table
m = MetaData()
seq = Sequence("some_seq")
t1 = Table("t1", m, Column("id", Integer, seq, primary_key=True))
t2 = Table("t2", m, Column("id", Integer, seq, primary_key=True))
t1.create(pg_engine)
t2.create(pg_engine)> To render "IF NOT EXISTS" then just invoke the SQL: conn.execute(text("CREATE SEQ IF NOT EXISTS ..."))
So in this example, how could I avoid creating the sequence? I'd be happy to create it once, or not at all, but it seems that table create tries to create the sequence automatically, no matter what.
The schema bug was actually the behaviour of the optional=True. I still don't know what it does, but it behaves like if the whole sequence line wouldn't be present. It just makes the column a SERIAL type and then PostgreSQL auto-creates the sequence in the table's schema, not in public. So with optional=True basically nothing matters, nor the sequence's name, not the sequence's schema?
To view this discussion on the web visit https://groups.google.com/d/msgid/sqlalchemy/ac36c479-cf6f-4f78-9dd6-213fd2268ce2n%40googlegroups.com.
True
, indicates that this Sequence
object only needs to be explicitly generated
on backends that don’t provide another way to generate primary
key identifiers. Currently, it essentially means, “don’t create
this sequence on the PostgreSQL backend, where the SERIAL keyword
creates a sequence for us automatically”.To view this discussion on the web visit https://groups.google.com/d/msgid/sqlalchemy/d83a92e9-c4f2-4659-89df-9a6727f05232%40www.fastmail.com.