diff --git a/docs/design/AZURE_FEDERATIONS.md b/docs/design/AZURE_FEDERATIONS.md new file mode 100644 index 00000000000..99d7e3cfb56 --- /dev/null +++ b/docs/design/AZURE_FEDERATIONS.md @@ -0,0 +1,94 @@ +# Azure Federations + +Implementing Federations inside a new Doctrine Sharding Extension. Some extensions to the DBAL and ORM core have to be done to get this working. + +1. DBAL (Database Abstraction Layer) + +* Add support for Database Schema Operations + * CREATE FEDERATION + * CREATE TABLE ... FEDERATED ON + * Add support to create a multi-tenent schema from any given schema +* Add API to pick a shard based on distribution key and atomic value +* Add API to ask about federations, federation members and so on. +* Add Sharding Abstraction + * If a shard is picked via distribution key and atomic value fire queries against this only + * Or query the global database. + +2. ORM (Object-Relational Mapper) + +* Federation Key has to be part of the clustered index of the table + * Test with a pure Multi-Tenent App with Filtering = ON (TaskList) + * Test with sharded app (Weather) + +## Implementation Details + +SQL Azure requires one and exactly one clustered index. It makes no difference if the primary key +or any other key is the clustered index. Sharding requires an external ID generation (no auto-increment) +such as GUIDs. GUIDs have negative properties with regard to clustered index performance, so that +typically you would add a "created" timestamp for example that holds the clustered index instead +of making the GUID a clustered index. + +## Example API: + + @@@ php + 'tcp:dbname.database.windows.net', + 'sharding' => array( + 'federationName' => 'Orders_Federation', + 'distributionKey' => 'CustID', + 'distributionType' => 'integer', + 'filteringEnabled' => false, + ), + // ... + ); + + $conn = DriverManager::getConnection($dbParams); + $shardManager = $conn->getShardManager(); + + // Example 1: query against root database + $sql = "SELECT * FROM Products"; + $rows = $conn->executeQuery($sql); + + // Example 2: query against the selected shard with CustomerId = 100 + $aCustomerID = 100; + $shardManager->selectShard($aCustomerID); // Using Default federationName and distributionKey + // Query: "USE FEDERATION Orders_Federation (CustID = $aCustomerID) WITH RESET, FILTERING OFF;" + + $sql = "SELECT * FROM Customers"; + $rows = $conn->executeQuery($sql); + + // Example 3: Reset API to root database again + $shardManager->selectGlobal(); + +## ID Generation + +With sharding all the ids have to be generated for global uniqueness. There are three strategies for this. + +1. Use GUIDs as described here http://blogs.msdn.com/b/cbiyikoglu/archive/2011/06/20/id-generation-in-federations-identity-sequences-and-guids-uniqueidentifier.aspx +2. Having a central table that is accessed with a second connection to generate sequential ids +3. Using natural keys from the domain. + +The second approach has the benefit of having numerical primary keys, however also a central failure location. The third strategy can seldom be used, because the domains dont allow this. Identity columns cannot be used at all. + + @@@ php + 'dbname.database.windows.net', + // ... + ); + $conn = DriverManager::getConnection($dbParams); + + $idGenerator = new TableHiLoIdGenerator($conn, 'id_table_name', $multiplicator = 1); + // only once, create this table + $idGenerator->createTable(); + + $nextId = $idGenerator->generateId('for_table_name'); + $nextOtherId = $idGenerator->generateId('for_other_table'); + +The connection for the table generator has to be a different one than the one used for the main app to avoid transaction clashes. diff --git a/docs/design/SHARDING.md b/docs/design/SHARDING.md new file mode 100644 index 00000000000..24e6cef3e4b --- /dev/null +++ b/docs/design/SHARDING.md @@ -0,0 +1,74 @@ +# Doctrine Shards + +Doctrine Extension to support horizontal sharding in the Doctrine ORM. + +## Idea + +Implement sharding inside Doctrine at a level that is as unobtrusive to the developer as possible. + +Problems to tackle: + +1. Where to send INSERT statements? +2. How to generate primary keys? +3. How to pick shards for update, delete statements? +4. How to pick shards for select operations? +5. How to merge select queries that span multiple shards? +6. How to handle/prevent multi-shard queries that cannot be merged (GROUP BY)? +7. How to handle non-sharded data? (static metadata tables for example) +8. How to handle multiple connections? +9. Implementation on the DBAL or ORM level? + +## Roadmap + +Version 1: DBAL 2.3 (Multi-Tenant Apps) + + 1. ID Generation support (in DBAL + ORM done) + 2. Multi-Tenant Support: Either pick a global metadata database or exactly one shard. + 3. Fan-out queries over all shards (or a subset) by result appending + +Version 2: ORM related (complex): + + 4. ID resolving (Pick shard for a new ID) + 5. Query resolving (Pick shards a query should send to) + 6. Shard resolving (Pick shards an ID could be on) + 7. Transactions + 8. Read Only objects + +## Technical Requirements for Database Schemas + +Sharded tables require the sharding-distribution key as one of their columns. This will affect your code compared to a normalized db-schema. If you have a Blog <-> BlogPost <-> PostComments entity setup sharded by `blog_id` then even the PostComment table needs this column, even if an "unsharded", normalized DB-Schema does not need this information. + +## Implementation Details + +Assumptions: + +* For querying you either want to query ALL or just exactly one shard. +* IDs for ALL sharded tables have to be unique across all shards. +* Non-shareded data is replicated between all shards. They redundantly keep the information available. This is necessary so join queries on shards to reference data work. +* If you retrieve an object A from a shard, then all references and collections of this object reside on the same shard. +* The database schema on all shards is the same (or compatible) + +### SQL Azure Federations + +SQL Azure is a special case, points 1, 2, 3, 4, 7 and 8 are partly handled on the database level. This makes it a perfect test-implementation for just the subset of features in points 5-6. However there need to be a way to configure SchemaTool to generate the correct Schema on SQL Azure. + +* SELECT Operations: The most simple assumption is to always query all shards unless the user specifies otherwise explicitly. +* Queries can be merged in PHP code, this obviously does not work for DISTINCT, GROUP BY and ORDER BY queries. + +### Generic Sharding + +More features are necessary to implement sharding on the PHP level, independent from database support: + +1. Configuration of multiple connections, one connection = one shard. +2. Primary Key Generation mechanisms (UUID, central table, sequence emulation) + +## Primary Use-Cases + +1. Multi-Tenant Applications + +These are easier to support as you have some value to determine the shard id for the whole request very early on. +Here also queries can always be limited to a single shard. + +2. Scale-Out by some attribute (Round-Robin?) + +This strategy requires access to multiple shards in a single request based on the data accessed. diff --git a/docs/examples/sharding/README.md b/docs/examples/sharding/README.md new file mode 100644 index 00000000000..3680e544f40 --- /dev/null +++ b/docs/examples/sharding/README.md @@ -0,0 +1,26 @@ +# Sharding with SQLAzure Example + +This example demonstrates Sharding with SQL Azure Federations. + +## Requirements + +1. Windows Azure Account +2. SQL Azure Database +3. Composer for dependencies + +## Install + + composer install + +Change "examples/sharding/bootstrap.php" to contain Database connection. + +## Order to execute Scripts + +1. create_schema.php +2. view_federation_members.php +3. insert_data.php +4. split_federation.php +5. insert_data_after_split.php +6. query_filtering_off.php +7. query_filtering_on.php + diff --git a/docs/examples/sharding/bootstrap.php b/docs/examples/sharding/bootstrap.php new file mode 100644 index 00000000000..fe174f1c1b7 --- /dev/null +++ b/docs/examples/sharding/bootstrap.php @@ -0,0 +1,26 @@ + 'SalesDB', + 'host' => 'tcp:dbname.windows.net', + 'user' => 'user@dbname', + 'password' => 'XXX', + 'sharding' => array( + 'federationName' => 'Orders_Federation', + 'distributionKey' => 'CustId', + 'distributionType' => 'integer', + ) +); + +if ($config['host'] == "tcp:dbname.windows.net") { + die("You have to change the configuration to your Azure account.\n"); +} + +$conn = DriverManager::getConnection($config); +$shardManager = new SQLAzureShardManager($conn); + diff --git a/docs/examples/sharding/composer.json b/docs/examples/sharding/composer.json new file mode 100644 index 00000000000..214f922178e --- /dev/null +++ b/docs/examples/sharding/composer.json @@ -0,0 +1,6 @@ +{ + "require": { + "doctrine/dbal": "*", + "doctrine/shards": "0.3" + } +} diff --git a/docs/examples/sharding/create_schema.php b/docs/examples/sharding/create_schema.php new file mode 100644 index 00000000000..ac6b66cd81f --- /dev/null +++ b/docs/examples/sharding/create_schema.php @@ -0,0 +1,51 @@ +createTable('Products'); +$products->addColumn('ProductID', 'integer'); +$products->addColumn('SupplierID', 'integer'); +$products->addColumn('ProductName', 'string'); +$products->addColumn('Price', 'decimal', array('scale' => 2, 'precision' => 12)); +$products->setPrimaryKey(array('ProductID')); +$products->addOption('azure.federated', true); + +$customers = $schema->createTable('Customers'); +$customers->addColumn('CustomerID', 'integer'); +$customers->addColumn('CompanyName', 'string'); +$customers->addColumn('FirstName', 'string'); +$customers->addColumn('LastName', 'string'); +$customers->setPrimaryKey(array('CustomerID')); +$customers->addOption('azure.federated', true); +$customers->addOption('azure.federatedOnColumnName', 'CustomerID'); + +$orders = $schema->createTable('Orders'); +$orders->addColumn('CustomerID', 'integer'); +$orders->addColumn('OrderID', 'integer'); +$orders->addColumn('OrderDate', 'datetime'); +$orders->setPrimaryKey(array('CustomerID', 'OrderID')); +$orders->addOption('azure.federated', true); +$orders->addOption('azure.federatedOnColumnName', 'CustomerID'); + +$orderItems = $schema->createTable('OrderItems'); +$orderItems->addColumn('CustomerID', 'integer'); +$orderItems->addColumn('OrderID', 'integer'); +$orderItems->addColumn('ProductID', 'integer'); +$orderItems->addColumn('Quantity', 'integer'); +$orderItems->setPrimaryKey(array('CustomerID', 'OrderID', 'ProductID')); +$orderItems->addOption('azure.federated', true); +$orderItems->addOption('azure.federatedOnColumnName', 'CustomerID'); + +// Create the Schema + Federation: +$synchronizer = new SQLAzureSchemaSynchronizer($conn, $shardManager); + +// Or jut look at the SQL: +echo implode("\n", $synchronizer->getCreateSchema($schema)); + +$synchronizer->createSchema($schema); + diff --git a/docs/examples/sharding/insert_data.php b/docs/examples/sharding/insert_data.php new file mode 100644 index 00000000000..57aeda6c9f8 --- /dev/null +++ b/docs/examples/sharding/insert_data.php @@ -0,0 +1,132 @@ +selectShard(0); + +$conn->insert("Products", array( + "ProductID" => 386, + "SupplierID" => 1001, + "ProductName" => 'Titanium Extension Bracket Left Hand', + "Price" => 5.25, +)); +$conn->insert("Products", array( + "ProductID" => 387, + "SupplierID" => 1001, + "ProductName" => 'Titanium Extension Bracket Right Hand', + "Price" => 5.25, +)); +$conn->insert("Products", array( + "ProductID" => 388, + "SupplierID" => 1001, + "ProductName" => 'Fusion Generator Module 5 kV', + "Price" => 10.50, +)); +$conn->insert("Products", array( + "ProductID" => 389, + "SupplierID" => 1001, + "ProductName" => 'Bypass Filter 400 MHz Low Pass', + "Price" => 10.50, +)); + +$conn->insert("Customers", array( + 'CustomerID' => 10, + 'CompanyName' => 'Van Nuys', + 'FirstName' => 'Catherine', + 'LastName' => 'Abel', +)); +$conn->insert("Customers", array( + 'CustomerID' => 20, + 'CompanyName' => 'Abercrombie', + 'FirstName' => 'Kim', + 'LastName' => 'Branch', +)); +$conn->insert("Customers", array( + 'CustomerID' => 30, + 'CompanyName' => 'Contoso', + 'FirstName' => 'Frances', + 'LastName' => 'Adams', +)); +$conn->insert("Customers", array( + 'CustomerID' => 40, + 'CompanyName' => 'A. Datum Corporation', + 'FirstName' => 'Mark', + 'LastName' => 'Harrington', +)); +$conn->insert("Customers", array( + 'CustomerID' => 50, + 'CompanyName' => 'Adventure Works', + 'FirstName' => 'Keith', + 'LastName' => 'Harris', +)); +$conn->insert("Customers", array( + 'CustomerID' => 60, + 'CompanyName' => 'Alpine Ski House', + 'FirstName' => 'Wilson', + 'LastName' => 'Pais', +)); +$conn->insert("Customers", array( + 'CustomerID' => 70, + 'CompanyName' => 'Baldwin Museum of Science', + 'FirstName' => 'Roger', + 'LastName' => 'Harui', +)); +$conn->insert("Customers", array( + 'CustomerID' => 80, + 'CompanyName' => 'Blue Yonder Airlines', + 'FirstName' => 'Pilar', + 'LastName' => 'Pinilla', +)); +$conn->insert("Customers", array( + 'CustomerID' => 90, + 'CompanyName' => 'City Power & Light', + 'FirstName' => 'Kari', + 'LastName' => 'Hensien', +)); +$conn->insert("Customers", array( + 'CustomerID' => 100, + 'CompanyName' => 'Coho Winery', + 'FirstName' => 'Peter', + 'LastName' => 'Brehm', +)); + +$conn->executeUpdate(" + DECLARE @orderId INT + + DECLARE @customerId INT + + SET @orderId = 10 + SELECT @customerId = CustomerId FROM Customers WHERE LastName = 'Hensien' and FirstName = 'Kari' + + INSERT INTO Orders (CustomerId, OrderId, OrderDate) + VALUES (@customerId, @orderId, GetDate()) + + INSERT INTO OrderItems (CustomerID, OrderID, ProductID, Quantity) + VALUES (@customerId, @orderId, 388, 4) + + SET @orderId = 20 + SELECT @customerId = CustomerId FROM Customers WHERE LastName = 'Harui' and FirstName = 'Roger' + + INSERT INTO Orders (CustomerId, OrderId, OrderDate) + VALUES (@customerId, @orderId, GetDate()) + + INSERT INTO OrderItems (CustomerID, OrderID, ProductID, Quantity) + VALUES (@customerId, @orderId, 389, 2) + + SET @orderId = 30 + SELECT @customerId = CustomerId FROM Customers WHERE LastName = 'Brehm' and FirstName = 'Peter' + + INSERT INTO Orders (CustomerId, OrderId, OrderDate) + VALUES (@customerId, @orderId, GetDate()) + + INSERT INTO OrderItems (CustomerID, OrderID, ProductID, Quantity) + VALUES (@customerId, @orderId, 387, 3) + + SET @orderId = 40 + SELECT @customerId = CustomerId FROM Customers WHERE LastName = 'Pais' and FirstName = 'Wilson' + + INSERT INTO Orders (CustomerId, OrderId, OrderDate) + VALUES (@customerId, @orderId, GetDate()) + + INSERT INTO OrderItems (CustomerID, OrderID, ProductID, Quantity) + VALUES (@customerId, @orderId, 388, 1)"); diff --git a/docs/examples/sharding/insert_data_aftersplit.php b/docs/examples/sharding/insert_data_aftersplit.php new file mode 100644 index 00000000000..312e90b235b --- /dev/null +++ b/docs/examples/sharding/insert_data_aftersplit.php @@ -0,0 +1,27 @@ +selectShard($newCustomerId); + +$conn->insert("Customers", array( + "CustomerID" => $newCustomerId, + "CompanyName" => "Microsoft", + "FirstName" => "Brian", + "LastName" => "Swan", +)); + +$conn->insert("Orders", array( + "CustomerID" => 55, + "OrderID" => 37, + "OrderDate" => date('Y-m-d H:i:s'), +)); + +$conn->insert("OrderItems", array( + "CustomerID" => 55, + "OrderID" => 37, + "ProductID" => 387, + "Quantity" => 1, +)); diff --git a/docs/examples/sharding/query_filtering_off.php b/docs/examples/sharding/query_filtering_off.php new file mode 100644 index 00000000000..c0b24fa087d --- /dev/null +++ b/docs/examples/sharding/query_filtering_off.php @@ -0,0 +1,8 @@ +selectShard(0); + +$data = $conn->fetchAll('SELECT * FROM Customers'); +print_r($data); diff --git a/docs/examples/sharding/query_filtering_on.php b/docs/examples/sharding/query_filtering_on.php new file mode 100644 index 00000000000..e7d9e14546c --- /dev/null +++ b/docs/examples/sharding/query_filtering_on.php @@ -0,0 +1,9 @@ +setFilteringEnabled(true); +$shardManager->selectShard(55); + +$data = $conn->fetchAll('SELECT * FROM Customers'); +print_r($data); diff --git a/docs/examples/sharding/split_federation.php b/docs/examples/sharding/split_federation.php new file mode 100644 index 00000000000..ff681edfd2a --- /dev/null +++ b/docs/examples/sharding/split_federation.php @@ -0,0 +1,5 @@ +splitFederation(60); diff --git a/docs/examples/sharding/view_federation_members.php b/docs/examples/sharding/view_federation_members.php new file mode 100644 index 00000000000..497e4df6d2f --- /dev/null +++ b/docs/examples/sharding/view_federation_members.php @@ -0,0 +1,8 @@ +getShards(); +foreach ($shards as $shard) { + print_r($shard); +} diff --git a/lib/Doctrine/DBAL/Schema/Synchronizer/AbstractSchemaSynchronizer.php b/lib/Doctrine/DBAL/Schema/Synchronizer/AbstractSchemaSynchronizer.php new file mode 100644 index 00000000000..16fb033994e --- /dev/null +++ b/lib/Doctrine/DBAL/Schema/Synchronizer/AbstractSchemaSynchronizer.php @@ -0,0 +1,58 @@ +. + */ + +namespace Doctrine\DBAL\Schema\Synchronizer; + +use Doctrine\DBAL\Connection; + +/** + * Abstract schema synchronizer with methods for executing batches of SQL. + */ +abstract class AbstractSchemaSynchronizer implements SchemaSynchronizer +{ + /** + * @var Connection + */ + protected $conn; + + public function __construct(Connection $conn) + { + $this->conn = $conn; + } + + protected function processSqlSafely(array $sql) + { + foreach ($sql as $s) { + try { + $this->conn->exec($s); + } catch(\Exception $e) { + + } + } + } + + protected function processSql(array $sql) + { + foreach ($sql as $s) { + $this->conn->exec($s); + } + } + +} + diff --git a/lib/Doctrine/DBAL/Schema/Synchronizer/SchemaSynchronizer.php b/lib/Doctrine/DBAL/Schema/Synchronizer/SchemaSynchronizer.php new file mode 100644 index 00000000000..c24981529a8 --- /dev/null +++ b/lib/Doctrine/DBAL/Schema/Synchronizer/SchemaSynchronizer.php @@ -0,0 +1,96 @@ +. + */ + +namespace Doctrine\DBAL\Schema\Synchronizer; + +use Doctrine\DBAL\Schema\Schema; + +/** + * The synchronizer knows how to synchronize a schema with the configured + * database. + * + * @author Benjamin Eberlei + */ +interface SchemaSynchronizer +{ + /** + * Get the SQL statements that can be executed to create the schema. + * + * @param Schema $createSchema + * @return array + */ + function getCreateSchema(Schema $createSchema); + + /** + * Get the SQL Statements to update given schema with the underlying db. + * + * @param Schema $toSchema + * @param bool $noDrops + * @return array + */ + function getUpdateSchema(Schema $toSchema, $noDrops = false); + + /** + * Get the SQL Statements to drop the given schema from underlying db. + * + * @param Schema $dropSchema + * @return array + */ + function getDropSchema(Schema $dropSchema); + + /** + * Get the SQL statements to drop all schema assets from underlying db. + * + * @return array + */ + function getDropAllSchema(); + + /** + * Create the Schema + * + * @param Schema $createSchema + * @return void + */ + function createSchema(Schema $createSchema); + + /** + * Update the Schema to new schema version. + * + * @param Schema $toSchema + * @param bool $noDrops + * @return void + */ + function updateSchema(Schema $toSchema, $noDrops = false); + + /** + * Drop the given database schema from the underlying db. + * + * @param Schema $dropSchema + * @return void + */ + function dropSchema(Schema $dropSchema); + + /** + * Drop all assets from the underyling db. + * + * @return void + */ + function dropAllSchema(); +} + diff --git a/lib/Doctrine/DBAL/Schema/Synchronizer/SingleDatabaseSynchronizer.php b/lib/Doctrine/DBAL/Schema/Synchronizer/SingleDatabaseSynchronizer.php new file mode 100644 index 00000000000..38ea53ac0ba --- /dev/null +++ b/lib/Doctrine/DBAL/Schema/Synchronizer/SingleDatabaseSynchronizer.php @@ -0,0 +1,197 @@ +. + */ +namespace Doctrine\DBAL\Schema\Synchronizer; + +use Doctrine\DBAL\Connection; +use Doctrine\DBAL\Schema\Schema; +use Doctrine\DBAL\Schema\Comparator; +use Doctrine\DBAL\Schema\Visitor\DropSchemaSqlCollector; + +/** + * Schema Synchronizer for Default DBAL Connection + * + * @author Benjamin Eberlei + */ +class SingleDatabaseSynchronizer extends AbstractSchemaSynchronizer +{ + /** + * @var Doctrine\DBAL\Platforms\AbstractPlatform + */ + private $platform; + + public function __construct(Connection $conn) + { + parent::__construct($conn); + $this->platform = $conn->getDatabasePlatform(); + } + + /** + * Get the SQL statements that can be executed to create the schema. + * + * @param Schema $createSchema + * @return array + */ + public function getCreateSchema(Schema $createSchema) + { + return $createSchema->toSql($this->platform); + } + + /** + * Get the SQL Statements to update given schema with the underlying db. + * + * @param Schema $toSchema + * @param bool $noDrops + * @return array + */ + public function getUpdateSchema(Schema $toSchema, $noDrops = false) + { + $comparator = new Comparator(); + $sm = $this->conn->getSchemaManager(); + + $fromSchema = $sm->createSchema(); + $schemaDiff = $comparator->compare($fromSchema, $toSchema); + + if ($noDrops) { + return $schemaDiff->toSaveSql($this->platform); + } + + return $schemaDiff->toSql($this->platform); + } + + /** + * Get the SQL Statements to drop the given schema from underlying db. + * + * @param Schema $dropSchema + * @return array + */ + public function getDropSchema(Schema $dropSchema) + { + $visitor = new DropSchemaSqlCollector($this->platform); + $sm = $this->conn->getSchemaManager(); + + $fullSchema = $sm->createSchema(); + + foreach ($fullSchema->getTables() as $table) { + if ( $dropSchema->hasTable($table->getName())) { + $visitor->acceptTable($table); + } + + foreach ($table->getForeignKeys() as $foreignKey) { + if ( ! $dropSchema->hasTable($table->getName())) { + continue; + } + + if ( ! $dropSchema->hasTable($foreignKey->getForeignTableName())) { + continue; + } + + $visitor->acceptForeignKey($table, $foreignKey); + } + } + + if ( ! $this->platform->supportsSequences()) { + return $visitor->getQueries(); + } + + foreach ($dropSchema->getSequences() as $sequence) { + $visitor->acceptSequence($sequence); + } + + foreach ($dropSchema->getTables() as $table) { + /* @var $sequence Table */ + if ( ! $table->hasPrimaryKey()) { + continue; + } + + $columns = $table->getPrimaryKey()->getColumns(); + if (count($columns) > 1) { + continue; + } + + $checkSequence = $table->getName() . "_" . $columns[0] . "_seq"; + if ($fullSchema->hasSequence($checkSequence)) { + $visitor->acceptSequence($fullSchema->getSequence($checkSequence)); + } + } + + return $visitor->getQueries(); + } + + /** + * Get the SQL statements to drop all schema assets from underlying db. + * + * @return array + */ + public function getDropAllSchema() + { + $sm = $this->conn->getSchemaManager(); + $visitor = new DropSchemaSqlCollector($this->platform); + + /* @var $schema \Doctrine\DBAL\Schema\Schema */ + $schema = $sm->createSchema(); + $schema->visit($visitor); + + return $visitor->getQueries(); + } + + /** + * Create the Schema + * + * @param Schema $createSchema + * @return void + */ + public function createSchema(Schema $createSchema) + { + $this->processSql($this->getCreateSchema($createSchema)); + } + + /** + * Update the Schema to new schema version. + * + * @param Schema $toSchema + * @param bool $noDrops + * @return void + */ + public function updateSchema(Schema $toSchema, $noDrops = false) + { + $this->processSql($this->getUpdateSchema($toSchema, $noDrops)); + } + + /** + * Drop the given database schema from the underlying db. + * + * @param Schema $dropSchema + * @return void + */ + public function dropSchema(Schema $dropSchema) + { + $this->processSqlSafely($this->getDropSchema($dropSchema)); + } + + /** + * Drop all assets from the underyling db. + * + * @return void + */ + public function dropAllSchema() + { + $this->processSql($this->getDropAllSchema()); + } +} + diff --git a/lib/Doctrine/DBAL/Sharding/PoolingShardConnection.php b/lib/Doctrine/DBAL/Sharding/PoolingShardConnection.php new file mode 100644 index 00000000000..6453e638315 --- /dev/null +++ b/lib/Doctrine/DBAL/Sharding/PoolingShardConnection.php @@ -0,0 +1,201 @@ +. + */ + +namespace Doctrine\DBAL\Sharding; + +use Doctrine\DBAL\Connection; +use Doctrine\DBAL\Event\ConnectionEventArgs; +use Doctrine\DBAL\Events; +use Doctrine\DBAL\Driver; +use Doctrine\DBAL\Configuration; + +use Doctrine\Common\EventManager; + +use Doctrine\DBAL\Sharding\ShardChoser\ShardChoser; + +/** + * Sharding implementation that pools many different connections + * internally and serves data from the currently active connection. + * + * The internals of this class are: + * + * - All sharding clients are specified and given a shard-id during + * configuration. + * - By default, the global shard is selected. If no global shard is configured + * an exception is thrown on access. + * - Selecting a shard by distribution value delegates the mapping + * "distributionValue" => "client" to the ShardChooser interface. + * - An exception is thrown if trying to switch shards during an open + * transaction. + * + * Instantiation through the DriverManager looks like: + * + * @example + * + * $conn = DriverManager::getConnection(array( + * 'wrapperClass' => 'Doctrine\DBAL\Sharding\PoolingShardConnection', + * 'driver' => 'pdo_mysql', + * 'global' => array('user' => '', 'password' => '', 'host' => '', 'dbname' => ''), + * 'shards' => array( + * array('id' => 1, 'user' => 'slave1', 'password', 'host' => '', 'dbname' => ''), + * array('id' => 2, 'user' => 'slave2', 'password', 'host' => '', 'dbname' => ''), + * ), + * 'shardChoser' => 'Doctrine\DBAL\Sharding\ShardChoser\MultiTenantShardChoser', + * )); + * $shardManager = $conn->getShardManager(); + * $shardManager->selectGlobal(); + * $shardManager->selectShard($value); + * + * @author Benjamin Eberlei + */ +class PoolingShardConnection extends Connection +{ + /** + * @var array + */ + private $activeConnections; + + /** + * @var int + */ + private $activeShardId; + + /** + * @var array + */ + private $connections; + + /** + * @var ShardManager + */ + private $shardManager; + + public function __construct(array $params, Driver $driver, Configuration $config = null, EventManager $eventManager = null) + { + if ( !isset($params['global']) || !isset($params['shards'])) { + throw new \InvalidArgumentException("Connection Parameters require 'global' and 'shards' configurations."); + } + + if ( !isset($params['shardChoser'])) { + throw new \InvalidArgumentException("Missing Shard Choser configuration 'shardChoser'"); + } + + if (is_string($params['shardChoser'])) { + $params['shardChoser'] = new $params['shardChoser']; + } + + if ( ! ($params['shardChoser'] instanceof ShardChoser)) { + throw new \InvalidArgumentException("The 'shardChoser' configuration is not a valid instance of Doctrine\DBAL\Sharding\ShardChoser\ShardChoser"); + } + + $this->connections[0] = array_merge($params, $params['global']); + + foreach ($params['shards'] as $shard) { + if ( ! isset($shard['id'])) { + throw new \InvalidArgumentException("Missing 'id' for one configured shard. Please specificy a unique shard-id."); + } + + if ( !is_numeric($shard['id']) || $shard['id'] < 1) { + throw new \InvalidArgumentException("Shard Id has to be a non-negative number."); + } + + if (isset($this->connections[$shard['id']])) { + throw new \InvalidArgumentException("Shard " . $shard['id'] . " is duplicated in the configuration."); + } + + $this->connections[$shard['id']] = array_merge($params, $shard); + } + + parent::__construct($params, $driver, $config, $eventManager); + } + + /** + * Connect to a given shard + * + * @param mixed $shardId + * @return bool + */ + public function connect($shardId = null) + { + if ($shardId === null && $this->_conn) { + return false; + } + + if ($shardId !== null && $shardId === $this->activeShardId) { + return false; + } + + if ($this->getTransactionNestingLevel() > 0) { + throw new ShardingException("Cannot switch shard when transaction is active."); + } + + $this->activeShardId = (int)$shardId; + + if (isset($this->activeConnections[$this->activeShardId])) { + $this->_conn = $this->activeConnections[$this->activeShardId]; + return false; + } + + $this->_conn = $this->activeConnections[$this->activeShardId] = $this->connectTo($this->activeShardId); + + if ($this->_eventManager->hasListeners(Events::postConnect)) { + $eventArgs = new Event\ConnectionEventArgs($this); + $this->_eventManager->dispatchEvent(Events::postConnect, $eventArgs); + } + + return true; + } + + + /** + * Connect to a specific connection + * + * @param string $shardId + * @return Driver + */ + protected function connectTo($shardId) + { + $params = $this->getParams(); + + $driverOptions = isset($params['driverOptions']) ? $params['driverOptions'] : array(); + + $connectionParams = $this->connections[$shardId]; + + $user = isset($connectionParams['user']) ? $connectionParams['user'] : null; + $password = isset($connectionParams['password']) ? $connectionParams['password'] : null; + + return $this->_driver->connect($connectionParams, $user, $password, $driverOptions); + } + + public function isConnected($shardId = null) + { + if ($shardId === null) { + return $this->_conn !== null; + } + + return isset($this->activeConnections[$shardId]); + } + + public function close() + { + $this->_conn = null; + $this->activeConnections = null; + } +} + diff --git a/lib/Doctrine/DBAL/Sharding/PoolingShardManager.php b/lib/Doctrine/DBAL/Sharding/PoolingShardManager.php new file mode 100644 index 00000000000..6f6c5d2c2b8 --- /dev/null +++ b/lib/Doctrine/DBAL/Sharding/PoolingShardManager.php @@ -0,0 +1,98 @@ +. + */ + +namespace Doctrine\DBAL\Sharding; + +use Doctrine\DBAL\Sharding\ShardChoser\ShardChoser; + +/** + * Shard Manager for the Connection Pooling Shard Strategy + * + * @author Benjamin Eberlei + */ +class PoolingShardManager implements ShardManager +{ + private $conn; + private $choser; + private $currentDistributionValue; + + public function __construct(PoolingShardConnection $conn) + { + $params = $conn->getParams(); + $this->conn = $conn; + $this->choser = $params['shardChoser']; + } + + public function selectGlobal() + { + $this->conn->connect(0); + $this->currentDistributionValue = null; + } + + public function selectShard($distributionValue) + { + $shardId = $this->choser->pickShard($distributionValue, $this->conn); + $this->conn->connect($shardId); + $this->currentDistributionValue = $distributionValue; + } + + public function getCurrentDistributionValue() + { + return $this->currentDistributionValue; + } + + public function getShards() + { + $params = $this->conn->getParams(); + $shards = array(); + + foreach ($params['shards'] as $shard) { + $shards[] = array('id' => $shard['id']); + } + + return $shards; + } + + public function queryAll($sql, array $params, array $types) + { + $shards = $this->getShards(); + if (!$shards) { + throw new \RuntimeException("No shards found."); + } + + $result = array(); + $oldDistribution = $this->getCurrentDistributionValue(); + + foreach ($shards as $shard) { + $this->selectShard($shard['id']); + foreach ($this->conn->fetchAll($sql, $params, $types) as $row) { + $result[] = $row; + } + } + + if ($oldDistribution === null) { + $this->selectGlobal(); + } else { + $this->selectShard($oldDistribution); + } + + return $result; + } +} + diff --git a/lib/Doctrine/DBAL/Sharding/SQLAzure/SQLAzureFederationsSynchronizer.php b/lib/Doctrine/DBAL/Sharding/SQLAzure/SQLAzureFederationsSynchronizer.php new file mode 100644 index 00000000000..05f11a737ec --- /dev/null +++ b/lib/Doctrine/DBAL/Sharding/SQLAzure/SQLAzureFederationsSynchronizer.php @@ -0,0 +1,296 @@ +. + */ + +namespace Doctrine\DBAL\Sharding\SQLAzure; + +use Doctrine\DBAL\Schema\Schema; +use Doctrine\DBAL\Connection; +use Doctrine\DBAL\Types\Type; + +use Doctrine\DBAL\Schema\Synchronizer\AbstractSchemaSynchronizer; +use Doctrine\DBAL\Sharding\SingleDatabaseSynchronizer; + +/** + * SQL Azure Schema Synchronizer + * + * Will iterate over all shards when performing schema operations. This is done + * by partitioning the passed schema into subschemas for the federation and the + * global database and then applying the operations step by step using the + * {@see \Doctrine\DBAL\Sharding\SingleDatabaseSynchronizer}. + * + * @author Benjamin Eberlei + */ +class SQLAzureFederationsSynchronizer implements AbstractSchemaSynchronizer +{ + const FEDERATION_TABLE_FEDERATED = 'azure.federated'; + const FEDERATION_DISTRIBUTION_NAME = 'azure.federatedOnDistributionName'; + + + /** + * @var SQLAzureShardManager + */ + private $shardManager; + + /** + * @var SchemaSynchronizer + */ + private $synchronizer; + + public function __construct(Connection $conn, SQLAzureShardManager $shardManager, SchemaSynchronizer $sync = null) + { + parent::__construct($conn); + $this->shardManager = $shardManager; + $this->synchronizer = $sync ?: new SingleDatabaseSynchronizer($conn); + } + + /** + * Get the SQL statements that can be executed to create the schema. + * + * @param Schema $createSchema + * @return array + */ + public function getCreateSchema(Schema $createSchema) + { + $sql = array(); + + list($global, $federation) = $this->partitionSchema($createSchema); + + $globalSql = $this->synchronizer->getCreateSchema($global); + if ($globalSql) { + $sql[] = "-- Create Root Federation\n" . + "USE FEDERATION ROOT WITH RESET;"; + $sql = array_merge($sql, $globalSql); + } + + $federationSql = $this->synchronizer->getCreateSchema($federation); + + if ($federationSql) { + $defaultValue = $this->getFederationTypeDefaultValue(); + + $sql[] = $this->getCreateFederationStatement(); + $sql[] = "USE FEDERATION " . $this->shardManager->getFederationName() . " (" . $this->shardManager->getDistributionKey() . " = " . $defaultValue . ") WITH RESET, FILTERING = OFF;"; + $sql = array_merge($sql, $federationSql); + } + + return $sql; + } + + /** + * Get the SQL Statements to update given schema with the underlying db. + * + * @param Schema $toSchema + * @param bool $noDrops + * @return array + */ + public function getUpdateSchema(Schema $toSchema, $noDrops = false) + { + return $this->work($toSchema, function($synchronizer, $schema) use ($noDrops) { + return $synchronizer->getUpdateSchema($schema, $noDrops); + }); + } + + /** + * Get the SQL Statements to drop the given schema from underlying db. + * + * @param Schema $dropSchema + * @return array + */ + public function getDropSchema(Schema $dropSchema) + { + return $this->work($dropSchema, function($synchronizer, $schema) { + return $synchronizer->getDropSchema($schema); + }); + } + + /** + * Create the Schema + * + * @param Schema $createSchema + * @return void + */ + public function createSchema(Schema $createSchema) + { + $this->processSql($this->getCreateSchema($createSchema)); + } + + /** + * Update the Schema to new schema version. + * + * @param Schema $toSchema + * @return void + */ + public function updateSchema(Schema $toSchema, $noDrops = false) + { + $this->processSql($this->getUpdateSchema($toSchema, $noDrops)); + } + + /** + * Drop the given database schema from the underlying db. + * + * @param Schema $dropSchema + * @return void + */ + public function dropSchema(Schema $dropSchema) + { + $this->processSqlSafely($this->getDropSchema($dropSchema)); + } + + /** + * Get the SQL statements to drop all schema assets from underlying db. + * + * @return array + */ + public function getDropAllSchema() + { + $this->shardManager->selectGlobal(); + $globalSql = $this->synchronizer->getDropAllSchema(); + + if ($globalSql) { + $sql[] = "-- Work on Root Federation\nUSE FEDERATION ROOT WITH RESET;"; + $sql = array_merge($sql, $globalSql); + } + + $shards = $this->shardManager->getShards(); + foreach ($shards as $shard) { + $this->shardManager->selectShard($shard['rangeLow']); + + $federationSql = $this->synchronizer->getDropAllSchema(); + if ($federationSql) { + $sql[] = "-- Work on Federation ID " . $shard['id'] . "\n" . + "USE FEDERATION " . $this->shardManager->getFederationName() . " (" . $this->shardManager->getDistributionKey() . " = " . $shard['rangeLow'].") WITH RESET, FILTERING = OFF;"; + $sql = array_merge($sql, $federationSql); + } + } + + $sql[] = "USE FEDERATION ROOT WITH RESET;"; + $sql[] = "DROP FEDERATION " . $this->shardManager->getFederationName(); + + return $sql; + } + + /** + * Drop all assets from the underyling db. + * + * @return void + */ + public function dropAllSchema() + { + $this->processSqlSafely($this->getDropAllSchema()); + } + + private function partitionSchema(Schema $schema) + { + return array( + $this->extractSchemaFederation($schema, false), + $this->extractSchemaFederation($schema, true), + ); + } + + private function extractSchemaFederation(Schema $schema, $isFederation) + { + $partionedSchema = clone $schema; + + foreach ($partionedSchema->getTables() as $table) { + if ($isFederation) { + $table->addOption(self::FEDERATION_DISTRIBUTION_NAME, $this->shardManager->getDistributionKey()); + } + + if ( $table->hasOption(self::FEDERATION_TABLE_FEDERATED) !== $isFederation) { + $partionedSchema->dropTable($table->getName()); + } else { + foreach ($table->getForeignKeys() as $fk) { + $foreignTable = $schema->getTable($fk->getForeignTableName()); + if ($foreignTable->hasOption(self::FEDERATION_TABLE_FEDERATED) !== $isFederation) { + throw new \RuntimeException("Cannot have foreign key between global/federation."); + } + } + } + } + + return $partionedSchema; + } + + /** + * Work on the Global/Federation based on currently existing shards and + * perform the given operation on the underyling schema synchronizer given + * the different partioned schema instances. + * + * @param Schema $schema + * @param Closure $operation + * @return array + */ + private function work(Schema $schema, \Closure $operation) + { + list($global, $federation) = $this->partitionSchema($schema); + $sql = array(); + + $this->shardManager->selectGlobal(); + $globalSql = $operation($this->synchronizer, $global); + + if ($globalSql) { + $sql[] = "-- Work on Root Federation\nUSE FEDERATION ROOT WITH RESET;"; + $sql = array_merge($sql, $globalSql); + } + + $shards = $this->shardManager->getShards(); + + foreach ($shards as $shard) { + $this->shardManager->selectShard($shard['rangeLow']); + + $federationSql = $operation($this->synchronizer, $federation); + if ($federationSql) { + $sql[] = "-- Work on Federation ID " . $shard['id'] . "\n" . + "USE FEDERATION " . $this->shardManager->getFederationName() . " (" . $this->shardManager->getDistributionKey() . " = " . $shard['rangeLow'].") WITH RESET, FILTERING = OFF;"; + $sql = array_merge($sql, $federationSql); + } + } + + return $sql; + } + + private function getFederationTypeDefaultValue() + { + $federationType = Type::getType($this->shardManager->getDistributionType()); + + switch ($federationType->getName()) { + case Type::GUID: + $defaultValue = '00000000-0000-0000-0000-000000000000'; + break; + case Type::INTEGER: + case Type::SMALLINT: + case Type::BIGINT: + $defaultValue = '0'; + break; + default: + $defaultValue = ''; + break; + } + return $defaultValue; + } + + private function getCreateFederationStatement() + { + $federationType = Type::getType($this->shardManager->getDistributionType()); + $federationTypeSql = $federationType->getSqlDeclaration(array(), $this->conn->getDatabasePlatform()); + + return "--Create Federation\n" . + "CREATE FEDERATION " . $this->shardManager->getFederationName() . " (" . $this->shardManager->getDistributionKey() . " " . $federationTypeSql ." RANGE)"; + } +} + diff --git a/lib/Doctrine/DBAL/Sharding/SQLAzure/SQLAzureShardManager.php b/lib/Doctrine/DBAL/Sharding/SQLAzure/SQLAzureShardManager.php new file mode 100644 index 00000000000..80ca3d928ac --- /dev/null +++ b/lib/Doctrine/DBAL/Sharding/SQLAzure/SQLAzureShardManager.php @@ -0,0 +1,238 @@ +. + */ + +namespace Doctrine\DBAL\Sharding\SQLAzure; + +use Doctrine\DBAL\Sharding\ShardManager; +use Doctrine\DBAL\Sharding\ShardingException; +use Doctrine\DBAL\Connection; +use Doctrine\DBAL\Types\Type; + +/** + * Sharding using the SQL Azure Federations support. + * + * @author Benjamin Eberlei + */ +class SQLAzureShardManager implements ShardManager +{ + /** + * @var string + */ + private $federationName; + + /** + * @var bool + */ + private $filteringEnabled; + + /** + * @var string + */ + private $distributionKey; + + /** + * @var string + */ + private $distributionType; + + /** + * @var Connection + */ + private $conn; + + /** + * @var string + */ + private $currentDistributionValue; + + /** + * @param Connection $conn + */ + public function __construct(Connection $conn) + { + $this->conn = $conn; + $params = $conn->getParams(); + + if ( ! isset($params['sharding']['federationName'])) { + throw ShardingException::missingDefaultFederationName(); + } + + if ( ! isset($params['sharding']['distributionKey'])) { + throw ShardingException::missingDefaultDistributionKey(); + } + + if ( ! isset($params['sharding']['distributionType'])) { + throw ShardingException::missingDistributionType(); + } + + $this->federationName = $params['sharding']['federationName']; + $this->distributionKey = $params['sharding']['distributionKey']; + $this->distributionType = $params['sharding']['distributionType']; + $this->filteringEnabled = (isset($params['sharding']['filteringEnabled'])) ? (bool)$params['sharding']['filteringEnabled'] : false; + } + + /** + * Get name of the federation + * + * @return string + */ + public function getFederationName() + { + return $this->federationName; + } + + /** + * Get the distribution key + * + * @return string + */ + public function getDistributionKey() + { + return $this->distributionKey; + } + + /** + * Get the Doctrine Type name used for the distribution + * + * @return string + */ + public function getDistributionType() + { + return $this->distributionType; + } + + /** + * Enabled/Disable filtering on the fly. + * + * @param bool $flag + * @return void + */ + public function setFilteringEnabled($flag) + { + $this->filteringEnabled = (bool)$flag; + } + + /** + * {@inheritDoc} + */ + public function selectGlobal() + { + if ($this->conn->isTransactionActive()) { + throw ShardingException::activeTransaction(); + } + + $sql = "USE FEDERATION ROOT WITH RESET"; + $this->conn->exec($sql); + $this->currentDistributionValue = null; + } + + /** + * {@inheritDoc} + */ + public function selectShard($distributionValue) + { + if ($this->conn->isTransactionActive()) { + throw ShardingException::activeTransaction(); + } + + if ($distributionValue === null || is_bool($distributionValue) || !is_scalar($distributionValue)) { + throw ShardingException::noShardDistributionValue(); + } + + $platform = $this->conn->getDatabasePlatform(); + $sql = sprintf( + "USE FEDERATION %s (%s = %s) WITH RESET, FILTERING = %s;", + $platform->quoteIdentifier($this->federationName), + $platform->quoteIdentifier($this->distributionKey), + $this->conn->quote($distributionValue), + ($this->filteringEnabled ? 'ON' : 'OFF') + ); + + $this->conn->exec($sql); + $this->currentDistributionValue = $distributionValue; + } + + /** + * {@inheritDoc} + */ + public function getCurrentDistributionValue() + { + return $this->currentDistributionValue; + } + + /** + * {@inheritDoc} + */ + public function getShards() + { + $sql = "SELECT member_id as id, + distribution_name as distribution_key, + CAST(range_low AS CHAR) AS rangeLow, + CAST(range_high AS CHAR) AS rangeHigh + FROM sys.federation_member_distributions d + INNER JOIN sys.federations f ON f.federation_id = d.federation_id + WHERE f.name = " . $this->conn->quote($this->federationName); + return $this->conn->fetchAll($sql); + } + + /** + * {@inheritDoc} + */ + public function queryAll($sql, array $params = array(), array $types = array()) + { + $shards = $this->getShards(); + if (!$shards) { + throw new \RuntimeException("No shards found for " . $this->federationName); + } + + $result = array(); + $oldDistribution = $this->getCurrentDistributionValue(); + + foreach ($shards as $shard) { + $this->selectShard($shard['rangeLow']); + foreach ($this->conn->fetchAll($sql, $params, $types) as $row) { + $result[] = $row; + } + } + + if ($oldDistribution === null) { + $this->selectGlobal(); + } else { + $this->selectShard($oldDistribution); + } + + return $result; + } + + /** + * Split Federation at a given distribution value. + * + * @param mixed $splitDistributionValue + */ + public function splitFederation($splitDistributionValue) + { + $type = Type::getType($this->distributionType); + + $sql = "ALTER FEDERATION " . $this->getFederationName() . " " . + "SPLIT AT (" . $this->getDistributionKey() . " = " . + $this->conn->quote($splitDistributionValue, $type->getBindingType()) . ")"; + $this->conn->exec($sql); + } +} + diff --git a/lib/Doctrine/DBAL/Sharding/SQLAzure/Schema/MultiTenantVisitor.php b/lib/Doctrine/DBAL/Sharding/SQLAzure/Schema/MultiTenantVisitor.php new file mode 100644 index 00000000000..2b2b4578d14 --- /dev/null +++ b/lib/Doctrine/DBAL/Sharding/SQLAzure/Schema/MultiTenantVisitor.php @@ -0,0 +1,161 @@ +. + */ + +namespace Doctrine\DBAL\Sharding\SQLAzure\Schema; + +use Doctrine\DBAL\Schema\Visitor\Visitor, + Doctrine\DBAL\Schema\Table, + Doctrine\DBAL\Schema\Schema, + Doctrine\DBAL\Schema\Column, + Doctrine\DBAL\Schema\ForeignKeyConstraint, + Doctrine\DBAL\Schema\Constraint, + Doctrine\DBAL\Schema\Sequence, + Doctrine\DBAL\Schema\Index; + +/** + * Converts a single tenant schema into a multi-tenant schema for SQL Azure + * Federations under the following assumptions: + * + * - Every table is part of the multi-tenant application, only explicitly + * excluded tables are non-federated. The behavior of the tables being in + * global or federated database is undefined. It depends on you selecting a + * federation before DDL statements or not. + * - Every Primary key of a federated table is extended by another column + * 'tenant_id' with a default value of the SQLAzure function + * `federation_filtering_value('tenant_id')`. + * - You always have to work with `filtering=On` when using federations with this + * multi-tenant approach. + * - Primary keys are either using globally unique ids (GUID, Table Generator) + * or you explicitly add the tenent_id in every UPDATE or DELETE statement + * (otherwise they will affect the same-id rows from other tenents as well). + * SQLAzure throws errors when you try to create IDENTIY columns on federated + * tables. + * + * @author Benjamin Eberlei + */ +class MultiTenantVisitor implements Visitor +{ + /** + * @var array + */ + private $excludedTables = array(); + + /** + * @var string + */ + private $tenantColumnName; + + /** + * @var string + */ + private $tenantColumnType = 'integer'; + + /** + * Name of the federation distribution, defaulting to the tenantColumnName + * if not specified. + * + * @var string + */ + private $distributionName; + + public function __construct(array $excludedTables = array(), $tenantColumnName = 'tenant_id', $distributionName = null) + { + $this->excludedTables = $excludedTables; + $this->tenantColumnName = $tenantColumnName; + $this->distributionName = $distributionName ?: $tenantColumnName; + } + + /** + * @param Table $table + */ + public function acceptTable(Table $table) + { + if (in_array($table->getName(), $this->excludedTables)) { + return; + } + + $table->addColumn($this->tenantColumnName, $this->tenantColumnType, array( + 'default' => "federation_filtering_value('". $this->distributionName ."')", + )); + + $clusteredIndex = $this->getClusteredIndex($table); + + $indexColumns = $clusteredIndex->getColumns(); + $indexColumns[] = $this->tenantColumnName; + + if ($clusteredIndex->isPrimary()) { + $table->dropPrimaryKey(); + $table->setPrimaryKey($indexColumns); + } else { + $table->dropIndex($clusteredIndex->getName()); + $table->addIndex($indexColumns, $clusteredIndex->getName()); + $table->getIndex($clusteredIndex->getName())->addFlag('clustered'); + } + } + + private function getClusteredIndex($table) + { + foreach ($table->getIndexes() as $index) { + if ($index->isPrimary() && ! $index->hasFlag('nonclustered')) { + return $index; + } else if ($index->hasFlag('clustered')) { + return $index; + } + } + throw new \RuntimeException("No clustered index found on table " . $table->getName()); + } + + /** + * @param Schema $schema + */ + public function acceptSchema(Schema $schema) + { + } + + /** + * @param Column $column + */ + public function acceptColumn(Table $table, Column $column) + { + } + + /** + * @param Table $localTable + * @param ForeignKeyConstraint $fkConstraint + */ + public function acceptForeignKey(Table $localTable, ForeignKeyConstraint $fkConstraint) + { + } + + /** + * @param Table $table + * @param Index $index + */ + public function acceptIndex(Table $table, Index $index) + { + } + + /** + * @param Sequence $sequence + */ + public function acceptSequence(Sequence $sequence) + { + } +} + diff --git a/lib/Doctrine/DBAL/Sharding/ShardChoser/MultiTenantShardChoser.php b/lib/Doctrine/DBAL/Sharding/ShardChoser/MultiTenantShardChoser.php new file mode 100644 index 00000000000..c6cdabfb4c6 --- /dev/null +++ b/lib/Doctrine/DBAL/Sharding/ShardChoser/MultiTenantShardChoser.php @@ -0,0 +1,37 @@ +. + */ + +namespace Doctrine\DBAL\Sharding\ShardChoser; + +use Doctrine\DBAL\Sharding\PoolingShardConnection; + +/** + * The MultiTenant Shard choser assumes that the distribution value directly + * maps to the shard id. + * + * @author Benjamin Eberlei + */ +class MultiTenantShardChoser implements ShardChoser +{ + public function pickShard($distributionValue, PoolingShardConnection $conn) + { + return $distributionValue; + } +} + diff --git a/lib/Doctrine/DBAL/Sharding/ShardChoser/ShardChoser.php b/lib/Doctrine/DBAL/Sharding/ShardChoser/ShardChoser.php new file mode 100644 index 00000000000..2aa9f74ea75 --- /dev/null +++ b/lib/Doctrine/DBAL/Sharding/ShardChoser/ShardChoser.php @@ -0,0 +1,41 @@ +. + */ + +namespace Doctrine\DBAL\Sharding\ShardChoser; + +use Doctrine\DBAL\Sharding\PoolingShardConnection; + +/** + * Given a distribution value this shard-choser strategy will pick the shard to + * connect to for retrieving rows with the distribution value. + * + * @author Benjamin Eberlei + */ +interface ShardChoser +{ + /** + * Pick a shard for the given distribution value + * + * @param string $distributionValue + * @param PoolingShardConnection $conn + * @return int + */ + function pickShard($distributionValue, PoolingShardConnection $conn); +} + diff --git a/lib/Doctrine/DBAL/Sharding/ShardManager.php b/lib/Doctrine/DBAL/Sharding/ShardManager.php new file mode 100644 index 00000000000..aa67992a30f --- /dev/null +++ b/lib/Doctrine/DBAL/Sharding/ShardManager.php @@ -0,0 +1,95 @@ +. + */ + +namespace Doctrine\DBAL\Sharding; + +use Doctrine\DBAL\Connection; + +/** + * Sharding Manager gives access to APIs to implementing sharding on top of + * Doctrine\DBAL\Connection instances. + * + * For simplicity and developer ease-of-use (and understanding) the sharding + * API only covers single shard queries, no fan-out support. It is primarily + * suited for multi-tenant applications. + * + * The assumption about sharding here + * is that a distribution value can be found that gives access to all the + * necessary data for all use-cases. Switching between shards should be done with + * caution, especially if lazy loading is implemented. Any query is always + * executed against the last shard that was selected. If a query is created for + * a shard Y but then a shard X is selected when its actually excecuted you + * will hit the wrong shard. + * + * @author Benjamin Eberlei + */ +interface ShardManager +{ + /** + * Select global database with global data. + * + * This is the default database that is connected when no shard is + * selected. + * + * @return void + */ + function selectGlobal(); + + /** + * SELECT queries after this statement will be issued against the selected + * shard. + * + * @throws ShardingException If no value is passed as shard identifier. + * @param mixed $distributionValue + * @param array $options + * @return void + */ + function selectShard($distributionValue); + + /** + * Get the distribution value currently used for sharding. + * + * @return string + */ + function getCurrentDistributionValue(); + + /** + * Get information about the amount of shards and other details. + * + * Format is implementation specific, each shard is one element and has a + * 'name' attribute at least. + * + * @return array + */ + function getShards(); + + /** + * Query all shards in undefined order and return the results appended to + * each other. Restore the previous distribution value after execution. + * + * Using {@link Connection::fetchAll} to retrieve rows internally. + * + * @param string $sql + * @param array $params + * @param array $types + * @return array + */ + function queryAll($sql, array $params, array $types); +} + diff --git a/lib/Doctrine/DBAL/Sharding/ShardingException.php b/lib/Doctrine/DBAL/Sharding/ShardingException.php new file mode 100644 index 00000000000..06dd1695af9 --- /dev/null +++ b/lib/Doctrine/DBAL/Sharding/ShardingException.php @@ -0,0 +1,61 @@ +. + */ + +namespace Doctrine\DBAL\Sharding; + +use Doctrine\DBAL\DBALException; + +/** + * Sharding related Exceptions + * + * @since 2.3 + */ +class ShardingException extends DBALException +{ + static public function notImplemented() + { + return new self("This functionality is not implemented with this sharding provider.", 1331557937); + } + + static public function missingDefaultFederationName() + { + return new self("SQLAzure requires a federation name to be set during sharding configuration.", 1332141280); + } + + static public function missingDefaultDistributionKey() + { + return new self("SQLAzure requires a distribution key to be set during sharding configuration.", 1332141329); + } + + static public function activeTransaction() + { + return new self("Cannot switch shard during an active transaction.", 1332141766); + } + + static public function noShardDistributionValue() + { + return new self("You have to specify a string or integer as shard distribution value.", 1332142103); + } + + static public function missingDistributionType() + { + return new self("You have to specify a sharding distribution type such as 'integer', 'string', 'guid'."); + } +} + diff --git a/lib/Doctrine/DBAL/Types/JsonArrayType.php b/lib/Doctrine/DBAL/Types/JsonArrayType.php index 37c60921e8a..3785e84f6c7 100755 --- a/lib/Doctrine/DBAL/Types/JsonArrayType.php +++ b/lib/Doctrine/DBAL/Types/JsonArrayType.php @@ -13,7 +13,7 @@ * OF THIS SOFTWARE, EVEN IF ADVISED OF THE POSSIBILITY OF SUCH DAMAGE. * * This software consists of voluntary contributions made by many individuals - * and is licensed under the LGPL. For more information, see + * and is licensed under the MIT license. For more information, see * . */ @@ -56,4 +56,4 @@ public function getName() { return Type::JSON_ARRAY; } -} \ No newline at end of file +} diff --git a/lib/Doctrine/DBAL/Types/SimpleArrayType.php b/lib/Doctrine/DBAL/Types/SimpleArrayType.php index 8e95def626e..3fe8579872f 100755 --- a/lib/Doctrine/DBAL/Types/SimpleArrayType.php +++ b/lib/Doctrine/DBAL/Types/SimpleArrayType.php @@ -13,7 +13,7 @@ * OF THIS SOFTWARE, EVEN IF ADVISED OF THE POSSIBILITY OF SUCH DAMAGE. * * This software consists of voluntary contributions made by many individuals - * and is licensed under the LGPL. For more information, see + * and is licensed under the MIT license. For more information, see * . */ @@ -58,4 +58,4 @@ public function getName() { return Type::SIMPLE_ARRAY; } -} \ No newline at end of file +} diff --git a/tests/Doctrine/Tests/DBAL/Functional/WriteTest.php b/tests/Doctrine/Tests/DBAL/Functional/WriteTest.php index a313a2e6dd4..f1a3a5983eb 100644 --- a/tests/Doctrine/Tests/DBAL/Functional/WriteTest.php +++ b/tests/Doctrine/Tests/DBAL/Functional/WriteTest.php @@ -153,16 +153,21 @@ public function testLastInsertIdSequence() $this->markTestSkipped('Test only works on platforms with sequences.'); } - $sequence = new \Doctrine\DBAL\Schema\Sequence('write_table_seq'); + $sequence = new \Doctrine\DBAL\Schema\Sequence('write_table_id_seq'); try { - $this->_conn->getSchemaManager()->dropSequence($sequence); - } catch(\Exception $e) {} - $this->_conn->getSchemaManager()->createSequence($sequence); + $this->_conn->getSchemaManager()->createSequence($sequence); + } catch(\Exception $e) { + } + + $sequences = $this->_conn->getSchemaManager()->listSequences(); + $this->assertEquals(1, count(array_filter($sequences, function($sequence) { + return $sequence->getName() === 'write_table_id_seq'; + }))); - $stmt = $this->_conn->query($this->_conn->getDatabasePlatform()->getSequenceNextValSQL('write_table_seq')); + $stmt = $this->_conn->query($this->_conn->getDatabasePlatform()->getSequenceNextValSQL('write_table_id_seq')); $nextSequenceVal = $stmt->fetchColumn(); - $lastInsertId = $this->_conn->lastInsertId('write_table_seq'); + $lastInsertId = $this->_conn->lastInsertId('write_table_id_seq'); $this->assertTrue($lastInsertId > 0); $this->assertEquals($nextSequenceVal, $lastInsertId); diff --git a/tests/Doctrine/Tests/DBAL/Schema/Synchronizer/SingleDatabaseSynchronizerTest.php b/tests/Doctrine/Tests/DBAL/Schema/Synchronizer/SingleDatabaseSynchronizerTest.php new file mode 100644 index 00000000000..e2f52c478a3 --- /dev/null +++ b/tests/Doctrine/Tests/DBAL/Schema/Synchronizer/SingleDatabaseSynchronizerTest.php @@ -0,0 +1,88 @@ +. + */ + +namespace Doctrine\Tests\DBAL\Schema\Synchronizer; + +use Doctrine\DBAL\DriverManager; +use Doctrine\DBAL\Schema\Schema; +use Doctrine\DBAL\Schema\Synchronizer\SingleDatabaseSynchronizer; + +class SingleDatabaseSynchronizerTest extends \PHPUnit_Framework_TestCase +{ + private $conn; + private $synchronizer; + + public function setUp() + { + $this->conn = DriverManager::getConnection(array( + 'driver' => 'pdo_sqlite', + 'memory' => true, + )); + $this->synchronizer = new SingleDatabaseSynchronizer($this->conn); + } + + public function testGetCreateSchema() + { + $schema = new Schema(); + $table = $schema->createTable('test'); + $table->addColumn('id', 'integer'); + $table->setPrimaryKey(array('id')); + + $sql = $this->synchronizer->getCreateSchema($schema); + $this->assertEquals(array('CREATE TABLE test (id INTEGER NOT NULL, PRIMARY KEY(id))'), $sql); + } + + public function testGetUpdateSchema() + { + $schema = new Schema(); + $table = $schema->createTable('test'); + $table->addColumn('id', 'integer'); + $table->setPrimaryKey(array('id')); + + $sql = $this->synchronizer->getUpdateSchema($schema); + $this->assertEquals(array('CREATE TABLE test (id INTEGER NOT NULL, PRIMARY KEY(id))'), $sql); + } + + public function testGetDropSchema() + { + $schema = new Schema(); + $table = $schema->createTable('test'); + $table->addColumn('id', 'integer'); + $table->setPrimaryKey(array('id')); + + $this->synchronizer->createSchema($schema); + + $sql = $this->synchronizer->getDropSchema($schema); + $this->assertEquals(array('DROP TABLE test'), $sql); + } + + public function testGetDropAllSchema() + { + $schema = new Schema(); + $table = $schema->createTable('test'); + $table->addColumn('id', 'integer'); + $table->setPrimaryKey(array('id')); + + $this->synchronizer->createSchema($schema); + + $sql = $this->synchronizer->getDropAllSchema(); + $this->assertEquals(array('DROP TABLE test'), $sql); + } +} + diff --git a/tests/Doctrine/Tests/DBAL/Sharding/PoolingShardConnectionTest.php b/tests/Doctrine/Tests/DBAL/Sharding/PoolingShardConnectionTest.php new file mode 100644 index 00000000000..59259fd81c1 --- /dev/null +++ b/tests/Doctrine/Tests/DBAL/Sharding/PoolingShardConnectionTest.php @@ -0,0 +1,182 @@ +. + */ + +namespace Doctrine\Tests\DBAL\Sharding; + +use Doctrine\DBAL\DriverManager; + +class PoolingShardConnectionTest extends \PHPUnit_Framework_TestCase +{ + public function testConnect() + { + $conn = DriverManager::getConnection(array( + 'wrapperClass' => 'Doctrine\DBAL\Sharding\PoolingShardConnection', + 'driver' => 'pdo_sqlite', + 'global' => array('memory' => true), + 'shards' => array( + array('id' => 1, 'memory' => true), + array('id' => 2, 'memory' => true), + ), + 'shardChoser' => 'Doctrine\DBAL\Sharding\ShardChoser\MultiTenantShardChoser', + )); + + $this->assertFalse($conn->isConnected(0)); + $conn->connect(0); + $this->assertEquals(1, $conn->fetchColumn('SELECT 1')); + $this->assertTrue($conn->isConnected(0)); + + $this->assertFalse($conn->isConnected(1)); + $conn->connect(1); + $this->assertEquals(1, $conn->fetchColumn('SELECT 1')); + $this->assertTrue($conn->isConnected(1)); + + $this->assertFalse($conn->isConnected(2)); + $conn->connect(2); + $this->assertEquals(1, $conn->fetchColumn('SELECT 1')); + $this->assertTrue($conn->isConnected(2)); + + $conn->close(); + $this->assertFalse($conn->isConnected(0)); + $this->assertFalse($conn->isConnected(1)); + $this->assertFalse($conn->isConnected(2)); + } + + public function testNoGlobalServerException() + { + $this->setExpectedException('InvalidArgumentException', "Connection Parameters require 'global' and 'shards' configurations."); + + $conn = DriverManager::getConnection(array( + 'wrapperClass' => 'Doctrine\DBAL\Sharding\PoolingShardConnection', + 'driver' => 'pdo_sqlite', + 'shards' => array( + array('id' => 1, 'memory' => true), + array('id' => 2, 'memory' => true), + ), + 'shardChoser' => 'Doctrine\DBAL\Sharding\ShardChoser\MultiTenantShardChoser', + )); + } + + public function testNoShardsServersExecption() + { + $this->setExpectedException('InvalidArgumentException', "Connection Parameters require 'global' and 'shards' configurations."); + + $conn = DriverManager::getConnection(array( + 'wrapperClass' => 'Doctrine\DBAL\Sharding\PoolingShardConnection', + 'driver' => 'pdo_sqlite', + 'global' => array('memory' => true), + 'shardChoser' => 'Doctrine\DBAL\Sharding\ShardChoser\MultiTenantShardChoser', + )); + } + + public function testNoShardsChoserExecption() + { + $this->setExpectedException('InvalidArgumentException', "Missing Shard Choser configuration 'shardChoser'"); + + $conn = DriverManager::getConnection(array( + 'wrapperClass' => 'Doctrine\DBAL\Sharding\PoolingShardConnection', + 'driver' => 'pdo_sqlite', + 'global' => array('memory' => true), + 'shards' => array( + array('id' => 1, 'memory' => true), + array('id' => 2, 'memory' => true), + ), + )); + } + + public function testShardChoserWrongInstance() + { + $this->setExpectedException('InvalidArgumentException', "The 'shardChoser' configuration is not a valid instance of Doctrine\DBAL\Sharding\ShardChoser\ShardChoser"); + + $conn = DriverManager::getConnection(array( + 'wrapperClass' => 'Doctrine\DBAL\Sharding\PoolingShardConnection', + 'driver' => 'pdo_sqlite', + 'global' => array('memory' => true), + 'shards' => array( + array('id' => 1, 'memory' => true), + array('id' => 2, 'memory' => true), + ), + 'shardChoser' => new \stdClass, + )); + } + + public function testShardNonNumericId() + { + $this->setExpectedException('InvalidArgumentException', "Shard Id has to be a non-negative number."); + + $conn = DriverManager::getConnection(array( + 'wrapperClass' => 'Doctrine\DBAL\Sharding\PoolingShardConnection', + 'driver' => 'pdo_sqlite', + 'global' => array('memory' => true), + 'shards' => array( + array('id' => 'foo', 'memory' => true), + ), + 'shardChoser' => 'Doctrine\DBAL\Sharding\ShardChoser\MultiTenantShardChoser', + )); + } + + public function testShardMissingId() + { + $this->setExpectedException('InvalidArgumentException', "Missing 'id' for one configured shard. Please specificy a unique shard-id."); + + $conn = DriverManager::getConnection(array( + 'wrapperClass' => 'Doctrine\DBAL\Sharding\PoolingShardConnection', + 'driver' => 'pdo_sqlite', + 'global' => array('memory' => true), + 'shards' => array( + array('memory' => true), + ), + 'shardChoser' => 'Doctrine\DBAL\Sharding\ShardChoser\MultiTenantShardChoser', + )); + } + + public function testDuplicateShardId() + { + $this->setExpectedException('InvalidArgumentException', "Shard 1 is duplicated in the configuration."); + + $conn = DriverManager::getConnection(array( + 'wrapperClass' => 'Doctrine\DBAL\Sharding\PoolingShardConnection', + 'driver' => 'pdo_sqlite', + 'global' => array('memory' => true), + 'shards' => array( + array('id' => 1, 'memory' => true), + array('id' => 1, 'memory' => true), + ), + 'shardChoser' => 'Doctrine\DBAL\Sharding\ShardChoser\MultiTenantShardChoser', + )); + } + + public function testSwitchShardWithOpenTransactionException() + { + $conn = DriverManager::getConnection(array( + 'wrapperClass' => 'Doctrine\DBAL\Sharding\PoolingShardConnection', + 'driver' => 'pdo_sqlite', + 'global' => array('memory' => true), + 'shards' => array( + array('id' => 1, 'memory' => true), + ), + 'shardChoser' => 'Doctrine\DBAL\Sharding\ShardChoser\MultiTenantShardChoser', + )); + + $conn->beginTransaction(); + + $this->setExpectedException('Doctrine\DBAL\Sharding\ShardingException', 'Cannot switch shard when transaction is active.'); + $conn->connect(1); + } +} + diff --git a/tests/Doctrine/Tests/DBAL/Sharding/PoolingShardManagerTest.php b/tests/Doctrine/Tests/DBAL/Sharding/PoolingShardManagerTest.php new file mode 100644 index 00000000000..002f9f0e236 --- /dev/null +++ b/tests/Doctrine/Tests/DBAL/Sharding/PoolingShardManagerTest.php @@ -0,0 +1,108 @@ +. + */ +namespace Doctrine\Tests\DBAL\Sharding; + +use Doctrine\DBAL\Sharding\PoolingShardManager; + +class PoolingShardManagerTest extends \PHPUnit_Framework_TestCase +{ + private function createConnectionMock() + { + return $this->getMock('Doctrine\DBAL\Sharding\PoolingShardConnection', array('connect', 'getParams', 'fetchAll'), array(), '', false); + } + + private function createPassthroughShardChoser() + { + $mock = $this->getMock('Doctrine\DBAL\Sharding\ShardChoser\ShardChoser'); + $mock->expects($this->any()) + ->method('pickShard') + ->will($this->returnCallback(function($value) { return $value; })); + return $mock; + } + + public function testSelectGlobal() + { + $conn = $this->createConnectionMock(); + $conn->expects($this->once())->method('connect')->with($this->equalTo(0)); + + $shardManager = new PoolingShardManager($conn, $this->createPassthroughShardChoser()); + $shardManager->selectGlobal(); + + $this->assertNull($shardManager->getCurrentDistributionValue()); + } + + public function testSelectShard() + { + $shardId = 10; + $conn = $this->createConnectionMock(); + $conn->expects($this->at(0))->method('getParams')->will($this->returnValue(array('shardChoser' => $this->createPassthroughShardChoser()))); + $conn->expects($this->at(1))->method('connect')->with($this->equalTo($shardId)); + + $shardManager = new PoolingShardManager($conn); + $shardManager->selectShard($shardId); + + $this->assertEquals($shardId, $shardManager->getCurrentDistributionValue()); + } + + public function testGetShards() + { + $conn = $this->createConnectionMock(); + $conn->expects($this->any())->method('getParams')->will( + $this->returnValue( + array('shards' => array( array('id' => 1), array('id' => 2) ), 'shardChoser' => $this->createPassthroughShardChoser()) + ) + ); + + $shardManager = new PoolingShardManager($conn, $this->createPassthroughShardChoser()); + $shards = $shardManager->getShards(); + + $this->assertEquals(array(array('id' => 1), array('id' => 2)), $shards); + } + + public function testQueryAll() + { + $sql = "SELECT * FROM table"; + $params = array(1); + $types = array(1); + + $conn = $this->createConnectionMock(); + $conn->expects($this->at(0))->method('getParams')->will($this->returnValue( + array('shards' => array( array('id' => 1), array('id' => 2) ), 'shardChoser' => $this->createPassthroughShardChoser()) + )); + $conn->expects($this->at(1))->method('getParams')->will($this->returnValue( + array('shards' => array( array('id' => 1), array('id' => 2) ), 'shardChoser' => $this->createPassthroughShardChoser()) + )); + $conn->expects($this->at(2))->method('connect')->with($this->equalTo(1)); + $conn->expects($this->at(3)) + ->method('fetchAll') + ->with($this->equalTo($sql), $this->equalTo($params), $this->equalTo($types)) + ->will($this->returnValue(array( array('id' => 1) ) )); + $conn->expects($this->at(4))->method('connect')->with($this->equalTo(2)); + $conn->expects($this->at(5)) + ->method('fetchAll') + ->with($this->equalTo($sql), $this->equalTo($params), $this->equalTo($types)) + ->will($this->returnValue(array( array('id' => 2) ) )); + + $shardManager = new PoolingShardManager($conn, $this->createPassthroughShardChoser()); + $result = $shardManager->queryAll($sql, $params, $types); + + $this->assertEquals(array(array('id' => 1), array('id' => 2)), $result); + } +} + diff --git a/tests/Doctrine/Tests/DBAL/Sharding/SQLAzure/AbstractTestCase.php b/tests/Doctrine/Tests/DBAL/Sharding/SQLAzure/AbstractTestCase.php new file mode 100644 index 00000000000..ccf185c509b --- /dev/null +++ b/tests/Doctrine/Tests/DBAL/Sharding/SQLAzure/AbstractTestCase.php @@ -0,0 +1,82 @@ +markTestSkipped('No driver or sqlserver driver specified.'); + } + + $params = array( + 'driver' => $GLOBALS['db_type'], + 'dbname' => $GLOBALS['db_name'], + 'user' => $GLOBALS['db_username'], + 'password' => $GLOBALS['db_password'], + 'host' => $GLOBALS['db_host'], + 'sharding' => array( + 'federationName' => 'Orders_Federation', + 'distributionKey' => 'CustID', + 'distributionType' => 'integer', + 'filteringEnabled' => false, + ), + 'driverOptions' => array('MultipleActiveResultSets' => false) + ); + $this->conn = DriverManager::getConnection($params); + // assume database is created and schema is: + // Global products table + // Customers, Orders, OrderItems federation tables. + // See http://cloud.dzone.com/articles/using-sql-azure-federations + $this->sm = new SQLAzureShardManager($this->conn); + } + + public function createShopSchema() + { + $schema = new Schema(); + + $products = $schema->createTable('Products'); + $products->addColumn('ProductID', 'integer'); + $products->addColumn('SupplierID', 'integer'); + $products->addColumn('ProductName', 'string'); + $products->addColumn('Price', 'decimal', array('scale' => 2, 'precision' => 12)); + $products->setPrimaryKey(array('ProductID')); + $products->addOption('azure.federated', true); + + $customers = $schema->createTable('Customers'); + $customers->addColumn('CustomerID', 'integer'); + $customers->addColumn('CompanyName', 'string'); + $customers->addColumn('FirstName', 'string'); + $customers->addColumn('LastName', 'string'); + $customers->setPrimaryKey(array('CustomerID')); + $customers->addOption('azure.federated', true); + $customers->addOption('azure.federatedOnColumnName', 'CustomerID'); + + $orders = $schema->createTable('Orders'); + $orders->addColumn('CustomerID', 'integer'); + $orders->addColumn('OrderID', 'integer'); + $orders->addColumn('OrderDate', 'datetime'); + $orders->setPrimaryKey(array('CustomerID', 'OrderID')); + $orders->addOption('azure.federated', true); + $orders->addOption('azure.federatedOnColumnName', 'CustomerID'); + + $orderItems = $schema->createTable('OrderItems'); + $orderItems->addColumn('CustomerID', 'integer'); + $orderItems->addColumn('OrderID', 'integer'); + $orderItems->addColumn('ProductID', 'integer'); + $orderItems->addColumn('Quantity', 'integer'); + $orderItems->setPrimaryKey(array('CustomerID', 'OrderID', 'ProductID')); + $orderItems->addOption('azure.federated', true); + $orderItems->addOption('azure.federatedOnColumnName', 'CustomerID'); + + return $schema; + } +} diff --git a/tests/Doctrine/Tests/DBAL/Sharding/SQLAzure/FunctionalTest.php b/tests/Doctrine/Tests/DBAL/Sharding/SQLAzure/FunctionalTest.php new file mode 100644 index 00000000000..1051efb5dc2 --- /dev/null +++ b/tests/Doctrine/Tests/DBAL/Sharding/SQLAzure/FunctionalTest.php @@ -0,0 +1,44 @@ +createShopSchema(); + + $synchronizer = new SQLAzureSchemaSynchronizer($this->conn, $this->sm); + $synchronizer->dropAllSchema(); + $synchronizer->createSchema($schema); + + $this->sm->selectShard(0); + + $this->conn->insert("Products", array( + "ProductID" => 1, + "SupplierID" => 2, + "ProductName" => "Test", + "Price" => 10.45 + )); + + $this->conn->insert("Customers", array( + "CustomerID" => 1, + "CompanyName" => "Foo", + "FirstName" => "Benjamin", + "LastName" => "E.", + )); + + $query = "SELECT * FROM Products"; + $data = $this->conn->fetchAll($query); + $this->assertTrue(count($data) > 0); + + $query = "SELECT * FROM Customers"; + $data = $this->conn->fetchAll($query); + $this->assertTrue(count($data) > 0); + + $data = $this->sm->queryAll("SELECT * FROM Customers"); + $this->assertTrue(count($data) > 0); + } +} + diff --git a/tests/Doctrine/Tests/DBAL/Sharding/SQLAzure/MultiTenantVisitorTest.php b/tests/Doctrine/Tests/DBAL/Sharding/SQLAzure/MultiTenantVisitorTest.php new file mode 100644 index 00000000000..7eb038fc4c4 --- /dev/null +++ b/tests/Doctrine/Tests/DBAL/Sharding/SQLAzure/MultiTenantVisitorTest.php @@ -0,0 +1,65 @@ +. + */ + +namespace Doctrine\Tests\DBAL\Sharding\SQLAzure; + +use Doctrine\DBAL\Platforms\SQLAzurePlatform; +use Doctrine\DBAL\Schema\Schema; +use Doctrine\DBAL\Sharding\SQLAzure\Schema\MultiTenantVisitor; + +class MultiTenantVisitorTest extends \PHPUnit_Framework_TestCase +{ + public function testMultiTenantPrimaryKey() + { + $platform = new SQLAzurePlatform(); + $visitor = new MultiTenantVisitor(); + + $schema = new Schema(); + $foo = $schema->createTable('foo'); + $foo->addColumn('id', 'string'); + $foo->setPrimaryKey(array('id')); + $schema->visit($visitor); + + $this->assertEquals(array('id', 'tenant_id'), $foo->getPrimaryKey()->getColumns()); + $this->assertTrue($foo->hasColumn('tenant_id')); + } + + public function testMultiTenantNonPrimaryKey() + { + $platform = new SQLAzurePlatform(); + $visitor = new MultiTenantVisitor(); + + $schema = new Schema(); + $foo = $schema->createTable('foo'); + $foo->addColumn('id', 'string'); + $foo->addColumn('created', 'datetime'); + $foo->setPrimaryKey(array('id')); + $foo->addIndex(array('created'), 'idx'); + + $foo->getPrimaryKey()->addFlag('nonclustered'); + $foo->getIndex('idx')->addFlag('clustered'); + + $schema->visit($visitor); + + $this->assertEquals(array('id'), $foo->getPrimaryKey()->getColumns()); + $this->assertTrue($foo->hasColumn('tenant_id')); + $this->assertEquals(array('created', 'tenant_id'), $foo->getIndex('idx')->getColumns()); + } +} + diff --git a/tests/Doctrine/Tests/DBAL/Sharding/SQLAzure/SQLAzureFederationsSynchronizerTest.php b/tests/Doctrine/Tests/DBAL/Sharding/SQLAzure/SQLAzureFederationsSynchronizerTest.php new file mode 100644 index 00000000000..091a3636fe2 --- /dev/null +++ b/tests/Doctrine/Tests/DBAL/Sharding/SQLAzure/SQLAzureFederationsSynchronizerTest.php @@ -0,0 +1,50 @@ +createShopSchema(); + + $synchronizer = new SQLAzureFederationsSynchronizer($this->conn, $this->sm); + $sql = $synchronizer->getCreateSchema($schema); + + $this->assertEquals(array ( + "--Create Federation\nCREATE FEDERATION Orders_Federation (CustID INT RANGE)", + "USE FEDERATION Orders_Federation (CustID = 0) WITH RESET, FILTERING = OFF;", + "CREATE TABLE Products (ProductID INT NOT NULL, SupplierID INT NOT NULL, ProductName NVARCHAR(255) NOT NULL, Price NUMERIC(12, 2) NOT NULL, PRIMARY KEY (ProductID))", + "CREATE TABLE Customers (CustomerID INT NOT NULL, CompanyName NVARCHAR(255) NOT NULL, FirstName NVARCHAR(255) NOT NULL, LastName NVARCHAR(255) NOT NULL, PRIMARY KEY (CustomerID))", + "CREATE TABLE Orders (CustomerID INT NOT NULL, OrderID INT NOT NULL, OrderDate DATETIME2(6) NOT NULL, PRIMARY KEY (CustomerID, OrderID))", + "CREATE TABLE OrderItems (CustomerID INT NOT NULL, OrderID INT NOT NULL, ProductID INT NOT NULL, Quantity INT NOT NULL, PRIMARY KEY (CustomerID, OrderID, ProductID))", + ), $sql); + } + + public function testUpdateSchema() + { + $schema = $this->createShopSchema(); + + $synchronizer = new SQLAzureFederationsSynchronizer($this->conn, $this->sm); + $synchronizer->dropAllSchema(); + + $sql = $synchronizer->getUpdateSchema($schema); + + $this->assertEquals(array(), $sql); + } + + public function testDropSchema() + { + $schema = $this->createShopSchema(); + + $synchronizer = new SQLAzureFederationsSynchronizer($this->conn, $this->sm); + $synchronizer->dropAllSchema(); + $synchronizer->createSchema($schema); + $sql = $synchronizer->getDropSchema($schema); + + $this->assertEQuals(5, count($sql)); + } +} + diff --git a/tests/Doctrine/Tests/DBAL/Sharding/SQLAzure/SQLAzureShardManagerTest.php b/tests/Doctrine/Tests/DBAL/Sharding/SQLAzure/SQLAzureShardManagerTest.php new file mode 100644 index 00000000000..f73e494081a --- /dev/null +++ b/tests/Doctrine/Tests/DBAL/Sharding/SQLAzure/SQLAzureShardManagerTest.php @@ -0,0 +1,93 @@ +setExpectedException('Doctrine\DBAL\Sharding\ShardingException', 'SQLAzure requires a federation name to be set during sharding configuration.'); + + $conn = $this->createConnection(array('sharding' => array('distributionKey' => 'abc', 'distributionType' => 'integer'))); + $sm = new SQLAzureShardManager($conn); + } + + public function testNoDistributionKey() + { + $this->setExpectedException('Doctrine\DBAL\Sharding\ShardingException', 'SQLAzure requires a distribution key to be set during sharding configuration.'); + + $conn = $this->createConnection(array('sharding' => array('federationName' => 'abc', 'distributionType' => 'integer'))); + $sm = new SQLAzureShardManager($conn); + } + + public function testNoDistributionType() + { + $this->setExpectedException('Doctrine\DBAL\Sharding\ShardingException'); + + $conn = $this->createConnection(array('sharding' => array('federationName' => 'abc', 'distributionKey' => 'foo'))); + $sm = new SQLAzureShardManager($conn); + } + + public function testGetDefaultDistributionValue() + { + $conn = $this->createConnection(array('sharding' => array('federationName' => 'abc', 'distributionKey' => 'foo', 'distributionType' => 'integer'))); + + $sm = new SQLAzureShardManager($conn); + $this->assertNull($sm->getCurrentDistributionValue()); + } + + public function testSelectGlobalTransactionActive() + { + $conn = $this->createConnection(array('sharding' => array('federationName' => 'abc', 'distributionKey' => 'foo', 'distributionType' => 'integer'))); + $conn->expects($this->at(1))->method('isTransactionActive')->will($this->returnValue(true)); + + $this->setExpectedException('Doctrine\DBAL\Sharding\ShardingException', 'Cannot switch shard during an active transaction.'); + + $sm = new SQLAzureShardManager($conn); + $sm->selectGlobal(); + } + + public function testSelectGlobal() + { + $conn = $this->createConnection(array('sharding' => array('federationName' => 'abc', 'distributionKey' => 'foo', 'distributionType' => 'integer'))); + $conn->expects($this->at(1))->method('isTransactionActive')->will($this->returnValue(false)); + $conn->expects($this->at(2))->method('exec')->with($this->equalTo('USE FEDERATION ROOT WITH RESET')); + + $sm = new SQLAzureShardManager($conn); + $sm->selectGlobal(); + } + + public function testSelectShard() + { + $conn = $this->createConnection(array('sharding' => array('federationName' => 'abc', 'distributionKey' => 'foo', 'distributionType' => 'integer'))); + $conn->expects($this->at(1))->method('isTransactionActive')->will($this->returnValue(true)); + + $this->setExpectedException('Doctrine\DBAL\Sharding\ShardingException', 'Cannot switch shard during an active transaction.'); + + $sm = new SQLAzureShardManager($conn); + $sm->selectShard(1234); + + $this->assertEquals(1234, $sm->getCurrentDistributionValue()); + } + + public function testSelectShardNoDistriubtionValue() + { + $conn = $this->createConnection(array('sharding' => array('federationName' => 'abc', 'distributionKey' => 'foo', 'distributionType' => 'integer'))); + $conn->expects($this->at(1))->method('isTransactionActive')->will($this->returnValue(false)); + + $this->setExpectedException('Doctrine\DBAL\Sharding\ShardingException', 'You have to specify a string or integer as shard distribution value.'); + + $sm = new SQLAzureShardManager($conn); + $sm->selectShard(null); + } + + private function createConnection(array $params) + { + $conn = $this->getMock('Doctrine\DBAL\Connection', array('getParams', 'exec', 'isTransactionActive'), array(), '', false); + $conn->expects($this->at(0))->method('getParams')->will($this->returnValue($params)); + return $conn; + } +} + diff --git a/tests/Doctrine/Tests/DBAL/Sharding/ShardChoser/MultiTenantShardChoserTest.php b/tests/Doctrine/Tests/DBAL/Sharding/ShardChoser/MultiTenantShardChoserTest.php new file mode 100644 index 00000000000..4e06f8d451f --- /dev/null +++ b/tests/Doctrine/Tests/DBAL/Sharding/ShardChoser/MultiTenantShardChoserTest.php @@ -0,0 +1,40 @@ +. + */ + +namespace Doctrine\Tests\DBAL\Sharding\ShardChoser; + +use Doctrine\DBAL\Sharding\ShardChoser\MultiTenantShardChoser; + +class MultiTenantShardChoserTest extends \PHPUnit_Framework_TestCase +{ + public function testPickShard() + { + $choser = new MultiTenantShardChoser(); + $conn = $this->createConnectionMock(); + + $this->assertEquals(1, $choser->pickShard(1, $conn)); + $this->assertEquals(2, $choser->pickShard(2, $conn)); + } + + private function createConnectionMock() + { + return $this->getMock('Doctrine\DBAL\Sharding\PoolingShardConnection', array('connect', 'getParams', 'fetchAll'), array(), '', false); + } +} +