Subject | RE: [firebird-support] Get the last count |
---|---|
Author | Dunbar, Norman (Capgemini) |
Post date | 2011-04-07T08:13:04Z |
Morning Walter,
from movimdet
where movim_id = (
select movim_id
from movimcab
where movim_date = (
select max(movim_date)
from movimcab
)
);
I would advise adding a descending index to the movim_date column in
movimcab to make extracting the maximum date much easier as data volumes
increase.
One question, although you have the movim_id in each table, movimdet
also has product codes. I assume that there will be other products and
not just product 501? If so, is the following a decent data set for your
needs where another product code is in use?
MOVIMDET
-----------------------
1 101 02
1 501 20
2 101 12
2 501 20
3 101 202
3 501 15
If so, then my query above will require the product_code adding to the
list of selected columns on the first line:
select product_code,product_count
from movimdet
where movim_id = (
select movim_id
from movimcab
where movim_date = (
select max(movim_date)
from movimcab
)
);
PRODUCT_CODE PRODUCT_COUNT
--------------------------
101 202
501 15
And, if you had a movimdesc table holding product_code and
product_descriptions, the following would also be helpful:
MOVIMDESC
-----------
101 Widget
501 Thermo-nuclear device
select d.product_desc,n.product_count
from movimdet n
join movimdesc d on (d.product_code = n.product_code)
where movim_id = (
select movim_id
from movimcab
where movim_date = (
select max(movim_date)
from movimcab
)
);
I'd have a unique ascending index on product_desc in this table.
PRODUCT_DESC PRODUCT_COUNT
--------------------------
Widget 202
Thermo-nuclear device 15
HTH
Cheers,
Norman.
Norman Dunbar
Contract Senior Oracle DBA
Capgemini Database Team (EA)
Internal : 7 28 2051
External : 0113 231 2051
Information in this message may be confidential and may be legally privileged. If you have received this message by mistake, please notify the sender immediately, delete it and do not copy it to anyone else.
We have checked this email and its attachments for viruses. But you should still check any attachment before opening it.
We may have to make this message and any reply to it public if asked to under the Freedom of Information Act, Data Protection Act or for litigation. Email messages and attachments sent to or from any Environment Agency address may also be accessed by someone other than the sender or recipient, for business purposes.
If we have sent you information and you wish to use it please read our terms and conditions which you can get by calling us on 08708 506 506. Find out more about the Environment Agency at www.environment-agency.gov.uk
>> I have a table MOVIMCAB (Movim_ID, Movim_Date)select product_count
>> and a table MOVIMDET (Movim_ID, Product_Code, Product_Count)
>> both tables can be relationated by the Movim_ID column
>>
>> How can I to know which is the Product_Count of the last date?
>>
>> MOVIMCAB
>> ------------------------
>> 1 01/01/2010
>> 2 02/02/2010
>> 3 06/03/2010
>>
>> MOVIMDET
>> -----------------------
>> 1 501 20
>> 2 501 12
>> 3 501 15
>>
>> I want to get 15, because it is the Product_Count of the last date.
from movimdet
where movim_id = (
select movim_id
from movimcab
where movim_date = (
select max(movim_date)
from movimcab
)
);
I would advise adding a descending index to the movim_date column in
movimcab to make extracting the maximum date much easier as data volumes
increase.
One question, although you have the movim_id in each table, movimdet
also has product codes. I assume that there will be other products and
not just product 501? If so, is the following a decent data set for your
needs where another product code is in use?
MOVIMDET
-----------------------
1 101 02
1 501 20
2 101 12
2 501 20
3 101 202
3 501 15
If so, then my query above will require the product_code adding to the
list of selected columns on the first line:
select product_code,product_count
from movimdet
where movim_id = (
select movim_id
from movimcab
where movim_date = (
select max(movim_date)
from movimcab
)
);
PRODUCT_CODE PRODUCT_COUNT
--------------------------
101 202
501 15
And, if you had a movimdesc table holding product_code and
product_descriptions, the following would also be helpful:
MOVIMDESC
-----------
101 Widget
501 Thermo-nuclear device
select d.product_desc,n.product_count
from movimdet n
join movimdesc d on (d.product_code = n.product_code)
where movim_id = (
select movim_id
from movimcab
where movim_date = (
select max(movim_date)
from movimcab
)
);
I'd have a unique ascending index on product_desc in this table.
PRODUCT_DESC PRODUCT_COUNT
--------------------------
Widget 202
Thermo-nuclear device 15
HTH
Cheers,
Norman.
Norman Dunbar
Contract Senior Oracle DBA
Capgemini Database Team (EA)
Internal : 7 28 2051
External : 0113 231 2051
Information in this message may be confidential and may be legally privileged. If you have received this message by mistake, please notify the sender immediately, delete it and do not copy it to anyone else.
We have checked this email and its attachments for viruses. But you should still check any attachment before opening it.
We may have to make this message and any reply to it public if asked to under the Freedom of Information Act, Data Protection Act or for litigation. Email messages and attachments sent to or from any Environment Agency address may also be accessed by someone other than the sender or recipient, for business purposes.
If we have sent you information and you wish to use it please read our terms and conditions which you can get by calling us on 08708 506 506. Find out more about the Environment Agency at www.environment-agency.gov.uk