Zend_Db_Select Visão Geral do Objeto Select O objeto Zend_Db_Select representa um comando de consulta SQL SELECT. A classe possui métodos para a adição de partes individuais em uma query. Você pode especificar algumas partes da consulta usando métodos PHP e estruturas de dados, e a classe se encarrega de formar a sintaxe SQL correta para você. Depois da construção de uma consulta, você pode executá-la como se você houvesse a escrito em uma string. As vantagens oferecidas pelo Zend_Db_Select incluem: Métodos orientados a objetos para especificação de consultas SQL de maneira "piece-by-piece" (aos pedaços ou em partes); Abstração de independência de base de dados de algumas partes da consulta SQL; Colocação automática de aspas nos identificadores de metadados na maioria dos casos, para dar suporte aos identificadores que contém palavras SQL reservadas e caracteres especiais; Colocação automática de aspas nos identificadores e valores, para ajudar na redução de ataques por "SQL injection". A utilização de Zend_Db_Select não é obrigatória. Para consultas SELECT muito simples, normalmente é mais fácil escrever toda a consulta SQL em uma string e executá-la usando métodos da classe Adapter, como o query() ou fetchAll(). O uso de Zend_Db_Select é muito útil quando você precisa montar uma consulta SELECT usando "procedures" (através de procedimentos), ou quando você precisa montar a consulta baseando-se na lógica condicional da sua aplicação. Criando um Objeto Select Você pode criar uma instância de um objeto Zend_Db_Select usando o método select() de um objeto Zend_Db_Adapter_Abstract. Exemplo do método select() do adaptador para bases de dados select();]]> Outra forma de criar um objeto Zend_Db_Select é com o construtor dele, especificando o adaptador como parâmetro. Examplo da criação de um novo objeto Select Construindo Consultas Select Ao contruir um consulta, você pode adicionar cláusulas uma por uma. Existe um método diferente para cada cláusula no objeto. Exemplo do uso de métodos para adicionar cláusulas select(); // Add a FROM clause $select->from( ...specify table and columns... ) // Add a WHERE clause $select->where( ...specify search criteria... ) // Add an ORDER BY clause $select->order( ...specify sorting criteria... );]]> Você também pode usar a maior parte dos métodos do objeto Zend_Db_Select com uma interface "fluent" conveniente. Uma interface "fluent" significa que cada método retorna uma referência para o objeto no qual foi chamado, então você pode imediatamente chamar outro método. Examplo de uso da interface "fluent" select() ->from( ...specify table and columns... ) ->where( ...specify search criteria... ) ->order( ...specify sorting criteria... );]]> Os exemplos nesta seção mostram o uso da interface "fluent", mas você pode usar a interface "non-fluent" em todos os casos. É freqüentemente necessário usar a interface "non-fluent" quando, por exemplo, sua aplicação precisa executar alguma lógica antes de adicionar uma cláusula a uma consulta. Adicionando uma cláusula FROM Especifique a tabela para esta consulta usando o método from(). Você pode especificar o nome da tabela como uma simples string. Zend_Db_Select coloca o entre aspas o nome da tabela, então, você pode usar caracteres especiais. Example of the from() method select() ->from( 'products' );]]> You can also specify the correlation name (sometimes called the "table alias") for a table. Instead of a simple string, use an associative array mapping the correlation name to the table name. In other clauses of the SQL query, use this correlation name. If your query joins more than one table, Zend_Db_Select generates unique correlation names based on the table names, for any tables for which you don't specify the correlation name. Example of specifying a table correlation name select() ->from( array('p' => 'products') );]]> Algumas marcas de RDBMS dão suporte a um especificador de schema para uma tabela. Você pode especificar o nome a tabela como "schemaName.tableName", onde Zend_Db_Select coloca entre aspas cada uma das partes individualmente, ou então você deve especificar o nome do schema separadamente. Um nome de schema especificado no nome da tabela precede um schema fornecido separadamente se eventualmente ambos forem informados. Exemplo de especificação de nome de schema select() ->from( 'myschema.products' ); // or $select = $db->select() ->from('products', '*', 'myschema');]]> Adicionando Colunas No segundo argumento do método from() , você pode especificaras colunas a serem selecionadas da respectiva tabela. Se você não especificar nenhuma coluna, o valor padrão é "*", o caracter curinga para "todas as colunas". Você pode listar as colunas em um simples array de strings, ou como um mapeamento associativo do alias da coluna para nome da coluna. Se você só tiver uma coluna para consultar, e não precisar indicar um alias, você pode listá-la em uma string simples ao invés de um array. Se você passar um array vazio como o argumento de colunas, nenhuma coluna da respectiva tabela será incluída no result set. Veja um exemplo de código sob a seção do método join(). Você pode especificar o nome da coluna como "correlationName.columnName". Zend_Db_Select os coloca entre aspas individualmente. Caso você não especifique o nome da correlação para uma coluna, é usado o nome da correlação da tabela indicada no métodofrom(). Examples of specifying columns select() ->from(array('p' => 'products'), array('product_id', 'product_name')); // Build the same query, specifying correlation names: // SELECT p."product_id", p."product_name" // FROM "products" AS p $select = $db->select() ->from(array('p' => 'products'), array('p.product_id', 'p.product_name')); // Build this query with an alias for one column: // SELECT p."product_id" AS prodno, p."product_name" // FROM "products" AS p $select = $db->select() ->from(array('p' => 'products'), array('prodno' => 'product_id', 'product_name'));]]> Adicionando Colunas de Expressões Algumas vezes as colunas de uma consulta SQL são expressões, e não simplesmente o nome de uma couna da tabela. Expressões não devem usar nomes de correlação ou aspas. Se a string da coluna possuir parênteses, Zend_Db_Select a reconhecerá como uma expressão. Você também pode criar um objeto do tipo Zend_Db_Expr explicitamente, para prevenir que uma string seja tratada como um nome de coluna. Zend_Db_Expr é uma classe diminuta que contém uma única string. Zend_Db_Select reconhece obtejos do tipo Zend_Db_Expr e os converte novamente para strings, mas não efetua qualquer alteração como a colocação de aspas ou nomes de correlação. O uso de Zend_Db_Expr para nomes de colunas não é necessário se as expressões contiverem parênteses; Zend_Db_Select reconhece os parênteses e trata a string como uma expresão, ignorando a colocação de aspas e de nomes de correlação. Exemplos de especificação de colunas contendo expressões select() ->from(array('p' => 'products'), array('product_id', 'LOWER(product_name)')); // Build this query: // SELECT p."product_id", (p.cost * 1.08) AS cost_plus_tax // FROM "products" AS p $select = $db->select() ->from(array('p' => 'products'), array('product_id', 'cost_plus_tax' => '(p.cost * 1.08)')); // Build this query using Zend_Db_Expr explicitly: // SELECT p."product_id", p.cost * 1.08 AS cost_plus_tax // FROM "products" AS p $select = $db->select() ->from(array('p' => 'products'), array('product_id', 'cost_plus_tax' => new Zend_Db_Expr('p.cost * 1.08')));]]> Nos casos acima, Zend_Db_Select não altera a string para colocar os nomes de correlação ou aspas. Se as mudanças forem necessárias para evitar alguma ambiguidade, você deve fazê-las manualmente na string. Se os nomes das colunas são palavras-chave SQL ou possuem caracteres especiais, você deve usar o método quoteIdentifier() da classe Adapter, e interpolar o resultado na string. O método quoteIdentifier() usa aspas no SQL para delimitar o identificador, o que deixa claro que ele é um identificador de uma tabela ou coluna e não parte da síntaxe SQL. Seu código fica mais independente de base de dados se você usar o método quoteIdentifier() ao invés de digitar as aspas nas strings porque algumas marcas de SGBD Relacionais usam símbolos fora do padrão para referenciar identificadores. O método quoteIdentifier() é projetado para usar os símbolos de referência apropriados de acordo com o tipo de adaptador. O método quoteIdentifier() também ignora qualquer caracter de referência que aparecer no nome de um identificador. Examples of quoting columns in an expression select() ->from(array('p' => 'products'), array('origin' => '(p.' . $db->quoteIdentifier('from') . ' + 10)'));]]> Adding Another Table to the Query with JOIN Many useful queries involve using a JOIN to combine rows from multiple tables. You can add tables to a Zend_Db_Select query using the join() method. Using this method is similar to the from() method, except you can also specify a join condition in most cases. Example of the join() method select() ->from(array('p' => 'products'), array('product_id', 'product_name')) ->join(array('l' => 'line_items'), 'p.product_id = l.product_id');]]> The second argument to join() is a string that is the join condition. This is an expression that declares the criteria by which rows in one table match rows in the the other table. You can use correlation names in this expression. No quoting is applied to the expression you specify for the join condition; if you have column names that need to be quoted, you must use quoteIdentifier() as you form the string for the join condition. The third argument to join() is an array of column names, like that used in the from() method. It defaults to "*", supports correlation names, expressions, and Zend_Db_Expr in the same way as the array of column names in the from() method. To select no columns from a table, use an empty array for the list of columns. This usage works in the from() method too, but typically you want some columns from the primary table in your queries, whereas you might want no columns from a joined table. Example of specifying no columns select() ->from(array('p' => 'products'), array('product_id', 'product_name')) ->join(array('l' => 'line_items'), 'p.product_id = l.product_id', array() ); // empty list of columns]]> Note the empty array() in the above example in place of a list of columns from the joined table. SQL has several types of joins. See the list below for the methods to support different join types in Zend_Db_Select. INNER JOIN with the join(table, join, [columns]) or joinInner(table, join, [columns]) methods. This may be the most common type of join. Rows from each table are compared using the join condition you specify. The result set includes only the rows that satisfy the join condition. The result set can be empty if no rows satisfy this condition. All RDBMS brands support this join type. LEFT JOIN with the joinLeft(table, condition, [columns]) method. All rows from the left operand table are included, matching rows from the right operand table included, and the columns from the right operand table are filled with NULLs if no row exists matching the left table. All RDBMS brands support this join type. RIGHT JOIN with the joinRight(table, condition, [columns]) method. Right outer join is the complement of left outer join. All rows from the right operand table are included, matching rows from the left operand table included, and the columns from the left operand table are filled with NULLs if no row exists matching the right table. Some RDBMS brands don't support this join type, but in general any right join can be represented as a left join by reversing the order of the tables. FULL JOIN with the joinFull(table, condition, [columns]) method. A full outer join is like combining a left outer join and a right outer join. All rows from both tables are included, paired with each other on the same row of the result set if they satisfy the join condition, and otherwise paired with NULLs in place of columns from the other table. Some RDBMS brands don't support this join type. CROSS JOIN with the joinCross(table, [columns]) method. A cross join is a Cartesian product. Every row in the first table is matched to every row in the second table. Therefore the number of rows in the result set is equal to the product of the number of rows in each table. You can filter the result set using conditions in a WHERE clause; in this way a cross join is similar to the old SQL-89 join syntax. The joinCross() method has no parameter to specify the join condition. Some RDBMS brands don't support this join type. NATURAL JOIN with the joinNatural(table, [columns]) method. A natural join compares any column(s) that appear with the same name in both tables. The comparison is equality of all the column(s); comparing the columns using inequality is not a natural join. Only natural inner joins are supported by this API, even though SQL permits natural outer joins as well. The joinNatural() method has no parameter to specify the join condition. Adding a WHERE Clause You can specify criteria for restricting rows of the result set using the where() method. The first argument of this method is a SQL expression, and this expression is used in a SQL WHERE clause in the query. Example of the where() method 100.00 $select = $db->select() ->from( 'products', array('product_id', 'product_name', 'price')) ->where('price > 100.00');]]> No quoting is applied to expressions given to the where() or orWhere() methods. If you have column names that need to be quoted, you must use quoteIdentifier() as you form the string for the condition. The second argument to the where() method is optional. It is a value to substitute into the expression. Zend_Db_Select quotes the value and substitutes it for a question-mark ("?") symbol in the expression. This method accepts only one parameter. If you have an expression into which you need to substitute multiple variables, you must format the string manually, interpolating variables and performing quoting yourself. Example of a parameter in the where() method 100.00) $minimumPrice = 100; $select = $db->select() ->from( 'products', array('product_id', 'product_name', 'price')) ->where('price > ?', $minimumPrice);]]> You can invoke the where() method multiple times on the same Zend_Db_Select object. The resulting query combines the multiple terms together using AND between them. Example of multiple where() methods 100.00) // AND (price < 500.00) $minimumPrice = 100; $maximumPrice = 500; $select = $db->select() ->from('products', array('product_id', 'product_name', 'price')) ->where('price > ?', $minimumPrice) ->where('price < ?', $maximumPrice);]]> If you need to combine terms together using OR, use the orWhere() method. This method is used in the same way as the where() method, except that the term specified is preceded by OR, instead of AND. Example of the orWhere() method 500.00) $minimumPrice = 100; $maximumPrice = 500; $select = $db->select() ->from('products', array('product_id', 'product_name', 'price')) ->where('price < ?', $minimumPrice) ->orWhere('price > ?', $maximumPrice);]]> Zend_Db_Select automatically puts parentheses around each expression you specify using the where() or orWhere() methods. This helps to ensure that Boolean operator precedence does not cause unexpected results. Example of parenthesizing Boolean expressions 500.00) // AND (product_name = 'Apple') $minimumPrice = 100; $maximumPrice = 500; $prod = 'Apple'; $select = $db->select() ->from('products', array('product_id', 'product_name', 'price')) ->where("price < $minimumPrice OR price > $maximumPrice") ->where('product_name = ?', $prod);]]> In the example above, the results would be quite different without the parentheses, because AND has higher precedence than OR. Zend_Db_Select applies the parentheses so the effect is that each expression in successive calls to the where() bind more tightly than the AND that combines the expressions. Adding a GROUP BY Clause In SQL, the GROUP BY clause allows you to reduce the rows of a query result set to one row per unique value found in the column(s) named in the GROUP BY clause. In Zend_Db_Select, you can specify the column(s) to use for calculating the groups of rows using the group() method. The argument to this method is a column or an array of columns to use in the GROUP BY clause. Example of the group() method select() ->from(array('p' => 'products'), array('product_id')) ->join(array('l' => 'line_items'), 'p.product_id = l.product_id', array('line_items_per_product' => 'COUNT(*)')) ->group('p.product_id');]]> Like the columns array in the from() method, you can use correlation names in the column name strings, and the column is quoted as an identifier unless the string contains parentheses or is an object of type Zend_Db_Expr. Adding a HAVING Clause In SQL, the HAVING clause applies a restriction condition on groups of rows. This is similar to how a WHERE clause applies a restriction condition on rows. But the two clauses are different because WHERE conditions are applied before groups are defined, whereas HAVING conditions are applied after groups are defined. In Zend_Db_Select, you can specify conditions for restricting groups using the having() method. Its usage is similar to that of the where() method. The first argument is a string containing a SQL expression. The optional second argument is a value that is used to replace a positional parameter placeholder in the SQL expression. Expressions given in multiple invocations of the having() method are combined using the Boolean AND operator, or the OR operator if you use the orHaving() method. Example of the having() method 10 $select = $db->select() ->from(array('p' => 'products'), array('product_id')) ->join(array('l' => 'line_items'), 'p.product_id = l.product_id', array('line_items_per_product' => 'COUNT(*)')) ->group('p.product_id') ->having('line_items_per_product > 10');]]> No quoting is applied to expressions given to the having() or orHaving() methods. If you have column names that need to be quoted, you must use quoteIdentifier() as you form the string for the condition. Adding an ORDER BY Clause In SQL, the ORDER BY clause specifies one or more columns or expressions by which the result set of a query is sorted. If multiple columns are listed, the secondary columns are used to resolve ties; the sort order is determined by the secondary columns if the preceding columns contain identical values. The default sorting is from least value to greatest value. You can also sort by greatest value to least value for a given column in the list by specifying the keyword DESC after that column. In Zend_Db_Select, you can use the order() method to specify a column or an array of columns by which to sort. Each element of the array is a string naming a column. optionally with the ASC DESC keyword following it, separated by a space. Like in the from() and group() methods, column names are quoted as identifiers, unless they contain contain parentheses or are an object of type Zend_Db_Expr. Example of the order() method select() ->from(array('p' => 'products'), array('product_id')) ->join(array('l' => 'line_items'), 'p.product_id = l.product_id', array('line_items_per_product' => 'COUNT(*)')) ->group('p.product_id') ->order(array('line_items_per_product DESC', 'product_id'));]]> Adding a LIMIT Clause Some RDBMS brands extend SQL with a query clause known as the LIMIT clause. This clause reduces the number of rows in the result set to at most a number you specify. You can also specify to skip a number of rows before starting to output. This feature makes it easy to take a subset of a result set, for example when displaying query results on progressive pages of output. In Zend_Db_Select, you can use the limit() method to specify the count of rows and the number of rows to skip. The first argument to this method is the desired count of rows. The second argument is the number of rows to skip. Example of the limit() method select() ->from(array('p' => 'products'), array('product_id', 'product_name')) ->limit(10, 20);]]> The LIMIT syntax is not supported by all RDBMS brands. Some RDBMS require different syntax to support similar functionality. Each Zend_Db_Adapter_Abstract class includes a method to produce SQL appropriate for that RDBMS. Use the limitPage() method for an alternative way to specify row count and offset. This method allows you to limit the result set to one of a series of fixed-length subsets of rows from the query's total result set. In other words, you specify the length of a "page" of results, and the ordinal number of the single page of results you want the query to return. The page number is the first argument of the limitPage() method, and the page length is the second argument. Both arguments are required; they have no default values. Example of the limitPage() method select() ->from(array('p' => 'products'), array('product_id', 'product_name')) ->limitPage(2, 10);]]> Adding the DISTINCT Query Modifier The distinct() method enables you to add the DISTINCT keyword to your SQL query. Example of the distinct() method select() ->distinct() ->from(array('p' => 'products'), 'product_name');]]> Adding the FOR UPDATE Query Modifier The forUpdate() method enables you to add the FOR UPDATE modifier to your SQL query. Example of forUpdate() method select() ->forUpdate() ->from(array('p' => 'products'));]]> Executing Select Queries This section describes how to execute the query represented by a Zend_Db_Select object. Executing Select Queries from the Db Adapter You can execute the query represented by the Zend_Db_Select object by passing it as the first argument to the query() method of a Zend_Db_Adapter_Abstract object. Use the Zend_Db_Select objects instead of a string query. The query() method returns an object of type Zend_Db_Statement or PDOStatement, depending on the adapter type. Example using the Db adapter's query() method select() ->from('products'); $stmt = $db->query($select); $result = $stmt->fetchAll();]]> Executing Select Queries from the Object As an alternative to using the query() method of the adapter object, you can use the query() method of the Zend_Db_Select object. Both methods return an object of type Zend_Db_Statement or PDOStatement, depending on the adapter type. Example using the Select object's query method select() ->from('products'); $stmt = $select->query(); $result = $stmt->fetchAll();]]> Converting a Select Object to a SQL String If you need access to a string representation of the SQL query corresponding to the Zend_Db_Select object, use the __toString() method. Example of the __toString() method select() ->from('products'); $sql = $select->__toString(); echo "$sql\n"; // The output is the string: // SELECT * FROM "products"]]> Other methods This section describes other methods of the Zend_Db_Select class that are not covered above: getPart() and reset(). Retrieving Parts of the Select Object The getPart() method returns a representation of one part of your SQL query. For example, you can use this method to return the array of expressions for the WHERE clause, or the array of columns (or column expressions) that are in the SELECT list, or the values of the count and offset for the LIMIT clause. The return value is not a string containing a fragment of SQL syntax. The return value is an internal representation, which is typically an array structure containing values and expressions. Each part of the query has a different structure. The single argument to the getPart() method is a string that identifies which part of the Select query to return. For example, the string 'from' identifies the part of the Select object that stores information about the tables in the FROM clause, including joined tables. The Zend_Db_Select class defines constants you can use for parts of the SQL query. You can use these constant definitions, or you can the literal strings. Constants used by getPart() and reset() Constant String value Zend_Db_Select::DISTINCT 'distinct' Zend_Db_Select::FOR_UPDATE 'forupdate' Zend_Db_Select::COLUMNS 'columns' Zend_Db_Select::FROM 'from' Zend_Db_Select::WHERE 'where' Zend_Db_Select::GROUP 'group' Zend_Db_Select::HAVING 'having' Zend_Db_Select::ORDER 'order' Zend_Db_Select::LIMIT_COUNT 'limitcount' Zend_Db_Select::LIMIT_OFFSET 'limitoffset'
Example of the getPart() method select() ->from('products') ->order('product_id'); // You can use a string literal to specify the part $orderData = $select->getPart( 'order' ); // You can use a constant to specify the same part $orderData = $select->getPart( Zend_Db_Select::ORDER ); // The return value may be an array structure, not a string. // Each part has a different structure. print_r( $orderData );]]>
Resetting Parts of the Select Object The reset() method enables you to clear one specified part of the SQL query, or else clear all parts of the SQL query if you omit the argument. The single argument is optional. You can specify the part of the query to clear, using the same strings you used in the argument to the getPart() method. The part of the query you specify is reset to a default state. If you omit the parameter, reset() changes all parts of the query to their default state. This makes the Zend_Db_Select object equivalent to a new object, as though you had just instantiated it. Example of the reset() method select() ->from(array('p' => 'products') ->order('product_name'); // Changed requirement, instead order by a different columns: // SELECT p.* // FROM "products" AS p // ORDER BY "product_id" // Clear one part so we can redefine it $select->reset( Zend_Db_Select::ORDER ); // And specify a different column $select->order('product_id'); // Clear all parts of the query $select->reset();]]>