Jump to content

Compare Array to SQLite DB Contents?


Recommended Posts

Hi all,

I have a large array with data and a SQLite database with similar data. I'm trying to see what the differences are between the two and output an array of the differences.

I have a small reproducer that works, but the 'loop check' takes upwards of a minute to output the differences. Is there a better way to do this?

Thanks for the help!

#include <SQLite.au3>
#include <SQLite.dll.au3>

Local $hQuery, $aRow
Local $sDBPath = @ScriptDir & "\Temp.db"
Local $aArray[10000]
_SQLite_Startup()

If FileExists($sDBPath) = 0 Then
    $iTimer = TimerInit()
    _SQLite_Open($sDBPath)
    _SQLite_Exec(-1, 'create table tblTest (a text, b text, c text);')

    ; Add random information to the db to query against
    _SQLite_Exec(-1, "begin immediate;")
    For $i = 0 To 10000
        _SQLite_Exec(-1, 'insert into tblTest (a, b, c) values ("' & Chr(Random(Asc("A"), Asc("Z"), 1)) & '", "' & Chr(Random(Asc("a"), Asc("z"), 1)) & '", "' & Random(0, 9) & '");')
    Next
    _SQLite_Exec(-1, "commit;")
    ConsoleWrite("!> DB Creation Timer: " & Round((TimerDiff($iTimer) / 1000), 2) & @CRLF)
Else
    _SQLite_Open($sDBPath)
EndIf

ConsoleWrite("Creating array..." & @CRLF)
For $i = 0 To UBound($aArray) - 1
    $aArray[$i] = Chr(Random(Asc("A"), Asc("Z"), 1))
Next

ConsoleWrite("Beginning loop check..." & @CRLF)
$iTimer = TimerInit()
_SQLite_Query(-1, 'select a from tblTest;', $hQuery)
While _SQLite_FetchData($hQuery, $aRow) = $SQLITE_OK
    Local $iItem = _ArraySearch($aArray, $aRow[0])
    If $iItem > 0 Then
        _ArrayDelete($aArray, $iItem)
    EndIf
WEnd
ConsoleWrite("!> Loop Check Timer: " & Round((TimerDiff($iTimer) / 1000), 2) & @CRLF)

_ArrayDisplay($aArray)

_SQLite_Close()
_SQLite_Shutdown()
Link to comment
Share on other sites

The best way is to put the array into a memory db and then compare the 2 db using something like this (schematic example)

_SQLite_GetTable2d(-1, "SELECT * FROM table1 WHERE items1 NOT IN (SELECT items2 FROM table2) ;", $array, $iRows, $iColumns)
Edited by mikell
Link to comment
Share on other sites

Ok, that makes sense, but I am not sure how to compare the 2 databases when the _SQLite_* commands can only point to a single database at a time.

Here's what I tried (which didn't work)

#include <SQLite.au3>
#include <SQLite.dll.au3>

Local $hQuery, $aRow
Local $sDBPath = @ScriptDir & "\Temp.db"
Local $aArray[10000]
_SQLite_Startup()

If FileExists($sDBPath) = 0 Then
    $iTimer = TimerInit()
    _SQLite_Open($sDBPath)
    _SQLite_Exec(-1, 'create table tblTest (a text, b text, c text);')

    ; Add random information to the db to query against
    _SQLite_Exec(-1, "begin immediate;")
    For $i = 0 To 10000
        _SQLite_Exec(-1, 'insert into tblTest (a, b, c) values ("' & Chr(Random(Asc("A"), Asc("Z"), 1)) & '", "' & Chr(Random(Asc("a"), Asc("z"), 1)) & '", "' & Random(0, 9) & '");')
    Next
    _SQLite_Exec(-1, "commit;")
    ConsoleWrite("!> DB Creation Timer: " & Round((TimerDiff($iTimer) / 1000), 2) & @CRLF)
Else
    _SQLite_Open($sDBPath)
EndIf

ConsoleWrite("Creating array..." & @CRLF)
For $i = 0 To UBound($aArray) - 1
    $aArray[$i] = Chr(Random(Asc("A"), Asc("Z"), 1))
Next

ConsoleWrite("Creating memory DB..." & @CRLF)
$hMemDB = _SQLite_Open()
_SQLite_Exec(-1, 'create table tblTestMem (a text);')
_SQLite_Exec(-1, "begin immediate;")
For $i = 0 To UBound($aArray) - 1
    _SQLite_Exec($hMemDB, 'insert into tblTestMem (a) values ("' & $aArray[$i] & '");')
Next
_SQLite_Exec(-1, "commit;")

ConsoleWrite("Beginning 1st loop check..." & @CRLF)
$iTimer = TimerInit()
Dim $aResults, $iRows, $iColumns
_SQLite_GetTable2d($hMemDB, 'select * from tblTestMem where a NOT IN (select a from tblTest) ;', $aResults, $iRows, $iColumns)
ConsoleWrite("!> Loop Check Timer: " & Round((TimerDiff($iTimer) / 1000), 2) & @CRLF)

_ArrayDisplay($aResults)

;~ ConsoleWrite("Beginning loop check..." & @CRLF)
;~ $iTimer = TimerInit()
;~ _SQLite_Query(-1, 'select a from tblTest;', $hQuery)
;~ While _SQLite_FetchData($hQuery, $aRow) = $SQLITE_OK
;~  Local $iItem = _ArraySearch($aArray, $aRow[0])
;~  If $iItem > 0 Then
;~      _ArrayDelete($aArray, $iItem)
;~  EndIf
;~ WEnd
;~ ConsoleWrite("!> Loop Check Timer: " & Round((TimerDiff($iTimer) / 1000), 2) & @CRLF)

;~ _ArrayDisplay($aArray)

_SQLite_Close()
_SQLite_Shutdown()
Link to comment
Share on other sites

What makes you think that the _SQLite commands can only work with one DB at a time? Use the handles returned by the _SQLite_Open functions to use to refer to them, that's what they're for.

If I posted any code, assume that code was written using the latest release version unless stated otherwise. Also, if it doesn't work on XP I can't help with that because I don't have access to XP, and I'm not going to.
Give a programmer the correct code and he can do his work for a day. Teach a programmer to debug and he can do his work for a lifetime - by Chirag Gude
How to ask questions the smart way!

I hereby grant any person the right to use any code I post, that I am the original author of, on the autoitscript.com forums, unless I've specifically stated otherwise in the code or the thread post. If you do use my code all I ask, as a courtesy, is to make note of where you got it from.

Back up and restore Windows user files _Array.au3 - Modified array functions that include support for 2D arrays.  -  ColorChooser - An add-on for SciTE that pops up a color dialog so you can select and paste a color code into a script.  -  Customizable Splashscreen GUI w/Progress Bar - Create a custom "splash screen" GUI with a progress bar and custom label.  -  _FileGetProperty - Retrieve the properties of a file  -  SciTE Toolbar - A toolbar demo for use with the SciTE editor  -  GUIRegisterMsg demo - Demo script to show how to use the Windows messages to interact with controls and your GUI.  -   Latin Square password generator

Link to comment
Share on other sites

Two equally easy ways:

A] load your array into a memory DB making use of a large transaction and possibly multi-valued inserts. Then use ATTACH to attach the disk DB to the memory DB and run a single query. Details follow.

B] load your array into a new table (still using of a large transaction and possibly multi-valued inserts) of your disk DB and run the almost-same comparison as above.

SQL skeletons:

A]

1) open a memory DB

2) create table copy (columns with types)

3) begin

4) insert into copy (optional column list) values (values for row #1), (values for row #2), ... (values for row N)

Don't try to insert 100000 rows at a time, say 5 to 100 depending on the size of your data since SQL statements are limited in size).

5) commit

6) attach 'mydiskDBFilename' as disk

Depending on which side (or both) you want differences and on which criterions, your SQL may need change

7) select * from copy except select * from disk.myDiskTable

or

7) select * from disk.myDiskTable except select * from copy

or something more complex to highlight differences both sides in the same run (that can easily be done as well)

8) detach disk

B]

1) create table copy (columns with types)

2) begin

3) insert into copy (optional column list) values (values for row #1), (values for row #2), ... (values for row N)

Don't try to insert 100000 rows at a time, say 5 to 100 depending on the size of your data since SQL statements are limited in size).

4) commit

Depending on which side (or both) you want differences and on which criterions, your SQL may need change

5) select * from copy except select * from diskDBtable

or

5) select * from diskDBtable  except select * from copy

or something more complex to highlight differences both sides in the same run (that can easily be done as well)

Edited by jchd

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 jchd. I've followed your advice, but I'm stumped on how to tell _SQLite_Exec() or _SQLite_GetTable2d() to point to two different databases. I'm just so accustomed to setting $hDB as either -1 or the database handle that I've been using. How can I do this?

Link to comment
Share on other sites

OK seems working  :)

#include <SQLite.au3>
#include <SQLite.dll.au3>

Dim $aResults, $iRows, $iColumns
Local $hQuery, $aRow
Local $sDBPath = @ScriptDir & "\Temp.db"
_SQLite_Startup()

$sDB = _SQLite_Open($sDBPath)
_SQLite_Exec(-1, 'create table if not exists tblTest (a text, b text, c text);')
_SQLite_Exec(-1, "begin;")
For $i = 0 To 10000
     _SQLite_Exec(-1, 'insert into tblTest (a, b, c) values ("' & Chr(Random(Asc("C"), Asc("Z"), 1)) & '", "' & Chr(Random(Asc("a"), Asc("z"), 1)) & '", "' & Random(0, 9) & '");')
Next
_SQLite_Exec(-1, "commit;")


;_SQLite_GetTable2d(-1, 'select * from tblTest ;', $aResults, $iRows, $iColumns)
; _ArrayDisplay($aResults, "$sDB")

;======================================
Local $aArray[10000]
For $i = 0 To UBound($aArray) - 1
    $aArray[$i] = Chr(Random(Asc("A"), Asc("Z"), 1))
Next
; _ArrayDisplay($aArray, "$aArray")

_SQLite_Exec(-1, 'create table tblTestarray (a text);')
_SQLite_Exec(-1, "begin;")
For $i = 0 To UBound($aArray) - 1
    _SQLite_Exec(-1, 'insert into tblTestarray (a) values ("' & $aArray[$i] & '");')
Next
_SQLite_Exec(-1, "commit;")

_SQLite_GetTable2d(-1, 'select * from tblTestarray ;', $aResults, $iRows, $iColumns)
_ArrayDisplay($aResults, "tblTestarray")
;=======================================

_SQLite_GetTable2d(-1, 'select * from tblTestarray where a NOT IN (select a from tblTest) ;', $aResults, $iRows, $iColumns)
_ArrayDisplay($aResults, "check")

_SQLite_Exec(-1, 'drop table tblTestarray;')

_SQLite_Close()
_SQLite_Shutdown()
Link to comment
Share on other sites

Oh, thank you mikell! I've been sitting here scratching my head thinking about how to compare two physical databases when it's so easy to simply create a temporary table in the currently working database and dump it when all the checking is done.  :sweating:

Thanks!!

Link to comment
Share on other sites

Ahem, it was my option B]

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

My remark was directed to the OP.

BTW, generally avoid ... where a NOT IN (select ... and replace by the EXCEPT construct when dealing with the full table.

Of course building an index (maybe even temporary) on tabletest.a here will greatly help.

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

Thank you for your help, jchd and mikell.

You know, I kept focusing on your option A] and trying to figure out the code with your details, that I never even looked at option B]. Sorry about that! >_< I'm just starting my journey into the land of SQL, so I appreciate all the help.

Link to comment
Share on other sites

No hurt done, it's all OK.

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...