Please start any new threads on our new
site at https://forums.sqlteam.com. We've got lots of great SQL Server
experts to answer whatever question you can come up with.
Author |
Topic |
consol
Starting Member
3 Posts |
Posted - 2013-07-12 : 08:56:05
|
Hi,I have limited knowledge of SQL.I am totalising water flow.I use a PLC (programmable logic controller) to increment a counter every time the flowmeter sends a pulse.I have an application that logs this incrementing total every 10 sec to a table.At midnight, the PLC resets the counter to zero.I end up with a table containing a daily flow total.I use this flow total in production reports.I record, in another table, the start/end times of various production processes.Using these times, I can calculate the total amount of water used in a process, (Total at 'End time' minus Total at 'Start time'), in a day.My problem is when a process runs over a number of days.How do I account for the reset at midnight (rollover)?I need to get the delta change of the water total from the start of a process to the end of a process a few days later.At the moment I'm doing the following:Get value at start time/date (Vs)Get max value for each day between start and finish of process (Vm)Get value at end time/date (Ve)So for a total running over 3 days:Total = (Ve + Vm1 + Vm2) - VsHow can I write a query to do this for me.There are actually 30 flow meters in the process.Basically, I want to input a start date/time and end date/time and return the total flow through each meter. (and allow for the reset of each meter at midnight) Thanks for any help with this. (It's wrecking my head!)Con |
|
James K
Master Smack Fu Yak Hacker
3873 Posts |
Posted - 2013-07-12 : 09:47:27
|
Something along the lines shown below. You may need to add the meterId etc. in your query, but the basic idea is that you find each day's flow (in the inner query) and then sum them up in the outer query:DECLARE @startDate DATETIME = '2013-07-12 09:12:28.150';DECLARE @endDate DATETIME = '2013-07-15 13:28:31.000';SELECT SUM(MaxVal-MinVal) FROM ( SELECT CAST(YourDateTimeCol AS DATE) AS Date, MAX(VALUE) AS MaxVal, MIN(VALUE) AS MinVal FROM YourTable WHERE YourDateTimeCol >= @startDate AND YourDateTimeCol <= @endDate GROUP BY CAST(YourDateTimeCol AS DATE)) s |
 |
|
consol
Starting Member
3 Posts |
Posted - 2013-07-12 : 10:20:28
|
Thanks James,That's a neater method than my convoluted mess!How would I structure this to return multiple meter totals in one table?Thanks again for your helpCon |
 |
|
James K
Master Smack Fu Yak Hacker
3873 Posts |
Posted - 2013-07-12 : 10:30:55
|
You can add the meterId also to the query:DECLARE @startDate DATETIME = '2013-07-12 09:12:28.150';DECLARE @endDate DATETIME = '2013-07-15 13:28:31.000';SELECT meterId, SUM(MaxVal-MinVal) FROM ( SELECT CAST(YourDateTimeCol AS DATE) AS Date, meterId, MAX(VALUE) AS MaxVal, MIN(VALUE) AS MinVal FROM YourTable WHERE YourDateTimeCol >= @startDate AND YourDateTimeCol <= @endDate GROUP BY CAST(YourDateTimeCol AS DATE), meterId) sGROUP BY meterId; |
 |
|
consol
Starting Member
3 Posts |
Posted - 2013-07-12 : 10:43:13
|
James,Thanks very much for such a neat solution.Appreciate it.Con |
 |
|
James K
Master Smack Fu Yak Hacker
3873 Posts |
Posted - 2013-07-12 : 12:40:24
|
You are very welcome - glad to help. |
 |
|
|
|
|
|
|