SELECT Ta.fldYear, Ta.fldPosition, Ta.fldName,
Count(Tb.fldPosition) as RankOrder
FROM [Your Table] as Ta LEFT JOIN [Your Table] as Tb
ON Ta.fldYear=Tb.FldYear AND Ta.fldPosition = Tb.fldPosition
AND Ta.fldName < Tb.fldName
GROUP BY Ta.fldYear, Ta.fldPosition, Ta.fldName
Open a new query
-- Add your table to the query two times (I'll call those two - Table 1 and
Table 2)
-- Drag from the Year field in table 1 to the year field in table 2
-- Drag from the position field in table 1 to the position field in table 2
-- Drag from the Name field in table 1 to the name field in table 2
(That should set up three join lines) between the tables
-- Add the fields year, position, and name from table 1 to the grid
-- Add the position field from table 2 to the grid
-- SELECT View: Totals from the menu
-- Change GROUP BY to Count under table 2 position field
-- SELECT View: SQL View from the menu
In the text that is now visible,
-- Change INNER JOIN to LEFT JOIN
-- Change table1.Name field = Table2.Name Field to
table1.Name field < Table2.Name Field
Try to run the query. If it runs, then save it and use that as the source
of a crosstab query. IF you have problems with the crosstab query, post
back with any error messages, so someone can help you.
--
John Spencer
Access MVP 2002-2005, 2007-2008
Center for Health Program Development and Management
University of Maryland Baltimore County
..
Frank Situmorang said:
John,
I want to use your suggestion, but can you explain again on how can we
make
the query you said ( SQL) and then how can we make the TRANSFOR and
Pivot. I
appreciate your help on how can we build that query. Normally I can use
grid
query and also someone told me in this thread how to make SQL but we must
in
in the form first and then in the data record source, we can build the
SQL.
Thanks in advance
--
H. Frank Situmorang
:
Duane,
I thought by adding the Ranking that I would get multiple lines for each
position in the Crosstab query. OR did I miss something with that.
Year Position Name RankOrder
2007 Deacon Bob 1
2007 Deacon Tom 2
2007 Deacon Zeara 3
2008 Deacon Bob 1
2008 Deacon Zeara 2
Then crosstab would return
Position Rank 2007 2008
Deacon 1 Bob Bob
Deacon 2 Tom Zeara
Decaon 3 Zeara (Null)
--
John Spencer
Access MVP 2002-2005, 2007-2008
Center for Health Program Development and Management
University of Maryland Baltimore County
..
John's idea should work. However, do you ever have a year with more
than
one
person in a position? If so, the crosstab would only return one of the
names.
--
Duane Hookom
Microsoft Access MVP
:
What does your data look like? What tables? What Fields in the
tables?
Do you have one table with fields like - fldYear, fldPosition, and
fldName?
Assuming that is the structure, I would first build a query to get the
data
and a ranking order for the data (qOrdered). WARNING: Untested SQL
statements follow - they may have syntax errors or they may give
undesired
results.
SELECT Ta.fldYear, Ta.fldPosition, Ta.fldName,
Count(Tb.fldPosition) as RankOrder
FROM [Your Table] as Ta LEFT JOIN [Your Table] as Tb
ON Ta.fldYear=Tb.FldYear AND Ta.fldPosition = Tb.fldPosition
AND Ta.fldName < Tb.fldName
GROUP BY Ta.fldYear, Ta.fldPosition, Ta.fldName
Now I would use the saved query as the source of a crosstab query.
TRANSFORM First(FldName) as theName
SELECT fldPosition, fldRankOrder
FROM qOrdered
GROUP BY fldPosition, fldRankOrder
PIVOT fldYear
Hope this helps.
--
John Spencer
Access MVP 2002-2005, 2007-2008
Center for Health Program Development and Management
University of Maryland Baltimore County
..
Hello,
Maybe I have a langguage problem in expressing my difficulties, but
here
is
what I wanted
Normal report based on the normal query:
Year 2005
No. Position Name
1, Elder Mr. A
2. clerck Mr. B
3. Deacon Mr. C
Year 2006
1, Elder Mr. D
2. clerck Mr. E
3. Deacon Mr. F
Year 2007...same way downward
I wanted it that the year is Sideway"
No. Position Name Year 2005 Year 2006 Year 2007
1, Elder Mr. A Mr. D
.......
2. clerck Mr. B Mr. E
.......
3. Deacon Mr. C Mr. F
.........
In other words no grouping in rowheading, and only grouping by year
for
column heading, and should be able goes side way whenever we have
next
year
and on.
We need your help
Thanks