Index: includes/database/mysql/database.inc =================================================================== RCS file: /cvs/drupal/drupal/includes/database/mysql/database.inc,v retrieving revision 1.11 diff -u -r1.11 database.inc --- includes/database/mysql/database.inc 8 Dec 2008 21:41:53 -0000 1.11 +++ includes/database/mysql/database.inc 23 Dec 2008 04:26:30 -0000 @@ -35,9 +35,12 @@ // Force MySQL to use the UTF-8 character set by default. $this->exec('SET NAMES "utf8"'); - // Enable MySQL's "strict mode", which removes most of MySQL's - // "just be lazy" behaviors that end up causing more trouble than they're worth. - $this->exec('SET sql_mode=STRICT_ALL_TABLES'); + // Force MySQL's behavior to conform more closely to SQL standards. + // This allows Drupal to run almost seamlessly on many different + // kinds of database systems. These settings force MySQL to behave + // the same as postgresql, or sqlite in regards to syntax interpretation + // and invalid data handling. See http://drupal.org/node/344575 for further disscussion. + $this->exec("SET sql_mode='ANSI,TRADITIONAL,ONLY_FULL_GROUP_BY'"); } public function queryRange($query, array $args, $from, $count, array $options = array()) { Index: modules/simpletest/tests/database_test.install =================================================================== RCS file: /cvs/drupal/drupal/modules/simpletest/tests/database_test.install,v retrieving revision 1.3 diff -u -r1.3 database_test.install --- modules/simpletest/tests/database_test.install 8 Oct 2008 18:34:30 -0000 1.3 +++ modules/simpletest/tests/database_test.install 23 Dec 2008 04:26:30 -0000 @@ -150,6 +150,22 @@ 'primary key' => array('tid'), ); + $schema['test_date'] = array( + 'description' => 'A simple table including a datetime field for testing datetime behavior.', + 'fields' => array( + 'id' => array( + 'description' => 'Simple unique ID.', + 'type' => 'serial', + 'not null' => TRUE, + ), + 'dummy_date' => array( + 'description' => 'A dummy datetime field.', + 'type' => 'datetime', + ), + ), + 'primary key' => array('id'), + ); + return $schema; } Index: modules/simpletest/tests/database_test.test =================================================================== RCS file: /cvs/drupal/drupal/modules/simpletest/tests/database_test.test,v retrieving revision 1.27 diff -u -r1.27 database_test.test --- modules/simpletest/tests/database_test.test 20 Dec 2008 18:24:40 -0000 1.27 +++ modules/simpletest/tests/database_test.test 23 Dec 2008 04:26:31 -0000 @@ -1922,3 +1922,148 @@ $this->assertFalse(db_table_exists('temporary'), t('The temporary table is, indeed, temporary.')); } } + +/** + * Test how the current database driver interprets the SQL syntax. + * + * In order to ensure consistent SQL handling throughout Drupal + * across multiple kinds of database systems, we test that the + * database system interprets SQL syntax in an expected fashion. + */ +class DatabaseAnsiSyntaxTestCase extends DatabaseTestCase { + function getInfo() { + return array( + 'name' => t('ANSI SQL syntax tests'), + 'description' => t('Test ANSI SQL syntax interpretation.'), + 'group' => t('Database'), + ); + } + + function setUp() { + parent::setUp('database_test'); + } + + /** + * Test for ANSI string concatenation. + */ + function testBasicConcat() { + $result = db_query("SELECT 'This' || ' ' || 'is' || ' a ' || 'test.'"); + $this->assertIdentical($result->fetchField(), 'This is a test.', t('Basic ANSI Concat works.')); + } + + /** + * Test for ANSI string concatenation with field values. + */ + function testFieldConcat() { + $result = db_query("SELECT 'The age of ' || name || ' is ' || age || '.' FROM {test} WHERE age = :age", array(':age' => 25)); + $this->assertIdentical($result->fetchField(), 'The age of John is 25.', t('Field ANSI Concat works.')); + } + + /** + * ANSI standard allows for double quotes to escape field names. + */ + function testQuotes() { + $result = db_query('SELECT "name" FROM {test} WHERE age = :age', array(':age' => 25)); + $this->assertIdentical($result->fetchField(), 'John', t('ANSI field quoting works.')); + } +} + +/** + * Test invalid data handling. + */ +class DatabaseInvalidDataTestCase extends DatabaseTestCase { + function getInfo() { + return array( + 'name' => t('SQL handling tests'), + 'description' => t('Test handling of invalid data.'), + 'group' => t('Database'), + ); + } + + function setUp() { + parent::setUp('database_test'); + } + + /** + * Traditional SQL database systems abort inserts when invalid data is encountered. + */ + function testInsertDuplicateData() { + // Try to insert multiple records where at least one has bad data. + try { + db_insert('test') + ->fields(array('name', 'age', 'job')) + ->values(array( + 'name' => 'Elvis', + 'age' => 63, + 'job' => 'Singer', + ))->values(array( + 'name' => 'John', // <-- Duplicate value on unique field. + 'age' => 17, + 'job' => 'Consultant', + )) + ->values(array( + 'name' => 'Frank', + 'age' => 75, + 'job' => 'Singer', + )) + ->execute(); + $this->assertTrue(FALSE, t('Insert succeedded when it should not have.')); + } + catch (Exception $e) { + // Check the first record was inserted. + $result = db_query('SELECT name FROM {test} WHERE age = :age', array(':age' => 63)); + $this->assertIdentical($result->fetchField(), 'Elvis', t('First record inserted as expected.')); + + // Ensure the other values were not inserted. + $record = db_select('test') + ->fields('test', array('name', 'age')) + ->condition('age', array(17, 75),'IN') + ->execute()->fetchObject(); + $this->assertFalse($record, $e->getMessage() .':: '. t('Insert aborted as expected.')); + } + } + + /** + * Dates do not allow zero values for month/day or a zero value for an entire date. + */ + function testInvalidDate() { + // Test zero in month. + try { + db_insert('test_date') + ->fields(array( + 'dummy_date' => '2008-00-01 12:00:00' + )) + ->execute(); + $this->assertTrue(FALSE, t('Insert with zero as month in date unexpectedly succeeded.')); + } + catch (Exception $e) { + $this->assertTrue(TRUE, t('Insert with zero as month in date causes expected SQL error.')); + } + + // Test zero in day. + try { + db_insert('test_date') + ->fields(array( + 'dummy_date' => '2008-05-00 12:00:00' + )) + ->execute(); + $this->assertTrue(FALSE, t('Insert with zero as day in date unexpectedly succeeded.')); + } + catch (Exception $e) { + $this->assertTrue(TRUE, t('Insert with zero as day in date causes expected SQL error.')); + } + + // Test 0000-00-00 00:00:00 is invalid. + try { + db_insert('test_date') + ->fields(array( + 'dummy_date' => '0000-00-00 00:00:00' + )) + ->execute(); + $this->assertTrue(FALSE, t('Insertion of zero date unexpectedly succeeded.')); + } + catch (Exception $e) { + $this->assertTrue(TRUE, t('Insertion of zero date failed as expected.')); + } + } +}