>
Part | Description |
ALL | Assumed if you don't include one of the predicates. The Microsoft Jet database engine selects all of the records that meet the conditions in the SQL statement. The following two examples are equivalent and return all records from the Employees table:
SELECT ALL * |
DISTINCT | Omits records that contain duplicate data in the selected fields. To be included in the results of the query, the values for each field listed in the SELECT statement must be unique. For example, several employees listed in an Employees table may have the same last name. If two records contain Smith in the Last Name field, the following SQL statement returns only one record that contains Smith:
SELECT DISTINCTIf you omit DISTINCT, this query returns both Smith records. If the SELECT clause contains more than one field, the combination of values from all fields must be unique for a given record to be included in the results. The output of a query that uses DISTINCT isn't updatable and doesn't reflect subsequent changes made by other users. |
Part | Description |
DISTINCTROW | Omits data based on entire duplicate records, not just duplicate fields. For example, you could create a query that joins the Customers and Orders tables on the Customer ID field. The Customers table contains no duplicate Customer ID fields, but the Orders table does because each customer can have many orders. The following SQL statement shows how you can use DISTINCTROW to produce a list of companies that have at least one order but without any details about those orders:
SELECT DISTINCTROW CompanyNameIf you omit DISTINCTROW, this query produces multiple rows for each company that has more than one order. DISTINCTROW has an effect only when you select fields from some, but not all, of the tables used in the query. DISTINCTROW is ignored if your query includes only one table, or if you output fields from all tables. |
TOP | Returns a certain number of records that fall at the top or the bottom of a range specified by an ORDER BY clause. Suppose you want the names of the top 25 students from the class of 1994:
SELECT TOP 25If you don't include the ORDER BY clause, the query will return an arbitrary set of 25 records from the Students table that satisfy the WHERE clause. The TOP predicate doesn't choose between equal values. In the preceding example, if the twenty-fifth and twenty-sixth highest grade point averages are the same, the query will return 26 records. |
Part | Description |
TOP | You can also use the PERCENT reserved word to return a certain percentage of records that fall at the top or the bottom of a range specified by an ORDER BY clause. Suppose that, instead of the top 25 students, you want the bottom 10 percent of the class:
SELECT TOP 10 PERCENTThe ASC predicate specifies a return of bottom values. The value that follows TOP must be an unsigned Integer. TOP doesn't affect the query's updatability. |
table | The name of the table from which records are retrieved. |
First name | Customer ID |
Bob | 1 |
Adam | 2 |
Beverly | 3 |
Bob | 4 |
Customer ID | Order ID |
1 | 1 |
1 | 2 |
Customer ID | Order ID |
2 | 3 |
2 | 4 |
2 | 5 |
4 | 6 |
4 | 7 |
SELECT ALL FirstName FROM Customers INNER JOIN Orders ON Customers.CustomerID = Orders.CustomerID;
Result | Updatable |
Bob Bob Adam Adam Adam Bob Bob | Yes |
SELECT DISTINCT FirstName FROM Customers INNER JOIN Orders ON Customers.CustomerID = Orders.CustomerID;
Result | Updatable |
Bob Adam | No |
SELECT DISTINCTROW FirstName FROM Customers INNER JOIN Orders ON Customers.CustomerID = Orders.CustomerID;
Result | Updatable |
Bob Adam Bob | Yes |
SELECT TOP 5 FirstName FROM Customers INNER JOIN Orders ON Customers.CustomerID = Orders.CustomerID ORDER BY Orders.OrderID;
Result | Updatable |
Bob Bob Adam Adam Adam | Yes |