Skip to content

Commit

Permalink
* Added CDbSchema::resetSequence() and checkIntegrity()
Browse files Browse the repository at this point in the history
  • Loading branch information
qiang.xue committed Jun 10, 2009
1 parent 0f48a6b commit 7c9033c
Show file tree
Hide file tree
Showing 8 changed files with 230 additions and 2 deletions.
2 changes: 1 addition & 1 deletion CHANGELOG
Expand Up @@ -5,7 +5,7 @@
Version 1.1a to be released
---------------------------
- New: Refactored scenario-based validation and massive assignments (Qiang)

- New: Added CDbSchema::checkIntegrity() and resetSequence() (Qiang)

Version 1.0.7 to be released
----------------------------
Expand Down
25 changes: 25 additions & 0 deletions framework/db/schema/CDbSchema.php
Expand Up @@ -164,6 +164,31 @@ public function compareTableNames($name1,$name2)
return $name1===$name2;
}

/**
* Resets the sequence value of a table's primary key.
* The sequence will be reset such that the primary key of the next new row inserted
* will have the specified value or 1.
* @param CDbTableSchema the table schema whose primary key sequence will be reset
* @param mixed the value for the primary key of the next new row inserted. If this is not set,
* the next new row's primary key will have a value 1.
* @since 1.1
*/
public function resetSequence($table,$value=null)
{
throw new CDbException(Yii::t('yii','Resetting PK sequence is not supported.'));
}

/**
* Enables or disables integrity check.
* @param boolean whether to turn on or off the integrity check.
* @param string the schema of the tables. Defaults to empty string, meaning the current or default schema.
* @since 1.1
*/
public function checkIntegrity($check=true,$schema='')
{
throw new CDbException(Yii::t('yii','Setting integrity check is not supported.'));
}

/**
* Creates a command builder for the database.
* This method may be overridden by child classes to create a DBMS-specific command builder.
Expand Down
29 changes: 29 additions & 0 deletions framework/db/schema/mysql/CMysqlSchema.php
Expand Up @@ -54,6 +54,35 @@ public function compareTableNames($name1,$name2)
return parent::compareTableNames(strtolower($name1),strtolower($name2));
}

/**
* Resets the sequence value of a table's primary key.
* The sequence will be reset such that the primary key of the next new row inserted
* will have the specified value or 1.
* @param CDbTableSchema the table schema whose primary key sequence will be reset
* @param mixed the value for the primary key of the next new row inserted. If this is not set,
* the next new row's primary key will have a value 1.
* @since 1.1
*/
public function resetSequence($table,$value=null)
{
if($value===null)
$value=$this->getDbConnection()->createCommand("SELECT MAX(`{$table->primaryKey}`) FROM {$table->rawName}")->queryScalar()+1;
else
$value=(int)$value;
$this->getDbConnection()->createCommand("ALTER TABLE {$table->rawName} AUTO_INCREMENT=$value")->execute();
}

/**
* Enables or disables integrity check.
* @param boolean whether to turn on or off the integrity check.
* @param string the schema of the tables. Defaults to empty string, meaning the current or default schema.
* @since 1.1
*/
public function checkIntegrity($check=true,$schema='')
{
$this->getDbConnection()->createCommand('SET FOREIGN_KEY_CHECKS='.($check?1:0))->execute();
}

/**
* Creates a table instance representing the metadata for the named table.
* @return CMysqlTableSchema driver dependent table metadata. Null if the table does not exist.
Expand Down
46 changes: 45 additions & 1 deletion framework/db/schema/pgsql/CPgsqlSchema.php
Expand Up @@ -31,6 +31,50 @@ public function quoteTableName($name)
return '"'.$name.'"';
}

/**
* Resets the sequence value of a table's primary key.
* The sequence will be reset such that the primary key of the next new row inserted
* will have the specified value or 1.
* @param CDbTableSchema the table schema whose primary key sequence will be reset
* @param mixed the value for the primary key of the next new row inserted. If this is not set,
* the next new row's primary key will have a value 1.
* @since 1.1
*/
public function resetSequence($table,$value=null)
{
if($table->sequenceName!==null)
{
$seq='"'.$table->sequenceName.'"';
if(strpos($seq,'.')!==false)
$seq=str_replace('.','"."',$seq);
if($value===null)
$value="(SELECT COALESCE(MAX(\"{$table->primaryKey}\"),0) FROM {$table->rawName}) + 1";
else
$value=(int)$value;
$this->getDbConnection()->createCommand("SELECT SETVAL('$seq', $value, false)")->execute();
}
}

/**
* Enables or disables integrity check.
* @param boolean whether to turn on or off the integrity check.
* @param string the schema of the tables. Defaults to empty string, meaning the current or default schema.
* @since 1.1
*/
public function checkIntegrity($check=true,$schema='')
{
$enable=$check ? 'ENABLE' : 'DISABLE';
$tableNames=$this->getTableNames($schema);
$db=$this->getDbConnection();
foreach($tableNames as $tableName)
{
$tableName='"'.$tableName.'"';
if(strpos($tableName,'.')!==false)
$tableName=str_replace('.','"."',$tableName);
$db->createCommand("ALTER TABLE $tableName $enable TRIGGER ALL")->execute();
}
}

/**
* Creates a table instance representing the metadata for the named table.
* @return CDbTableSchema driver dependent table metadata.
Expand Down Expand Up @@ -275,7 +319,7 @@ protected function findTableNames($schema='')
if($schema===self::DEFAULT_SCHEMA)
$names[]=$row['table_name'];
else
$names[]=$row['schema_name'].'.'.$row['table_name'];
$names[]=$row['table_schema'].'.'.$row['table_name'];
}
return $names;
}
Expand Down
30 changes: 30 additions & 0 deletions framework/db/schema/sqlite/CSqliteSchema.php
Expand Up @@ -18,6 +18,36 @@
*/
class CSqliteSchema extends CDbSchema
{
/**
* Resets the sequence value of a table's primary key.
* The sequence will be reset such that the primary key of the next new row inserted
* will have the specified value or 1.
* @param CDbTableSchema the table schema whose primary key sequence will be reset
* @param mixed the value for the primary key of the next new row inserted. If this is not set,
* the next new row's primary key will have a value 1.
* @since 1.1
*/
public function resetSequence($table,$value=null)
{
if($value===null)
$value=$this->getDbConnection()->createCommand("SELECT MAX(`{$table->primaryKey}`) FROM {$table->rawName}")->queryScalar();
else
$value=(int)$value-1;
$this->getDbConnection()->createCommand("UPDATE sqlite_sequence SET seq='$value' WHERE name='{$table->name}'")->execute();
}

/**
* Enables or disables integrity check.
* @param boolean whether to turn on or off the integrity check.
* @param string the schema of the tables. Defaults to empty string, meaning the current or default schema.
* @since 1.1
*/
public function checkIntegrity($check=true,$schema='')
{
// SQLite doesn't enforce integrity
return;
}

/**
* Returns all table names in the database.
* @param string the schema of the tables. This is not used for sqlite database.
Expand Down
29 changes: 29 additions & 0 deletions tests/unit/framework/db/schema/CMysqlTest.php
Expand Up @@ -243,4 +243,33 @@ public function testCommandBuilder()
$c=$builder->createPkCriteria($table2,array());
$this->assertEquals('0=1',$c->condition);
}

public function testResetSequence()
{
$max=$this->db->createCommand("SELECT MAX(id) FROM users")->queryScalar();
$this->db->createCommand("DELETE FROM users")->execute();
$this->db->createCommand("INSERT INTO users (username, password, email) VALUES ('user4','pass4','email4')")->execute();
$max2=$this->db->createCommand("SELECT MAX(id) FROM users")->queryScalar();
$this->assertEquals($max+1,$max2);

$userTable=$this->db->schema->getTable('users');

$this->db->createCommand("DELETE FROM users")->execute();
$this->db->schema->resetSequence($userTable);return;
$this->db->createCommand("INSERT INTO users (username, password, email) VALUES ('user4','pass4','email4')")->execute();
$max=$this->db->createCommand("SELECT MAX(id) FROM users")->queryScalar();
$this->assertEquals(1,$max);
$this->db->createCommand("INSERT INTO users (username, password, email) VALUES ('user4','pass4','email4')")->execute();
$max=$this->db->createCommand("SELECT MAX(id) FROM users")->queryScalar();
$this->assertEquals(2,$max);

$this->db->createCommand("DELETE FROM users")->execute();
$this->db->schema->resetSequence($userTable,10);
$this->db->createCommand("INSERT INTO users (username, password, email) VALUES ('user4','pass4','email4')")->execute();
$max=$this->db->createCommand("SELECT MAX(id) FROM users")->queryScalar();
$this->assertEquals(10,$max);
$this->db->createCommand("INSERT INTO users (username, password, email) VALUES ('user4','pass4','email4')")->execute();
$max=$this->db->createCommand("SELECT MAX(id) FROM users")->queryScalar();
$this->assertEquals(11,$max);
}
}
36 changes: 36 additions & 0 deletions tests/unit/framework/db/schema/CPostgresTest.php
Expand Up @@ -232,4 +232,40 @@ public function testCommandBuilder()
$c=$builder->createColumnCriteria($table,array('id'=>1,'author_id'=>2),'title=\'\'');
$this->assertEquals('"test"."posts"."id"=:yp0 AND "test"."posts"."author_id"=:yp1 AND (title=\'\')',$c->condition);
}

public function testResetSequence()
{
$max=$this->db->createCommand("SELECT MAX(id) FROM test.users")->queryScalar();
$this->db->createCommand("DELETE FROM test.users")->execute();
$this->db->createCommand("INSERT INTO test.users (username, password, email) VALUES ('user4','pass4','email4')")->execute();
$max2=$this->db->createCommand("SELECT MAX(id) FROM test.users")->queryScalar();
$this->assertEquals($max+1,$max2);

$userTable=$this->db->schema->getTable('test.users');

$this->db->createCommand("DELETE FROM test.users")->execute();
$this->db->schema->resetSequence($userTable);
$this->db->createCommand("INSERT INTO test.users (username, password, email) VALUES ('user4','pass4','email4')")->execute();
$max=$this->db->createCommand("SELECT MAX(id) FROM test.users")->queryScalar();
$this->assertEquals(1,$max);
$this->db->createCommand("INSERT INTO test.users (username, password, email) VALUES ('user4','pass4','email4')")->execute();
$max=$this->db->createCommand("SELECT MAX(id) FROM test.users")->queryScalar();
$this->assertEquals(2,$max);

$this->db->createCommand("DELETE FROM test.users")->execute();
$this->db->schema->resetSequence($userTable,10);
$this->db->createCommand("INSERT INTO test.users (username, password, email) VALUES ('user4','pass4','email4')")->execute();
$max=$this->db->createCommand("SELECT MAX(id) FROM test.users")->queryScalar();
$this->assertEquals(10,$max);
$this->db->createCommand("INSERT INTO test.users (username, password, email) VALUES ('user4','pass4','email4')")->execute();
$max=$this->db->createCommand("SELECT MAX(id) FROM test.users")->queryScalar();
$this->assertEquals(11,$max);
}

public function testCheckIntegrity()
{
$this->db->schema->checkIntegrity(false,'test');
$this->db->createCommand("INSERT INTO test.profiles (first_name, last_name, user_id) VALUES ('first 1','last 1',1000)")->execute();
$this->db->schema->checkIntegrity(true,'test');
}
}
35 changes: 35 additions & 0 deletions tests/unit/framework/db/schema/CSqliteTest.php
Expand Up @@ -224,4 +224,39 @@ public function testCommandBuilder()
$c=$builder->createPkCriteria($table2,array());
$this->assertEquals('0=1',$c->condition);
}

public function testResetSequence()
{
$max=$this->db->createCommand("SELECT MAX(id) FROM users")->queryScalar();
$this->db->createCommand("DELETE FROM users")->execute();
$this->db->createCommand("INSERT INTO users (username, password, email) VALUES ('user4','pass4','email4')")->execute();
$max2=$this->db->createCommand("SELECT MAX(id) FROM users")->queryScalar();
$this->assertEquals($max+1,$max2);

$userTable=$this->db->schema->getTable('users');

$this->db->createCommand("DELETE FROM users")->execute();
$this->db->schema->resetSequence($userTable);
$this->db->createCommand("INSERT INTO users (username, password, email) VALUES ('user4','pass4','email4')")->execute();
$max=$this->db->createCommand("SELECT MAX(id) FROM users")->queryScalar();
$this->assertEquals(1,$max);
$this->db->createCommand("INSERT INTO users (username, password, email) VALUES ('user4','pass4','email4')")->execute();
$max=$this->db->createCommand("SELECT MAX(id) FROM users")->queryScalar();
$this->assertEquals(2,$max);

$this->db->createCommand("DELETE FROM users")->execute();
$this->db->schema->resetSequence($userTable,10);
$this->db->createCommand("INSERT INTO users (username, password, email) VALUES ('user4','pass4','email4')")->execute();
$max=$this->db->createCommand("SELECT MAX(id) FROM users")->queryScalar();
$this->assertEquals(10,$max);
$this->db->createCommand("INSERT INTO users (username, password, email) VALUES ('user4','pass4','email4')")->execute();
$max=$this->db->createCommand("SELECT MAX(id) FROM users")->queryScalar();
$this->assertEquals(11,$max);
}

public function testCheckIntegrity()
{
$this->db->schema->checkIntegrity(false);
$this->db->schema->checkIntegrity(true);
}
}

0 comments on commit 7c9033c

Please sign in to comment.