-
-
Notifications
You must be signed in to change notification settings - Fork 1.1k
New issue
Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.
By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.
Already on GitHub? Sign in to your account
"table not found" errors when concurrently reading from an in memory db #204
Comments
I've gotten this too. The reason is that each connection created by database/sql opens ":memory:", and thus gets a different in-memory database. Call sql.Open("sqlite3", "file::memory:?cache=shared") and this won't happen. |
Just run into this. As a possible fix, go-sqlite3 could warn if ":memory:" is used as the DB path and the cache parameter is not explicitly provided as either 'shared' or 'private'. Thoughts? |
I think a note in the Go docs that this is a common mistake, deferring to the SQLite documentation on the matter is better. When wrap something and introduce new behaviours in the wrapper, you only create further confusion. |
I think that's a fair point, except that it may not be obvious to newcomers that database/sql is using a pool of connections and how this interacts with :memory: After doing some further performance work on my current app, it actually looks like connection pooling results a pretty severe performance penalty with SQLite and that a single open connection is a better choice in any case. I've yet to write a proper benchmark for that and understand why that is though. |
Was there any resolution to what the best method of fixing this was? |
If you use |
@Brian-McM based on what @robertknight said, I used https://golang.org/pkg/database/sql/#DB.SetMaxOpenConns to set the
|
I think I ended up doing something that, but it was pretty long time ago @domthinks so hard to remember. |
did you try |
Just ran into this I do not thing that ".SetMaxOpenConns(1)" should be used since then the advantages of having more than one connection are simply gone. Also, it might be possible that a connection is dropped/expires and then SQLite just drops the database. So this can happen with one connection too. Maybe it would be wise to have the shared argument for mode=memory per default? |
This is related on the spec or behavior on sqlite3. If we will add this into doc, it will be FAQ style. However I'm not native speaker. Anyone, could you please send me pull-request to add this FAQ? |
Closes mattn#204 Closes mattn#309 Signed-off-by: Tycho Andersen <[email protected]>
Hi guys, I just hit this too, and sent a PR with a FAQ entry. Here's a minimal reproducer that I wrote to prove to myself this would work:
|
This is a little hairy. Looking at things like [1], it's evident that golang's stdlib sql package doesn't work quite correctly with sqlite3's in-memory databases. In particular, the connection pooling causes problems, since there's no way to duplicate a connection to a particular in-memory database. So, we use cache=shared to force everything to point to the same in-memory database. However, this causes some problems (mostly that untill the last connection to this database is closed, the DB is not pruned). So we have to do a little cleanup after ourselves in this case. [1]: mattn/go-sqlite3#204 Signed-off-by: Tycho Andersen <[email protected]>
This is a little hairy. Looking at things like [1], it's evident that golang's stdlib sql package doesn't work quite correctly with sqlite3's in-memory databases. In particular, the connection pooling causes problems, since there's no way to duplicate a connection to a particular in-memory database. So, we use cache=shared to force everything to point to the same in-memory database. However, this causes some problems (mostly that untill the last connection to this database is closed, the DB is not pruned). So we have to do a little cleanup after ourselves in this case. [1]: mattn/go-sqlite3#204 Signed-off-by: Tycho Andersen <[email protected]>
This is a little hairy. Looking at things like [1], it's evident that golang's stdlib sql package doesn't work quite correctly with sqlite3's in-memory databases. In particular, the connection pooling causes problems, since there's no way to duplicate a connection to a particular in-memory database. So, we use cache=shared to force everything to point to the same in-memory database. However, this causes some problems (mostly that untill the last connection to this database is closed, the DB is not pruned). So we have to do a little cleanup after ourselves in this case. [1]: mattn/go-sqlite3#204 Signed-off-by: Tycho Andersen <[email protected]>
Just for future reference, if you want to use a new in-memory db, e.g. for each new test case you can create a unique random string and place it in the filename:
Do this simply for each TestFunc and the DBs will be separated. |
Here is what worked for me.
|
One of the reasons using db.SetMaxOpenConns(1) might be bad is that trying to execute a query while having an open *sql.Rows will block because the object holds the only connection. |
@alkemir Do you mean something like this? rows, err := db.Query("SELECT FooID FROM Foo")
if err != nil {
return err
}
for rows.Next() {
var fooID int
if err := rows.Scan(&fooID); err != nil {
return err
}
if _, err := db.Exec("INSERT INTO Bar (FooID) VALUES (?001)", fooID); err != nil {
return err
}
}
return rows.Err() If so, the problem is resolved by using a transaction, or the relatively new tx, err := db.Begin()
if err != nil {
return err
}
defer tx.Rollback()
rows, err := tx.Query("SELECT FooID FROM Foo")
if err != nil {
return err
}
for rows.Next() {
var fooID int
if err := rows.Scan(&fooID); err != nil {
return err
}
if _, err := tx.Exec("INSERT INTO Bar (FooID) VALUES (?001)", fooID); err != nil {
return err
}
}
if err := rows.Err(); err != nil {
return err
}
return tx.Commit() |
Thats exactly what I mean. Thank you for posting alternatives! I think it is a pity that |
This change allows driver implementations to manage resources in driver.Connector, e.g. to share the same underlying database handle between multiple connections. That is, it allows embedded databases with in-memory backends like SQLite and Genji to safely release the resources once the sql.DB is closed. This makes it possible to address oddities with in-memory stores in SQLite and Genji drivers without introducing too much complexity in the driver implementations. See also: - mattn/go-sqlite3#204 - mattn/go-sqlite3#511 - chaisql/chai#210
This change allows driver implementations to manage resources in driver.Connector, e.g. to share the same underlying database handle between multiple connections. That is, it allows embedded databases with in-memory backends like SQLite and Genji to safely release the resources once the sql.DB is closed. This makes it possible to address oddities with in-memory stores in SQLite and Genji drivers without introducing too much complexity in the driver implementations. See also: - mattn/go-sqlite3#204 - mattn/go-sqlite3#511 - chaisql/chai#210
This change allows driver implementations to manage resources in driver.Connector, e.g. to share the same underlying database handle between multiple connections. That is, it allows embedded databases with in-memory backends like SQLite and Genji to safely release the resources once the sql.DB is closed. This makes it possible to address oddities with in-memory stores in SQLite and Genji drivers without introducing too much complexity in the driver implementations. See also: - mattn/go-sqlite3#204 - mattn/go-sqlite3#511 - chaisql/chai#210 Fixes #41790 Change-Id: Idbd19763134438ed38288b9d44f16608e4e97fd7 GitHub-Last-Rev: 962c785 GitHub-Pull-Request: #41710 Reviewed-on: https://go-review.googlesource.com/c/go/+/258360 Reviewed-by: Emmanuel Odeke <[email protected]> Reviewed-by: Daniel Theophanes <[email protected]> Trust: Emmanuel Odeke <[email protected]> Run-TryBot: Emmanuel Odeke <[email protected]> TryBot-Result: Go Bot <[email protected]>
I ran into a bug where occasionally I was getting "table not found" errors for a database we create on startup and never write to or modify. I managed to reproduce it in the following gist
https://gist.github.com/jmunson/7b1974215d34439688b0 (name it main_test.go in an empty dir and go test -v should work)
This test file will create an in memory db and create a key->value table with 3 entries, then we spawn 20 goroutines that each query for all 3 entries.
If this is ran with GOMAXPROCS set to 2 or more without setting MaxOpenConns to 1, then we get "table not found" errors.
I'm not sure if this is something that can be fixed or should just be documented around, but I thought I'd share in case anyone else runs into this.
The text was updated successfully, but these errors were encountered: