I strongly suggest you read up on database theory. An array should be implemented as a separate table (unless perhaps it contains only a small number of repeats and fields, where it may be faster). This is clearly not the case.
I assume your ?day array? is located at the end of the table definition (anywhere else is up to twice as bad). I also assume there is no index on the day fields (that would be 1000 indices, which is a lot even if they are all partial indices). Lets assume you want to check which tasks are planned for day 500. SQLite will need to do a full table scan (i.e. read every record) and uncompress all the regular fields plus 499 day array fields before it can check the value of ?day500?. With a separate table and the proposed indices, SQLite will retrieve exactly those entries of index todo_day which have day_no=500 and use the task_id to retrieve exactly the required rows from table task. With N the number of rows, D the number of days and K the average number of tasks per day, your method will incur a cost of O(N) * O(M) (examine all rows and all day columns), whereas the table method will incur a cost of O(log N) * (K+1) (locate first index entry + retrieve K rows). Which do you think will scale better? What happens when you reach the ?end of days? (i.e. less than 3 years after the first task is scheduled)? Von: Oskar Schneider [mailto:oskars93 at yahoo.com] Gesendet: Donnerstag, 05. M?rz 2015 14:00 An: Hick Gunter Cc: 'General Discussion of SQLite Database' Betreff: Re: AW: AW: [sqlite] Bitfield in Sqlite3-Table I just created for each day a seperate column is this worse than your approach? Hick Gunter <hick at scigames.at<mailto:hick at scigames.at>> schrieb am 8:01 Donnerstag, 5.M?rz 2015: Since you give no indication of the schema you are using: Create table task (id integer primary key, ?.); Create table todo ( task_id integer, day_no integer, foreign key (task_id) references task (id ) on delete cascade on update cascade ); Create unique index todo_day on todo (day_no, task_id); Create unique index todo_task on todo(task_id, day_no); -- what to do on day x Select task.* from todo join task on task.id = todo.task_id where todo.dayno = ? [ORDER BY ?]; -- when to do task x Select dayno from todo where task_id = ? [ORDER BY ?]; -- when to do which tasks that match Select todo.dayno,task.* from task join todo on task.id = todo.task_id where ? [ORDER BY]; Von: Oskar Schneider [mailto:oskars93 at yahoo.com] Gesendet: Mittwoch, 04. M?rz 2015 18:57 An: Hick Gunter Betreff: Re: AW: [sqlite] Bitfield in Sqlite3-Table With normalize you mean i should create a column for each integer-column for each bit? What is the fastest approach for queries? (omit 1. since i don't want to use external software) Hick Gunter <hick at scigames.at<mailto:hick at scigames.at>> schrieb am 17:19 Mittwoch, 4.M?rz 2015: In order of preference a) use FastBit software b) normalize your database design to eliminate the array c) use a BLOB of 125 bytes and user defined functions to operate on them d) use a string of 1000 characters ('0' or '1') and the SUBSTR() function -----Urspr?ngliche Nachricht----- Von: Oskar Schneider [mailto:oskars93 at yahoo.com<mailto:oskars93 at yahoo.com>] Gesendet: Mittwoch, 04. M?rz 2015 16:42 An: sqlite-users at mailinglists.sqlite.org<mailto:sqlite-users at mailinglists.sqlite.org> Betreff: [sqlite] Bitfield in Sqlite3-Table Hello, what is the best way to implement a Bitfield of size 1000 as a column in a Table. I need to make queries to select all rows which have the nth bit set?The bitfield describes for each day in about three years if a specific task needs to be done. _______________________________________________ sqlite-users mailing list sqlite-users at mailinglists.sqlite.org<mailto:sqlite-users at mailinglists.sqlite.org> http://mailinglists.sqlite.org/cgi-bin/mailman/listinfo/sqlite-users ___________________________________________ Gunter Hick Software Engineer Scientific Games International GmbH FN 157284 a, HG Wien Klitschgasse 2-4, A-1130 Vienna, Austria Tel: +43 1 80100 0 E-Mail: hick at scigames.at<mailto:hick at scigames.at> This communication (including any attachments) is intended for the use of the intended recipient(s) only and may contain information that is confidential, privileged or legally protected. Any unauthorized use or dissemination of this communication is strictly prohibited. If you have received this communication in error, please immediately notify the sender by return e-mail message and delete all copies of the original communication. Thank you for your cooperation. ___________________________________________ Gunter Hick Software Engineer Scientific Games International GmbH FN 157284 a, HG Wien Klitschgasse 2-4, A-1130 Vienna,Austria Tel: +43 1 80100 - 0 E-Mail: hick at scigames.at<mailto:hick at scigames.at> This communication (including any attachments) is intended for the use of the intended recipient(s) only and may contain information that is confidential, privileged or legally protected. Any unauthorized use or dissemination of this communication is strictly prohibited. If you have received this communication in error, please immediately notify the sender by return e-mail message and delete all copies of the original communication. Thank you for your cooperation. ___________________________________________ Gunter Hick Software Engineer Scientific Games International GmbH FN 157284 a, HG Wien Klitschgasse 2-4, A-1130 Vienna,Austria Tel: +43 1 80100 - 0 E-Mail: hick at scigames.at This communication (including any attachments) is intended for the use of the intended recipient(s) only and may contain information that is confidential, privileged or legally protected. Any unauthorized use or dissemination of this communication is strictly prohibited. If you have received this communication in error, please immediately notify the sender by return e-mail message and delete all copies of the original communication. Thank you for your cooperation.