Jump to content

SQLite - 3 different but connected selection in one query


Recommended Posts

basically i want to get 2d array with rows consist of : [unique title, count of items where IsRead = 'false' under this title, total items under this title]

but as it seems fail to deliver selected in first SELECT statement unique title to consequent SELECTions

Query:

$sQuery = "SELECT DISTINCT Title AS fft FROM SRDB UNION ALL SELECT count(Item) FROM SRDB WHERE Title = fft AND IsRead = 'false' UNION ALL SELECT count(Item) FROM SRDB WHERE Title = fft GROUP BY Title;"

and after "_SQLite_GetTable2d()" receive Error:    no such column: fft

my table is:

$sSqlFill_Table = "(Title, Item, IsRead)"

Title_01, 'aaa', 'true'
Title_01, 'bbb', 'false'
Title_01, 'ccc', 'true'
Title_02, 'ddd', 'false'
Title_02, 'eee', 'true'
Title_02, 'fff', 'false'
Title_03, 'ggg', 'false'
Title_03, 'hhh', 'true'
Title_03, 'iii', 'true'

another case - is to get those 2 counts() for any predetermined title

so - how i can correctly make connected selections in one query?

Link to comment
Share on other sites

@Iczer

You need a different type of query:

select
      Title,
      (select count(*) from SRDB S WHERE S.Title = T.Title AND IsRead = 'f') as "Not read",
      count(*) "Total"
FROM SRDB T
GROUP BY Title
order by Title

 

This wonderful site allows debugging and testing regular expressions (many flavors available). An absolute must have in your bookmarks.
Another excellent RegExp tutorial. Don't forget downloading your copy of up-to-date pcretest.exe and pcregrep.exe here
RegExp tutorial: enough to get started
PCRE v8.33 regexp documentation latest available release and currently implemented in AutoIt beta.

SQLitespeed is another feature-rich premier SQLite manager (includes import/export). Well worth a try.
SQLite Expert (freeware Personal Edition or payware Pro version) is a very useful SQLite database manager.
An excellent eBook covering almost every aspect of SQLite3: a must-read for anyone doing serious work.
SQL tutorial (covers "generic" SQL, but most of it applies to SQLite as well)
A work-in-progress SQLite3 tutorial. Don't miss other LxyzTHW pages!
SQLite official website with full documentation (may be newer than the SQLite library that comes standard with AutoIt)

Link to comment
Share on other sites

Thanks! Its working!

The only concern is - on real table it take  about  9,5 seconds for this query to get results. I have individual indexes on Title, Item and IsRead columns. Is there a way to speed up this query?

Link to comment
Share on other sites

Using SQLite Expert I ran this:

explain query plan
select
      Title,
      (select count(*) from SRDB S WHERE S.Title = T.Title AND IsRead = 'f') as "Not read",
      count(*) "Total"
FROM SRDB T
GROUP BY Title
order by Title

on the test table created like this:

CREATE TABLE "srdb" (
  "Title" CHAR, 
  "Item" CHAR, 
  "Isread" CHAR);

CREATE INDEX "ixtitle" ON "srdb" ("Title");

CREATE INDEX "ixread" ON "srdb" ("Isread");

SQLite returns the following explanation for the above query:

selectid    order   from    detail
0   0   0   SCAN TABLE SRDB AS T USING COVERING INDEX ixtitle
0   0   0   EXECUTE CORRELATED SCALAR SUBQUERY 1
1   0   0   SEARCH TABLE SRDB AS S USING INDEX ixread (Isread=?)

This shows that the engine correctly uses the available simple indices. Of course the correlated subquery is inevitably slowing things down, but not knowing your data makes providing good hints difficult. If the IsRead column only contains boolean values, you can save some cycles by making it INT and storing 0/1 there (as integers). Also, the ORDER BY clause I used forces a final sort on he resultset, which again eats some time.

Now if you create a compound index like this:

CREATE INDEX "ixMixed" ON "srdb" ("Title", "Isread");

you discover that the engine now makes a better use of the mixed index:

selectid    order   from    detail
0   0   0   SCAN TABLE SRDB AS T USING COVERING INDEX ixtitle
0   0   0   EXECUTE CORRELATED SCALAR SUBQUERY 1
1   0   0   SEARCH TABLE SRDB AS S USING COVERING INDEX ixMixed (Title=? AND Isread=?)

How many rows does your table contain? Do you have a large number of rows having the same title on average?

This wonderful site allows debugging and testing regular expressions (many flavors available). An absolute must have in your bookmarks.
Another excellent RegExp tutorial. Don't forget downloading your copy of up-to-date pcretest.exe and pcregrep.exe here
RegExp tutorial: enough to get started
PCRE v8.33 regexp documentation latest available release and currently implemented in AutoIt beta.

SQLitespeed is another feature-rich premier SQLite manager (includes import/export). Well worth a try.
SQLite Expert (freeware Personal Edition or payware Pro version) is a very useful SQLite database manager.
An excellent eBook covering almost every aspect of SQLite3: a must-read for anyone doing serious work.
SQL tutorial (covers "generic" SQL, but most of it applies to SQLite as well)
A work-in-progress SQLite3 tutorial. Don't miss other LxyzTHW pages!
SQLite official website with full documentation (may be newer than the SQLite library that comes standard with AutoIt)

Link to comment
Share on other sites

Create an account or sign in to comment

You need to be a member in order to leave a comment

Create an account

Sign up for a new account in our community. It's easy!

Register a new account

Sign in

Already have an account? Sign in here.

Sign In Now
 Share

  • Recently Browsing   0 members

    • No registered users viewing this page.
×
×
  • Create New...