473,474 Members | 1,682 Online
Bytes | Software Development & Data Engineering Community
Create Post

Home Posts Topics Members FAQ

Populate table with stored proc

I am looking to populate a Schedule table with information from two
other tables. I am able to populate it row by row, but I have created
tables that should provide all necessary information for me to be
able
to automatically populate a "generic" schedule for a few weeks or
more
at a time.

The schedule table contains:
(pk) schedule_id, start_datetime, end_datetime, shift_employee,
shift_position
A DaysOff table contains:
(pk) emp_id, dayoff_1, dayoff_2 <-- the days off are entered in day
of
week (1-7) form
A CalendarDays table contains:
(pk) date, calendar_dow <-- dow contains the day of week number (as
above) for each day until 2010.
My main question is how to put all of this information together and
have SQL populate the rows with data based on days off, for a few
weeks in advance. Any
suggestions?

Apr 24 '07 #1
4 6556
Nate (na**********@westecnow.com) writes:
I am looking to populate a Schedule table with information from two
other tables. I am able to populate it row by row, but I have created
tables that should provide all necessary information for me to be able
to automatically populate a "generic" schedule for a few weeks or more
at a time.

The schedule table contains:
(pk) schedule_id, start_datetime, end_datetime, shift_employee,
shift_position
A DaysOff table contains:
(pk) emp_id, dayoff_1, dayoff_2 <-- the days off are entered in day of
week (1-7) form
A CalendarDays table contains:
(pk) date, calendar_dow <-- dow contains the day of week number (as
above) for each day until 2010.
My main question is how to put all of this information together and have
SQL populate the rows with data based on days off, for a few weeks in
advance. Any suggestions?
The problem looks kind of interesting, but alas the hour is late here,
so I'm not able to compose a solution right now. But I would like some
clarifications:

1) Which version of SQL Server are you using?
2) Do I understand the DaysOff table correctly that this table details
two days in the week a certain employer never works, for instance
one bloke is always free on Tuesdays and Fridays?
3) What is supposed to go into shift_employee and shift_position?

It would be great if you could post:
1) CREATE TABLE statements for your tables.
2) INSERT statements with sample data (at least for the first two tables).
3) The desired result given the sample.

This makes it easy to test a solution. It also helps to clarify your
problem.

--
Erland Sommarskog, SQL Server MVP, es****@sommarskog.se

Books Online for SQL Server 2005 at
http://www.microsoft.com/technet/pro...ads/books.mspx
Books Online for SQL Server 2000 at
http://www.microsoft.com/sql/prodinf...ons/books.mspx
Apr 24 '07 #2
It is a little bit unclear based on your tables to figure out how to
transform the days off to the schedule (what are those shifts, start/end
datetime, etc.). But here is a way to pull the schedule data together based
on your calendar table and the table with days off.

The first step is to normalize the DaysOff table. You can either redesign
the table and have it with only emp_id and dayoff columns and PK (emp_id,
dayoff), or if redesign is not possible then use a view, like this:

CREATE VIEW EmployeeDaysOff
(emp_id, dayoff)
AS
SELECT emp_id,
dayoff_1
FROM DaysOff
UNION ALL
SELECT emp_id,
dayoff_2
FROM DaysOff;

Then pulling the schedule based on your calendar table and this view becomes
a simple query:

DECLARE @start DATETIME
DECLARE @end DATETIME

SET @start = '20070429'
SET @end = '20070512'

SELECT E.emp_id,
C.date
FROM DaysOff AS E, CalendarDays AS C
WHERE C.date BETWEEN @start and @end
AND NOT EXISTS
(SELECT *
FROM EmployeeDaysOff AS O
WHERE O.emp_id = E.emp_id
AND O.dayoff = C.calendar_dow);

Notes:
- You can pass those parameters (@start and @end) to your stored procedure,
that will be the date range to open schedule for
- In the query I used DaysOff to get all employees. But you probably have a
table with employees and should replace it with that. The query above will
not produce the correct results if you have employees that do not have days
off.

If you are on SQL Server 2005 you can use the EXCEPT, like this:

SELECT E.emp_id,
C.date
FROM DaysOff AS E, CalendarDays AS C
WHERE C.date BETWEEN @start and @end
EXCEPT
SELECT O.emp_id,
C.date
FROM EmployeeDaysOff AS O, CalendarDays AS C
WHERE C.date BETWEEN @start and @end
AND O.dayoff = C.calendar_dow;

The same note to replacing DaysOff with the table with employees apply for
the here (for the first query before EXCEPT).

HTH,

Plamen Ratchev
http://www.SQLStudio.com

Apr 24 '07 #3
Just to clarify, you can still get the same results without normalizing the
DaysOff table... :)

SELECT E.emp_id,
C.date
FROM DaysOff AS E, CalendarDays AS C
WHERE C.date BETWEEN @start and @end
AND NOT EXISTS
(SELECT *
FROM DaysOff AS O
WHERE O.emp_id = E.emp_id
AND C.calendar_dow IN (O.dayoff_1, O.dayoff_2));

Plamen Ratchev
http://www.SQLStudio.com
Apr 24 '07 #4
In addition, if you meant to have the data into the schedule table by
listing the ranges of dates between the days off for each employee, you can
get the data like this (ROW_NUMBER assumes SQL Server 2005 is used):

SELECT emp_id,
MIN(date) AS StartDate,
MAX(date) AS EndDate
FROM (
SELECT E.emp_id,
C.date,
C.date - ROW_NUMBER() OVER(PARTITION BY E.emp_id
ORDER BY C.date) AS RangeGroup
FROM DaysOff AS E, CalendarDays AS C
WHERE C.date BETWEEN @start and @end
AND NOT EXISTS
(SELECT *
FROM EmployeeDaysOff AS O
WHERE O.emp_id = E.emp_id
AND O.dayoff = C.calendar_dow)) AS S
GROUP BY emp_id, RangeGroup;

Plamen Ratchev
http://www.SQLStudio.com
Apr 25 '07 #5

This thread has been closed and replies have been disabled. Please start a new discussion.

Similar topics

3
by: Alex | last post by:
I have a "source" table that is being populated by a DTS bulk import of a text file. I need to scrub the source table after the import step by running appropriate stored proc(s) to copy the source...
35
by: .:mmac:. | last post by:
I have a bunch of files (Playlist files for media player) and I am trying to create an automatically generated web page that includes the last 20 or 30 of these files. The files are created every...
4
by: Robin Tucker | last post by:
Hi, I'm trying to determine with my program whether or not a given database supports a given feature set. To do this I'm querying for certain stored procedures in the sysobjects table and if...
2
by: hubert.trzewik | last post by:
Hello, Is it possible to EXEC stored procedure from a query? I want to execute stored procedure for every line of SELECT result table. I guess it's possible with cursors, but maybe it's...
3
by: Yul | last post by:
Hi, We are in the process of designing an ASP.NET app, where a user will enter some 'Customer ID' to be queried in the database. If the ID is valid, several stored procedures will be called to...
5
by: Uwe C. Schroeder | last post by:
-----BEGIN PGP SIGNED MESSAGE----- Hash: SHA1 Hi, maybe my mind is stuck, but here's something strange. This is the classic "counter" thing, where you can't / won't use sequences....
5
by: John | last post by:
Hi all, I'm sorry I'm reposting this but the original was urgent and I do need closure on this. I'm calling a stored proc which does 4 "selects" and then I populate a dataset looping through...
2
by: Nate | last post by:
I am looking to populate a Schedule table with information from two other tables. I am able to populate it row by row, but I have created tables that should provide all necessary information for me...
2
by: cookie0311 | last post by:
Hi I am trying to place three DropDownLists inside a Repeater, each DLL is dependent on it’s previous DDL’s selection. I’m developing in asp.net and VB. An Initial DDL (inside the repeater) needs...
0
Oralloy
by: Oralloy | last post by:
Hello folks, I am unable to find appropriate documentation on the type promotion of bit-fields when using the generalised comparison operator "<=>". The problem is that using the GNU compilers,...
0
jinu1996
by: jinu1996 | last post by:
In today's digital age, having a compelling online presence is paramount for businesses aiming to thrive in a competitive landscape. At the heart of this digital strategy lies an intricately woven...
1
by: Hystou | last post by:
Overview: Windows 11 and 10 have less user interface control over operating system update behaviour than previous versions of Windows. In Windows 11 and 10, there is no way to turn off the Windows...
1
isladogs
by: isladogs | last post by:
The next Access Europe User Group meeting will be on Wednesday 1 May 2024 starting at 18:00 UK time (6PM UTC+1) and finishing by 19:30 (7.30PM). In this session, we are pleased to welcome a new...
0
by: conductexam | last post by:
I have .net C# application in which I am extracting data from word file and save it in database particularly. To store word all data as it is I am converting the whole word file firstly in HTML and...
0
by: adsilva | last post by:
A Windows Forms form does not have the event Unload, like VB6. What one acts like?
0
by: 6302768590 | last post by:
Hai team i want code for transfer the data from one system to another through IP address by using C# our system has to for every 5mins then we have to update the data what the data is updated ...
1
muto222
php
by: muto222 | last post by:
How can i add a mobile payment intergratation into php mysql website.
0
bsmnconsultancy
by: bsmnconsultancy | last post by:
In today's digital era, a well-designed website is crucial for businesses looking to succeed. Whether you're a small business owner or a large corporation in Toronto, having a strong online presence...

By using Bytes.com and it's services, you agree to our Privacy Policy and Terms of Use.

To disable or enable advertisements and analytics tracking please visit the manage ads & tracking page.