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

database is locked #274

Closed
stevenh opened this Issue Feb 21, 2016 · 27 comments

Comments

Projects
None yet
@stevenh

stevenh commented Feb 21, 2016

We have a little app which has multiple goroutines all running queries and it often fails with "database is locked" :(

we're running with:

db, err := sql.Open("sqlite3", "test.db?cache=shared&mode=rwc")
PRAGMA journal_mode = WAL;
PRAGMA synchronous = NORMAL;

sqlite3 -version
3.10.2 2016-01-20 15:27:19 17efb4209f97fb4971656086b138599a91a75ff9

Is this a known issue?

@mattn

This comment has been minimized.

Show comment
Hide comment
@mattn

mattn Feb 22, 2016

Owner

did you try _busy_timeout ?

Owner

mattn commented Feb 22, 2016

did you try _busy_timeout ?

@stevenh

This comment has been minimized.

Show comment
Hide comment
@stevenh

stevenh Feb 22, 2016

I wasn't aware of this, so no I hadn't.

I would however has expected busy_timeout to only effect table locks but the error says "database is locked" is the error misleading?

stevenh commented Feb 22, 2016

I wasn't aware of this, so no I hadn't.

I would however has expected busy_timeout to only effect table locks but the error says "database is locked" is the error misleading?

@mrnugget

This comment has been minimized.

Show comment
Hide comment
@mrnugget

mrnugget Mar 3, 2016

Just chiming in here, because I keep running into the same problem. I created a gist that can pretty reliably demonstrate the "database is locked" error. In this program I open 1 goroutine that writes 5000 times to one table (users) and another goroutine that spawns 5000 goroutines that read from another table.

db, err := sql.Open("sqlite3", "database_file.sqlite?cache=shared&mode=rwc") doesn't fix the problem, and adding _busy_timeout makes the program really, really slow.

What helped was using db.SetMaxOpenConns(1). Which is the same as wrapping a mutex around every DB access.

I really want to understand what's going on here and what's possible with sqlite3 in Go and what's not. My guess is that the database is locked error isn't a problem in sqlite (which explicitly allows writing to and reading from different tables at the same time), but rather a combination of sqlite's thread-safety, Go's database/sql connection pooling and go-sqlite3 connection management.

mrnugget commented Mar 3, 2016

Just chiming in here, because I keep running into the same problem. I created a gist that can pretty reliably demonstrate the "database is locked" error. In this program I open 1 goroutine that writes 5000 times to one table (users) and another goroutine that spawns 5000 goroutines that read from another table.

db, err := sql.Open("sqlite3", "database_file.sqlite?cache=shared&mode=rwc") doesn't fix the problem, and adding _busy_timeout makes the program really, really slow.

What helped was using db.SetMaxOpenConns(1). Which is the same as wrapping a mutex around every DB access.

I really want to understand what's going on here and what's possible with sqlite3 in Go and what's not. My guess is that the database is locked error isn't a problem in sqlite (which explicitly allows writing to and reading from different tables at the same time), but rather a combination of sqlite's thread-safety, Go's database/sql connection pooling and go-sqlite3 connection management.

@mattn

This comment has been minimized.

Show comment
Hide comment
@mattn
Owner

mattn commented Mar 3, 2016

@mrnugget

This comment has been minimized.

Show comment
Hide comment
@mrnugget

mrnugget Mar 3, 2016

That still results in "database is locked" errors and I think it's even more than before.

mrnugget commented Mar 3, 2016

That still results in "database is locked" errors and I think it's even more than before.

@stevenh

This comment has been minimized.

Show comment
Hide comment
@stevenh

stevenh Mar 3, 2016

Yer, I think the issue is with multiple threads and this message is equivalent to MySQL's deadlock detected, at least in our case, just MySQL's message is much clearer as it doesn't have multiple meanings which seems to be the case with sqlite.

As none of the suggestions resolved the issue we've had to move away from sqlite unfortunately.

I'll leave this bug open for others to contribute to, as its clearly wider spread.

stevenh commented Mar 3, 2016

Yer, I think the issue is with multiple threads and this message is equivalent to MySQL's deadlock detected, at least in our case, just MySQL's message is much clearer as it doesn't have multiple meanings which seems to be the case with sqlite.

As none of the suggestions resolved the issue we've had to move away from sqlite unfortunately.

I'll leave this bug open for others to contribute to, as its clearly wider spread.

@mrnugget

This comment has been minimized.

Show comment
Hide comment
@mrnugget

mrnugget Mar 4, 2016

After some more reading and investigating, I think there is no proper solution where we can use multiple sql.DB connections in combination with sqlite3. Why?

  • The thread-safety guarantees sqlite makes only cover the case where you have one sqlite3 *db in your program and access it from different threads. sqlite can then coordinate access to the database in its own functions.
  • If we don't limit the amount of sql.DB connections (which is the database/sql default), we create multiple sqlite3 *db instances in our program. These act independently from each other. Now each connection has to do its own synchronization and they have to synchronise with the the other connections. We're now essentially in "multiple processes accessing the same file"-land. The sqlite FAQ describes this:

SQLite allows multiple processes to have the database file open at once, and for multiple processes to read the database at once. When any process wants to write, it must lock the entire database file for the duration of its update. But that normally only takes a few milliseconds. Other processes just wait on the writer to finish then continue about their business.

(Highlight by me)

The difference between sqlite and client/server databases (PostgreSQL, MySQL, ...) is that sqlite3 synchronizes access to the database file on the client-side, which is only possible if multiple threads/goroutines use the same client. If multiple clients (processes, goroutines with their own connection) use the same database file, the synchronization has to happen through the database file, in which case it's locked completely for every write action.

So I'd say that the only solution is to use db.SetMaxOpenConns(1) (or use the busy timeout).

If anything of what I just said is wrong, please feel free to point it out.

EDIT:

Basically everything I said above is wrong.

Apparently what I said about "thread-safety guarantees" only in "shared db instance across threads" is wrong. I found some sample code that shows usage of multiple db instances across multiple threads. Apparently that is the recommended way to go.

This sqlite wiki entry also shows how sqlite behaves when used in multiple threads with multiple database instances: a lot of SQLITE_BUSY/"database is locked" errors. The conclusion on the wiki page is as follows:

Make sure you're compiling SQLite with -DTHREADSAFE=1.
Make sure that each thread opens the database file and keeps its own sqlite structure.
Make sure you handle the likely possibility that one or more threads collide when they access the db file at the same time: handle SQLITE_BUSY appropriately.

Using one connection across multiple goroutines by using db.SetMaxOpenConns(1) and letting database/sql synchronize access to the shared connection with its mutexes might cause problems, since connections in database/sql are stateful, which means that a db.Begin() in one goroutine effects other goroutines.

To update the conclusion at the top of the original version of this comment:

I think there is no proper solution where we can use multiple sql.DB connections in combination with sqlite3 in Go without handling "database is locked" by retrying or by incrementing the busy_timeout. It seems like this is expected behaviour when using sqlite in a multi-threaded context.

mrnugget commented Mar 4, 2016

After some more reading and investigating, I think there is no proper solution where we can use multiple sql.DB connections in combination with sqlite3. Why?

  • The thread-safety guarantees sqlite makes only cover the case where you have one sqlite3 *db in your program and access it from different threads. sqlite can then coordinate access to the database in its own functions.
  • If we don't limit the amount of sql.DB connections (which is the database/sql default), we create multiple sqlite3 *db instances in our program. These act independently from each other. Now each connection has to do its own synchronization and they have to synchronise with the the other connections. We're now essentially in "multiple processes accessing the same file"-land. The sqlite FAQ describes this:

SQLite allows multiple processes to have the database file open at once, and for multiple processes to read the database at once. When any process wants to write, it must lock the entire database file for the duration of its update. But that normally only takes a few milliseconds. Other processes just wait on the writer to finish then continue about their business.

(Highlight by me)

The difference between sqlite and client/server databases (PostgreSQL, MySQL, ...) is that sqlite3 synchronizes access to the database file on the client-side, which is only possible if multiple threads/goroutines use the same client. If multiple clients (processes, goroutines with their own connection) use the same database file, the synchronization has to happen through the database file, in which case it's locked completely for every write action.

So I'd say that the only solution is to use db.SetMaxOpenConns(1) (or use the busy timeout).

If anything of what I just said is wrong, please feel free to point it out.

EDIT:

Basically everything I said above is wrong.

Apparently what I said about "thread-safety guarantees" only in "shared db instance across threads" is wrong. I found some sample code that shows usage of multiple db instances across multiple threads. Apparently that is the recommended way to go.

This sqlite wiki entry also shows how sqlite behaves when used in multiple threads with multiple database instances: a lot of SQLITE_BUSY/"database is locked" errors. The conclusion on the wiki page is as follows:

Make sure you're compiling SQLite with -DTHREADSAFE=1.
Make sure that each thread opens the database file and keeps its own sqlite structure.
Make sure you handle the likely possibility that one or more threads collide when they access the db file at the same time: handle SQLITE_BUSY appropriately.

Using one connection across multiple goroutines by using db.SetMaxOpenConns(1) and letting database/sql synchronize access to the shared connection with its mutexes might cause problems, since connections in database/sql are stateful, which means that a db.Begin() in one goroutine effects other goroutines.

To update the conclusion at the top of the original version of this comment:

I think there is no proper solution where we can use multiple sql.DB connections in combination with sqlite3 in Go without handling "database is locked" by retrying or by incrementing the busy_timeout. It seems like this is expected behaviour when using sqlite in a multi-threaded context.

mrnugget added a commit to applikatoni/applikatoni that referenced this issue Mar 5, 2016

Use a database busy timeout of 30sec
The reason for this commit is this issue:

    #35

We ran into "database is locked" errors because of webhooks trying to
read from the database on every log entry they received -- all the while
are log entries being saved to the database.

This change increases the busy timeout of the 5sec default value to
30sec. We'll see how that plays out. First tests confirm that it might
slow the deployment process down but the errors disappear since the
queries are retried.

For more information, start reading here:

* #35
* mattn/go-sqlite3#274
* https://gist.github.com/mrnugget/0eda3b2b53a70fa4a894
@sqweek

This comment has been minimized.

Show comment
Hide comment
@sqweek

sqweek Apr 19, 2016

Contributor

Yer, I think the issue is with multiple threads and this message is equivalent to MySQL's deadlock detected, at least in our case, just MySQL's message is much clearer as it doesn't have multiple meanings which seems to be the case with sqlite.

sqlite's "database is locked" error doesn't have multiple meanings. It means "I tried to obtain a lock on the database but failed because a separate process/connection held a conflicting lock". It's certainly not a deadlock, and is 100% expected in code creating multiple connections to the same DB.

My guess is that the database is locked error isn't a problem in sqlite (which explicitly allows writing to and reading from different tables at the same time),

To be more specific, sqlite's locking protocol allows for many readers and exactly one writer at any given time. ie. if you attempt to start two write transactions concurrently, the second will encounter SQLITE_BUSY.

In rollback-journal mode, a read transaction will also encounter SQLITE_BUSY if it starts just as a write transaction enters its COMMIT phase - as hinted at in previous comments sqlite locks the entire database for the duration of COMMIT. This doesn't happen in WAL mode, because COMMIT doesn't need to update the main database file (just the write ahead journal).

Anyway I think you came to the same conclusion, that SQLITE_BUSY is unavoidable when using multiple connections to the same database. Shared cache mode helps by introducing finer locks (table-level instead of database-level), but still if you have two transactions trying to update the same table at once the second will get SQLITE_BUSY.

Setting the busy timeout is one way to cope with the situation - if your timeout is longer than the longest write transaction performed by your application that will mitigate many of the errors.

But even then, you can still easily get SQLITE_BUSY via a transaction along the lines of:

BEGIN;
SELECT MAX(x) FROM table1;
INSERT INTO table1 VALUES(x+1);
COMMIT;

If there is already a write transaction in progress on table1 when this INSERT statement runs, sqlite will immediately return SQLITE_BUSY, without waiting for the busy timeout.

In rollback-journal mode, this is because sqlite knows it has a read-lock (from the earlier SELECT), so waiting is just going to hold up the existing write transaction.

In WAL mode, this is because the earlier SELECT has the effect of pinning this transaction's view of the database to that point in time. sqlite knows the existing write transaction is going to update database potentially invalidating the SELECT results, and doesn't let you write to the database from this view of the past.

For this conflicting writer case, the proper course of action is for the application to ROLLBACK the transaction, and potentially try again once the other write transaction has completed.

I don't think there is any issue with go-sqlite3 here.

Contributor

sqweek commented Apr 19, 2016

Yer, I think the issue is with multiple threads and this message is equivalent to MySQL's deadlock detected, at least in our case, just MySQL's message is much clearer as it doesn't have multiple meanings which seems to be the case with sqlite.

sqlite's "database is locked" error doesn't have multiple meanings. It means "I tried to obtain a lock on the database but failed because a separate process/connection held a conflicting lock". It's certainly not a deadlock, and is 100% expected in code creating multiple connections to the same DB.

My guess is that the database is locked error isn't a problem in sqlite (which explicitly allows writing to and reading from different tables at the same time),

To be more specific, sqlite's locking protocol allows for many readers and exactly one writer at any given time. ie. if you attempt to start two write transactions concurrently, the second will encounter SQLITE_BUSY.

In rollback-journal mode, a read transaction will also encounter SQLITE_BUSY if it starts just as a write transaction enters its COMMIT phase - as hinted at in previous comments sqlite locks the entire database for the duration of COMMIT. This doesn't happen in WAL mode, because COMMIT doesn't need to update the main database file (just the write ahead journal).

Anyway I think you came to the same conclusion, that SQLITE_BUSY is unavoidable when using multiple connections to the same database. Shared cache mode helps by introducing finer locks (table-level instead of database-level), but still if you have two transactions trying to update the same table at once the second will get SQLITE_BUSY.

Setting the busy timeout is one way to cope with the situation - if your timeout is longer than the longest write transaction performed by your application that will mitigate many of the errors.

But even then, you can still easily get SQLITE_BUSY via a transaction along the lines of:

BEGIN;
SELECT MAX(x) FROM table1;
INSERT INTO table1 VALUES(x+1);
COMMIT;

If there is already a write transaction in progress on table1 when this INSERT statement runs, sqlite will immediately return SQLITE_BUSY, without waiting for the busy timeout.

In rollback-journal mode, this is because sqlite knows it has a read-lock (from the earlier SELECT), so waiting is just going to hold up the existing write transaction.

In WAL mode, this is because the earlier SELECT has the effect of pinning this transaction's view of the database to that point in time. sqlite knows the existing write transaction is going to update database potentially invalidating the SELECT results, and doesn't let you write to the database from this view of the past.

For this conflicting writer case, the proper course of action is for the application to ROLLBACK the transaction, and potentially try again once the other write transaction has completed.

I don't think there is any issue with go-sqlite3 here.

@Klowner

This comment has been minimized.

Show comment
Hide comment
@Klowner

Klowner Jul 5, 2016

fwiw, I stumbled across this ticket and subsequently found http://stackoverflow.com/questions/32479071/sqlite3-error-database-is-locked-in-golang

After the addition rows.Close() calls to my code I don't seem to be experiencing the database is locked issue.

Klowner commented Jul 5, 2016

fwiw, I stumbled across this ticket and subsequently found http://stackoverflow.com/questions/32479071/sqlite3-error-database-is-locked-in-golang

After the addition rows.Close() calls to my code I don't seem to be experiencing the database is locked issue.

@jrots

This comment has been minimized.

Show comment
Hide comment
@jrots

jrots Jul 15, 2016

Still experiencing this issue atm..
So what is the best solution/ practices here to avoid these "locked issues" ?

  • creating a writer connection with : db.SetMaxOpenConns(1) +
  • a separate reader connection for selects without SetMaxOpenConns() ?
  • avoid using tx.Begin() and Commit() as it will block other connections?

jrots commented Jul 15, 2016

Still experiencing this issue atm..
So what is the best solution/ practices here to avoid these "locked issues" ?

  • creating a writer connection with : db.SetMaxOpenConns(1) +
  • a separate reader connection for selects without SetMaxOpenConns() ?
  • avoid using tx.Begin() and Commit() as it will block other connections?
@sqweek

This comment has been minimized.

Show comment
Hide comment
@sqweek

sqweek Jul 15, 2016

Contributor

@jrots sqlite allows multiple readers but only a single writer at any one time. If you have multiple connections to the same DB, you will inevitably run into database is locked. This is an unavoidable consequence of sqlite's locking model, and therefore something your application needs to deal with. Possible solutions include:

  1. Only ever open a single connection to the DB (but note this can still result in multiple connections to the DB if a user runs multiple instances of your application at once)
  2. Set the busy timeout to something reasonably high (which causes sqlite to retry lock acquisition for a certain amount of time before returning database is locked). In go-sqlite3 this is achieved by appending eg. ?_busy_timeout=5000 to the filename passed to sql.Open, where 5000 is the number of milliseconds to retry.

Also note that tx.Begin() and tx.Commit() are currently affected by issue #184 which can result in a connection getting stuck in an inconsistent state if SQLITE_BUSY is encountered while commit is in progress. But setting an appropriate busy timeout should avoid this situation also (unless you have excessively long lived transactions in which case you might want to rethink your design and/or ensure that you're closing all your transaction/result objects in a timely manner).

Contributor

sqweek commented Jul 15, 2016

@jrots sqlite allows multiple readers but only a single writer at any one time. If you have multiple connections to the same DB, you will inevitably run into database is locked. This is an unavoidable consequence of sqlite's locking model, and therefore something your application needs to deal with. Possible solutions include:

  1. Only ever open a single connection to the DB (but note this can still result in multiple connections to the DB if a user runs multiple instances of your application at once)
  2. Set the busy timeout to something reasonably high (which causes sqlite to retry lock acquisition for a certain amount of time before returning database is locked). In go-sqlite3 this is achieved by appending eg. ?_busy_timeout=5000 to the filename passed to sql.Open, where 5000 is the number of milliseconds to retry.

Also note that tx.Begin() and tx.Commit() are currently affected by issue #184 which can result in a connection getting stuck in an inconsistent state if SQLITE_BUSY is encountered while commit is in progress. But setting an appropriate busy timeout should avoid this situation also (unless you have excessively long lived transactions in which case you might want to rethink your design and/or ensure that you're closing all your transaction/result objects in a timely manner).

@jrots

This comment has been minimized.

Show comment
Hide comment
@jrots

jrots Jul 15, 2016

@sqweek Thx for the thorough explanation! Are you also using db.SetMaxOpenConns(1) when initialising the connection or just avoid having that setting?

update: ok reread your answer & you probably don't use that, just one initialisation and let it underlying create multiple connections without that setting

jrots commented Jul 15, 2016

@sqweek Thx for the thorough explanation! Are you also using db.SetMaxOpenConns(1) when initialising the connection or just avoid having that setting?

update: ok reread your answer & you probably don't use that, just one initialisation and let it underlying create multiple connections without that setting

@roxma

This comment has been minimized.

Show comment
Hide comment
@roxma

roxma Apr 4, 2017

@mrnugget

since connections in database/sql are stateful, which means that a db.Begin() in one goroutine effects other goroutines.

I'm confused. I can't find the offical database/sql documentation on this, so here's what I found and looks sensible to me:

http://go-database-sql.org/modifying.html

In Go, a transaction is essentially an object that reserves a connection to the datastore

Which implies that the goroutine which calls the db.Begin() will own the connection, until the transaction ends with db.Commit() or db.Callback()

If it is true, how does this behavior affectes other groutines?

roxma commented Apr 4, 2017

@mrnugget

since connections in database/sql are stateful, which means that a db.Begin() in one goroutine effects other goroutines.

I'm confused. I can't find the offical database/sql documentation on this, so here's what I found and looks sensible to me:

http://go-database-sql.org/modifying.html

In Go, a transaction is essentially an object that reserves a connection to the datastore

Which implies that the goroutine which calls the db.Begin() will own the connection, until the transaction ends with db.Commit() or db.Callback()

If it is true, how does this behavior affectes other groutines?

@grj1046

This comment has been minimized.

Show comment
Hide comment
@grj1046

grj1046 May 17, 2017

at windows 10, it can run very well, but in centos7.3 database is locked error random occur. _busy_timeout is invalid. but db.SetMaxOpenConns(1) looks run well.

grj1046 commented May 17, 2017

at windows 10, it can run very well, but in centos7.3 database is locked error random occur. _busy_timeout is invalid. but db.SetMaxOpenConns(1) looks run well.

@sqlitefan

This comment has been minimized.

Show comment
Hide comment
@sqlitefan

sqlitefan Jul 5, 2017

@mattn You should change this line in sqlite3.go:

#cgo CFLAGS: -DSQLITE_ENABLE_RTREE -DSQLITE_THREADSAFE

as the following:

#cgo CFLAGS: -DSQLITE_ENABLE_RTREE -DSQLITE_THREADSAFE=1

It fixes the problem. SQLITE_THREADSAFE must be 1 because a single DB connection can be used from multiple threads when using it from multiple goroutines. See https://www.sqlite.org/threadsafe.html and https://sqlite.org/compile.html#threadsafe

https://golang.org/src/database/sql/doc.txt says:

Given an *sql.DB, it should be possible to share that instance between multiple goroutines, without any extra synchronization.

sqlitefan commented Jul 5, 2017

@mattn You should change this line in sqlite3.go:

#cgo CFLAGS: -DSQLITE_ENABLE_RTREE -DSQLITE_THREADSAFE

as the following:

#cgo CFLAGS: -DSQLITE_ENABLE_RTREE -DSQLITE_THREADSAFE=1

It fixes the problem. SQLITE_THREADSAFE must be 1 because a single DB connection can be used from multiple threads when using it from multiple goroutines. See https://www.sqlite.org/threadsafe.html and https://sqlite.org/compile.html#threadsafe

https://golang.org/src/database/sql/doc.txt says:

Given an *sql.DB, it should be possible to share that instance between multiple goroutines, without any extra synchronization.

@mattn mattn closed this in acfa601 Jul 5, 2017

@mattn

This comment has been minimized.

Show comment
Hide comment
@mattn

mattn Jul 5, 2017

Owner

@sqlitefan Thank you!

If you still have issue, please reopen this. 👍

Owner

mattn commented Jul 5, 2017

@sqlitefan Thank you!

If you still have issue, please reopen this. 👍

@xxxtonixxx

This comment has been minimized.

Show comment
Hide comment
@xxxtonixxx

xxxtonixxx commented Jul 6, 2017

It seems the problem isn't fixed yet... 😢

@mattn

This comment has been minimized.

Show comment
Hide comment
@mattn

mattn Jul 7, 2017

Owner

Well, I don't make sure what is your issue but you can't avoid busy timeout. SQLite is not provide infinite blocking.

Owner

mattn commented Jul 7, 2017

Well, I don't make sure what is your issue but you can't avoid busy timeout. SQLite is not provide infinite blocking.

@missinglink

This comment has been minimized.

Show comment
Hide comment
@missinglink

missinglink Jul 14, 2017

FYI: this option can be also checked at runtime:

sqlite> SELECT sqlite_compileoption_get(8);
THREADSAFE=1

[edit] see @papakai comment below

missinglink commented Jul 14, 2017

FYI: this option can be also checked at runtime:

sqlite> SELECT sqlite_compileoption_get(8);
THREADSAFE=1

[edit] see @papakai comment below

@mattn

This comment has been minimized.

Show comment
Hide comment
@mattn

mattn Jul 14, 2017

Owner

go-sqlite3 can't implement queue for waiting busy because it is contrary of the design of SQLite3. If it's possible to do, sqlite3 already would implemented this feature.

Owner

mattn commented Jul 14, 2017

go-sqlite3 can't implement queue for waiting busy because it is contrary of the design of SQLite3. If it's possible to do, sqlite3 already would implemented this feature.

@papakai

This comment has been minimized.

Show comment
Hide comment
@papakai

papakai Aug 25, 2017

@missinglink
Better way is

PRAGMA compile_options;

papakai commented Aug 25, 2017

@missinglink
Better way is

PRAGMA compile_options;
@rishiloyola

This comment has been minimized.

Show comment
Hide comment
@rishiloyola

rishiloyola Sep 15, 2017

So, what is the final solution? How can I handle this error? or How can I avoid this error?

rishiloyola commented Sep 15, 2017

So, what is the final solution? How can I handle this error? or How can I avoid this error?

@mattn

This comment has been minimized.

Show comment
Hide comment
@mattn

mattn Sep 16, 2017

Owner

You can check this error with err.(sqlite3.Error).Code == sqlite3.ErrLocked.

Owner

mattn commented Sep 16, 2017

You can check this error with err.(sqlite3.Error).Code == sqlite3.ErrLocked.

@sqweek

This comment has been minimized.

Show comment
Hide comment
@sqweek

sqweek Sep 16, 2017

Contributor

You can avoid it by only ever having a single active connection to the DB file. SQLite can only handle one writer at a time, so as soon as you have multiple connections (either in a single process or multiple instances of your program or whatever) and one of them is updating the DB there's a period of time in which it is inaccessible to other connections (they will return SQLITE_BUSY ie. "database is locked").

If you're seeing "database is locked" with a single connection, you probably have a statement hanging around which you've forgotten to close. Otherwise "database is locked" is expected behaviour and you'll have to handle it appropriately (usually by retrying the transaction, or using a busy_timeout so that SQLite automatically retries for a period of time).

Contributor

sqweek commented Sep 16, 2017

You can avoid it by only ever having a single active connection to the DB file. SQLite can only handle one writer at a time, so as soon as you have multiple connections (either in a single process or multiple instances of your program or whatever) and one of them is updating the DB there's a period of time in which it is inaccessible to other connections (they will return SQLITE_BUSY ie. "database is locked").

If you're seeing "database is locked" with a single connection, you probably have a statement hanging around which you've forgotten to close. Otherwise "database is locked" is expected behaviour and you'll have to handle it appropriately (usually by retrying the transaction, or using a busy_timeout so that SQLite automatically retries for a period of time).

@rishiloyola

This comment has been minimized.

Show comment
Hide comment
@rishiloyola

rishiloyola Sep 16, 2017

@sqweek I am closing all my statements. But db.Exec function throwing an error.
code - https://github.com/vkuznet/transfer2go/blob/master/core/catalog.go#L345-L349

rishiloyola commented Sep 16, 2017

@sqweek I am closing all my statements. But db.Exec function throwing an error.
code - https://github.com/vkuznet/transfer2go/blob/master/core/catalog.go#L345-L349

@sqweek

This comment has been minimized.

Show comment
Hide comment
@sqweek

sqweek Dec 24, 2017

Contributor

You should check and handle errors instead of ignoring them, for one. Also you should probably open a new issue with more details describing the deadlock, as deadlock is a completely different scenario to "database is locked".

Contributor

sqweek commented Dec 24, 2017

You should check and handle errors instead of ignoring them, for one. Also you should probably open a new issue with more details describing the deadlock, as deadlock is a completely different scenario to "database is locked".

@Xeoncross

This comment has been minimized.

Show comment
Hide comment
@Xeoncross

Xeoncross Jan 25, 2018

I would assume a simple solution would be either A) using mutexes on the actual query code, or B) using a channel that receives a struct with 1) query 2) params & 3) a response channel. Then any go routine anywhere in the app can run queries while having a single "moderator" insuring the queries are only ever run one-at-a-time.

Mutexes would probably be the simple way to solve this as they would force a one-at-a-time access pattern without any changes to the app query structure.

@mrnugget has a great example of this: https://gist.github.com/mrnugget/0eda3b2b53a70fa4a894

Xeoncross commented Jan 25, 2018

I would assume a simple solution would be either A) using mutexes on the actual query code, or B) using a channel that receives a struct with 1) query 2) params & 3) a response channel. Then any go routine anywhere in the app can run queries while having a single "moderator" insuring the queries are only ever run one-at-a-time.

Mutexes would probably be the simple way to solve this as they would force a one-at-a-time access pattern without any changes to the app query structure.

@mrnugget has a great example of this: https://gist.github.com/mrnugget/0eda3b2b53a70fa4a894

jmattheis added a commit to gotify/server that referenced this issue Feb 11, 2018

Limit sqlite to one connection
we use the database connection inside the handlers from the http
framework, therefore concurrent access occurs. Sqlite cannot handle
concurrent writes, so we limit sqlite to one connection.
see mattn/go-sqlite3#274

jmattheis added a commit to gotify/server that referenced this issue Feb 12, 2018

Limit sqlite to one connection
we use the database connection inside the handlers from the http
framework, therefore concurrent access occurs. Sqlite cannot handle
concurrent writes, so we limit sqlite to one connection.
see mattn/go-sqlite3#274

jmattheis added a commit to gotify/server that referenced this issue Feb 12, 2018

Limit sqlite to one connection
we use the database connection inside the handlers from the http
framework, therefore concurrent access occurs. Sqlite cannot handle
concurrent writes, so we limit sqlite to one connection.
see mattn/go-sqlite3#274

6f7262 added a commit to 6f7262/kipp that referenced this issue May 2, 2018

pawiecz added a commit to SamsungSLAV/weles that referenced this issue Oct 5, 2018

Fix database is locked error
Bug:
1. Create quickly around 10-30 job requests (same .yml can be used)
2. List Weles jobs after few seconds.
3. Some of the jobs should have following:
 "info": "Internal Weles error while creating file path in ArtifactDB : database is locked",

When Weles received requests in quick succession it tried to write to
database in more than 1 goroutine. This resulted in "database is locked"
error. This should be resolved by handling this error or customizing
sqlite3 settings.

The issue is described in the following thread:
mattn/go-sqlite3#274

This commit:
- adds logging of artifact insert failure
- sets _BUSY_TIMEOUT of sqlite3 to 5s
- limits max No of open db connections to 1
- fixes tests which failed inconsistently in CI

Verification:
Build Weles with this commit, go through steps below "Bug:". Jobs should
not fail due to "database is locked"

Change-Id: I45dd00e832df0cb234d49b219ad736c37a4be629
Signed-off-by: Alexander Mazuruk <a.mazuruk@samsung.com>
Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment