|
What result do you get using this query:
SELECT count(*)
FROM CaRates a, xtCaRates b
WHERE a.ptccp7 = b.ptccp7
and a.ptccp6 = b.ptccp6
and a.ptccp5 = b.ptccp5
and a.ptccp4 = b.ptccp4
and a.ptccp3 = b.ptccp3
and a.ptccp2 = b.ptccp2
and a.ptccp1 = b.ptccp1
and (
a.Term= 0 or
(a.Term > 20121214 and a.Term <> 20121231)
)
- sjl
"Rpglist" wrote in message
news:mailman.957.1353474725.10847.rpg400-l@xxxxxxxxxxxx...
There are no duplicates that's what is Driving me nuts I've verified this
through a query and had another programmer verify the same thing
Sent from my iPhone
On Nov 20, 2012, at 10:02 PM, "Birgitta Hauser" <Hauser@xxxxxxxxxxxxxxx>
wrote:
That's what I suspected there is no 1:1 relation but an 1:n relation
between
the files. You need to eliminate duplicates
To avoid duplicates, you may use the following SQL Statement:
Select Count(*)
From (Select Distinct Fld1, Fld2, Fl3, Fld4, Fld5, Fld6, Fld7From CaRates a join xtCaRates b
on a.ptccp7 = b.ptccp7 and
a.ptccp6 = b.ptccp6 and
a.ptccp5 = b.ptccp5 and
a.ptccp4 = b.ptccp4 and
a.ptccp3 = b.ptccp3 and
a.ptcpp2 = b.ptccp2 and
a.ptcpp1 = b.ptcpp1 and Where a.Term
=
0
or a.Term > :HostVar) x
or
Select Count(Distinct Fld1 concat Fld2 concat Fld3 concat Fld4 concat
Fld5
concat Fld6 concat Fld7)
From CaRates a join xtCaRates bon a.ptccp7 = b.ptccp7 and
a.ptccp6 = b.ptccp6 and
a.ptccp5 = b.ptccp5 and
a.ptccp4 = b.ptccp4 and
a.ptccp3 = b.ptccp3 and
a.ptcpp2 = b.ptccp2 and
a.ptcpp1 = b.ptcpp1 and Where a.Term = 0 or a.Term >
:HostVar
Mit freundlichen Grü�en / Best regards
Birgitta Hauser
"Shoot for the moon, even if you miss, you'll land among the stars."
(Les
Brown)
"If you think education is expensive, try ignorance." (Derek Bok)
"What is worse than training your staff and losing them? Not training
them
and keeping them!"
-----Ursprüngliche Nachricht-----
Von: rpg400-l-bounces@xxxxxxxxxxxx
[mailto:rpg400-l-bounces@xxxxxxxxxxxx]
Im
Auftrag von rpglist@xxxxxxxxxxx
Gesendet: Tuesday, 20.11 2012 20:54
An: RPG programming on the IBM i / System i
Betreff: Re: AW: Sql count not adding up correctly
Maybe here is a way to explain this better.
File A has 45,000 records over 15 fields, of which seven make each
record
unique.
File B has 22,000,000 records over the same 15 fields, of which seven
also
makes each record unique.
1. I need to A. update File B records that are found in File A and
update
one field and one field only - a date field.
2. I need to be able to run a query and prove the results are accurate.
I thought this count would do that, but its not and it appears I'm
updating
too many as well.
Mac
Still more than doubling up the numbers.....I have verified using QMxtCaRates.
Query that the # of reocrds in the second file matches up one to one
with the first....so instead of getting 150,000 records I should only
have 45K
You may also try the following
Select Count(*)
From CaRates a join xtCaRates bon a.ptccp7 = b.ptccp7 and
a.ptccp6 = b.ptccp6 and
a.ptccp5 = b.ptccp5 and
a.ptccp4 = b.ptccp4 and
a.ptccp3 = b.ptccp3 and
a.ptcpp2 = b.ptccp2 and
a.ptcpp1 = b.ptcpp1 and Where a.Term = 0 or a.Term >
:xDate;
Mit freundlichen Grü�en / Best regards
Birgitta Hauser
"Shoot for the moon, even if you miss, you'll land among the stars."
(Les
Brown)
"If you think education is expensive, try ignorance." (Derek Bok)
"What is worse than training your staff and losing them? Not training
them and keeping them!"
-----Ursprüngliche Nachricht-----
Von: rpg400-l-bounces@xxxxxxxxxxxx
[mailto:rpg400-l-bounces@xxxxxxxxxxxx]
Im
Auftrag von Michael Schutte
Gesendet: Tuesday, 20.11 2012 18:49
An: RPG programming on the IBM i / System i
Betreff: Re: Sql count not adding up correctly
What do you get when you run it like this...
Select count(*) from CaRates as a
Where exists
(select * from xtCaRates as b
where a.ptccp7 = b.ptccp7 and
a.ptccp6 = b.ptccp6 and
a.ptccp5 = b.ptccp5 and
a.ptccp4 = b.ptccp4 and
a.ptccp3 = b.ptccp3 and
a.ptcpp2 = b.ptccp2 and
a.ptcpp1 = b.ptcpp1 and
(a.Term = 0 or a.Term > :xDate))
There's clearly more than a 1 to 1 match between the two tables.
Your update is just doing an EXIST meaning find just one record in
But your validation is joining the two tables together. So if table
CaRates had one record were
ptcpp1 = 1
ptcpp2 = 2
ptcpp3 = 3
ptcpp4 = 4
ptcpp5 = 5
ptcpp6 = 6
ptcpp7 = 7
And xtCaRates had Two records with the same values, your select will
return a count of two, not one like the update EXISTS clause did.
If there were two records in both tables, then the result of count
would be
4 and so on.
On Mon, Nov 19, 2012 at 4:27 PM, <rpglist@xxxxxxxxxxx> wrote:
I'm having a problem trying to get an accurate count of my recordshave:
being updated.
Here is the SQL statement for the update:
Exec Sql
Update CaRates as a
Set a.Term = :xTermDate
Where exists
(select * from xtCaRates as b
where a.ptccp7 = b.ptccp7 and
a.ptccp6 = b.ptccp6 and
a.ptccp5 = b.ptccp5 and
a.ptccp4 = b.ptccp4 and
a.ptccp3 = b.ptccp3 and
a.ptcpp2 = b.ptccp2 and
a.ptcpp1 = b.ptcpp1 and
(a.Term = 0 or a.Term > :xDate));
The update seems to work just fine, but I'm trying to validate the
results and this statement always seems to give me more records than
I
--
SELECT count(*)
FROM CaRates a, xtCaRates b WHERE a.ptccp7 = b.ptccp7 and a.ptccp6 =
b.ptccp6 and a.ptccp5 = b.ptccp5 and a.ptccp4 =
b.ptccp4 and a.ptccp3 = b.ptccp3 and a.ptccp2 = b.ptccp2 and
a.ptccp1 = b.ptccp1
and (a.Term= 0 or a.Term > 20121214 and a.Term <> 20121231)
Any help or suggestion would be greatly appreciated.
--
This is the RPG programming on the IBM i / System i (RPG400-L)
mailing list To post a message email: RPG400-L@xxxxxxxxxxxx To
subscribe, unsubscribe, or change list options,
visit: http://lists.midrange.com/mailman/listinfo/rpg400-l
or email: RPG400-L-request@xxxxxxxxxxxx Before posting, please take
a moment to review the archives at
http://archive.midrange.com/rpg400-l.
This is the RPG programming on the IBM i / System i (RPG400-L)
mailing list To post a message email: RPG400-L@xxxxxxxxxxxx To
subscribe, unsubscribe, or change list options,
visit: http://lists.midrange.com/mailman/listinfo/rpg400-l
or email: RPG400-L-request@xxxxxxxxxxxx Before posting, please take a
moment to review the archives at
http://archive.midrange.com/rpg400-l.
--
This is the RPG programming on the IBM i / System i (RPG400-L)
mailing list To post a message email: RPG400-L@xxxxxxxxxxxx To
subscribe, unsubscribe, or change list options,
visit: http://lists.midrange.com/mailman/listinfo/rpg400-l
or email: RPG400-L-request@xxxxxxxxxxxx Before posting, please take a
moment to review the archives at
http://archive.midrange.com/rpg400-l.
--
This is the RPG programming on the IBM i / System i (RPG400-L) mailing
list To post a message email: RPG400-L@xxxxxxxxxxxx To subscribe,
unsubscribe, or change list options,
visit: http://lists.midrange.com/mailman/listinfo/rpg400-l
or email: RPG400-L-request@xxxxxxxxxxxx Before posting, please take a
moment to review the archives at http://archive.midrange.com/rpg400-l.
--
This is the RPG programming on the IBM i / System i (RPG400-L) mailing
list
To post a message email: RPG400-L@xxxxxxxxxxxx To subscribe,
unsubscribe,
or
change list options,
visit: http://lists.midrange.com/mailman/listinfo/rpg400-l
or email: RPG400-L-request@xxxxxxxxxxxx
Before posting, please take a moment to review the archives at
http://archive.midrange.com/rpg400-l.
--
This is the RPG programming on the IBM i / System i (RPG400-L) mailing
list
To post a message email: RPG400-L@xxxxxxxxxxxx
To subscribe, unsubscribe, or change list options,
visit: http://lists.midrange.com/mailman/listinfo/rpg400-l
or email: RPG400-L-request@xxxxxxxxxxxx
Before posting, please take a moment to review the archives
at http://archive.midrange.com/rpg400-l.
--
This is the RPG programming on the IBM i / System i (RPG400-L) mailing
list
To post a message email: RPG400-L@xxxxxxxxxxxx
To subscribe, unsubscribe, or change list options,
visit: http://lists.midrange.com/mailman/listinfo/rpg400-l
or email: RPG400-L-request@xxxxxxxxxxxx
Before posting, please take a moment to review the archives
at http://archive.midrange.com/rpg400-l.
As an Amazon Associate we earn from qualifying purchases.
This mailing list archive is Copyright 1997-2024 by midrange.com and David Gibbs as a compilation work. Use of the archive is restricted to research of a business or technical nature. Any other uses are prohibited. Full details are available on our policy page. If you have questions about this, please contact [javascript protected email address].
Operating expenses for this site are earned using the Amazon Associate program and Google Adsense.