on 2014 Apr 20 5:20 AM
I have a good working sql that works in sql server. The logical computation calculates how many lengths will fit a barrel. Maximum capacity per drum is 14300 meters. My question is how I can get this to work with Sybase.
Declare @tblLength table (num int, qty int, unit varchar(20))
insert @tblLength
values
(2,2500,''),
(1,3800,''),
(1,4200,''),
(1,6500,''),
(1,8300,'')
;with cte as
(
select i=1, qty, unit from @tblLength where num >= 1
union all
select i=i+1, t.qty, t.unit from @tblLength t, cte where t.qty=cte.qty and t.unit = cte.unit and t.num >= i+1
),
cte2 as
(
select *, id=row_number() over (order by qty desc) from cte
),
cte3 as
(
select j=1, qty, unit, id, tot=qty, drum=1 from cte2 where id = 1
union all
select j=j+1, cte2.qty, cte2.unit, cte2.id,
tot=case when cte3.tot+cte2.qty > 14300 then cte2.qty else cte3.tot+cte2.qty end,
drum=case when cte3.tot+cte2.qty > 14300 then cte3.drum + 1 else cte3.drum end
from cte2,cte3 where cte2.id = j+1
)
select drum, qty, unit from cte3
Request clarification before answering.
Here's a sample with a stored procedure. It uses the following assumptions:
Note: I usually use Watcom SQL but as your sample code has made use of T-SQL style, I have tried to combine that - the identifiers are not very well chosen but I hope you get the idea...
-- create the local temp table with sample length entries drop table @tblLength; declare local temporary table @tblLength (nr int default autoincrement primary key, num int, qty int, unit varchar(20)) not transactional; insert @tblLength (num, qty, unit) values (2,2500,''), (1,3800,''), (1,4200,''), (1,6500,''), (1,8300,''); -- select * from @tblLength -- -- STP with maximum drum capacity as parameter create or replace procedure STP_DistributeLengthToDrum(@max_drum_length int) begin -- local temp table to distribute lengthes to drums declare local temporary table @distribution (length_nr int, num int, qty int, drum_nr int) not transactional; -- local variables to store current drum number and left space declare @current_drum_nr int = 1; declare @current_drum_space int = 0; -- simple sanitiy check to use a default max drum capacity if isnull(@max_drum_length, 0) = 0 then set @max_drum_length = 14300; end if; set @current_drum_space = @max_drum_length; begin -- loop through all lengthes and test if they will fit on the current drum for for_crs as crs cursor for select nr as @length_nr, num as @num, qty as @qty from @tblLength order by nr do -- if it won't fit, fill the next drum if @num * @qty > @current_drum_space then set @current_drum_nr = @current_drum_nr + 1; set @current_drum_space = @max_drum_length; end if; -- note the occupied space for the next test set @current_drum_space = @current_drum_space - @num * @qty; -- store the according drum_nr for the current length entry insert @distribution values (@length_nr, @num, @qty, @current_drum_nr); end for; end; -- final select to list each drum with the according length entries and the occupied and left capacity select drum_nr, list(length_nr) as length_list, list(num * qty) as qty_list, sum(num * qty) as total_length, @max_drum_length - total_length as space_left from @distribution group by drum_nr order by drum_nr; end; -- call the procedure - note you can also combine that in joins with tables... select * from STP_DistributeLengthToDrum(14300);
This will return the following result set:
drum_nr, length_list, qty_list, total_length, space_left 1, 1,2,3, 5000,3800,4200, 13000, 1300 2, 4, 6500, 6500, 7800 3, 5, 8300, 8300, 6000
You must be a registered user to add a comment. If you've already registered, sign in. Otherwise, register and sign in.
Thank you!
This was exactly what I was looking for. The only thing I would add, and you also mentioned is to optimize the calculation so it fills the drums as much as possible and so there will be as few drums as possible. It will not be optimal if it takes the length of a sequence. Did you have some smart logic to it which can be supplemented in this?
Each length of tbllength are on separate lines. Like this:
insert @tblLength (num, qty, unit) values (1,2500,''), (1,2500,''), (1,3800,''), (1,4200,''), (1,6500,''), (1,8300,'');
When I run the procedure I would like the presents like this:
drum_nr---count---qty_list---total_length---space_left ______________________________________________________ 1---------2-------2500-------13000----------1300 1---------1-------3800-------13000----------1300 1---------1-------4200-------13000----------1300 2---------1-------6500-------6500-----------7800 3---------1-------8300-------8300-----------6000
Is it possible?
I'd try to make Volkers algorithm "greedy", which means to take as many lengthes as possible and take the big ones first. Plus don't stop using a drum when the next length doesn't fit but try smaller ones until no length fits. That wouldn't yield the optimal solution (as far as I remeber from student days) but some kind of optimization.
Doing so in your sample setting there is no drum spared but more space left on the third drum.
My procedural SQL skills are not really exciting so the following code needs carefull error checking and is to be optimized. It is indeed an extension of Volkers code. Please note that I've inserted a length > 14300 to show one of the problems with the sample code.
Presenting the results might be a nice task to optimize ones sql skills for the future.
-- create the local temp table with sample length entries
drop table @tblLength
;
declare local temporary table @tblLength (nr int default autoincrement primary key, num int, qty int, unit varchar(20))
not transactional
;
insert @tblLength (num, qty, unit)
values
(2,2500,''),
(1,3800,''),
(1,4200,''),
(1,6500,''),
(1,8300,''),
(1,14400,'')
;
-- select * from @tblLength --
-- STP with maximum drum capacity as parameter
create or replace procedure STP_DistributeLengthToDrum(@max_drum_length int)
begin
-- local temp table to distribute lengthes to drums
declare local temporary table @distribution (length_nr int, num int, qty int, drum_nr int) not transactional;
-- local variables to store current drum number and left space
declare @current_drum_nr int = 0;
declare @current_drum_space int = 0;
declare @count int = 0 ;
-- simple sanitiy check to use a default max drum capacity
if isnull(@max_drum_length, 0) = 0 then
set @max_drum_length = 14300;
end if;
begin
set @count = (select sum(num) from @tblLength where qty<=@max_drum_length) ;
while @count > 0
loop
set @current_drum_nr = @current_drum_nr + 1;
set @current_drum_space = @max_drum_length;
for for_crs as crs cursor for
select nr as @length_nr, num as @num, qty as @qty from @tblLength
where num > 0
order by qty desc
do
if @qty <= @current_drum_space then
set @current_drum_space = @current_drum_space - @qty;
insert @distribution values (@length_nr, 1, @qty, @current_drum_nr);
update @tblLength
set num = num - 1
where nr = @length_nr;
end if ;
end for ;
set @count = (select sum(num) from @tblLength where qty<=@max_drum_length) ;
end loop;
end ;
-- final select to list each drum with the according length entries and the occupied and left capacity
select drum_nr, list(length_nr) as length_list,
list(num * qty) as qty_list, sum(num * qty) as total_length,
@max_drum_length - total_length as space_left
from @distribution
group by drum_nr
order by drum_nr;
end
;
-- call the procedure - note you can also combine that in joins with tables...
select * from STP_DistributeLengthToDrum(14300)
;
Can't edit my last comment again so I post an improved solution here
-- create the local temp table with sample length entries
drop table @tblLength
;
declare local temporary table @tblLength (nr int default autoincrement primary key, num int, qty int, unit varchar(20))
not transactional
;
insert @tblLength (num, qty, unit)
values
(2,2500,''),
(1,3800,''),
(1,4200,''),
(1,6500,''),
(1,8300,''),
(1,14400,'')
;
-- select * from @tblLength --
-- STP with maximum drum capacity as parameter
create or replace procedure STP_DistributeLengthToDrum(@max_drum_length int)
begin
-- local temp table to distribute lengthes to drums
declare local temporary table @distribution (length_nr int, num int, qty int, drum_nr int) not transactional;
-- local variables to store current drum number, left space and length count
declare @current_drum_nr int = 0; -- starting with 0 now!
declare @current_drum_space int = 0;
declare @count int = 0 ;
declare @i int = 0 ;
-- simple sanitiy check to use a default max drum capacity
if isnull(@max_drum_length, 0) = 0 then
set @max_drum_length = 14300;
end if;
begin
-- while lengthes left in the pool
set @count = (select sum(num) from @tblLength where qty<=@max_drum_length) ;
while @count > 0
loop
-- use a new drum
set @current_drum_nr = @current_drum_nr + 1;
set @current_drum_space = @max_drum_length;
-- search all left lengthes from big to small
for for_crs as crs cursor for
select nr as @length_nr, num as @num, qty as @qty from @tblLength
where num > 0
order by qty desc
do
-- while length fits to the drum and is in the pool
set @i = 1 ;
while @qty <= @current_drum_space and @i <= @num
loop
set @i = @i + 1 ;
-- decrease current drum space
set @current_drum_space = @current_drum_space - @qty;
-- put length on the drum ...
insert @distribution values (@length_nr, 1, @qty, @current_drum_nr);
-- ... and take it from the pool
update @tblLength
set num = num - 1
where nr = @length_nr;
end loop ;
end for ;
-- get actual length count in the pool
set @count = (select sum(num) from @tblLength where qty<=@max_drum_length) ;
end loop;
end ;
-- final select to list each drum with the according length entries and the occupied and left capacity
select dist.drum_nr, count(dist.qty) as count, dist.qty as qty_list, max(aggr.total_length) as total_length, max(aggr.space_left) as space_left
from @distribution dist,
(select drum_nr as drum_nr,
sum(qty) as total_length,
@max_drum_length - total_length as space_left
from @distribution
group by drum_nr) aggr
where aggr.drum_nr = dist.drum_nr
group by dist.drum_nr, qty
order by dist.drum_nr asc, qty desc;
end
;
-- call the procedure - note you can also combine that in joins with tables...
select * from STP_DistributeLengthToDrum(14300)
;
Not sure what the best solution is. Works for me as shown. Try a "FOR UPDATE" clause in the cursor deklaration:
-- search all left lengthes from big to small
for for_crs as crs cursor for
select nr as @length_nr, num as @num, qty as @qty from @tblLength
where num > 0
order by qty desc
for update
do
Use (1) the "declare local temporary table" statement as shown twice im the sample code so far OR (2) examine the product documentation here: http://infocenter.sybase.com/help/index.jsp?docset=/com.sybase.help.sqlanywhere.12.0.1/sqlanywhere_e.... In either case I'd guess you shold put it in the function at the beginning for it is needed throughout the whole algorithm, shouldn't you? If you decide for option (1) from my last comment please don't forget to copy the content from the original "real" table into the newly created temporary table and to replace the table name in the code.
For those who are algorithmically inclined ... This appears to me as being the SQL approximation of the one-dimensional "First Fit" heuristic algorithm. {a heuristic for a family of N-P complete problems related to the "Bin Packing problem"} As such, without some sort or recursion or look ahead ... it may take some time to find a simplified algorithm to make this happen.
The original solution is a creative utilization of SQL Server features. A similarly crafty SQL Anywhere solution may take a bit of effort.
You must be a registered user to add a comment. If you've already registered, sign in. Otherwise, register and sign in.
> nobody will understand what's going on there
Always a danger... whenever I code recursive unions the "nobody will understand" includes ME, five minutes later 🙂
My simplistic attempt to split this into 2 parts with the use of a stored procedure fails. I suspect that may be because of inlining ...
Maybe some other readers have a better approach.
You must be a registered user to add a comment. If you've already registered, sign in. Otherwise, register and sign in.
Sadly, I'd love to help, but I still don't have a clue about what the query is trying to accomplish... in spite of your valiant attempts to explain it. Perhaps if you explained it as if you were speaking to a kindergarten class...
I just went through the same exercise as Breck and I concur that the main issue arises with the inclusion of cte3.
I suspect this is due to the documented restriction:
"References to other recursive common table expressions cannot appear within
the definition of recursive common table expressions as recursive common table
expressions cannot be mutually recursive."
In the case of this query, the definitions of cte and cte3 are both recursive (common table expressions), so that would seem to be the most likely candidate for the invalidness of cte3.
I don't know what the best approach is here; one could possibly inject a layer like a stored procedure or temporary stored procedure to isolate out the references ... but that seems inefficient.
You must be a registered user to add a comment. If you've already registered, sign in. Otherwise, register and sign in.
User | Count |
---|---|
47 | |
6 | |
6 | |
5 | |
5 | |
4 | |
4 | |
3 | |
3 | |
3 |
You must be a registered user to add a comment. If you've already registered, sign in. Otherwise, register and sign in.