Re: [sqlite] Index with two columns

2005-06-05 Thread Jakub Adamek

Richard, thank you very much.

Jakub

D. Richard Hipp wrote:

On Fri, 2005-06-03 at 13:20 +0200, Jakub Adamek wrote:

Hello, please, is there any way to make SQLite use an index on two 
columns when I want to select all rows which have some combination of 
the two columns?


SELECT * FROM PointFeature WHERE
DsetId=203 AND SectId IN (4,400);




SQLite does use multiple columns of a multi-column index
for == constraints.  But for an IN operator, it will only
using a single column.

This is something that I need to work on.

In the meantime, I suggest the following work-around:

   SELECT * FROM PointFeature WHERE DsetId=203 AND SectId=4
   UNION ALL
   SELECT * FROM PointFeature WHERE DsetId=203 AND SectId=400;



Re: [sqlite] Index with two columns

2005-06-03 Thread D. Richard Hipp
On Fri, 2005-06-03 at 13:20 +0200, Jakub Adamek wrote:
> Hello, please, is there any way to make SQLite use an index on two 
> columns when I want to select all rows which have some combination of 
> the two columns?
> 
> SELECT * FROM PointFeature WHERE
> DsetId=203 AND SectId IN (4,400);
> 

SQLite does use multiple columns of a multi-column index
for == constraints.  But for an IN operator, it will only
using a single column.

This is something that I need to work on.

In the meantime, I suggest the following work-around:

   SELECT * FROM PointFeature WHERE DsetId=203 AND SectId=4
   UNION ALL
   SELECT * FROM PointFeature WHERE DsetId=203 AND SectId=400;

-- 
D. Richard Hipp <[EMAIL PROTECTED]>



Re: [sqlite] Index with two columns

2005-06-03 Thread Derrell . Lipman
Jakub Adamek <[EMAIL PROTECTED]> writes:

> Hello, please, is there any way to make SQLite use an index on two 
> columns when I want to select all rows which have some combination of 
> the two columns?
>
> My table is:
> CREATE TABLE PointFeature (
> DSetId INTEGER,
> SectId INTEGER,
> PntItemId INTEGER);
>
> CREATE INDEX xxx ON PointFeature (DSetId, SectId, PntItemId);
>
> and the query is
> SELECT * FROM PointFeature WHERE
> DsetId=203 AND SectId IN (4,400);
>
> But the index is used just to find the DsetId and not to find SectId.
> Is there another form of the SQL which could do that? Or do I have to 
> use two separate queries

Try this instead:

  SELECT * FROM PointFeature WHERE
DsetId=203 AND (SectId = 4 OR SectId = 400);

Derrell


Re: [sqlite] Index with two columns

2005-06-03 Thread Brass Tilde
> Hello, please, is there any way to make SQLite use an index on two
> columns when I want to select all rows which have some combination of
> the two columns?

> SELECT * FROM PointFeature WHERE
> DsetId=203 AND SectId IN (4,400);

I can't answer the question you asked, but I will point out one thing.  Many 
SQL engines attempt to optimize index use in queries.

For instance, in MS SQL Server, your query might *not* use the second column in 
the index if using the index would take perform more
poorly than not using it.  Using an index is not always faster than doing a 
table scan.  If there are only a few rows where DsetId
is equal to 203, the table scan of that subset could very well be faster than 
using an index to look up the values.

In our MS SQL Server environment, we usually don't even bother to create 
indexes on more than one field if there are going to be
less than a few hundred rows in a subset of a query like that.  It takes the 
server longer to do the index lookup than it would the
table scan.