INTELLIGENT WORK FORUMS
FOR COMPUTER PROFESSIONALS

Log In

Come Join Us!

Are you a
Computer / IT professional?
Join Tek-Tips Forums!
  • Talk With Other Members
  • Be Notified Of Responses
    To Your Posts
  • Keyword Search
  • One-Click Access To Your
    Favorite Forums
  • Automated Signatures
    On Your Posts
  • Best Of All, It's Free!

*Tek-Tips's functionality depends on members receiving e-mail. By joining you are opting in to receive e-mail.

Posting Guidelines

Promoting, selling, recruiting, coursework and thesis posting is forbidden.

Jobs

getting an incremental value

Create a sequential/ranking number with no code by dhookom
Posted: 12 Jun 13

You can create a query that numbers/ranks records within groups. For instance the Orders table in Northwind has fields:

OrderID unique autonumber
CustomerID
OrderDate


Assuming you want to display the records by customer with each record numbered from 1 to whatever based on the OrderDate. Each different customer would begin numbering back at 1.

The SQL view is:

CODE --> SQL

SELECT Orders.OrderID, Orders.CustomerID, Orders.OrderDate, Count(Orders_1.OrderID) AS Rank
FROM Orders AS Orders_1 INNER JOIN Orders ON Orders_1.CustomerID = Orders.CustomerID
WHERE Orders.OrderDate>=[Orders_1].[OrderDate]
GROUP BY Orders.OrderID, Orders.CustomerID, Orders.OrderDate
ORDER BY Orders.CustomerID, Orders.OrderDate; 

If you don't want to group by CustomerID, just delete the join line between the two tables:

The new SQL view is:

CODE --> SQL

SELECT Orders.OrderID, Orders.OrderDate, Orders.CustomerID, Count(Orders_1.OrderID) AS Rank
FROM Orders AS Orders_1, Orders
WHERE Orders.OrderDate>[Orders_1].[OrderDate]
GROUP BY Orders.OrderID, Orders.OrderDate, Orders.CustomerID
ORDER BY Orders.OrderDate, Orders.CustomerID; 

Orders on the same date will have the same rank value.

Back to Microsoft: Access Queries and JET SQL FAQ Index
Back to Microsoft: Access Queries and JET SQL Forum

My Archive

Resources

Close Box

Join Tek-Tips® Today!

Join your peers on the Internet's largest technical computer professional community.
It's easy to join and it's free.

Here's Why Members Love Tek-Tips Forums:

Register now while it's still free!

Already a member? Close this window and log in.

Join Us             Close