"""Illustrates sharding using a single SQLite database, that will howeverhave multiple tables using a naming convention."""importdatetimefromsqlalchemyimportColumnfromsqlalchemyimportcreate_enginefromsqlalchemyimportDateTimefromsqlalchemyimporteventfromsqlalchemyimportFloatfromsqlalchemyimportForeignKeyfromsqlalchemyimportinspectfromsqlalchemyimportIntegerfromsqlalchemyimportselectfromsqlalchemyimportStringfromsqlalchemyimportTablefromsqlalchemy.ext.declarativeimportdeclarative_basefromsqlalchemy.ext.horizontal_shardimportShardedSessionfromsqlalchemy.ormimportrelationshipfromsqlalchemy.ormimportsessionmakerfromsqlalchemy.sqlimportoperatorsfromsqlalchemy.sqlimportvisitorsecho=Trueengine=create_engine("sqlite://",echo=echo)db1=engine.execution_options(table_prefix="north_america")db2=engine.execution_options(table_prefix="asia")db3=engine.execution_options(table_prefix="europe")db4=engine.execution_options(table_prefix="south_america")@event.listens_for(engine,"before_cursor_execute",retval=True)defbefore_cursor_execute(conn,cursor,statement,parameters,context,executemany):table_prefix=context.execution_options.get("table_prefix",None)iftable_prefix:statement=statement.replace("_prefix_",table_prefix)returnstatement,parameters# create session function. this binds the shard ids# to databases within a ShardedSession and returns it.Session=sessionmaker(class_=ShardedSession,future=True,shards={"north_america":db1,"asia":db2,"europe":db3,"south_america":db4,},)# mappings and tablesBase=declarative_base()# we need a way to create identifiers which are unique across all databases.# one easy way would be to just use a composite primary key, where one value# is the shard id. but here, we'll show something more "generic", an id# generation function. we'll use a simplistic "id table" stored in database# #1. Any other method will do just as well; UUID, hilo, application-specific,# etc.ids=Table("ids",Base.metadata,Column("nextid",Integer,nullable=False))defid_generator(ctx):# in reality, might want to use a separate transaction for this.withengine.begin()asconn:nextid=conn.scalar(ids.select().with_for_update())conn.execute(ids.update().values({ids.c.nextid:ids.c.nextid+1}))returnnextid# table setup. we'll store a lead table of continents/cities, and a secondary# table storing locations. a particular row will be placed in the database# whose shard id corresponds to the 'continent'. in this setup, secondary rows# in 'weather_reports' will be placed in the same DB as that of the parent, but# this can be changed if you're willing to write more complex sharding# functions.classWeatherLocation(Base):__tablename__="_prefix__weather_locations"id=Column(Integer,primary_key=True,default=id_generator)continent=Column(String(30),nullable=False)city=Column(String(50),nullable=False)reports=relationship("Report",backref="location")def__init__(self,continent,city):self.continent=continentself.city=cityclassReport(Base):__tablename__="_prefix__weather_reports"id=Column(Integer,primary_key=True)location_id=Column("location_id",Integer,ForeignKey("_prefix__weather_locations.id"))temperature=Column("temperature",Float)report_time=Column("report_time",DateTime,default=datetime.datetime.now)def__init__(self,temperature):self.temperature=temperature# create tablesfordbin(db1,db2,db3,db4):Base.metadata.create_all(db)# establish initial "id" in db1withdb1.begin()asconn:conn.execute(ids.insert(),{"nextid":1})# step 5. define sharding functions.# we'll use a straight mapping of a particular set of "country"# attributes to shard id.shard_lookup={"North America":"north_america","Asia":"asia","Europe":"europe","South America":"south_america",}defshard_chooser(mapper,instance,clause=None):"""shard chooser. looks at the given instance and returns a shard id note that we need to define conditions for the WeatherLocation class, as well as our secondary Report class which will point back to its WeatherLocation via its 'location' attribute. """ifisinstance(instance,WeatherLocation):returnshard_lookup[instance.continent]else:returnshard_chooser(mapper,instance.location)defid_chooser(query,ident):"""id chooser. given a primary key, returns a list of shards to search. here, we don't have any particular information from a pk so we just return all shard ids. often, you'd want to do some kind of round-robin strategy here so that requests are evenly distributed among DBs. """ifquery.lazy_loaded_from:# if we are in a lazy load, we can look at the parent object# and limit our search to that same shard, assuming that's how we've# set things up.return[query.lazy_loaded_from.identity_token]else:return["north_america","asia","europe","south_america"]defexecute_chooser(context):"""statement execution chooser. this also returns a list of shard ids, which can just be all of them. but here we'll search into the execution context in order to try to narrow down the list of shards to SELECT. """ids=[]# we'll grab continent names as we find them# and convert to shard idsforcolumn,operator,valuein_get_select_comparisons(context.statement):# "shares_lineage()" returns True if both columns refer to the same# statement column, adjusting for any annotations present.# (an annotation is an internal clone of a Column object# and occur when using ORM-mapped attributes like# "WeatherLocation.continent"). A simpler comparison, though less# accurate, would be "column.key == 'continent'".ifcolumn.shares_lineage(WeatherLocation.__table__.c.continent):ifoperator==operators.eq:ids.append(shard_lookup[value])elifoperator==operators.in_op:ids.extend(shard_lookup[v]forvinvalue)iflen(ids)==0:return["north_america","asia","europe","south_america"]else:returnidsdef_get_select_comparisons(statement):"""Search a Select or Query object for binary expressions. Returns expressions which match a Column against one or more literal values as a list of tuples of the form (column, operator, values). "values" is a single value or tuple of values depending on the operator. """binds={}clauses=set()comparisons=[]defvisit_bindparam(bind):# visit a bind parameter.value=bind.effective_valuebinds[bind]=valuedefvisit_column(column):clauses.add(column)defvisit_binary(binary):ifbinary.leftinclausesandbinary.rightinbinds:comparisons.append((binary.left,binary.operator,binds[binary.right]))elifbinary.leftinbindsandbinary.rightinclauses:comparisons.append((binary.right,binary.operator,binds[binary.left]))# here we will traverse through the query's criterion, searching# for SQL constructs. We will place simple column comparisons# into a list.ifstatement.whereclauseisnotNone:visitors.traverse(statement.whereclause,{},{"bindparam":visit_bindparam,"binary":visit_binary,"column":visit_column,},)returncomparisons# further configure create_session to use these functionsSession.configure(shard_chooser=shard_chooser,id_chooser=id_chooser,execute_chooser=execute_chooser,)# save and load objects!tokyo=WeatherLocation("Asia","Tokyo")newyork=WeatherLocation("North America","New York")toronto=WeatherLocation("North America","Toronto")london=WeatherLocation("Europe","London")dublin=WeatherLocation("Europe","Dublin")brasilia=WeatherLocation("South America","Brasila")quito=WeatherLocation("South America","Quito")tokyo.reports.append(Report(80.0))newyork.reports.append(Report(75))quito.reports.append(Report(85))withSession()assess:sess.add_all([tokyo,newyork,toronto,london,dublin,brasilia,quito])sess.commit()t=sess.get(WeatherLocation,tokyo.id)assertt.city==tokyo.cityassertt.reports[0].temperature==80.0north_american_cities=sess.execute(select(WeatherLocation).filter(WeatherLocation.continent=="North America")).scalars()assert{c.cityforcinnorth_american_cities}=={"New York","Toronto"}asia_and_europe=sess.execute(select(WeatherLocation).filter(WeatherLocation.continent.in_(["Europe","Asia"]))).scalars()assert{c.cityforcinasia_and_europe}=={"Tokyo","London","Dublin"}# the Report class uses a simple integer primary key. So across two# databases, a primary key will be repeated. The "identity_token" tracks# in memory that these two identical primary keys are local to different# databases.newyork_report=newyork.reports[0]tokyo_report=tokyo.reports[0]assertinspect(newyork_report).identity_key==(Report,(1,),"north_america",)assertinspect(tokyo_report).identity_key==(Report,(1,),"asia")# the token representing the originating shard is also available directlyassertinspect(newyork_report).identity_token=="north_america"assertinspect(tokyo_report).identity_token=="asia"