SQL Server Forums
Profile | Register | Active Topics | Members | Search | Forum FAQ
 
Register Now and get your question answered!
Username:
Password:
Save Password
Forgot your Password?

 All Forums
 SQL Server 2005 Forums
 Transact-SQL (2005)
 SQL query help
 New Topic  Reply to Topic
 Printer Friendly
Author Previous Topic Topic Next Topic  

jbon
Starting Member

Sweden
20 Posts

Posted - 10/25/2012 :  08:15:15  Show Profile  Reply with Quote
Hi,
lets say I have two tables INBOUND and OUTBOUND. They are related as 1 to many (one inbound can have several outbounds). INBOUND table have one column holding no of items delivered in. OUTBOUND table has one column holding no of items delivered out.

Now in my query I want to keep track on the current saldo, how do I do this?

Example:
INBOUND table
ItemID - NoOfItemsIn
------------------------
A - 100

OUTBOUND table
ItemID - NoOfItemsOut
------------------------
A - 20
A - 40
A - 40

My query I want to result as below
QUERY RESULT
ItemID - NoOfItemsOut - SaldoInStock
--------------------------------
A - 20 - 80
A - 40 - 40
A - 40 - 0

Note! SaldoInStock is not a column in table OUTBOUND

All suggestions of possible solutions is highly appreciated.

nigelrivett
Flowing Fount of Yak Knowledge

United Kingdom
3383 Posts

Posted - 10/25/2012 :  08:50:48  Show Profile  Visit nigelrivett's Homepage  Reply with Quote
with cte as (select *, seq = rownumber() over (order by NoOfItemsOut) from OUTBOUND)
select i.ItemId, o.NoOfItemsOut, SaldoInStock = i.NoOfItemsIn - (select sum(NoOfItemsOut from cte o2 where o2.seq <= o.seq)
from INBOUND i
join cte o
order by o2.seq

==========================================
Cursors are useful if you don't know sql.
SSIS can be used in a similar way.
Beer is not cold and it isn't fizzy.
Go to Top of Page

jbon
Starting Member

Sweden
20 Posts

Posted - 10/25/2012 :  09:28:47  Show Profile  Reply with Quote
Thx, gets following error

...'rownumber' is not a recognized built-in function name.

any ideas?

Is/means

SaldoInStock = i.NoOfItemsIn - (select sum(NoOfItemsOut from cte o2 where o2.seq <= o.seq)

same as

i.NoOfItemsIn - (select sum(NoOfItemsOut from cte o2 where o2.seq <= o.seq) as SaldoInStock

?
Go to Top of Page

webfred
Flowing Fount of Yak Knowledge

Germany
8760 Posts

Posted - 10/25/2012 :  09:32:58  Show Profile  Visit webfred's Homepage  Reply with Quote
change rownumber to row_number


Too old to Rock'n'Roll too young to die.
Go to Top of Page

jbon
Starting Member

Sweden
20 Posts

Posted - 10/26/2012 :  07:53:34  Show Profile  Reply with Quote
with cte as (select *, seq = row_number() over (order by NoOfItemsOut) from OUTBOUND)
select i.ItemId, o.NoOfItemsOut, i.NoOfItemsIn - (select sum(NoOfItemsOut) from cte o2 where o2.seq <= o.seq)
from INBOUND i
join cte o
order by o2.seq


Below gives me below error:
Msg 156, Level 15, State 1, Line 5
Incorrect syntax near the keyword 'order'.

Is it something wrong with/in the join statement?
Go to Top of Page

webfred
Flowing Fount of Yak Knowledge

Germany
8760 Posts

Posted - 10/26/2012 :  08:58:38  Show Profile  Visit webfred's Homepage  Reply with Quote
You can copy / paste and run this:

-- making testdata...
declare @INBOUND table(ItemID varchar(10),NoOfItemsIn int)
------------------------
insert @INBOUND
select 'A', 100

declare @OUTBOUND table(ItemID varchar(10),NoOfItemsOut int)
------------------------
insert @OUTBOUND
select 'A', 20 union all
select 'A', 40 union all
select 'A', 40

----My query I want to result as below
----QUERY RESULT
----ItemID - NoOfItemsOut - SaldoInStock
------------------------------------
----A - 20 - 80
----A - 40 - 40
----A - 40 - 0

-- nigel's solution...
;
with cte as (select *, seq = row_number() over (order by NoOfItemsOut) from @OUTBOUND)
select 
i.ItemId, 
o.NoOfItemsOut, 
i.NoOfItemsIn - (select sum(NoOfItemsOut) from cte o2 where o2.seq <= o.seq)
from @INBOUND i
join cte o on i.ItemId = o.ItemId
order by o.seq



Too old to Rock'n'Roll too young to die.
Go to Top of Page

webfred
Flowing Fount of Yak Knowledge

Germany
8760 Posts

Posted - 10/26/2012 :  09:05:12  Show Profile  Visit webfred's Homepage  Reply with Quote
Test this please - I have modified the solution so it can handle more than one ItemId...

-- making testdata...
declare @INBOUND table(ItemID varchar(10),NoOfItemsIn int)
------------------------
insert @INBOUND
select 'A', 100 union all
select 'B', 500

declare @OUTBOUND table(ItemID varchar(10),NoOfItemsOut int)
------------------------
insert @OUTBOUND
select 'A', 20 union all
select 'A', 40 union all
select 'A', 40 union all
select 'B', 450 union all
select 'B', 10

----My query I want to result as below
----QUERY RESULT
----ItemID - NoOfItemsOut - SaldoInStock
------------------------------------
----A - 20 - 80
----A - 40 - 40
----A - 40 - 0

-- nigel's solution...
;
with cte as (select *, seq = row_number() over (partition by ItemId order by NoOfItemsOut) from @OUTBOUND)
select 
i.ItemId, 
o.NoOfItemsOut, 
i.NoOfItemsIn - (select sum(NoOfItemsOut) from cte o2 where o2.seq <= o.seq and o2.ItemId = o.ItemId)
from @INBOUND i
join cte o on i.ItemId = o.ItemId
order by i.ItemId,o.seq



Too old to Rock'n'Roll too young to die.
Go to Top of Page

nigelrivett
Flowing Fount of Yak Knowledge

United Kingdom
3383 Posts

Posted - 10/26/2012 :  09:11:04  Show Profile  Visit nigelrivett's Homepage  Reply with Quote
sorry I missed out the join criteria

with cte as (select *, seq = row_number() over (order by NoOfItemsOut) from OUTBOUND)
select i.ItemId, o.NoOfItemsOut, i.NoOfItemsIn - (select sum(NoOfItemsOut) from cte o2 where o2.seq <= o.seq)
from INBOUND i
join cte o
on i.ItemId = o.ItemId
order by o2.seq

==========================================
Cursors are useful if you don't know sql.
SSIS can be used in a similar way.
Beer is not cold and it isn't fizzy.
Go to Top of Page

webfred
Flowing Fount of Yak Knowledge

Germany
8760 Posts

Posted - 10/26/2012 :  09:24:50  Show Profile  Visit webfred's Homepage  Reply with Quote
quote:
Originally posted by nigelrivett

sorry I missed out the join criteria

with cte as (select *, seq = row_number() over (order by NoOfItemsOut) from OUTBOUND)
select i.ItemId, o.NoOfItemsOut, i.NoOfItemsIn - (select sum(NoOfItemsOut) from cte o2 where o2.seq <= o.seq)
from INBOUND i
join cte o
on i.ItemId = o.ItemId
order by o2.seq

==========================================
Cursors are useful if you don't know sql.
SSIS can be used in a similar way.
Beer is not cold and it isn't fizzy.


The multi-part identifier "o2.seq" could not be bound.
Did'nt you see my post(s)???


Too old to Rock'n'Roll too young to die.
Go to Top of Page

jbon
Starting Member

Sweden
20 Posts

Posted - 10/26/2012 :  09:36:01  Show Profile  Reply with Quote
Hi Webfred & nigelrivett,
Thx for your help.

Webfred - your code worked as i want, thx.

Just curious... 'declare @INBOUND table(ItemID varchar(10),NoOfItemsIn int)' ... is this creating a ~"virtual" table? Really nice...
Go to Top of Page
  Previous Topic Topic Next Topic  
 New Topic  Reply to Topic
 Printer Friendly
Jump To:
SQL Server Forums © 2000-2009 SQLTeam Publishing, LLC Go To Top Of Page
This page was generated in 0.09 seconds. Powered By: Snitz Forums 2000