Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

Provide explain plan feature #315

Merged
merged 18 commits into from Mar 26, 2012
Merged
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Jump to
Jump to file
Failed to load files.
Diff view
Diff view
1 change: 1 addition & 0 deletions runtime/lib/Propel.php
Expand Up @@ -673,6 +673,7 @@ public static function initConnection($conparams, $name, $defaultClass = Propel:
try {
$con = new $classname($dsn, $user, $password, $driver_options);
$con->setAttribute(PDO::ATTR_ERRMODE, PDO::ERRMODE_EXCEPTION);
$con->setAttribute(PropelPDO::PROPEL_ATTR_CONNECTION_NAME, $name);
} catch (PDOException $e) {
throw new PropelException("Unable to open PDO connection", $e);
}
Expand Down
13 changes: 13 additions & 0 deletions runtime/lib/adapter/DBAdapter.php
Expand Up @@ -580,4 +580,17 @@ public function bindValue(PDOStatement $stmt, $parameter, $value, ColumnMap $cMa

return $stmt->bindValue($parameter, $value, $cMap->getPdoType());
}

/**
* Do Explain Plan for query object or query string
*
* @param PropelPDO $con propel connection
* @param ModelCriteria|string $query query the criteria or the query string
* @throws PropelException if explain plan is not implemented for adapter
* @return PDOStatement A PDO statement executed using the connection, ready to be fetched
*/
public function doExplainPlan(PropelPDO $con, $query)
{
throw new PropelException("Explain plan is not implemented for this adapter");
}
}
32 changes: 31 additions & 1 deletion runtime/lib/adapter/DBMySQL.php
Expand Up @@ -250,4 +250,34 @@ public function prepareParams($params)

return $params;
}
}

/**
* Do Explain Plan for query object or query string
*
* @param PropelPDO $con propel connection
* @param ModelCriteria|string $query query the criteria or the query string
* @throws PropelException
* @return PDOStatement A PDO statement executed using the connection, ready to be fetched
*/
public function doExplainPlan(PropelPDO $con, $query)
{
if ($query instanceof ModelCriteria) {
$params = array();
$dbMap = Propel::getDatabaseMap($query->getDbName());
$sql = BasePeer::createSelectSql($query, $params);
$sql = 'EXPLAIN ' . $sql;
} else {
$sql = 'EXPLAIN ' . $query;
}

$stmt = $con->prepare($sql);

if ($query instanceof ModelCriteria) {
$this->bindValues($stmt, $params, $dbMap);
}

$stmt->execute();

return $stmt;
Copy link
Contributor

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

you should add a blank line before the return statement

}
}
60 changes: 60 additions & 0 deletions runtime/lib/adapter/DBOracle.php
Expand Up @@ -236,4 +236,64 @@ public function bindValue(PDOStatement $stmt, $parameter, $value, ColumnMap $cMa

return $stmt->bindValue($parameter, $value, $cMap->getPdoType());
}

/**
* Do Explain Plan for query object or query string
*
* @param PropelPDO $con propel connection
* @param ModelCriteria|string $query query the criteria or the query string
* @throws PropelException
* @return PDOStatement A PDO statement executed using the connection, ready to be fetched
*/
public function doExplainPlan(PropelPDO $con, $query)
{
$con->beginTransaction();
if ($query instanceof ModelCriteria) {
$params = array();
$dbMap = Propel::getDatabaseMap($query->getDbName());
$sql = BasePeer::createSelectSql($query, $params);
} else {
$sql = $query;
}
// unique id for the query string
$uniqueId = uniqid('Propel', true);

$stmt = $con->prepare($this->getExplainPlanQuery($sql, $uniqueId));

if ($query instanceof ModelCriteria) {
$this->bindValues($stmt, $params, $dbMap);
}

$stmt->execute();
// explain plan is save in a table, data must be commit
$con->commit();

$stmt = $con->prepare($this->getExplainPlanReadQuery($uniqueId));
$stmt->execute();
return $stmt;
}

/**
* Explain Plan compute query getter
*
* @param string $query query to explain
* @param string $uniqueId query unique id
*/
public function getExplainPlanQuery($query, $uniqueId)
{
return sprintf('EXPLAIN PLAN SET STATEMENT_ID = \'%s\' FOR %s', $uniqueId, $query);
}

/**
* Explain Plan read query
*
* @param string $uniqueId
* @return string query unique id
*/
public function getExplainPlanReadQuery($uniqueId)
{
return sprintf('SELECT LEVEL, OPERATION, OPTIONS, COST, CARDINALITY, BYTES
FROM PLAN_TABLE CONNECT BY PRIOR ID = PARENT_ID AND PRIOR STATEMENT_ID = STATEMENT_ID
START WITH ID = 0 AND STATEMENT_ID = \'%s\' ORDER BY ID', $uniqueId);
}
}
3 changes: 3 additions & 0 deletions runtime/lib/connection/DebugPDO.php
Expand Up @@ -85,6 +85,9 @@
* - debugpdo.logging.details.method.pad (default: 28)
* How much horizontal space to reserve for the method name on a log line
*
* - debugpdo.logging.connection (default: false)
* Add connectionName in log used for explains
*
* The order in which the logging details are enabled is significant, since it determines the order in
* which they will appear in the log file.
*
Expand Down
22 changes: 22 additions & 0 deletions runtime/lib/connection/PropelPDO.php
Expand Up @@ -35,6 +35,11 @@ class PropelPDO extends PDO
*/
const PROPEL_ATTR_CACHE_PREPARES = -1;

/**
* Attribute to use to set the connection name usefull for explains
*/
const PROPEL_ATTR_CONNECTION_NAME = -2;

const DEFAULT_SLOW_THRESHOLD = 0.1;
const DEFAULT_ONLYSLOW_ENABLED = false;

Expand Down Expand Up @@ -106,6 +111,13 @@ class PropelPDO extends PDO
*/
protected $configuration;

/**
* The connection name
*
* @var string
*/
protected $connectionName;

/**
* The default value for runtime config item "debugpdo.logging.methods".
*
Expand Down Expand Up @@ -326,6 +338,9 @@ public function setAttribute($attribute, $value)
case self::PROPEL_ATTR_CACHE_PREPARES:
$this->cachePreparedStatements = $value;
break;
case self::PROPEL_ATTR_CONNECTION_NAME:
$this->connectionName = $value;
break;
default:
parent::setAttribute($attribute, $value);
}
Expand All @@ -345,6 +360,9 @@ public function getAttribute($attribute)
case self::PROPEL_ATTR_CACHE_PREPARES:
return $this->cachePreparedStatements;
break;
case self::PROPEL_ATTR_CONNECTION_NAME:
return $this->connectionName;
break;
default:
return parent::getAttribute($attribute);
}
Expand Down Expand Up @@ -724,6 +742,10 @@ protected function getLogPrefix($methodName, $debugSnapshot)
$value = str_pad($methodName, $this->getLoggingConfig('details.method.pad', 28), ' ', STR_PAD_RIGHT);
break;

case 'connection':
$value = $this->connectionName;
break;

default:
$value = 'n/a';
break;
Expand Down
30 changes: 30 additions & 0 deletions runtime/lib/query/ModelCriteria.php
Expand Up @@ -2163,4 +2163,34 @@ public function __clone()
$this->formatter = clone $this->formatter;
}
}

/**
* Make explain plan of the query
*
* @param PropelPDO $con propel connection
* @throws PropelException on error
* @return array array of the explain plan
*/
public function explain($con = null)
{
if ($con === null) {
$con = Propel::getConnection($this->getDbName());
}
$this->basePreSelect($con);

// check that the columns of the main class are already added (if this is the primary ModelCriteria)
if (!$this->hasSelectClause() && !$this->getPrimaryCriteria()) {
$this->addSelfSelectColumns();
}
$this->configureSelectColumns();

$db = Propel::getDB($this->getDbName());
try {
$stmt = $db->doExplainPlan($con, $this);
return $stmt->fetchAll(PDO::FETCH_ASSOC);
} catch (Exception $e) {
Propel::log($e->getMessage(), Propel::LOG_ERR);
throw new PropelException('Unable to execute query explain plan', $e);
}
}
}
7 changes: 6 additions & 1 deletion test/testsuite/runtime/adapter/DBOracleTest.php
Expand Up @@ -73,5 +73,10 @@ public function testCreateSelectSqlPart()
$this->assertEquals(array('book'), $fromClause, 'createSelectSqlPart() adds the tables from the select columns to the from clause');
}


public function testGetExplainPlanQuery()
{
$db = new DBOracle();
$explainQuery = $db->getExplainPlanQuery('SELECT B.* FROM (SELECT A.*, rownum AS PROPEL_ROWNUM FROM (SELECT book.ID AS ORA_COL_ALIAS_0, book.TITLE AS ORA_COL_ALIAS_1, book.ISBN AS ORA_COL_ALIAS_2, book.PRICE AS ORA_COL_ALIAS_3, book.PUBLISHER_ID AS ORA_COL_ALIAS_4, book.AUTHOR_ID AS ORA_COL_ALIAS_5, author.ID AS ORA_COL_ALIAS_6, author.FIRST_NAME AS ORA_COL_ALIAS_7, author.LAST_NAME AS ORA_COL_ALIAS_8, author.EMAIL AS ORA_COL_ALIAS_9, author.AGE AS ORA_COL_ALIAS_10, book.PRICE AS BOOK_PRICE FROM book, author) A ) B WHERE B.PROPEL_ROWNUM <= 1', 'iuyiuyiu');
$this->assertEquals('EXPLAIN PLAN SET STATEMENT_ID = \'iuyiuyiu\' FOR SELECT B.* FROM (SELECT A.*, rownum AS PROPEL_ROWNUM FROM (SELECT book.ID AS ORA_COL_ALIAS_0, book.TITLE AS ORA_COL_ALIAS_1, book.ISBN AS ORA_COL_ALIAS_2, book.PRICE AS ORA_COL_ALIAS_3, book.PUBLISHER_ID AS ORA_COL_ALIAS_4, book.AUTHOR_ID AS ORA_COL_ALIAS_5, author.ID AS ORA_COL_ALIAS_6, author.FIRST_NAME AS ORA_COL_ALIAS_7, author.LAST_NAME AS ORA_COL_ALIAS_8, author.EMAIL AS ORA_COL_ALIAS_9, author.AGE AS ORA_COL_ALIAS_10, book.PRICE AS BOOK_PRICE FROM book, author) A ) B WHERE B.PROPEL_ROWNUM <= 1', $explainQuery, 'getExplainPlanQuery() returns a SQL Explain query');
}
}
86 changes: 86 additions & 0 deletions test/testsuite/runtime/query/ExplainPlanTest.php
@@ -0,0 +1,86 @@
<?php

/**
* This file is part of the Propel package.
* For the full copyright and license information, please view the LICENSE
* file that was distributed with this source code.
*
* @license MIT License
*/

require_once dirname(__FILE__) . '/../../../tools/helpers/bookstore/BookstoreTestBase.php';
require_once dirname(__FILE__) . '/../../../tools/helpers/bookstore/BookstoreDataPopulator.php';

/**
* Test class for SubQueryTest.
*
* @author Francois Zaninotto
* @version $Id$
* @package runtime.query
*/
class ExplainPlanTest extends BookstoreTestBase
{
public function testExplainPlanFromObject()
{
BookstoreDataPopulator::depopulate($this->con);
BookstoreDataPopulator::populate($this->con);

$db = Propel::getDb(BookPeer::DATABASE_NAME);

$c = new ModelCriteria('bookstore', 'Book');
$c->join('Book.Author');
$c->where('Author.FirstName = ?', 'Neal');
$c->select('Title');
$explain = $c->explain($this->con);

if ($db instanceof DBMySQL) {
$this->assertEquals(sizeof($explain), 2, 'Explain plan return two lines');

// explain can change sometime, test can't be strict
$this->assertArrayHasKey('select_type',$explain[0], 'Line 1, select_type key exist');
$this->assertArrayHasKey('table',$explain[0], 'Line 1, table key exist');
$this->assertArrayHasKey('type',$explain[0], 'Line 1, type key exist');
$this->assertArrayHasKey('possible_keys',$explain[0], 'Line 1, possible_keys key exist');

$this->assertArrayHasKey('select_type',$explain[1], 'Line 2, select_type key exist');
$this->assertArrayHasKey('table',$explain[1], 'Line 2, table key exist');
$this->assertArrayHasKey('type',$explain[1], 'Line 2, type key exist');
$this->assertArrayHasKey('possible_keys',$explain[1], 'Line 2, possible_keys key exist');
} elseif($db instanceof DBOracle) {
Copy link
Contributor

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

I guess it should be else if

$this->assertTrue(sizeof($explain) > 2, 'Explain plan return more than 2 lines');
} else {
$this->markTestSkipped('Cannot test explain plan on adapter ' . get_class($db));
}
}

public function testExplainPlanFromString()
{
BookstoreDataPopulator::depopulate($this->con);
BookstoreDataPopulator::populate($this->con);

$db = Propel::getDb(BookPeer::DATABASE_NAME);

$query = 'SELECT book.TITLE AS Title FROM book INNER JOIN author ON (book.AUTHOR_ID=author.ID) WHERE author.FIRST_NAME = \'Neal\'';
$stmt = $db->doExplainPlan($this->con, $query);
$explain = $stmt->fetchAll(PDO::FETCH_ASSOC);

if ($db instanceof DBMySQL) {
$this->assertEquals(sizeof($explain), 2, 'Explain plan return two lines');

// explain can change sometime, test can't be strict
$this->assertArrayHasKey('select_type',$explain[0], 'Line 1, select_type key exist');
$this->assertArrayHasKey('table',$explain[0], 'Line 1, table key exist');
$this->assertArrayHasKey('type',$explain[0], 'Line 1, type key exist');
$this->assertArrayHasKey('possible_keys',$explain[0], 'Line 1, possible_keys key exist');

$this->assertArrayHasKey('select_type',$explain[1], 'Line 2, select_type key exist');
$this->assertArrayHasKey('table',$explain[1], 'Line 2, table key exist');
$this->assertArrayHasKey('type',$explain[1], 'Line 2, type key exist');
$this->assertArrayHasKey('possible_keys',$explain[1], 'Line 2, possible_keys key exist');
} elseif($db instanceof DBOracle) {
$this->assertTrue(sizeof($explain) > 2, 'Explain plan return more than 2 lines');
} else {
$this->markTestSkipped('Cannot test explain plan on adapter ' . get_class($db));
}
}
}