Manual:Database access

From MediaWiki.org
Jump to: navigation, search

Other languages:
català • ‎Deutsch • ‎English • ‎español • ‎suomi • ‎français • ‎italiano • ‎日本語 • ‎Nederlands • ‎polski • ‎português • ‎português do Brasil

This article provides an overview of database access and general database issues in MediaWiki.

Database layout[edit | edit source]

For information about the MediaWiki database layout, such as a description of the tables and their contents, please see Manual:Database layout and maintenance/tables.sql.

Logging into MySQL[edit | edit source]

In LocalSettings.php you’ll find your wiki’s MySQL password and username, for example:

## Database settings
$wgDBtype           = "mysql";
$wgDBserver         = "localhost";
$wgDBname           =  yourwebsite
$wgDBuser           =  yourwebsite
$wgDBpassword       = LongPassword

With PuTTY (a telnet/SSH client), login by entering the following:

mysql -u <$wgDBuser> -p --database=<$wgDBname>

Replacing <$wgDBuser> and <$wgDBname> with the LocalSettings.php information. You will then be prompted for your password $wgDBpassword after which you will see the mysql> prompt.

Database Abstraction Layer[edit | edit source]

MediaWiki provides a database abstraction layer. Unless you are working on the abstraction layer, you should never directly call PHP's database functions (such as mysql_query() or pg_send_query().)

The abstraction layer is accessed by using the wfGetDB() function. For more detailed documentation on wfGetDB(), see the entry on wfGetDB() in the GlobalFunctions.php file reference.

Typically, wfGetDB() is called with a single parameter, which can be the DB_SLAVE (for read queries) or DB_MASTER (for write queries and read queries that need to have absolutely newest information) constant. The distinction between master and slave is important in a multi-database environment, such as Wikimedia. This function will return you a DatabaseBase object that you can use to access the database. See the #Wrapper functions section below for what you can do with this Database object.

Result wrappers of select queries are arrays whose keys are integers starting at 1. To make a read query, something like this usually suffices:

$dbr = wfGetDB( DB_SLAVE );
$res = $dbr->select( /* ...see docs... */ );
foreach( $res as $row ) {
	...
}

For a write query, use something like:

$dbw = wfGetDB( DB_MASTER );
$dbw->insert( /* ...see docs... */ );

We use the convention $dbr for read and $dbw for write to help you keep track of whether the database object is a slave (read-only) or a master (read/write). If you write to a slave, the world will explode. Or to be precise, a subsequent write query which succeeded on the master may fail when replicated to the slave due to a unique key collision. Replication on the slave will stop and it may take hours to repair the database and get it back online. Setting read_only in my.cnf on the slave will avoid this scenario, but given the dire consequences, we prefer to have as many checks as possible.

Wrapper functions[edit | edit source]

We provide a query() function for raw SQL, but the wrapper functions like select() and insert() are usually more convenient. They can take care of things like table prefixes and escaping for you under some circumstances. If you really need to make your own SQL, please read the documentation for tableName() and addQuotes(). You will need both of them.

Another important reason to use the high level methods rather than constructing your own queries is to ensure that your code will run properly regardless of the database type. Currently there is MySQL and reasonable support for SQLite and PostgreSQL, also somewhat limited for Oracle and DB2, but there could be other databases in the future such as MSSQL or Firebird.

In the following, the available wrapper functions are listed. For a detailed description of the parameters of the wrapper functions, please refer to class DatabaseBase's docs. Particularly see DatabaseBase::select for an explanation of the $table, $vars, $conds, $fname, $options, and $join_conds parameters that are used by many of the other wrapper functions.

function select( $table, $vars, $conds = '', $fname = 'Database::select', $options = array(), $join_conds = array() );
function selectField( $table, $var, $cond = '', $fname = __METHOD__, $options = array() );
function selectRow( $table, $vars, $conds = '', $fname = 'Database::select', $options = array() );
function insert( $table, $a, $fname = 'Database::insert', $options = array() );
function insertSelect( $destTable, $srcTable, $varMap, $conds, $fname = 'Database::insertSelect', $insertOptions = array(), $selectOptions = array() );
function update( $table, $values, $conds, $fname = 'Database::update', $options = array() );
function delete( $table, $conds, $fname = 'Database::delete' );
function deleteJoin( $delTable, $joinTable, $delVar, $joinVar, $conds, $fname = 'Database::deleteJoin' );
function buildLike(/*...*/);

Wrapper function: select()[edit | edit source]

The select() function provides the MediaWiki interface for a SELECT statement. The components of the SELECT statement are coded as parameters of the select() function. An example is

$dbr = wfGetDB( DB_SLAVE );
$res = $dbr->select(
	'category',                                   // $table
	array( 'cat_title', 'cat_pages' ),            // $vars (columns of the table)
	'cat_pages > 0',                              // $conds
	__METHOD__,                                   // $fname = 'Database::select',
	array( 'ORDER BY' => 'cat_title ASC' )        // $options = array()
);

This example corresponds to the query

SELECT cat_title, cat_pages FROM category WHERE cat_pages > 0 ORDER BY cat_title ASC

JOINs are also possible; for example:

$res = $dbw->select(
	array( 'watchlist', 'user_properties' ),
	array( 'wl_user' ),
	array(
		'wl_user != 1' ,
		'wl_namespace' => '0',
		'wl_title' => 'Main_page',
		'up_property' => 'enotifwatchlistpages',
	),
	__METHOD__,
	array(),
	array( 'user_properties' => array( 'INNER JOIN', array(
		'wl_user=up_user' ) ) )
);

This example corresponds to the query

SELECT wl_user FROM `watchlist` INNER JOIN `user_properties` ON ((wl_user=up_user)) WHERE (wl_user != 1) AND wl_namespace = '0' AND wl_title = 'Main_page'
AND up_property = 'enotifwatchlistpages'

Arguments are either single values (such as 'category' and 'cat_pages > 0') or arrays, if more than one value is passed for an argument position (such as array('cat_pages > 0', $myNextCond)). If you pass in strings, you must manually use DatabaseBase::addQuotes() on your values as you construct the string, as the wrapper will not do this for you. The array construction for $conds is somewhat limited; it can only do equality relationships (i.e. WHERE key = 'value').

You can access individual rows of the result using a foreach loop. Once you have a row object, you can use the -> operator to access a specific field. A full example might be

$dbr = wfGetDB( DB_SLAVE );
$res = $dbr->select(
	'category',                                   // $table
	array( 'cat_title', 'cat_pages' ),            // $vars (columns of the table)
	'cat_pages > 0',                              // $conds
	__METHOD__,                                   // $fname = 'Database::select',
	array( 'ORDER BY' => 'cat_title ASC' )        // $options = array()
);        
$output = '';
foreach( $res as $row ) {
        $output .= 'Category ' . $row->cat_title . ' contains ' . $row->cat_pages . " entries.\n";
}

Which will put an alphabetical list of categories with how many entries each category has in the variable $output.

Convenience functions[edit | edit source]

For compatibility with PostgreSQL, insert ids are obtained using nextSequenceValue() and insertId(). The parameter for nextSequenceValue() can be obtained from the CREATE SEQUENCE statement in maintenance/postgres/tables.sql and always follows the format of x_y_seq, with x being the table name (e.g. page) and y being the primary key (e.g. page_id), e.g. page_page_id_seq. For example:

$id = $dbw->nextSequenceValue( 'page_page_id_seq' );
$dbw->insert( 'page', array( 'page_id' => $id ) );
$id = $dbw->insertId();

For some other useful functions, e.g. affectedRows(), numRows(), etc., see Manual:Database.php.

Basic query optimization[edit | edit source]

MediaWiki developers who need to write DB queries should have some understanding of databases and the performance issues associated with them. Patches containing unacceptably slow features will not be accepted. Unindexed queries are generally not welcome in MediaWiki, except in special pages derived from QueryPage. It's a common pitfall for new developers to submit code containing SQL queries which examine huge numbers of rows. Remember that COUNT(*) is O(N), counting rows in a table is like counting beans in a bucket.

Replication[edit | edit source]

The largest installation of MediaWiki, Wikipedia, uses a large set of slave MySQL servers replicating writes made to a master MySQL server. It is important to understand the issues associated with this setup if you want to write code destined for Wikipedia.

It's often the case that the best algorithm to use for a given task depends on whether or not replication is in use. Due to our unabashed Wikipedia-centrism, we often just use the replication-friendly version, but if you like, you can use wfGetLB()->getServerCount() > 1 to check to see if replication is in use.

Lag[edit | edit source]

Lag primarily occurs when large write queries are sent to the master. Writes on the master are executed in parallel, but they are executed in serial when they are replicated to the slaves. The master writes the query to the binlog when the transaction is committed. The slaves poll the binlog and start executing the query as soon as it appears. They can service reads while they are performing a write query, but will not read anything more from the binlog and thus will perform no more writes. This means that if the write query runs for a long time, the slaves will lag behind the master for the time it takes for the write query to complete.

Lag can be exacerbated by high read load. MediaWiki's load balancer will stop sending reads to a slave when it is lagged by more than 30 seconds. If the load ratios are set incorrectly, or if there is too much load generally, this may lead to a slave permanently hovering around 30 seconds lag.

If all slaves are lagged by more than 30 seconds, MediaWiki will stop writing to the database. All edits and other write operations will be refused, with an error returned to the user. This gives the slaves a chance to catch up. Before we had this mechanism, the slaves would regularly lag by several minutes, making review of recent edits difficult.

In addition to this, MediaWiki attempts to ensure that the user sees events occurring on the wiki in chronological order. A few seconds of lag can be tolerated, as long as the user sees a consistent picture from subsequent requests. This is done by saving the master binlog position in the session, and then at the start of each request, waiting for the slave to catch up to that position before doing any reads from it. If this wait times out, reads are allowed anyway, but the request is considered to be in "lagged slave mode". Lagged slave mode can be checked by calling wfGetLB()->getLaggedSlaveMode(). The only practical consequence at present is a warning displayed in the page footer.

Lag avoidance[edit | edit source]

To avoid excessive lag, queries that write large numbers of rows should be split up, generally to write one row at a time. Multi-row INSERT ... SELECT queries are the worst offenders and should be avoided altogether. Instead do the select first and then the insert.

Working with lag[edit | edit source]

Despite our best efforts, it's not practical to guarantee a low-lag environment. Replication lag will usually be less than one second, but may occasionally be up to 30 seconds. For scalability, it's very important to keep load on the master low, so simply sending all your queries to the master is not the answer. So when you have a genuine need for up-to-date data, the following approach is advised:

  1. Do a quick query to the master for a sequence number or timestamp
  2. Run the full query on the slave and check if it matches the data you got from the master
  3. If it doesn't, run the full query on the master

To avoid swamping the master every time the slaves lag, use of this approach should be kept to a minimum. In most cases you should just read from the slave and let the user deal with the delay.

Lock contention[edit | edit source]

Due to the high write rate on Wikipedia (and some other wikis), MediaWiki developers need to be very careful to structure their writes to avoid long-lasting locks. By default, MediaWiki opens a transaction at the first query, and commits it before the output is sent. Locks will be held from the time when the query is done until the commit. So you can reduce lock time by doing as much processing as possible before you do your write queries. Update operations which do not require database access can be delayed until after the commit by adding an object to $wgPostCommitUpdateList.

Often this approach is not good enough, and it becomes necessary to enclose small groups of queries in their own transaction. Use the following syntax:

$dbw = wfGetDB( DB_MASTER );
$dbw->begin();
/* Do queries */
$dbw->commit();

Use of locking reads (e.g. the FOR UPDATE clause) is not advised. They are poorly implemented in InnoDB and will cause regular deadlock errors. It's also surprisingly easy to cripple the wiki with lock contention.

Instead of locking reads, combine your existence checks into your write queries, by using an appropriate condition in the WHERE clause of an UPDATE, or by using unique indexes in combination with INSERT IGNORE. Then use the affected row count to see if the query succeeded.

Database schema[edit | edit source]

Don't forget about indexes when designing databases, things may work smoothly on your test wiki with a dozen of pages, but will bring a real wiki to a halt. See above for details.

For naming conventions, see Manual:Coding conventions/Database.

SQLite compatibility[edit | edit source]

When writing MySQL table definitions or upgrade patches, it is important to remember that SQLite shares MySQL's schema, but that works only if definitions are written in a specific way:

  • Primary keys must be declared within main table declaration, but normal keys should be added separately with CREATE INDEX:
Wrong Right
CREATE TABLE /*_*/foo (
    foo_id INT NOT NULL AUTO_INCREMENT,
    foo_text VARCHAR(256),
    PRIMARY KEY(foo_id),
    KEY(foo_text)
);
CREATE TABLE /*_*/foo (
    foo_id INT NOT NULL PRIMARY KEY AUTO_INCREMENT,
    foo_text VARCHAR(256)
) /*$wgDBTableOptions*/;
 
CREATE INDEX /*i*/foo_text ON /*_*/foo (foo_text);

However, primary keys spanning over more than one field should be included in the main table definition:

CREATE TABLE /*_*/foo (
    foo_id INT NOT NULL,
    foo_text VARCHAR(256),
    PRIMARY KEY(foo_id, foo_text)
) /*$wgDBTableOptions*/;
 
CREATE INDEX /*i*/foo_text ON /*_*/foo (foo_text);
  • Don't add more than one column per statement:
Wrong Right
ALTER TABLE /*_*/foo
    ADD foo_bar BLOB,
    ADD foo_baz INT;
ALTER TABLE /*_*/foo ADD foo_bar BLOB;
ALTER TABLE /*_*/foo ADD foo_baz INT;
  • Set explicit defaults when adding NOT NULL columns:
Wrong Right
ALTER TABLE /*_*/foo ADD COLUMN foo_bar VARCHAR(32) BINARY NOT NULL;
ALTER TABLE /*_*/foo ADD COLUMN foo_bar VARCHAR(32) BINARY NOT NULL DEFAULT '';

You can run basic compatibility checks with php sqlite.php --check-syntax filename.sql, or, if you need to test an update patch, php sqlite.php --check-syntax tables.sql filename.sql, assuming that you're in $IP/maintenance/.

See also[edit | edit source]

Databases Engines: MySQLOraclePostgreSQLSQLite
Technical documentation: Schema (tables) – API property associationsField prefixesPrimary key storage in other fieldsWikimedia extension tables
Configuration: SettingsSharing
Development: AccessOptimizationPolicyUpdaterExtension schema updatesPatch file
Core tables: archivecategorycategorylinkschange_tagconfigexternallinksfilearchivehitcounterimageimagelinksinterwikiiwlinksipblocksjobl10n_cachelanglinkslogginglog_searchmsg_resourcemsg_resource_linksmodule_depsobjectcacheoldimagepagepagelinkspage_propspage_restrictionsprotected_titlesquerycachequerycachetwoquerycache_inforecentchangesredirectrevisionsearchindexsitessite_statstag_summarytemplatelinkstexttranscacheupdateloguploadstashuseruser_former_groupsuser_groupsuser_newtalkuser_propertiesvalid_tagwatchlist