So, I created the entire database you made and mimicked/molded it to work
with the table I had created. I finally figured out why neither the one you
made or the one I mentioned earlier wouldn't work. I needed to have at least
3 generations. So, I understand how to get it to show 3 generations, now how
do I get it to show 2, 3, 4, however many I want (meaning it will vary with
each cat) with only one main query to run? And how can I get it to display
only one cat's pedigree at a time on the form? I'm sorry if I seem to
ignorant, but I'm doing my best to learn.
Sincerely,
Miss Stoffelees
:
Dear Mr./Miss Stoffelees,
Here's my version of your initial pedigree query. I had to set up a Table,
of course, to provide a meaningful example, but I expect you may want to make
changes to it. For example, maybe date of birth (whelping/queening/hatching,
&c.) is not of importance to you, so you could just zap that. (But for now,
don't erase it, as some of my Queries depend on it.)
Let's start with the Table that contains all of the (fake) data used in this
example. You should be able to reproduce everything here using your own copy
of Access. (Sorry, I had to fold this Data sheet, and most of the others, to
avoid having the lines get folded automatically at unhappy places.)
The [Kitties_ID] field is an Auto number type, meaning that it's generated
automatically and guaranteed to be unique. You might choose some other type
ID field, such as a name, but then you'd have to be sure you never reused a
name, and you'd have to type it yourself. (Also, Auto numbers take only 4
bytes, while names are usually longer, a consideration if you have big enough
Tables that size is a problem.)
[Sire] and [Dam] fields contain "foreign key" values identifying which
record in [Kitties] identifies a parent of the kitty in the current record.
For example, in this Table, the record for "Pretty" (record # 548426157) has
a [Sire] field of -1604637614, which refers to the record for "Tiger".
[Kitties] Table Datasheet View:
Kitties_ID Name Sex Sire
----------- ------- --- -----------
289370756 ?? 289370756
-220441218 Lioness F 289370756
-1604637614 Tiger M 289370756
369735989 Puff F 289370756
548426157 Pretty F -1604637614
2051116689 Tugger M -1604637614
-776932656 Cutie F -1604637614
341341803 Growler M -1604637614
-224409238 Zinger F 2051116689
481390556 Mouser M 341341803
-41180253 Bitsy F 2051116689
252328743 Striper M 341341803
Dam Born
---------- --------
289370756 1/1/1950
289370756 1/1/1990
289370756 1/1/1990
289370756 1/1/1990
369735989 1/1/1996
369735989 1/1/1996
369735989 1/1/1996
-220441218 1/1/1997
-220441218 1/1/1998
-776932656 1/1/1999
-224409238 1/1/2000
548426157 1/1/2000
Well, that's it for the "data". The remaining examples are all based on
these. (For now, let's assume that inbreeding is not a problem for virtual
cats.)
Let's say that we want to list the parents & grandparents of everyone in our
collection. The following Query goes back 2 generations, but you could extend
it if you wish.
[Q_010Ancestors] SQL:
SELECT [Kitties].[Name], [Kitties].[Kitties_ID],
KS.Name AS S, KD.Name AS D, KSS.Name AS SS,
KSD.Name AS SD, KDS.Name AS DS, KDD.Name AS DD
FROM (((((Kitties
INNER JOIN Kitties AS KS
ON [Kitties].[Sire]=KS.Kitties_ID)
INNER JOIN Kitties AS KD
ON [Kitties].[Dam]=KD.Kitties_ID)
INNER JOIN Kitties AS KSS
ON KS.Sire=KSS.Kitties_ID)
INNER JOIN Kitties AS KSD
ON KS.Dam=KSD.Kitties_ID)
INNER JOIN Kitties AS KDS
ON KD.Sire=KDS.Kitties_ID)
INNER JOIN Kitties AS KDD
ON KD.Dam=KDD.Kitties_ID
ORDER BY [Kitties].[Born];
Running this gives the following list of ancestors. "S" refers to sire,
"DS" refers to dam's sire, etc.
[Q_010Ancestors] Query Datasheet View:
Name Kitties_ID S D SS
------- ----------- ------- ------- -----
?? 289370756 ?? ?? ??
Lioness -220441218 ?? ?? ??
Tiger -1604637614 ?? ?? ??
Puff 369735989 ?? ?? ??
Pretty 548426157 Tiger Puff ??
Tugger 2051116689 Tiger Puff ??
Cutie -776932656 Tiger Puff ??
Growler 341341803 Tiger Lioness ??
Zinger -224409238 Tugger Lioness Tiger
Mouser 481390556 Growler Cutie Tiger
Bitsy -41180253 Tugger Zinger Tiger
Striper 252328743 Growler Pretty Tiger
SD DS DD
------- ------ -------
?? ?? ??
?? ?? ??
?? ?? ??
?? ?? ??
?? ?? ??
?? ?? ??
?? ?? ??
?? ?? ??
Puff ?? ??
Lioness Tiger Puff
Puff Tugger Lioness
Lioness Tiger Puff
In a Form, I assume you'd use a Query like this as the Form's data source,
and place text boxes or similar controls at suitable places on the Form.
OK, now let's go the other direction -- to offspring. Since I'm
distinguishing between toms and queens, I define a Query for the offspring of
queens:
[Q_020ChildF] SQL:
SELECT Parent.Kitties_ID, Parent.Name,
Child.Kitties_ID AS Offspring_Kitties_ID
FROM Kitties AS Child
INNER JOIN Kitties AS Parent
ON Child.Dam = Parent.Kitties_ID;
Running this produces a list like this:
[Q_020ChildF] Query Datasheet View:
Kitties_ID Name Offspring_Kitties_ID
---------- ------- --------------------
-776932656 Cutie 481390556
-224409238 Zinger -41180253
-220441218 Lioness 341341803
-220441218 Lioness -224409238
289370756 ?? 289370756
289370756 ?? 369735989
289370756 ?? -1604637614
289370756 ?? -220441218
369735989 Puff -776932656
369735989 Puff 2051116689
369735989 Puff 548426157
548426157 Pretty 252328743
For offspring of toms, we use the same SQL, with a minor change in the last
line.
[Q_030ChildM] SQL:
SELECT Parent.Kitties_ID, Parent.Name,
Child.Kitties_ID AS Offspring_Kitties_ID
FROM Kitties AS Child
INNER JOIN Kitties AS Parent
ON Child.Sire=Parent.Kitties_ID;
The list will be different from [Q_020ChildF], but the format is the same.
OK, we want a list of all offspring of each kitty, regardless of sex, and we
can do that with a Union Query:
[Q_040Offspring] SQL:
SELECT * FROM Q_020ChildF
UNION SELECT * FROM Q_030ChildM
ORDER BY Name;
The combined list looks like this. I used key values for offspring instead
of names, since I figured you wouldn't have lots of use for this exact
format. Names get added in the next step.
[Q_040Offspring] Query Datasheet View:
Kitties_ID Name Offspring_Kitties_ID
---------- ------- --------------------
289370756 ?? -1604637614
289370756 ?? -220441218
289370756 ?? 289370756
289370756 ?? 369735989
-776932656 Cutie 481390556
341341803 Growler 252328743
341341803 Growler 481390556
-220441218 Lioness -224409238
-220441218 Lioness 341341803
548426157 Pretty 252328743
369735989 Puff -776932656
369735989 Puff 548426157
369735989 Puff 2051116689
-1604637614 Tiger -776932656
-1604637614 Tiger 341341803
-1604637614 Tiger 548426157
-1604637614 Tiger 2051116689
2051116689 Tugger -224409238
2051116689 Tugger -41180253
-224409238 Zinger -41180253
What I want next is to assign a sequential number (random order here, but
with a bit of effort you could sort them by date or name) to each offspring
of a given parent, for the purpose of listing them later.
[Q_050OffspringNumber] SQL:
SELECT QO1.Kitties_ID, QO1.Name,
QO1.Offspring_Kitties_ID,
K.Name AS Off_Name,
Count(QO2.Kitties_ID) AS Sequence
FROM (Q_040Offspring AS QO1
INNER JOIN Q_040Offspring AS QO2
ON QO1.Kitties_ID = QO2.Kitties_ID)
INNER JOIN Kitties AS K
ON QO1.Offspring_Kitties_ID = K.Kitties_ID
WHERE (((QO2.Offspring_Kitties_ID)
<=[QO1]![Offspring_Kitties_ID]))
GROUP BY QO1.Kitties_ID, QO1.Name,
QO1.Offspring_Kitties_ID, K.Name
ORDER BY QO1.Name, Count(QO2.Kitties_ID);
So here you get the name and the sequence number.
[Q_050OffspringNumber] Query Datasheet View:
Kitties_ID Name Offspring_ Off_Name Sequence
Kitties_ID
----------- ------- ----------- -------- --------
289370756 ?? -1604637614 Tiger 1
289370756 ?? -220441218 Lioness 2
289370756 ?? 289370756 ?? 3
289370756 ?? 369735989 Puff 4
-776932656 Cutie 481390556 Mouser 1
341341803 Growler 252328743 Striper 1
341341803 Growler 481390556 Mouser 2
-220441218 Lioness -224409238 Zinger 1
-220441218 Lioness 341341803 Growler 2
548426157 Pretty 252328743 Striper 1
369735989 Puff -776932656 Cutie 1
369735989 Puff 548426157 Pretty 2
369735989 Puff 2051116689 Tugger 3
-1604637614 Tiger -776932656 Cutie 1
-1604637614 Tiger 341341803 Growler 2
-1604637614 Tiger 548426157 Pretty 3
-1604637614 Tiger 2051116689 Tugger 4
2051116689 Tugger -224409238 Zinger 1
2051116689 Tugger -41180253 Bitsy 2
-224409238 Zinger -41180253 Bitsy 1
Now let's reorganize these so that, for each parent in our Table, that
parent's offspring are combined into one record.
[Q_060OffspringXtab] SQL:
TRANSFORM First(QON.Off_Name) AS FON
SELECT QON.Name, QON.Kitties_ID
FROM Q_050OffspringNumber AS QON
GROUP BY QON.Name, QON.Kitties_ID
PIVOT QON.Sequence;
[Q_060OffspringXtab] Query Datasheet View:
Name Kitties_ID 1 2 3 4
------- ----------- ------- ------- ------ --------
?? 289370756 Tiger Lioness ?? Puff
Cutie -776932656 Mouser
Growler 341341803 Striper Mouser
Lioness -220441218 Zinger Growler
Pretty 548426157 Striper
Puff 369735989 Cutie Pretty Tugger
Tiger -1604637614 Cutie Growler Pretty Tugger
Tugger 2051116689 Zinger Bitsy
Zinger -224409238 Bitsy
Access gives you lots of freedom in deciding how to organize your stuff.
Here, I limited that freedom somewhat in allowing, for example, only a
couple of choices for [Sex], and in requiring the [Sire] and [Dam] fields to
contain only values that match the [Kitties_ID] field of some existing record
in [Kitties]. (This won't guarantee that the recorded information is
accurate, but it can help avoid some types of careless mistakes, such as
leaving the field empty.) How I enforced the rules is not evident in what
I've shown you, but if you wish to do that, look up "Validation Rule" and
"Referential Integrity" in Access Help. (Or, you could simply be careful,
and never make data-entry mistakes.)
Good luck, and pet some kittycats for me.
-- Vincent Johns <
[email protected]>
Please feel free to quote anything I say here.