NextPVR Forums
  • ______
  • Home
  • New Posts
  • Wiki
  • Members
  • Help
  • Search
  • Register
  • Login
  • Home
  • Wiki
  • Members
  • Help
  • Search
NextPVR Forums Public Developers v
« Previous 1 … 5 6 7 8 9 … 93 Next »
Another SQL question

 
  • 0 Vote(s) - 0 Average
Another SQL question
bgowland
Offline

Posting Freak

West Yorkshire, UK
Posts: 4,583
Threads: 384
Joined: Dec 2004
#1
2012-06-23, 11:32 PM
I'm still not sure why I struggle with SQL of all things. It must be a blind-spot of mine.

Anyway, to the point, I need to find the 'Next' programme to go along with a NOW/NEXT type of view. Doing NOW is easy and I thought NEXT would be too.

So what's wrong with this SQL query which basically tries to find 1 programme for each channel which hasn't started yet...
Code:
select * from epg_event where start_time >= datetime('now') GROUP BY channel_oid
...it works and does only provide one programme for each channel but the start_time columns are showing me dates of either the 6th or 7th of July. It seems it's showing me the very last programme for each channel in my EPG_EVENT table whereas I obviously need the very first for each channel which hasn't started yet. :confused:

Cheers,
Brian
ACTCMS
Offline

Posting Freak

UK
Posts: 2,730
Threads: 101
Joined: Jun 2007
#2
2012-06-24, 12:00 AM
The basic query will return every programme which has not yet started - the GROUP BY then rolls them up by channel_oid so you get a single programme for each group - you would seem to be getting the last when you really want the first.

My knowledge of sql syntax is very elementary, but I would expect there to be some modifer which would allow you to specify First - unfortunately, I haven't a clue what it is - sorry

Alex
bgowland
Offline

Posting Freak

West Yorkshire, UK
Posts: 4,583
Threads: 384
Joined: Dec 2004
#3
2012-06-24, 12:21 AM
Yep, that's pretty much it.

I've been hopping between the SQLite docs and SQLiteSpy testing various queries and I still can't get my head around it. I even managed to return 240,000+ results with one query when there's only ~9500 events in the table and I only want the next 25 events for the channels I have.

Another tweak and I think SQLiteSpy went in to recursive meltdown and I had to kill it with Task Manager. :eek:

Brain hurts - time to grab a beer and stare at the TV I think. Smile

Cheers,
Brian
gEd
Offline

Posting Freak

London
Posts: 3,514
Threads: 100
Joined: Jan 2005
#4
2012-06-24, 01:09 AM
how about

SELECT TOP 1 * from epg_event where start_time >= datetime('now') ORDER BY thedatetime GROUP BY channel_oid
“If this is the way Queen Victoria treats her prisoners, she doesn't deserve to have any.”
rookie
Offline

Member

Posts: 87
Threads: 10
Joined: Dec 2008
#5
2012-06-24, 01:42 AM
Does sqllite support 'SELECT TOP 1 *...' syntax?

Is there a table for channel oids? I'll call it 'channel_oid_table' (I don't have the scheme up in front of me). If there a table, then something like this might get close:


[INDENT]SELECT * from epg_event where start_time > datetime('now') ORDER BY thedatetime GROUP BY channel_oid LIMIT (select COUNT(*) FROM channel_oid_table)
[/INDENT]


There is still the problem of where a channel might have multiple programs started before one of the channels has a program start. This would be so much easier with a little C# or Perl to process the results set.
EVGA 730i 113-YW-E115
C2D E8400 C0 Stepping
4gb GSkill F2-8000CL5D-4GBPQ
500 GB Seagate SATAII
Win7
HVR-2250 TV Tuner
NPVR 2.3.6
odin
Offline

Member

Posts: 105
Threads: 12
Joined: Oct 2011
#6
2012-06-24, 10:51 AM (This post was last modified: 2012-06-24, 10:58 AM by odin.)
Brian, here's my 'now and next' query that I've just written on my sqllite db. It is working for me. Give it a try and see if this is what you want or if you can make it more 'elegant'.. This uses a subquery which is a union..

Code:
SELECT
b.oid,b.channel_oid,b.description,b.start_time,b.end_time
FROM epg_event b,
(SELECT
MIN(a.start_time) as start_time,
a.channel_oid
FROM epg_event a
WHERE
a.start_time > datetime('now','localtime')
GROUP BY a.channel_oid
UNION
SELECT
MIN(a.start_time) as start_time,
a.channel_oid
FROM epg_event a
WHERE
a.end_time >= datetime('now','localtime')
GROUP BY a.channel_oid
) c
WHERE
c.start_time = b.start_time and c.channel_oid = b.channel_oid
ORDER by b.channel_oid, b.start_time
mvallevand
Offline

Posting Freak

Ontario Canada
Posts: 52,847
Threads: 954
Joined: May 2006
#7
2012-06-24, 01:27 PM
I'd use something like

Code:
select * from EPG_EVENT
where oid in
(select min(oid)
from EPG_EVENT
where start_time > datetime('now')
group by channel_oid)

Martin
ACTCMS
Offline

Posting Freak

UK
Posts: 2,730
Threads: 101
Joined: Jun 2007
#8
2012-06-24, 05:28 PM
odin Wrote:Brian, here's my 'now and next' query that I've just written on my sqllite db. It is working for me. Give it a try and see if this is what you want or if you can make it more 'elegant'.. This uses a subquery which is a union..
That worked for me after I made the changes underlined otherwise it didn't like the c.channel_oid in the final SELECT clause...
Code:
SELECT
b.oid,b.channel_oid,b.description,b.start_time,b.end_time
FROM epg_event b,
(SELECT
MIN(a.start_time) as start_time,
a.channel_oid [U]as channel_oid[/U]
FROM epg_event a
WHERE
a.start_time > datetime('now','localtime')
GROUP BY a.channel_oid [U]as channel_oid[/U]
UNION
SELECT
MIN(a.start_time) as start_time,
a.channel_oid
FROM epg_event a
WHERE
a.end_time >= datetime('now','localtime')
GROUP BY a.channel_oid
) c
WHERE
c.start_time = b.start_time and c.channel_oid = b.channel_oid
ORDER by b.channel_oid, b.start_time.
Alex
ACTCMS
Offline

Posting Freak

UK
Posts: 2,730
Threads: 101
Joined: Jun 2007
#9
2012-06-24, 05:38 PM
mvallevand Wrote:I'd use something like

Code:
select * from EPG_EVENT
where oid in
(select min(oid)
from EPG_EVENT
where start_time > datetime('now')
group by channel_oid)
Martin
Very elegant Martin Smile unfortunately, there seems to be no guarantee that the EPG_EVENT oid is in the same sequence as start_time (at least not on my system)

Alex
bgowland
Offline

Posting Freak

West Yorkshire, UK
Posts: 4,583
Threads: 384
Joined: Dec 2004
#10
2012-06-24, 06:00 PM
Thanks guys.

gEd, as rookie suggests 'TOP' isn't supported by SQLite (I believe it's a Transact-SQL extension). Unfortunately, rookie, your query doesn't work - something about a SQLite rule that 'ORDER BY' must appear at the end of a query.

Thanks odin and Martin - after I posted my original question, I realised MIN(...) was going to be the key to it but couldn't get it to work exactly.

I'd be slightly concerned about using MIN(oid) though Martin. I'm sure it will work for guide data supplied by XMLTV sources where the XML is ordered by date/time (mine is). In the case of harvesting the EPG data from the broadcast stream, however, there's no guarantee in what order the events will be written to the database and oid is an autoincrement. It is possible, I think, that a section of a DVB EIT could be harvested and written before another section which contains earlier events. Not sure.

Thanks odin for combining the NOW query in with NEXT - I already had a working NOW query but my next question would probably have been how to combine the two. Big Grin

I had to adjust it slightly - in particular, datetime('now', 'localtime') returns a datetime adjusted to the user's locale (as you'd expect) but all EPG_EVENT data is normalized to UTC datetimes so datetime('now') is what's needed. I also had to adjust the criteria for the datetime parts slightly to get correct results.

Anyway - for any future readers of this thread, the following works exactly...
Code:
SELECT
b.oid,b.channel_oid,b.title,b.start_time,b.end_time
FROM epg_event b,
(SELECT
MIN(a.start_time) as start_time,
a.channel_oid, a.end_time
FROM epg_event a
WHERE
a.start_time > datetime('now')  
GROUP BY a.channel_oid
UNION
SELECT
MIN(a.start_time) as start_time,
a.channel_oid, a.end_time
FROM epg_event a
WHERE
a.start_time <= datetime('now') AND a.end_time > datetime('now')
GROUP BY a.channel_oid
) c
WHERE
c.start_time = b.start_time and c.channel_oid = b.channel_oid
ORDER by b.channel_oid
« Next Oldest | Next Newest »

Users browsing this thread: 1 Guest(s)

Pages (2): 1 2 Next »


Possibly Related Threads…
Thread Author Replies Views Last Post
  Web API only_new Question Gazavant 6 2,617 2021-04-04, 06:54 PM
Last Post: sub
  Another Artwork question scJohn 15 8,079 2019-09-10, 05:33 PM
Last Post: nonob
  WEB API GuidService/Listing question(s) scJohn 6 4,233 2017-08-09, 02:18 PM
Last Post: scJohn
  skin question pBS 2 3,326 2016-06-18, 07:03 PM
Last Post: pBS
  Timing.Info question mvallevand 2 2,062 2013-04-19, 03:54 AM
Last Post: mvallevand
  N-PVR db3 EPG_EVENT time format question bgowland 3 2,073 2011-03-12, 05:26 AM
Last Post: bgowland
  Ping UncleJohnsBand (question about npvr soap) ioan 2 2,026 2011-02-18, 01:12 AM
Last Post: UncleJohnsBand
  Skin question - how to centre a list UiList control on screen? McBainUK 2 1,827 2011-02-17, 08:46 AM
Last Post: McBainUK
  Skin question for "Visible" 7ore 14 5,293 2010-09-22, 09:04 PM
Last Post: sub
  A question about fast incremental updates ACTCMS 12 4,324 2009-12-07, 03:42 AM
Last Post: sub

  • View a Printable Version
  • Subscribe to this thread
Forum Jump:

© Designed by D&D, modified by NextPVR - Powered by MyBB

Linear Mode
Threaded Mode