Skip to content

Commit

Permalink
initial CockroachDB support (partial)
Browse files Browse the repository at this point in the history
The following changes are made to support CockroachDB (crdb):

- Detecting use of cockroach. - Removal of custom PostgreSQL types (i.e.
`vin_t` and `vout_t`) and related code since crdb does not support them.
- Not erroring out when checking PostgreSQL-specific information (e.g.
`synchronous_commit` and almost all the `pg_settings` dumped in the
table at startup). - Setting the `sql_sequence` SERIAL operating mode
since by default `SERIAL` type columns in crdb do not create a sequence.
- Empty arrays made using the `ARRAY[]` constructor in CockroachDB
require type _annotation_ (e.g. `ARRAY[]:::BIGINT[]` with ***three***
`:` characters for annotation instead of conversion), a concept that
does not exist in PostgreSQL).  May need to use the literal format like
`SELECT '{}'::int[];` or whatever works for both PostgreSQL and
CockroachDB. - Replaces `cardinality(arr)` with `array_length(arr,1)`
since crdb does not have `cardinality`
- Update README.md files for cockroachdb
- Replace DELETE USING with subquery statements
- Prevent too many versions of nextval() during bulk inserts using
 autoincrement of row primary key by lowering garbage the collection
 interval (from 25 hours!) to 20 minutes.
- Note that update permissions may be required for zone config.
- Remove dups with alternate queries that do not oom on cockroach
- Deleting a unique index requires CASCADE

Also: - Remove the `updateAllVotes` option from `ChainDB` sync since it
is always done on the fly. For now, let `StoreBlock` keep the option to
update ticket/vote spend info. Also keep
`(*ChainDB).UpdateSpendingInfoInAllTickets` as it could be a helpful
recovery and repair function. - `HeightDB`, `HashDB`, and `HeightHashDB`
now use `DBBestBlock` to get the data from the `meta` table.  See
`HeightDBLegacy`, etc. for the querying the `blocks` table instead. -
Before sync, check the `ibd_complete` flag in the meta `table` and force
indexing and full update of `addresses` table spending info as required.
- Remove unused code and comments from dcrpg/internal code.
  • Loading branch information
chappjc authored Jun 5, 2019
1 parent 7fd507b commit 3ddc034
Show file tree
Hide file tree
Showing 20 changed files with 703 additions and 331 deletions.
31 changes: 25 additions & 6 deletions README.md
Original file line number Diff line number Diff line change
Expand Up @@ -27,11 +27,12 @@ modern javascript features, as well as SCSS for styling.
- [From v2.x or earlier](#from-v2x-or-earlier)
- [Getting Started](#getting-started)
- [Configuring PostgreSQL (**IMPORTANT!** Seriously, read this.)](#configuring-postgresql-important-seriously-read-this)
- [CockroachDB Support (experimental)](#cockroachdb-support-experimental)
- [Creating the dcrdata Configuration File](#creating-the-dcrdata-configuration-file)
- [Using Environment Variables for Configuration](#using-environment-variables-for-configuration)
- [Indexing the Blockchain](#indexing-the-blockchain)
- [Starting dcrdata](#starting-dcrdata)
- [Hiding the PostgreSQL db Configuration settings.](#hiding-the-postgresql-db-configuration-settings)
- [Hiding the PostgreSQL Settings Table](#hiding-the-postgresql-settings-table)
- [Running the Web Interface During Synchronization](#running-the-web-interface-during-synchronization)
- [System Hardware Requirements](#system-hardware-requirements)
- [dcrdata only (PostgreSQL on other host)](#dcrdata-only-postgresql-on-other-host)
Expand Down Expand Up @@ -142,7 +143,9 @@ Always run the Current release or on the Current stable branch. Do not use `mast
dcrd version is compatible. dcrdata v3.1.x and later required dcrd v1.4.x or a
later version with JSON-RPC server version 5.x.y.
- (For "full" mode) PostgreSQL 10.5+. Version 11.x is supported and recommended
for improved performance with a number of tasks.
for improved performance with a number of tasks. Support for CockroachDB is an
experimental feature. See [CockroachDB Support (experimental)](#cockroachdb-support-experimental)
for details.

## Docker Support

Expand Down Expand Up @@ -349,6 +352,23 @@ On Linux, you may wish to use a unix domain socket instead of a TCP connection.
The path to the socket depends on the system, but it is commonly
`/var/run/postgresql`. Just set this path in `pghost`.

### CockroachDB Support (experimental)

While dcrdata now provides [support for CockroachDB](https://github.com/decred/dcrdata/issues/1291),
this is an experimental feature with caveats:

- Compared to a well-configure PostgreSQL backend, CoackroachDB performance is
suboptimal. See the [CockroachDB issue](https://github.com/decred/dcrdata/issues/1291)
for more information.
- The bulk of the testing and performance optimization is done with PostgreSQL
in mind.

If you decide to use CockroachDB with dcrdata, (1) do not do so in production
and (2) expect some bugs and relatively poor performance.

See [dcrdata's CockroachDB wiki page](https://github.com/decred/dcrdata/wiki/CockroachDB)
for more information.
### Creating the dcrdata Configuration File
Begin with the sample configuration file. With the default `appdata` directory
Expand Down Expand Up @@ -422,10 +442,10 @@ Unlike dcrdata.conf, which must be placed in the `appdata` folder or explicitly
set with `-C`, the "public" and "views" folders _must_ be in the same folder as
the `dcrdata` executable.
### Hiding the PostgreSQL db Configuration settings.
### Hiding the PostgreSQL Settings Table
By default postgres configuration settings are logged on system start up.
`--hidepgconfig` flag blocks the logging on dcrdata start up.
By default, postgres settings are displayed in a table on start up of dcrdata.
To block display of this table, use the `--hidepgconfig` switch..
### Running the Web Interface During Synchronization
Expand Down Expand Up @@ -486,7 +506,6 @@ Recommend:
- 8+ GB RAM
- SSD (NVMe preferred) with 60 GB free space

## dcrdata Daemon
The root of the repository is the `main` package for the `dcrdata` app, which
Expand Down
15 changes: 6 additions & 9 deletions cmd/rebuilddb2/rebuilddb2.go
Original file line number Diff line number Diff line change
@@ -1,11 +1,10 @@
// Copyright (c) 2018, The Decred developers
// Copyright (c) 2018-2019, The Decred developers
// Copyright (c) 2017, The dcrdata developers
// See LICENSE for details.

package main

import (
"database/sql"
"fmt"
"net"
"net/http"
Expand Down Expand Up @@ -194,13 +193,11 @@ func mainCore() error {
// Check current height of DB
lastBlock, err := db.HeightDB()
if err != nil {
if err == sql.ErrNoRows {
lastBlock = -1
log.Info("blocks table is empty, starting fresh.")
} else {
log.Errorln("RetrieveBestBlockHeight:", err)
return err
}
log.Errorln("RetrieveBestBlockHeight:", err)
return err
}
if lastBlock == -1 {
log.Info("tables are empty, starting fresh.")
}

// Start waiting for the interrupt signal
Expand Down
13 changes: 12 additions & 1 deletion db/dcrpg/README.md
Original file line number Diff line number Diff line change
Expand Up @@ -3,13 +3,24 @@
The `dcrpg` package provides types and functions for manipulating PostgreSQL
tables, and storing blocks, transactions, inputs, and outputs.

## Supported Database Software

PostgreSQL versions 10.5 to 11.x are fully supported. The bulk of the testing
and performance optimization is done with PostgreSQL in mind.

[Experimental support for CockroachDB](https://github.com/decred/dcrdata/issues/1291)
was added for dcrdata 5.0. However, compared to a well-configure PostgreSQL
backend, CoackroachDB performance is suboptimal. See the
[CockroachDB support issue](https://github.com/decred/dcrdata/issues/1291) for
more information.

## Performance and Bulk Loading

When performing a bulk data import, it is wise to first drop any existing
indexes and create them again after insertion is completed. Functions are
provided to create and drop the indexes.

PostgreSQL performance will be poor, particuarly during bulk import, unless
PostgreSQL performance will be poor, particularly during bulk import, unless
synchronous transaction commits are disabled via the `synchronous_commit = off`
configuration setting in your postgresql.conf. There are numerous
[PostreSQL tuning settings](https://wiki.postgresql.org/wiki/Tuning_Your_PostgreSQL_Server),
Expand Down
8 changes: 8 additions & 0 deletions db/dcrpg/indexing.go
Original file line number Diff line number Diff line change
Expand Up @@ -334,6 +334,14 @@ func (pgb *ChainDB) DeleteDuplicateVouts() (int64, error) {
return DeleteDuplicateVouts(pgb.db)
}

func (pgb *ChainDB) DeleteDuplicateVinsCockroach() (int64, error) {
return DeleteDuplicateVinsCockroach(pgb.db)
}

func (pgb *ChainDB) DeleteDuplicateVoutsCockroach() (int64, error) {
return DeleteDuplicateVoutsCockroach(pgb.db)
}

func (pgb *ChainDB) DeleteDuplicateTxns() (int64, error) {
return DeleteDuplicateTxns(pgb.db)
}
Expand Down
10 changes: 5 additions & 5 deletions db/dcrpg/internal/addrstmts.go
Original file line number Diff line number Diff line change
Expand Up @@ -54,25 +54,25 @@ const (
// on (tx_vin_vout_row_id, address, is_funding).
IndexAddressTableOnVoutID = `CREATE UNIQUE INDEX ` + IndexOfAddressTableOnVoutID +
` ON addresses(tx_vin_vout_row_id, address, is_funding);`
DeindexAddressTableOnVoutID = `DROP INDEX ` + IndexOfAddressTableOnVoutID + `;`
DeindexAddressTableOnVoutID = `DROP INDEX ` + IndexOfAddressTableOnVoutID + ` CASCADE;`

// IndexBlockTimeOnTableAddress creates a sorted index on block_time, which
// accelerates queries with ORDER BY block_time LIMIT n OFFSET m.
IndexBlockTimeOnTableAddress = `CREATE INDEX ` + IndexOfAddressTableOnBlockTime +
` ON addresses(block_time DESC NULLS LAST);`
DeindexBlockTimeOnTableAddress = `DROP INDEX ` + IndexOfAddressTableOnBlockTime + `;`
DeindexBlockTimeOnTableAddress = `DROP INDEX ` + IndexOfAddressTableOnBlockTime + ` CASCADE;`

IndexMatchingTxHashOnTableAddress = `CREATE INDEX ` + IndexOfAddressTableOnMatchingTx +
` ON addresses(matching_tx_hash);`
DeindexMatchingTxHashOnTableAddress = `DROP INDEX ` + IndexOfAddressTableOnMatchingTx + `;`
DeindexMatchingTxHashOnTableAddress = `DROP INDEX ` + IndexOfAddressTableOnMatchingTx + ` CASCADE;`

IndexAddressTableOnAddress = `CREATE INDEX ` + IndexOfAddressTableOnAddress +
` ON addresses(address);`
DeindexAddressTableOnAddress = `DROP INDEX ` + IndexOfAddressTableOnAddress + `;`
DeindexAddressTableOnAddress = `DROP INDEX ` + IndexOfAddressTableOnAddress + ` CASCADE;`

IndexAddressTableOnTxHash = `CREATE INDEX ` + IndexOfAddressTableOnTx +
` ON addresses(tx_hash);`
DeindexAddressTableOnTxHash = `DROP INDEX ` + IndexOfAddressTableOnTx + `;`
DeindexAddressTableOnTxHash = `DROP INDEX ` + IndexOfAddressTableOnTx + ` CASCADE;`

// SelectSpendingTxsByPrevTx = `SELECT id, tx_hash, tx_index, prev_tx_index FROM vins WHERE prev_tx_hash=$1;`
// SelectSpendingTxByPrevOut = `SELECT id, tx_hash, tx_index FROM vins WHERE prev_tx_hash=$1 AND prev_tx_index=$2;`
Expand Down
10 changes: 6 additions & 4 deletions db/dcrpg/internal/blockstmts.go
Original file line number Diff line number Diff line change
@@ -1,3 +1,7 @@
// Copyright (c) 2018-2019, The Decred developers
// Copyright (c) 2017, Jonathan Chappelow
// See LICENSE for details.

package internal

import (
Expand Down Expand Up @@ -83,12 +87,12 @@ const (

// IndexBlockTableOnHash creates the unique index uix_block_hash on (hash).
IndexBlockTableOnHash = `CREATE UNIQUE INDEX ` + IndexOfBlocksTableOnHash + ` ON blocks(hash);`
DeindexBlockTableOnHash = `DROP INDEX ` + IndexOfBlocksTableOnHash + `;`
DeindexBlockTableOnHash = `DROP INDEX ` + IndexOfBlocksTableOnHash + ` CASCADE;`

// IndexBlocksTableOnHeight creates the index uix_block_height on (height).
// This is not unique because of side chains.
IndexBlocksTableOnHeight = `CREATE INDEX ` + IndexOfBlocksTableOnHeight + ` ON blocks(height);`
DeindexBlocksTableOnHeight = `DROP INDEX ` + IndexOfBlocksTableOnHeight + `;`
DeindexBlocksTableOnHeight = `DROP INDEX ` + IndexOfBlocksTableOnHeight + ` CASCADE;`

SelectBlockByTimeRangeSQL = `SELECT hash, height, size, time, numtx
FROM blocks WHERE time BETWEEN $1 and $2 ORDER BY time DESC LIMIT $3;`
Expand Down Expand Up @@ -218,8 +222,6 @@ const (
WHERE is_mainchain
AND height > $1
ORDER BY height;`

// TODO: index block_chain where needed
)

func MakeBlockInsertStatement(block *dbtypes.Block, checked bool) string {
Expand Down
27 changes: 7 additions & 20 deletions db/dcrpg/internal/common.go
Original file line number Diff line number Diff line change
@@ -1,3 +1,7 @@
// Copyright (c) 2018-2019, The Decred developers
// Copyright (c) 2017, Jonathan Chappelow
// See LICENSE for details.

package internal

import (
Expand Down Expand Up @@ -41,29 +45,12 @@ func makeARRAYOfTEXT(text []string) string {
return buffer.String()
}

func makeARRAYOfUnquotedTEXT(text []string) string {
if len(text) == 0 {
return "ARRAY[]"
}
buffer := bytes.NewBufferString("ARRAY[")
for i, txt := range text {
if i == len(text)-1 {
buffer.WriteString(txt)
break
}
buffer.WriteString(txt + `, `)
}
buffer.WriteString("]")

return buffer.String()
}

func makeARRAYOfBIGINTs(ints []uint64) string {
if len(ints) == 0 {
return "ARRAY[]::BIGINT[]"
return "'{}'::BIGINT[]" // cockroachdb: "ARRAY[]:::BIGINT[]"
}

buffer := bytes.NewBufferString("ARRAY[")
buffer := bytes.NewBufferString("'{")
for i, v := range ints {
u := strconv.FormatUint(v, 10)
if i == len(ints)-1 {
Expand All @@ -72,7 +59,7 @@ func makeARRAYOfBIGINTs(ints []uint64) string {
}
buffer.WriteString(u + `, `)
}
buffer.WriteString("]")
buffer.WriteString("}'::BIGINT[]")

return buffer.String()
}
5 changes: 5 additions & 0 deletions db/dcrpg/internal/meta.go
Original file line number Diff line number Diff line change
@@ -1,3 +1,6 @@
// Copyright (c) 2019, The Decred developers
// See LICENSE for details.

package internal

const (
Expand Down Expand Up @@ -32,6 +35,8 @@ const (
SetMetaDBBestBlock = `UPDATE meta
SET best_block_height = $1, best_block_hash = $2;`

SelectMetaDBIbdComplete = `SELECT ibd_complete FROM meta;`

SetMetaDBIbdComplete = `UPDATE meta
SET ibd_complete = $1;`

Expand Down
78 changes: 74 additions & 4 deletions db/dcrpg/internal/rewind.go
Original file line number Diff line number Diff line change
Expand Up @@ -11,22 +11,53 @@ const (
WHERE (
(addresses.tx_vin_vout_row_id=ANY(transactions.vin_db_ids) AND addresses.is_funding=false)
OR
(addresses.tx_vin_vout_row_id=ANY(transactions.vout_DB_IDs) AND addresses.is_funding=true)
(addresses.tx_vin_vout_row_id=ANY(transactions.vout_db_ids) AND addresses.is_funding=true)
)
AND transactions.id = ANY(array_cat(blocks.txdbids, blocks.stxdbids))
AND blocks.hash=$1;`

// For CockroachDB, which does not allow the USING clause with DELETE, a
// subquery (addressesForBlockHash) is needed.

// This query with two JOINs is more straight forward, and faster in
// PostgreSQL, but much slower in CockroachDB.
//
// addressesForBlockHash = `SELECT addresses.id
// FROM transactions
// JOIN blocks ON
// blocks.hash=$1
// AND transactions.id = ANY(array_cat(blocks.txdbids, blocks.stxdbids))
// JOIN addresses ON
// (addresses.tx_vin_vout_row_id=ANY(transactions.vin_db_ids) AND addresses.is_funding=false)
// OR (addresses.tx_vin_vout_row_id=ANY(transactions.vout_db_ids) AND addresses.is_funding=true)`

addressesForBlockHash = `SELECT addresses.id
FROM addresses
JOIN transactions ON
(NOT addresses.is_funding AND addresses.tx_vin_vout_row_id = ANY(transactions.vin_db_ids))
OR
(addresses.is_funding AND addresses.tx_vin_vout_row_id = ANY(transactions.vout_db_ids))
WHERE transactions.id IN
(
SELECT transactions.id
FROM transactions
JOIN blocks ON blocks.hash = $1
AND transactions.id = ANY(array_cat(blocks.txdbids, blocks.stxdbids))
)`

DeleteAddressesSubQry = `DELETE FROM addresses WHERE id IN (` + addressesForBlockHash + `);`

DeleteStakeAddressesFunding = `DELETE FROM addresses
USING transactions, blocks
WHERE addresses.tx_vin_vout_row_id=ANY(transactions.vin_db_ids)
AND addresses.is_funding=false
AND NOT addresses.is_funding
AND transactions.id = ANY(blocks.stxdbids)
AND blocks.hash=$1;`

DeleteStakeAddressesSpending = `DELETE FROM addresses
USING transactions, blocks
WHERE addresses.tx_vin_vout_row_id=ANY(transactions.vout_DB_IDs)
AND addresses.is_funding=true
WHERE addresses.tx_vin_vout_row_id=ANY(transactions.vout_db_ids)
AND addresses.is_funding
AND transactions.id = ANY(blocks.stxdbids)
AND blocks.hash=$1;`

Expand All @@ -38,6 +69,33 @@ const (
AND transactions.id = ANY(array_cat(blocks.txdbids,blocks.stxdbids))
AND blocks.hash=$1;`

// For CockroachDB, which does not allow the USING clause with DELETE, a
// subquery (vinsForBlockHash) is needed.

// This query with two JOINs is more straight forward, and faster in
// PostgreSQL, but much slower in CockroachDB.
//
// vinsForBlockHash = `SELECT vins.id
// FROM transactions
// JOIN blocks ON
// blocks.hash=$1
// AND transactions.id = ANY(array_cat(blocks.txdbids, blocks.stxdbids))
// JOIN vins ON
// vins.id=ANY(transactions.vin_db_ids)`

vinsForBlockHash = `SELECT vins.id
FROM vins
JOIN transactions ON vins.id = ANY(transactions.vin_db_ids)
WHERE transactions.id IN
(
SELECT transactions.id
FROM transactions
JOIN blocks ON blocks.hash = $1
AND transactions.id = ANY(array_cat(blocks.txdbids, blocks.stxdbids))
)`

DeleteVinsSubQry = `DELETE FROM vins WHERE id IN (` + vinsForBlockHash + `);`

// DeleteStakeVins deletes rows of the vins table corresponding to inputs of
// the stake transactions (transactions.vin_db_ids) for a block
// (blocks.stxdbids) specified by its hash (blocks.hash).
Expand Down Expand Up @@ -88,6 +146,16 @@ const (
AND transactions.id = ANY(array_cat(blocks.txdbids,blocks.stxdbids))
AND blocks.hash=$1;`

voutsForBlockHash = `SELECT vouts.id
FROM transactions
JOIN blocks ON
blocks.hash=$1
AND transactions.id = ANY(array_cat(blocks.txdbids, blocks.stxdbids))
JOIN vouts ON
vouts.id=ANY(transactions.vout_db_ids)`

DeleteVoutsSubQry = `DELETE FROM vouts WHERE id IN (` + voutsForBlockHash + `);`

// DeleteStakeVouts deletes rows of the vouts table corresponding to inputs
// of the stake transactions (transactions.vout_db_ids) for a block
// (blocks.stxdbids) specified by its hash (blocks.hash).
Expand Down Expand Up @@ -147,6 +215,8 @@ const (
USING blocks
WHERE transactions.id = ANY(array_cat(blocks.txdbids, blocks.stxdbids))
AND blocks.hash=$1;`
DeleteTransactionsSimple = `DELETE FROM transactions
WHERE block_hash=$1;`

DeleteBlock = `DELETE FROM blocks
WHERE hash=$1;`
Expand Down
Loading

0 comments on commit 3ddc034

Please sign in to comment.