× The internal search function is temporarily non-functional. The current search engine is no longer viable and we are researching alternatives.
As a stop gap measure, we are using Google's custom search engine service.
If you know of an easy to use, open source, search engine ... please contact support@midrange.com.



Assuming:
Calendar table is named CALENDAR, with fields CALDATE (calendar
date) and BUSDAY (business day Y or N)
Calendar table has a record for all dates (weekends, holidays, etc)
Date fields in ORDERS table are ORDERDATE and SHIPDATE
Date fields in both tables are 8 characters long, stored as YYYYMMDD


This SELECT should return the shipping date for a given order date.

with DATES as (
select CALDATE from CALENDAR
where CALDATE > ORDERDATE and BUSDAY = 'Y'
order by CALDATE
fetch first 6 rows only)
select MAX(CALDATE) from DATES


That works for a single order. To do that for the entire ORDERS table, you
could create a cursor and loop through the file using the above statement to
determine the ship date.
Or you could create a user-defined function like this:

create function SHIPDATE (ORDERDATE char(8))
returns char(8)
language sql
begin
declare RETDATE char(8);
with DATES as (
select CALDATE from qtemp/CALENDAR
where CALDATE > ORDERDATE and BUSDAY = 'Y'
fetch first 6 rows only)
select MAX(CALDATE) into RETDATE from DATES;
return RETDATE;
end

Then you could:

UPDATE ORDERS
SET SHIPDATE = SHIPDATE(ORDERDATE)


No idea what the performance would be like. Probably would want an index on
CALDATE in CALENDAR!

Have fun!

Richard

-----Original Message-----
From: midrange-l-bounces@xxxxxxxxxxxx
[mailto:midrange-l-bounces@xxxxxxxxxxxx] On Behalf Of Jon Paris
Sent: Tuesday, July 12, 2011 12:31 PM
To: Midrange-L Midrange-l
Subject: SQL Inspiration needed

I'm collecting alternative solutions for a couple of SQL "problems" - things
that would be relatively easy (if laborious) in native RPG.

So ... given that I have a table ORDERS which contains order and shipping
dates, I need to populate the shipping dates such that the shipping date is
6 "business days" after the order date.

Business days can be determined from a calendar table keyed on date and
which contains a "Y" or "N" to indicate whether that date is a business day
or not.

Any ideas? The only ones we come up with are so darn nasty.


Jon Paris

www.partner400.com
www.SystemiDeveloper.com

--


As an Amazon Associate we earn from qualifying purchases.

This thread ...

Replies:

Follow On AppleNews
Return to Archive home page | Return to MIDRANGE.COM home page

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.