webmaster@1: $t('PostgreSQL database'),
webmaster@1: 'value' => $version,
webmaster@1: );
webmaster@1:
webmaster@1: if (version_compare($version, DRUPAL_MINIMUM_PGSQL) < 0) {
webmaster@1: $form['pgsql']['severity'] = REQUIREMENT_ERROR;
webmaster@1: $form['pgsql']['description'] = $t('Your PostgreSQL Server is too old. Drupal requires at least PostgreSQL %version.', array('%version' => DRUPAL_MINIMUM_PGSQL));
webmaster@1: }
webmaster@1:
webmaster@1: return $form;
webmaster@1: }
webmaster@1:
webmaster@1: /**
webmaster@1: * Returns the version of the database server currently in use.
webmaster@1: *
webmaster@1: * @return Database server version
webmaster@1: */
webmaster@1: function db_version() {
webmaster@1: return db_result(db_query("SHOW SERVER_VERSION"));
webmaster@1: }
webmaster@1:
webmaster@1: /**
webmaster@1: * Initialize a database connection.
webmaster@1: */
webmaster@1: function db_connect($url) {
webmaster@1: // Check if PostgreSQL support is present in PHP
webmaster@1: if (!function_exists('pg_connect')) {
webmaster@1: _db_error_page('Unable to use the PostgreSQL database because the PostgreSQL extension for PHP is not installed. Check your php.ini
to see how you can enable it.');
webmaster@1: }
webmaster@1:
webmaster@1: $url = parse_url($url);
webmaster@1: $conn_string = '';
webmaster@1:
webmaster@1: // Decode url-encoded information in the db connection string
webmaster@1: if (isset($url['user'])) {
webmaster@1: $conn_string .= ' user='. urldecode($url['user']);
webmaster@1: }
webmaster@1: if (isset($url['pass'])) {
webmaster@1: $conn_string .= ' password='. urldecode($url['pass']);
webmaster@1: }
webmaster@1: if (isset($url['host'])) {
webmaster@1: $conn_string .= ' host='. urldecode($url['host']);
webmaster@1: }
webmaster@1: if (isset($url['path'])) {
webmaster@1: $conn_string .= ' dbname='. substr(urldecode($url['path']), 1);
webmaster@1: }
webmaster@1: if (isset($url['port'])) {
webmaster@1: $conn_string .= ' port='. urldecode($url['port']);
webmaster@1: }
webmaster@1:
webmaster@1: // pg_last_error() does not return a useful error message for database
webmaster@1: // connection errors. We must turn on error tracking to get at a good error
webmaster@1: // message, which will be stored in $php_errormsg.
webmaster@1: $track_errors_previous = ini_get('track_errors');
webmaster@1: ini_set('track_errors', 1);
webmaster@1:
webmaster@1: $connection = @pg_connect($conn_string);
webmaster@1: if (!$connection) {
webmaster@1: require_once './includes/unicode.inc';
webmaster@1: _db_error_page(decode_entities($php_errormsg));
webmaster@1: }
webmaster@1:
webmaster@1: // Restore error tracking setting
webmaster@1: ini_set('track_errors', $track_errors_previous);
webmaster@1:
webmaster@15: pg_query($connection, "set client_encoding=\"UTF8\"");
webmaster@1: return $connection;
webmaster@1: }
webmaster@1:
webmaster@1: /**
webmaster@1: * Runs a basic query in the active database.
webmaster@1: *
webmaster@1: * User-supplied arguments to the query should be passed in as separate
webmaster@1: * parameters so that they can be properly escaped to avoid SQL injection
webmaster@1: * attacks.
webmaster@1: *
webmaster@1: * @param $query
webmaster@1: * A string containing an SQL query.
webmaster@1: * @param ...
webmaster@1: * A variable number of arguments which are substituted into the query
webmaster@1: * using printf() syntax. Instead of a variable number of query arguments,
webmaster@1: * you may also pass a single array containing the query arguments.
webmaster@1: *
webmaster@1: * Valid %-modifiers are: %s, %d, %f, %b (binary data, do not enclose
webmaster@1: * in '') and %%.
webmaster@1: *
webmaster@1: * NOTE: using this syntax will cast NULL and FALSE values to decimal 0,
webmaster@1: * and TRUE values to decimal 1.
webmaster@1: *
webmaster@1: * @return
webmaster@1: * A database query result resource, or FALSE if the query was not
webmaster@1: * executed correctly.
webmaster@1: */
webmaster@1: function db_query($query) {
webmaster@1: $args = func_get_args();
webmaster@1: array_shift($args);
webmaster@1: $query = db_prefix_tables($query);
webmaster@1: if (isset($args[0]) and is_array($args[0])) { // 'All arguments in one array' syntax
webmaster@1: $args = $args[0];
webmaster@1: }
webmaster@1: _db_query_callback($args, TRUE);
webmaster@1: $query = preg_replace_callback(DB_QUERY_REGEXP, '_db_query_callback', $query);
webmaster@1: return _db_query($query);
webmaster@1: }
webmaster@1:
webmaster@1: /**
webmaster@1: * Helper function for db_query().
webmaster@1: */
webmaster@1: function _db_query($query, $debug = 0) {
webmaster@1: global $active_db, $last_result, $queries;
webmaster@1:
webmaster@1: if (variable_get('dev_query', 0)) {
webmaster@1: list($usec, $sec) = explode(' ', microtime());
webmaster@1: $timer = (float)$usec + (float)$sec;
webmaster@1: }
webmaster@1:
webmaster@1: $last_result = pg_query($active_db, $query);
webmaster@1:
webmaster@1: if (variable_get('dev_query', 0)) {
webmaster@1: $bt = debug_backtrace();
webmaster@1: $query = $bt[2]['function'] ."\n". $query;
webmaster@1: list($usec, $sec) = explode(' ', microtime());
webmaster@1: $stop = (float)$usec + (float)$sec;
webmaster@1: $diff = $stop - $timer;
webmaster@1: $queries[] = array($query, $diff);
webmaster@1: }
webmaster@1:
webmaster@1: if ($debug) {
webmaster@1: print '
query: '. $query .'
error:'. pg_last_error($active_db) .'
';
webmaster@1: }
webmaster@1:
webmaster@1: if ($last_result !== FALSE) {
webmaster@1: return $last_result;
webmaster@1: }
webmaster@1: else {
webmaster@1: // Indicate to drupal_error_handler that this is a database error.
webmaster@1: ${DB_ERROR} = TRUE;
webmaster@1: trigger_error(check_plain(pg_last_error($active_db) ."\nquery: ". $query), E_USER_WARNING);
webmaster@1: return FALSE;
webmaster@1: }
webmaster@1: }
webmaster@1:
webmaster@1: /**
webmaster@1: * Fetch one result row from the previous query as an object.
webmaster@1: *
webmaster@1: * @param $result
webmaster@1: * A database query result resource, as returned from db_query().
webmaster@1: * @return
webmaster@1: * An object representing the next row of the result, or FALSE. The attributes
webmaster@1: * of this object are the table fields selected by the query.
webmaster@1: */
webmaster@1: function db_fetch_object($result) {
webmaster@1: if ($result) {
webmaster@1: return pg_fetch_object($result);
webmaster@1: }
webmaster@1: }
webmaster@1:
webmaster@1: /**
webmaster@1: * Fetch one result row from the previous query as an array.
webmaster@1: *
webmaster@1: * @param $result
webmaster@1: * A database query result resource, as returned from db_query().
webmaster@1: * @return
webmaster@1: * An associative array representing the next row of the result, or FALSE.
webmaster@1: * The keys of this object are the names of the table fields selected by the
webmaster@1: * query, and the values are the field values for this result row.
webmaster@1: */
webmaster@1: function db_fetch_array($result) {
webmaster@1: if ($result) {
webmaster@1: return pg_fetch_assoc($result);
webmaster@1: }
webmaster@1: }
webmaster@1:
webmaster@1: /**
webmaster@1: * Return an individual result field from the previous query.
webmaster@1: *
webmaster@1: * Only use this function if exactly one field is being selected; otherwise,
webmaster@1: * use db_fetch_object() or db_fetch_array().
webmaster@1: *
webmaster@1: * @param $result
webmaster@1: * A database query result resource, as returned from db_query().
webmaster@1: * @return
webmaster@1: * The resulting field or FALSE.
webmaster@1: */
webmaster@1: function db_result($result) {
webmaster@1: if ($result && pg_num_rows($result) > 0) {
webmaster@1: $array = pg_fetch_row($result);
webmaster@1: return $array[0];
webmaster@1: }
webmaster@1: return FALSE;
webmaster@1: }
webmaster@1:
webmaster@1: /**
webmaster@1: * Determine whether the previous query caused an error.
webmaster@1: */
webmaster@1: function db_error() {
webmaster@1: global $active_db;
webmaster@1: return pg_last_error($active_db);
webmaster@1: }
webmaster@1:
webmaster@1: /**
webmaster@1: * Returns the last insert id. This function is thread safe.
webmaster@1: *
webmaster@1: * @param $table
webmaster@1: * The name of the table you inserted into.
webmaster@1: * @param $field
webmaster@1: * The name of the autoincrement field.
webmaster@1: */
webmaster@1: function db_last_insert_id($table, $field) {
webmaster@1: return db_result(db_query("SELECT CURRVAL('{". db_escape_table($table) ."}_". db_escape_table($field) ."_seq')"));
webmaster@1: }
webmaster@1:
webmaster@1: /**
webmaster@1: * Determine the number of rows changed by the preceding query.
webmaster@1: */
webmaster@1: function db_affected_rows() {
webmaster@1: global $last_result;
webmaster@1: return empty($last_result) ? 0 : pg_affected_rows($last_result);
webmaster@1: }
webmaster@1:
webmaster@1: /**
webmaster@1: * Runs a limited-range query in the active database.
webmaster@1: *
webmaster@1: * Use this as a substitute for db_query() when a subset of the query
webmaster@1: * is to be returned.
webmaster@1: * User-supplied arguments to the query should be passed in as separate
webmaster@1: * parameters so that they can be properly escaped to avoid SQL injection
webmaster@1: * attacks.
webmaster@1: *
webmaster@1: * @param $query
webmaster@1: * A string containing an SQL query.
webmaster@1: * @param ...
webmaster@1: * A variable number of arguments which are substituted into the query
webmaster@1: * using printf() syntax. Instead of a variable number of query arguments,
webmaster@1: * you may also pass a single array containing the query arguments.
webmaster@1: * Valid %-modifiers are: %s, %d, %f, %b (binary data, do not enclose
webmaster@1: * in '') and %%.
webmaster@1: *
webmaster@1: * NOTE: using this syntax will cast NULL and FALSE values to decimal 0,
webmaster@1: * and TRUE values to decimal 1.
webmaster@1: *
webmaster@1: * @param $from
webmaster@1: * The first result row to return.
webmaster@1: * @param $count
webmaster@1: * The maximum number of result rows to return.
webmaster@1: * @return
webmaster@1: * A database query result resource, or FALSE if the query was not executed
webmaster@1: * correctly.
webmaster@1: */
webmaster@1: function db_query_range($query) {
webmaster@1: $args = func_get_args();
webmaster@1: $count = array_pop($args);
webmaster@1: $from = array_pop($args);
webmaster@1: array_shift($args);
webmaster@1:
webmaster@1: $query = db_prefix_tables($query);
webmaster@1: if (isset($args[0]) and is_array($args[0])) { // 'All arguments in one array' syntax
webmaster@1: $args = $args[0];
webmaster@1: }
webmaster@1: _db_query_callback($args, TRUE);
webmaster@1: $query = preg_replace_callback(DB_QUERY_REGEXP, '_db_query_callback', $query);
webmaster@1: $query .= ' LIMIT '. (int)$count .' OFFSET '. (int)$from;
webmaster@1: return _db_query($query);
webmaster@1: }
webmaster@1:
webmaster@1: /**
webmaster@1: * Runs a SELECT query and stores its results in a temporary table.
webmaster@1: *
webmaster@1: * Use this as a substitute for db_query() when the results need to stored
webmaster@1: * in a temporary table. Temporary tables exist for the duration of the page
webmaster@1: * request.
webmaster@1: * User-supplied arguments to the query should be passed in as separate parameters
webmaster@1: * so that they can be properly escaped to avoid SQL injection attacks.
webmaster@1: *
webmaster@1: * Note that if you need to know how many results were returned, you should do
webmaster@1: * a SELECT COUNT(*) on the temporary table afterwards. db_affected_rows() does
webmaster@1: * not give consistent result across different database types in this case.
webmaster@1: *
webmaster@1: * @param $query
webmaster@1: * A string containing a normal SELECT SQL query.
webmaster@1: * @param ...
webmaster@1: * A variable number of arguments which are substituted into the query
webmaster@1: * using printf() syntax. The query arguments can be enclosed in one
webmaster@1: * array instead.
webmaster@1: * Valid %-modifiers are: %s, %d, %f, %b (binary data, do not enclose
webmaster@1: * in '') and %%.
webmaster@1: *
webmaster@1: * NOTE: using this syntax will cast NULL and FALSE values to decimal 0,
webmaster@1: * and TRUE values to decimal 1.
webmaster@1: *
webmaster@1: * @param $table
webmaster@1: * The name of the temporary table to select into. This name will not be
webmaster@1: * prefixed as there is no risk of collision.
webmaster@1: * @return
webmaster@1: * A database query result resource, or FALSE if the query was not executed
webmaster@1: * correctly.
webmaster@1: */
webmaster@1: function db_query_temporary($query) {
webmaster@1: $args = func_get_args();
webmaster@1: $tablename = array_pop($args);
webmaster@1: array_shift($args);
webmaster@1:
webmaster@1: $query = preg_replace('/^SELECT/i', 'CREATE TEMPORARY TABLE '. $tablename .' AS SELECT', db_prefix_tables($query));
webmaster@1: if (isset($args[0]) and is_array($args[0])) { // 'All arguments in one array' syntax
webmaster@1: $args = $args[0];
webmaster@1: }
webmaster@1: _db_query_callback($args, TRUE);
webmaster@1: $query = preg_replace_callback(DB_QUERY_REGEXP, '_db_query_callback', $query);
webmaster@1: return _db_query($query);
webmaster@1: }
webmaster@1:
webmaster@1: /**
webmaster@1: * Returns a properly formatted Binary Large OBject value.
webmaster@1: * In case of PostgreSQL encodes data for insert into bytea field.
webmaster@1: *
webmaster@1: * @param $data
webmaster@1: * Data to encode.
webmaster@1: * @return
webmaster@1: * Encoded data.
webmaster@1: */
webmaster@1: function db_encode_blob($data) {
webmaster@1: return "'". pg_escape_bytea($data) ."'";
webmaster@1: }
webmaster@1:
webmaster@1: /**
webmaster@1: * Returns text from a Binary Large OBject value.
webmaster@1: * In case of PostgreSQL decodes data after select from bytea field.
webmaster@1: *
webmaster@1: * @param $data
webmaster@1: * Data to decode.
webmaster@1: * @return
webmaster@1: * Decoded data.
webmaster@1: */
webmaster@1: function db_decode_blob($data) {
webmaster@1: return pg_unescape_bytea($data);
webmaster@1: }
webmaster@1:
webmaster@1: /**
webmaster@1: * Prepare user input for use in a database query, preventing SQL injection attacks.
webmaster@1: * Note: This function requires PostgreSQL 7.2 or later.
webmaster@1: */
webmaster@1: function db_escape_string($text) {
webmaster@1: return pg_escape_string($text);
webmaster@1: }
webmaster@1:
webmaster@1: /**
webmaster@1: * Lock a table.
webmaster@1: * This function automatically starts a transaction.
webmaster@1: */
webmaster@1: function db_lock_table($table) {
webmaster@1: db_query('BEGIN; LOCK TABLE {'. db_escape_table($table) .'} IN EXCLUSIVE MODE');
webmaster@1: }
webmaster@1:
webmaster@1: /**
webmaster@1: * Unlock all locked tables.
webmaster@1: * This function automatically commits a transaction.
webmaster@1: */
webmaster@1: function db_unlock_tables() {
webmaster@1: db_query('COMMIT');
webmaster@1: }
webmaster@1:
webmaster@1: /**
webmaster@1: * Check if a table exists.
webmaster@1: */
webmaster@1: function db_table_exists($table) {
webmaster@1: return (bool) db_result(db_query("SELECT COUNT(*) FROM pg_class WHERE relname = '{". db_escape_table($table) ."}'"));
webmaster@1: }
webmaster@1:
webmaster@1: /**
webmaster@1: * Check if a column exists in the given table.
webmaster@1: */
webmaster@1: function db_column_exists($table, $column) {
webmaster@1: return (bool) db_result(db_query("SELECT COUNT(pg_attribute.attname) FROM pg_class, pg_attribute WHERE pg_attribute.attrelid = pg_class.oid AND pg_class.relname = '{". db_escape_table($table) ."}' AND attname = '". db_escape_table($column) ."'"));
webmaster@1: }
webmaster@1:
webmaster@1: /**
webmaster@1: * Verify if the database is set up correctly.
webmaster@1: */
webmaster@1: function db_check_setup() {
webmaster@1: $t = get_t();
webmaster@1:
webmaster@1: $encoding = db_result(db_query('SHOW server_encoding'));
webmaster@1: if (!in_array(strtolower($encoding), array('unicode', 'utf8'))) {
webmaster@1: drupal_set_message($t('Your PostgreSQL database is set up with the wrong character encoding (%encoding). It is possible it will not work as expected. It is advised to recreate it with UTF-8/Unicode encoding. More information can be found in the PostgreSQL documentation.', array('%encoding' => $encoding, '@url' => 'http://www.postgresql.org/docs/7.4/interactive/multibyte.html')), 'status');
webmaster@1: }
webmaster@1: }
webmaster@1:
webmaster@1: /**
webmaster@1: * Wraps the given table.field entry with a DISTINCT(). The wrapper is added to
webmaster@1: * the SELECT list entry of the given query and the resulting query is returned.
webmaster@1: * This function only applies the wrapper if a DISTINCT doesn't already exist in
webmaster@1: * the query.
webmaster@1: *
webmaster@1: * @param $table Table containing the field to set as DISTINCT
webmaster@1: * @param $field Field to set as DISTINCT
webmaster@1: * @param $query Query to apply the wrapper to
webmaster@1: * @return SQL query with the DISTINCT wrapper surrounding the given table.field.
webmaster@1: */
webmaster@1: function db_distinct_field($table, $field, $query) {
webmaster@7: if (!preg_match('/FROM\s+\S+\s+AS/si', $query)
webmaster@7: && !preg_match('/DISTINCT\s+ON\s*\(\s*(' . $table . '\s*\.\s*)?' . $field . '\s*\)/si', $query)
webmaster@7: && !preg_match('/DISTINCT[ (]' . $field . '/si', $query)
webmaster@7: && preg_match('/(.*FROM\s+)(.*?\s)(\s*(WHERE|GROUP|HAVING|ORDER|LIMIT|FOR).*)/Asi', $query, $m)) {
webmaster@7: $query = $m[1];
webmaster@7: $query .= preg_replace('/([\{\w+\}]+)\s+(' . $table . ')\s/Usi', '(SELECT DISTINCT ON (' . $field . ') * FROM \1) \2 ', $m[2]);
webmaster@7: $query .= $m[3];
webmaster@7: }
webmaster@1: return $query;
webmaster@1: }
webmaster@1:
webmaster@1: /**
webmaster@1: * @} End of "ingroup database".
webmaster@1: */
webmaster@1:
webmaster@1: /**
webmaster@1: * @ingroup schemaapi
webmaster@1: * @{
webmaster@1: */
webmaster@1:
webmaster@1: /**
webmaster@1: * This maps a generic data type in combination with its data size
webmaster@1: * to the engine-specific data type.
webmaster@1: */
webmaster@1: function db_type_map() {
webmaster@1: // Put :normal last so it gets preserved by array_flip. This makes
webmaster@1: // it much easier for modules (such as schema.module) to map
webmaster@1: // database types back into schema types.
webmaster@1: $map = array(
webmaster@1: 'varchar:normal' => 'varchar',
webmaster@1: 'char:normal' => 'character',
webmaster@1:
webmaster@1: 'text:tiny' => 'text',
webmaster@1: 'text:small' => 'text',
webmaster@1: 'text:medium' => 'text',
webmaster@1: 'text:big' => 'text',
webmaster@1: 'text:normal' => 'text',
webmaster@1:
webmaster@1: 'int:tiny' => 'smallint',
webmaster@1: 'int:small' => 'smallint',
webmaster@1: 'int:medium' => 'int',
webmaster@1: 'int:big' => 'bigint',
webmaster@1: 'int:normal' => 'int',
webmaster@1:
webmaster@1: 'float:tiny' => 'real',
webmaster@1: 'float:small' => 'real',
webmaster@1: 'float:medium' => 'real',
webmaster@1: 'float:big' => 'double precision',
webmaster@1: 'float:normal' => 'real',
webmaster@1:
webmaster@1: 'numeric:normal' => 'numeric',
webmaster@1:
webmaster@1: 'blob:big' => 'bytea',
webmaster@1: 'blob:normal' => 'bytea',
webmaster@1:
webmaster@1: 'datetime:normal' => 'timestamp',
webmaster@1:
webmaster@1: 'serial:tiny' => 'serial',
webmaster@1: 'serial:small' => 'serial',
webmaster@1: 'serial:medium' => 'serial',
webmaster@1: 'serial:big' => 'bigserial',
webmaster@1: 'serial:normal' => 'serial',
webmaster@1: );
webmaster@1: return $map;
webmaster@1: }
webmaster@1:
webmaster@1: /**
webmaster@1: * Generate SQL to create a new table from a Drupal schema definition.
webmaster@1: *
webmaster@1: * @param $name
webmaster@1: * The name of the table to create.
webmaster@1: * @param $table
webmaster@1: * A Schema API table definition array.
webmaster@1: * @return
webmaster@1: * An array of SQL statements to create the table.
webmaster@1: */
webmaster@1: function db_create_table_sql($name, $table) {
webmaster@1: $sql_fields = array();
webmaster@1: foreach ($table['fields'] as $field_name => $field) {
webmaster@1: $sql_fields[] = _db_create_field_sql($field_name, _db_process_field($field));
webmaster@1: }
webmaster@1:
webmaster@1: $sql_keys = array();
webmaster@1: if (isset($table['primary key']) && is_array($table['primary key'])) {
webmaster@1: $sql_keys[] = 'PRIMARY KEY ('. implode(', ', $table['primary key']) .')';
webmaster@1: }
webmaster@1: if (isset($table['unique keys']) && is_array($table['unique keys'])) {
webmaster@1: foreach ($table['unique keys'] as $key_name => $key) {
webmaster@1: $sql_keys[] = 'CONSTRAINT {'. $name .'}_'. $key_name .'_key UNIQUE ('. implode(', ', $key) .')';
webmaster@1: }
webmaster@1: }
webmaster@1:
webmaster@1: $sql = "CREATE TABLE {". $name ."} (\n\t";
webmaster@1: $sql .= implode(",\n\t", $sql_fields);
webmaster@1: if (count($sql_keys) > 0) {
webmaster@1: $sql .= ",\n\t";
webmaster@1: }
webmaster@1: $sql .= implode(",\n\t", $sql_keys);
webmaster@1: $sql .= "\n)";
webmaster@1: $statements[] = $sql;
webmaster@1:
webmaster@1: if (isset($table['indexes']) && is_array($table['indexes'])) {
webmaster@1: foreach ($table['indexes'] as $key_name => $key) {
webmaster@1: $statements[] = _db_create_index_sql($name, $key_name, $key);
webmaster@1: }
webmaster@1: }
webmaster@1:
webmaster@1: return $statements;
webmaster@1: }
webmaster@1:
webmaster@1: function _db_create_index_sql($table, $name, $fields) {
webmaster@1: $query = 'CREATE INDEX {'. $table .'}_'. $name .'_idx ON {'. $table .'} (';
webmaster@1: $query .= _db_create_key_sql($fields) .')';
webmaster@1: return $query;
webmaster@1: }
webmaster@1:
webmaster@1: function _db_create_key_sql($fields) {
webmaster@1: $ret = array();
webmaster@1: foreach ($fields as $field) {
webmaster@1: if (is_array($field)) {
webmaster@1: $ret[] = 'substr('. $field[0] .', 1, '. $field[1] .')';
webmaster@1: }
webmaster@1: else {
webmaster@1: $ret[] = $field;
webmaster@1: }
webmaster@1: }
webmaster@1: return implode(', ', $ret);
webmaster@1: }
webmaster@1:
webmaster@1: function _db_create_keys(&$ret, $table, $new_keys) {
webmaster@1: if (isset($new_keys['primary key'])) {
webmaster@1: db_add_primary_key($ret, $table, $new_keys['primary key']);
webmaster@1: }
webmaster@1: if (isset($new_keys['unique keys'])) {
webmaster@1: foreach ($new_keys['unique keys'] as $name => $fields) {
webmaster@1: db_add_unique_key($ret, $table, $name, $fields);
webmaster@1: }
webmaster@1: }
webmaster@1: if (isset($new_keys['indexes'])) {
webmaster@1: foreach ($new_keys['indexes'] as $name => $fields) {
webmaster@1: db_add_index($ret, $table, $name, $fields);
webmaster@1: }
webmaster@1: }
webmaster@1: }
webmaster@1:
webmaster@1: /**
webmaster@1: * Set database-engine specific properties for a field.
webmaster@1: *
webmaster@1: * @param $field
webmaster@1: * A field description array, as specified in the schema documentation.
webmaster@1: */
webmaster@1: function _db_process_field($field) {
webmaster@1: if (!isset($field['size'])) {
webmaster@1: $field['size'] = 'normal';
webmaster@1: }
webmaster@1: // Set the correct database-engine specific datatype.
webmaster@1: if (!isset($field['pgsql_type'])) {
webmaster@1: $map = db_type_map();
webmaster@1: $field['pgsql_type'] = $map[$field['type'] .':'. $field['size']];
webmaster@1: }
webmaster@1: if ($field['type'] == 'serial') {
webmaster@1: unset($field['not null']);
webmaster@1: }
webmaster@1: return $field;
webmaster@1: }
webmaster@1:
webmaster@1: /**
webmaster@1: * Create an SQL string for a field to be used in table creation or alteration.
webmaster@1: *
webmaster@1: * Before passing a field out of a schema definition into this function it has
webmaster@1: * to be processed by _db_process_field().
webmaster@1: *
webmaster@1: * @param $name
webmaster@1: * Name of the field.
webmaster@1: * @param $spec
webmaster@1: * The field specification, as per the schema data structure format.
webmaster@1: */
webmaster@1: function _db_create_field_sql($name, $spec) {
webmaster@1: $sql = $name .' '. $spec['pgsql_type'];
webmaster@1:
webmaster@1: if ($spec['type'] == 'serial') {
webmaster@1: unset($spec['not null']);
webmaster@1: }
webmaster@1: if (!empty($spec['unsigned'])) {
webmaster@1: if ($spec['type'] == 'serial') {
webmaster@1: $sql .= " CHECK ($name >= 0)";
webmaster@1: }
webmaster@1: else {
webmaster@1: $sql .= '_unsigned';
webmaster@1: }
webmaster@1: }
webmaster@1:
webmaster@1: if (!empty($spec['length'])) {
webmaster@1: $sql .= '('. $spec['length'] .')';
webmaster@1: }
webmaster@1: elseif (isset($spec['precision']) && isset($spec['scale'])) {
webmaster@1: $sql .= '('. $spec['precision'] .', '. $spec['scale'] .')';
webmaster@1: }
webmaster@1:
webmaster@1: if (isset($spec['not null']) && $spec['not null']) {
webmaster@1: $sql .= ' NOT NULL';
webmaster@1: }
webmaster@1: if (isset($spec['default'])) {
webmaster@1: $default = is_string($spec['default']) ? "'". $spec['default'] ."'" : $spec['default'];
webmaster@1: $sql .= " default $default";
webmaster@1: }
webmaster@1:
webmaster@1: return $sql;
webmaster@1: }
webmaster@1:
webmaster@1: /**
webmaster@1: * Rename a table.
webmaster@1: *
webmaster@1: * @param $ret
webmaster@1: * Array to which query results will be added.
webmaster@1: * @param $table
webmaster@1: * The table to be renamed.
webmaster@1: * @param $new_name
webmaster@1: * The new name for the table.
webmaster@1: */
webmaster@1: function db_rename_table(&$ret, $table, $new_name) {
webmaster@1: $ret[] = update_sql('ALTER TABLE {'. $table .'} RENAME TO {'. $new_name .'}');
webmaster@1: }
webmaster@1:
webmaster@1: /**
webmaster@1: * Drop a table.
webmaster@1: *
webmaster@1: * @param $ret
webmaster@1: * Array to which query results will be added.
webmaster@1: * @param $table
webmaster@1: * The table to be dropped.
webmaster@1: */
webmaster@1: function db_drop_table(&$ret, $table) {
webmaster@1: $ret[] = update_sql('DROP TABLE {'. $table .'}');
webmaster@1: }
webmaster@1:
webmaster@1: /**
webmaster@1: * Add a new field to a table.
webmaster@1: *
webmaster@1: * @param $ret
webmaster@1: * Array to which query results will be added.
webmaster@1: * @param $table
webmaster@1: * Name of the table to be altered.
webmaster@1: * @param $field
webmaster@1: * Name of the field to be added.
webmaster@1: * @param $spec
webmaster@1: * The field specification array, as taken from a schema definition.
webmaster@1: * The specification may also contain the key 'initial', the newly
webmaster@1: * created field will be set to the value of the key in all rows.
webmaster@1: * This is most useful for creating NOT NULL columns with no default
webmaster@1: * value in existing tables.
webmaster@1: * @param $keys_new
webmaster@1: * Optional keys and indexes specification to be created on the
webmaster@1: * table along with adding the field. The format is the same as a
webmaster@1: * table specification but without the 'fields' element. If you are
webmaster@1: * adding a type 'serial' field, you MUST specify at least one key
webmaster@1: * or index including it in this array. @see db_change_field for more
webmaster@1: * explanation why.
webmaster@1: */
webmaster@1: function db_add_field(&$ret, $table, $field, $spec, $new_keys = array()) {
webmaster@1: $fixnull = FALSE;
webmaster@1: if (!empty($spec['not null']) && !isset($spec['default'])) {
webmaster@1: $fixnull = TRUE;
webmaster@1: $spec['not null'] = FALSE;
webmaster@1: }
webmaster@1: $query = 'ALTER TABLE {'. $table .'} ADD COLUMN ';
webmaster@1: $query .= _db_create_field_sql($field, _db_process_field($spec));
webmaster@1: $ret[] = update_sql($query);
webmaster@1: if (isset($spec['initial'])) {
webmaster@1: // All this because update_sql does not support %-placeholders.
webmaster@1: $sql = 'UPDATE {'. $table .'} SET '. $field .' = '. db_type_placeholder($spec['type']);
webmaster@1: $result = db_query($sql, $spec['initial']);
webmaster@1: $ret[] = array('success' => $result !== FALSE, 'query' => check_plain($sql .' ('. $spec['initial'] .')'));
webmaster@1: }
webmaster@1: if ($fixnull) {
webmaster@1: $ret[] = update_sql("ALTER TABLE {". $table ."} ALTER $field SET NOT NULL");
webmaster@1: }
webmaster@1: if (isset($new_keys)) {
webmaster@1: _db_create_keys($ret, $table, $new_keys);
webmaster@1: }
webmaster@1: }
webmaster@1:
webmaster@1: /**
webmaster@1: * Drop a field.
webmaster@1: *
webmaster@1: * @param $ret
webmaster@1: * Array to which query results will be added.
webmaster@1: * @param $table
webmaster@1: * The table to be altered.
webmaster@1: * @param $field
webmaster@1: * The field to be dropped.
webmaster@1: */
webmaster@1: function db_drop_field(&$ret, $table, $field) {
webmaster@1: $ret[] = update_sql('ALTER TABLE {'. $table .'} DROP COLUMN '. $field);
webmaster@1: }
webmaster@1:
webmaster@1: /**
webmaster@1: * Set the default value for a field.
webmaster@1: *
webmaster@1: * @param $ret
webmaster@1: * Array to which query results will be added.
webmaster@1: * @param $table
webmaster@1: * The table to be altered.
webmaster@1: * @param $field
webmaster@1: * The field to be altered.
webmaster@1: * @param $default
webmaster@1: * Default value to be set. NULL for 'default NULL'.
webmaster@1: */
webmaster@1: function db_field_set_default(&$ret, $table, $field, $default) {
webmaster@1: if ($default == NULL) {
webmaster@1: $default = 'NULL';
webmaster@1: }
webmaster@1: else {
webmaster@1: $default = is_string($default) ? "'$default'" : $default;
webmaster@1: }
webmaster@1:
webmaster@1: $ret[] = update_sql('ALTER TABLE {'. $table .'} ALTER COLUMN '. $field .' SET DEFAULT '. $default);
webmaster@1: }
webmaster@1:
webmaster@1: /**
webmaster@1: * Set a field to have no default value.
webmaster@1: *
webmaster@1: * @param $ret
webmaster@1: * Array to which query results will be added.
webmaster@1: * @param $table
webmaster@1: * The table to be altered.
webmaster@1: * @param $field
webmaster@1: * The field to be altered.
webmaster@1: */
webmaster@1: function db_field_set_no_default(&$ret, $table, $field) {
webmaster@1: $ret[] = update_sql('ALTER TABLE {'. $table .'} ALTER COLUMN '. $field .' DROP DEFAULT');
webmaster@1: }
webmaster@1:
webmaster@1: /**
webmaster@1: * Add a primary key.
webmaster@1: *
webmaster@1: * @param $ret
webmaster@1: * Array to which query results will be added.
webmaster@1: * @param $table
webmaster@1: * The table to be altered.
webmaster@1: * @param $fields
webmaster@1: * Fields for the primary key.
webmaster@1: */
webmaster@1: function db_add_primary_key(&$ret, $table, $fields) {
webmaster@1: $ret[] = update_sql('ALTER TABLE {'. $table .'} ADD PRIMARY KEY ('.
webmaster@1: implode(',', $fields) .')');
webmaster@1: }
webmaster@1:
webmaster@1: /**
webmaster@1: * Drop the primary key.
webmaster@1: *
webmaster@1: * @param $ret
webmaster@1: * Array to which query results will be added.
webmaster@1: * @param $table
webmaster@1: * The table to be altered.
webmaster@1: */
webmaster@1: function db_drop_primary_key(&$ret, $table) {
webmaster@1: $ret[] = update_sql('ALTER TABLE {'. $table .'} DROP CONSTRAINT {'. $table .'}_pkey');
webmaster@1: }
webmaster@1:
webmaster@1: /**
webmaster@1: * Add a unique key.
webmaster@1: *
webmaster@1: * @param $ret
webmaster@1: * Array to which query results will be added.
webmaster@1: * @param $table
webmaster@1: * The table to be altered.
webmaster@1: * @param $name
webmaster@1: * The name of the key.
webmaster@1: * @param $fields
webmaster@1: * An array of field names.
webmaster@1: */
webmaster@1: function db_add_unique_key(&$ret, $table, $name, $fields) {
webmaster@1: $name = '{'. $table .'}_'. $name .'_key';
webmaster@1: $ret[] = update_sql('ALTER TABLE {'. $table .'} ADD CONSTRAINT '.
webmaster@1: $name .' UNIQUE ('. implode(',', $fields) .')');
webmaster@1: }
webmaster@1:
webmaster@1: /**
webmaster@1: * Drop a unique key.
webmaster@1: *
webmaster@1: * @param $ret
webmaster@1: * Array to which query results will be added.
webmaster@1: * @param $table
webmaster@1: * The table to be altered.
webmaster@1: * @param $name
webmaster@1: * The name of the key.
webmaster@1: */
webmaster@1: function db_drop_unique_key(&$ret, $table, $name) {
webmaster@1: $name = '{'. $table .'}_'. $name .'_key';
webmaster@1: $ret[] = update_sql('ALTER TABLE {'. $table .'} DROP CONSTRAINT '. $name);
webmaster@1: }
webmaster@1:
webmaster@1: /**
webmaster@1: * Add an index.
webmaster@1: *
webmaster@1: * @param $ret
webmaster@1: * Array to which query results will be added.
webmaster@1: * @param $table
webmaster@1: * The table to be altered.
webmaster@1: * @param $name
webmaster@1: * The name of the index.
webmaster@1: * @param $fields
webmaster@1: * An array of field names.
webmaster@1: */
webmaster@1: function db_add_index(&$ret, $table, $name, $fields) {
webmaster@1: $ret[] = update_sql(_db_create_index_sql($table, $name, $fields));
webmaster@1: }
webmaster@1:
webmaster@1: /**
webmaster@1: * Drop an index.
webmaster@1: *
webmaster@1: * @param $ret
webmaster@1: * Array to which query results will be added.
webmaster@1: * @param $table
webmaster@1: * The table to be altered.
webmaster@1: * @param $name
webmaster@1: * The name of the index.
webmaster@1: */
webmaster@1: function db_drop_index(&$ret, $table, $name) {
webmaster@1: $name = '{'. $table .'}_'. $name .'_idx';
webmaster@1: $ret[] = update_sql('DROP INDEX '. $name);
webmaster@1: }
webmaster@1:
webmaster@1: /**
webmaster@1: * Change a field definition.
webmaster@1: *
webmaster@1: * IMPORTANT NOTE: To maintain database portability, you have to explicitly
webmaster@1: * recreate all indices and primary keys that are using the changed field.
webmaster@1: *
webmaster@1: * That means that you have to drop all affected keys and indexes with
webmaster@1: * db_drop_{primary_key,unique_key,index}() before calling db_change_field().
webmaster@1: * To recreate the keys and indices, pass the key definitions as the
webmaster@1: * optional $new_keys argument directly to db_change_field().
webmaster@1: *
webmaster@1: * For example, suppose you have:
webmaster@1: * @code
webmaster@1: * $schema['foo'] = array(
webmaster@1: * 'fields' => array(
webmaster@1: * 'bar' => array('type' => 'int', 'not null' => TRUE)
webmaster@1: * ),
webmaster@1: * 'primary key' => array('bar')
webmaster@1: * );
webmaster@1: * @endcode
webmaster@1: * and you want to change foo.bar to be type serial, leaving it as the
webmaster@1: * primary key. The correct sequence is:
webmaster@1: * @code
webmaster@1: * db_drop_primary_key($ret, 'foo');
webmaster@1: * db_change_field($ret, 'foo', 'bar', 'bar',
webmaster@1: * array('type' => 'serial', 'not null' => TRUE),
webmaster@1: * array('primary key' => array('bar')));
webmaster@1: * @endcode
webmaster@1: *
webmaster@1: * The reasons for this are due to the different database engines:
webmaster@1: *
webmaster@1: * On PostgreSQL, changing a field definition involves adding a new field
webmaster@1: * and dropping an old one which* causes any indices, primary keys and
webmaster@1: * sequences (from serial-type fields) that use the changed field to be dropped.
webmaster@1: *
webmaster@1: * On MySQL, all type 'serial' fields must be part of at least one key
webmaster@1: * or index as soon as they are created. You cannot use
webmaster@1: * db_add_{primary_key,unique_key,index}() for this purpose because
webmaster@1: * the ALTER TABLE command will fail to add the column without a key
webmaster@1: * or index specification. The solution is to use the optional
webmaster@1: * $new_keys argument to create the key or index at the same time as
webmaster@1: * field.
webmaster@1: *
webmaster@1: * You could use db_add_{primary_key,unique_key,index}() in all cases
webmaster@1: * unless you are converting a field to be type serial. You can use
webmaster@1: * the $new_keys argument in all cases.
webmaster@1: *
webmaster@1: * @param $ret
webmaster@1: * Array to which query results will be added.
webmaster@1: * @param $table
webmaster@1: * Name of the table.
webmaster@1: * @param $field
webmaster@1: * Name of the field to change.
webmaster@1: * @param $field_new
webmaster@1: * New name for the field (set to the same as $field if you don't want to change the name).
webmaster@1: * @param $spec
webmaster@1: * The field specification for the new field.
webmaster@1: * @param $new_keys
webmaster@1: * Optional keys and indexes specification to be created on the
webmaster@1: * table along with changing the field. The format is the same as a
webmaster@1: * table specification but without the 'fields' element.
webmaster@1: */
webmaster@1: function db_change_field(&$ret, $table, $field, $field_new, $spec, $new_keys = array()) {
webmaster@1: $ret[] = update_sql("ALTER TABLE {". $table ."} RENAME $field TO ". $field ."_old");
webmaster@1: $not_null = isset($spec['not null']) ? $spec['not null'] : FALSE;
webmaster@1: unset($spec['not null']);
webmaster@1:
webmaster@1: db_add_field($ret, $table, "$field_new", $spec);
webmaster@1:
webmaster@1: $ret[] = update_sql("UPDATE {". $table ."} SET $field_new = ". $field ."_old");
webmaster@1:
webmaster@1: if ($not_null) {
webmaster@1: $ret[] = update_sql("ALTER TABLE {". $table ."} ALTER $field_new SET NOT NULL");
webmaster@1: }
webmaster@1:
webmaster@1: db_drop_field($ret, $table, $field .'_old');
webmaster@1:
webmaster@1: if (isset($new_keys)) {
webmaster@1: _db_create_keys($ret, $table, $new_keys);
webmaster@1: }
webmaster@1: }
webmaster@1:
webmaster@1: /**
webmaster@1: * @} End of "ingroup schemaapi".
webmaster@1: */
webmaster@1: