diff --git a/Makefile b/Makefile index a266edd9a..ea5a858bf 100644 --- a/Makefile +++ b/Makefile @@ -5,22 +5,57 @@ MODULE_big = cstore_fdw +VER := $(lastword $(shell pg_config --version)) +VER_WORDS = $(subst ., ,$(VER)) +MVER = $(firstword $(VER_WORDS)) + +# error for versions earlier than 10 so that lex comparison will work +ifneq ($(shell printf '%02d' $(MVER)),$(MVER)) +$(error version $(VER) not supported) +endif + +# lexicographic comparison of version number +ifeq ($(lastword $(sort 12 $(MVER))),$(MVER)) + USE_TABLEAM = yes + USE_FDW = yes +else ifeq ($(lastword $(sort 11 $(MVER))),$(MVER)) + USE_TABLEAM = no + USE_FDW = yes +else +$(error version $(VER) is not supported) +endif + PG_CPPFLAGS = -std=c11 -OBJS = cstore.o cstore_fdw.o cstore_writer.o cstore_reader.o \ +OBJS = cstore.o cstore_writer.o cstore_reader.o \ cstore_compression.o mod.o cstore_metadata_tables.o EXTENSION = cstore_fdw DATA = cstore_fdw--1.7.sql cstore_fdw--1.6--1.7.sql cstore_fdw--1.5--1.6.sql cstore_fdw--1.4--1.5.sql \ cstore_fdw--1.3--1.4.sql cstore_fdw--1.2--1.3.sql cstore_fdw--1.1--1.2.sql \ - cstore_fdw--1.0--1.1.sql + cstore_fdw--1.0--1.1.sql cstore_fdw--1.7--1.8.sql -REGRESS = fdw_create fdw_load fdw_query fdw_analyze fdw_data_types fdw_functions \ - fdw_block_filtering fdw_drop fdw_insert fdw_copyto fdw_alter fdw_truncate +REGRESS = extension_create EXTRA_CLEAN = cstore.pb-c.h cstore.pb-c.c data/*.cstore data/*.cstore.footer \ sql/block_filtering.sql sql/create.sql sql/data_types.sql sql/load.sql \ sql/copyto.sql expected/block_filtering.out expected/create.out \ expected/data_types.out expected/load.out expected/copyto.out +ifeq ($(USE_FDW),yes) + PG_CFLAGS += -DUSE_FDW + OBJS += cstore_fdw.o + REGRESS += fdw_create fdw_load fdw_query fdw_analyze fdw_data_types \ + fdw_functions fdw_block_filtering fdw_drop fdw_insert \ + fdw_copyto fdw_alter fdw_truncate fdw_clean +endif + +# disabled tests: am_block_filtering am_analyze +ifeq ($(USE_TABLEAM),yes) + PG_CFLAGS += -DUSE_TABLEAM + OBJS += cstore_tableam.o + REGRESS += am_create am_load am_query am_data_types am_functions \ + am_drop am_insert am_copyto am_alter am_truncate am_clean +endif + ifeq ($(enable_coverage),yes) PG_CPPFLAGS += --coverage SHLIB_LINK += --coverage @@ -41,18 +76,7 @@ PG_CONFIG = pg_config PGXS := $(shell $(PG_CONFIG) --pgxs) include $(PGXS) -ifndef MAJORVERSION - MAJORVERSION := $(basename $(VERSION)) -endif - -ifeq (,$(findstring $(MAJORVERSION), 9.3 9.4 9.5 9.6 10 11 12)) - $(error PostgreSQL 9.3 to 12 is required to compile this extension) -endif - -installcheck: remove_cstore_files - -remove_cstore_files: - rm -f data/*.cstore data/*.cstore.footer +installcheck: reindent: citus_indent . diff --git a/cstore.c b/cstore.c index f04fc4fc6..f5846a029 100644 --- a/cstore.c +++ b/cstore.c @@ -17,10 +17,70 @@ #include #include "miscadmin.h" +#include "utils/guc.h" #include "utils/rel.h" #include "cstore.h" +/* Default values for option parameters */ +#define DEFAULT_COMPRESSION_TYPE COMPRESSION_NONE +#define DEFAULT_STRIPE_ROW_COUNT 150000 +#define DEFAULT_BLOCK_ROW_COUNT 10000 + +int cstore_compression = DEFAULT_COMPRESSION_TYPE; +int cstore_stripe_row_count = DEFAULT_STRIPE_ROW_COUNT; +int cstore_block_row_count = DEFAULT_BLOCK_ROW_COUNT; + +static const struct config_enum_entry cstore_compression_options[] = +{ + { "none", COMPRESSION_NONE, false }, + { "pglz", COMPRESSION_PG_LZ, false }, + { NULL, 0, false } +}; + +void +cstore_init() +{ + DefineCustomEnumVariable("cstore.compression", + "Compression type for cstore.", + NULL, + &cstore_compression, + DEFAULT_COMPRESSION_TYPE, + cstore_compression_options, + PGC_USERSET, + 0, + NULL, + NULL, + NULL); + + DefineCustomIntVariable("cstore.stripe_row_count", + "Maximum number of tuples per stripe.", + NULL, + &cstore_stripe_row_count, + DEFAULT_STRIPE_ROW_COUNT, + STRIPE_ROW_COUNT_MINIMUM, + STRIPE_ROW_COUNT_MAXIMUM, + PGC_USERSET, + 0, + NULL, + NULL, + NULL); + + DefineCustomIntVariable("cstore.block_row_count", + "Maximum number of rows per block.", + NULL, + &cstore_block_row_count, + DEFAULT_BLOCK_ROW_COUNT, + BLOCK_ROW_COUNT_MINIMUM, + BLOCK_ROW_COUNT_MAXIMUM, + PGC_USERSET, + 0, + NULL, + NULL, + NULL); +} + + /* ParseCompressionType converts a string to a compression type. */ CompressionType ParseCompressionType(const char *compressionTypeString) diff --git a/cstore.h b/cstore.h index 87b552bbf..ad0ad20bd 100644 --- a/cstore.h +++ b/cstore.h @@ -24,11 +24,6 @@ #define OPTION_NAME_STRIPE_ROW_COUNT "stripe_row_count" #define OPTION_NAME_BLOCK_ROW_COUNT "block_row_count" -/* Default values for option parameters */ -#define DEFAULT_COMPRESSION_TYPE COMPRESSION_NONE -#define DEFAULT_STRIPE_ROW_COUNT 150000 -#define DEFAULT_BLOCK_ROW_COUNT 10000 - /* Limits for option parameters */ #define STRIPE_ROW_COUNT_MINIMUM 1000 #define STRIPE_ROW_COUNT_MAXIMUM 10000000 @@ -249,11 +244,15 @@ typedef struct TableWriteState StringInfo compressionBuffer; } TableWriteState; +extern int cstore_compression; +extern int cstore_stripe_row_count; +extern int cstore_block_row_count; + +extern void cstore_init(void); + extern CompressionType ParseCompressionType(const char *compressionTypeString); extern void InitializeCStoreTableFile(Oid relationId, Relation relation, CStoreOptions *cstoreOptions); -extern void CreateCStoreDatabaseDirectory(Oid databaseOid); -extern void RemoveCStoreDatabaseDirectory(Oid databaseOid); /* Function declarations for writing to a cstore file */ extern TableWriteState * CStoreBeginWrite(Oid relationId, diff --git a/cstore_fdw--1.7--1.8.sql b/cstore_fdw--1.7--1.8.sql new file mode 100644 index 000000000..8fe9416d1 --- /dev/null +++ b/cstore_fdw--1.7--1.8.sql @@ -0,0 +1,17 @@ +/* cstore_fdw/cstore_fdw--1.7--1.8.sql */ + +DO $proc$ +BEGIN + +IF version() ~ '12' THEN + EXECUTE $$ + CREATE FUNCTION cstore_tableam_handler(internal) + RETURNS table_am_handler + LANGUAGE C + AS 'MODULE_PATHNAME', 'cstore_tableam_handler'; + + CREATE ACCESS METHOD cstore_tableam + TYPE TABLE HANDLER cstore_tableam_handler; + $$; +END IF; +END$proc$; diff --git a/cstore_fdw.c b/cstore_fdw.c index 512dee5a3..a66ba1d80 100644 --- a/cstore_fdw.c +++ b/cstore_fdw.c @@ -1260,9 +1260,9 @@ static CStoreOptions * CStoreGetOptions(Oid foreignTableId) { CStoreOptions *cstoreOptions = NULL; - CompressionType compressionType = DEFAULT_COMPRESSION_TYPE; - int32 stripeRowCount = DEFAULT_STRIPE_ROW_COUNT; - int32 blockRowCount = DEFAULT_BLOCK_ROW_COUNT; + CompressionType compressionType = cstore_compression; + int32 stripeRowCount = cstore_stripe_row_count; + int32 blockRowCount = cstore_block_row_count; char *compressionTypeString = NULL; char *stripeRowCountString = NULL; char *blockRowCountString = NULL; diff --git a/cstore_fdw.control b/cstore_fdw.control index 6f781dcbb..57fd0808a 100644 --- a/cstore_fdw.control +++ b/cstore_fdw.control @@ -1,6 +1,6 @@ # cstore_fdw extension comment = 'foreign-data wrapper for flat cstore access' -default_version = '1.7' +default_version = '1.8' module_pathname = '$libdir/cstore_fdw' relocatable = false schema = cstore diff --git a/cstore_tableam.c b/cstore_tableam.c new file mode 100644 index 000000000..312e10981 --- /dev/null +++ b/cstore_tableam.c @@ -0,0 +1,680 @@ +#include "postgres.h" + +#include + +#include "miscadmin.h" + +#include "access/genam.h" +#include "access/heapam.h" +#include "access/multixact.h" +#include "access/rewriteheap.h" +#include "access/tableam.h" +#include "access/tsmapi.h" +#include "access/tuptoaster.h" +#include "access/xact.h" +#include "catalog/catalog.h" +#include "catalog/index.h" +#include "catalog/storage.h" +#include "catalog/storage_xlog.h" +#include "commands/progress.h" +#include "executor/executor.h" +#include "nodes/makefuncs.h" +#include "optimizer/plancat.h" +#include "pgstat.h" +#include "storage/bufmgr.h" +#include "storage/bufpage.h" +#include "storage/bufmgr.h" +#include "storage/lmgr.h" +#include "storage/predicate.h" +#include "storage/procarray.h" +#include "storage/smgr.h" +#include "utils/builtins.h" +#include "utils/rel.h" + +#include "cstore.h" +#include "cstore_tableam.h" + +typedef struct CStoreScanDescData +{ + TableScanDescData cs_base; + TableReadState *cs_readState; +} CStoreScanDescData; + +typedef struct CStoreScanDescData *CStoreScanDesc; + +static TableWriteState *CStoreWriteState = NULL; +static ExecutorEnd_hook_type PreviousExecutorEndHook = NULL; +static MemoryContext CStoreContext = NULL; + +static CStoreOptions * +CStoreTableAMGetOptions(void) +{ + CStoreOptions *cstoreOptions = palloc0(sizeof(CStoreOptions)); + cstoreOptions->compressionType = cstore_compression; + cstoreOptions->stripeRowCount = cstore_stripe_row_count; + cstoreOptions->blockRowCount = cstore_block_row_count; + return cstoreOptions; +} + + +static MemoryContext +GetCStoreMemoryContext(void) +{ + if (CStoreContext == NULL) + { + CStoreContext = AllocSetContextCreate(TopMemoryContext, "cstore context", + ALLOCSET_DEFAULT_SIZES); + } + return CStoreContext; +} + + +static void +cstore_init_write_state(Relation relation) +{ + /*TODO: upgrade lock to serialize writes */ + + if (CStoreWriteState != NULL) + { + /* TODO: consider whether it's possible for a new write to start */ + /* before an old one is flushed */ + Assert(CStoreWriteState->relation->rd_id == relation->rd_id); + } + + if (CStoreWriteState == NULL) + { + CStoreOptions *cstoreOptions = CStoreTableAMGetOptions(); + TupleDesc tupdesc = RelationGetDescr(relation); + + elog(LOG, "initializing write state for relation %d", relation->rd_id); + CStoreWriteState = CStoreBeginWrite(relation->rd_id, + cstoreOptions->compressionType, + cstoreOptions->stripeRowCount, + cstoreOptions->blockRowCount, + tupdesc); + + CStoreWriteState->relation = relation; + } +} + + +static void +cstore_free_write_state() +{ + if (CStoreWriteState != NULL) + { + elog(LOG, "flushing write state for relation %d", + CStoreWriteState->relation->rd_id); + CStoreEndWrite(CStoreWriteState); + CStoreWriteState = NULL; + } +} + + +static const TupleTableSlotOps * +cstore_slot_callbacks(Relation relation) +{ + return &TTSOpsVirtual; +} + + +static TableScanDesc +cstore_beginscan(Relation relation, Snapshot snapshot, + int nkeys, ScanKey key, + ParallelTableScanDesc parallel_scan, + uint32 flags) +{ + Oid relid = relation->rd_id; + TupleDesc tupdesc = relation->rd_att; + CStoreOptions *cstoreOptions = NULL; + TableReadState *readState = NULL; + CStoreScanDesc scan = palloc(sizeof(CStoreScanDescData)); + List *columnList = NIL; + MemoryContext oldContext = MemoryContextSwitchTo(GetCStoreMemoryContext()); + + cstoreOptions = CStoreTableAMGetOptions(); + + scan->cs_base.rs_rd = relation; + scan->cs_base.rs_snapshot = snapshot; + scan->cs_base.rs_nkeys = nkeys; + scan->cs_base.rs_key = key; + scan->cs_base.rs_flags = flags; + scan->cs_base.rs_parallel = parallel_scan; + + for (int i = 0; i < tupdesc->natts; i++) + { + Index varno = 0; + AttrNumber varattno = i + 1; + Oid vartype = tupdesc->attrs[i].atttypid; + int32 vartypmod = 0; + Oid varcollid = 0; + Index varlevelsup = 0; + Var *var; + + if (tupdesc->attrs[i].attisdropped) + { + continue; + } + + var = makeVar(varno, varattno, vartype, vartypmod, + varcollid, varlevelsup); + columnList = lappend(columnList, var); + } + + readState = CStoreBeginRead(relid, tupdesc, columnList, NULL); + readState->relation = relation; + + scan->cs_readState = readState; + + MemoryContextSwitchTo(oldContext); + return ((TableScanDesc) scan); +} + + +static void +cstore_endscan(TableScanDesc sscan) +{ + CStoreScanDesc scan = (CStoreScanDesc) sscan; + CStoreEndRead(scan->cs_readState); + scan->cs_readState = NULL; +} + + +static void +cstore_rescan(TableScanDesc sscan, ScanKey key, bool set_params, + bool allow_strat, bool allow_sync, bool allow_pagemode) +{ + elog(ERROR, "cstore_rescan not implemented"); +} + + +static bool +cstore_getnextslot(TableScanDesc sscan, ScanDirection direction, TupleTableSlot *slot) +{ + CStoreScanDesc scan = (CStoreScanDesc) sscan; + bool nextRowFound; + MemoryContext oldContext = MemoryContextSwitchTo(GetCStoreMemoryContext()); + + ExecClearTuple(slot); + + nextRowFound = CStoreReadNextRow(scan->cs_readState, slot->tts_values, + slot->tts_isnull); + + MemoryContextSwitchTo(oldContext); + + if (!nextRowFound) + { + return false; + } + + ExecStoreVirtualTuple(slot); + return true; +} + + +static Size +cstore_parallelscan_estimate(Relation rel) +{ + elog(ERROR, "cstore_parallelscan_estimate not implemented"); +} + + +static Size +cstore_parallelscan_initialize(Relation rel, ParallelTableScanDesc pscan) +{ + elog(ERROR, "cstore_parallelscan_initialize not implemented"); +} + + +static void +cstore_parallelscan_reinitialize(Relation rel, ParallelTableScanDesc pscan) +{ + elog(ERROR, "cstore_parallelscan_reinitialize not implemented"); +} + + +static IndexFetchTableData * +cstore_index_fetch_begin(Relation rel) +{ + elog(ERROR, "cstore_index_fetch_begin not implemented"); +} + + +static void +cstore_index_fetch_reset(IndexFetchTableData *scan) +{ + elog(ERROR, "cstore_index_fetch_reset not implemented"); +} + + +static void +cstore_index_fetch_end(IndexFetchTableData *scan) +{ + elog(ERROR, "cstore_index_fetch_end not implemented"); +} + + +static bool +cstore_index_fetch_tuple(struct IndexFetchTableData *scan, + ItemPointer tid, + Snapshot snapshot, + TupleTableSlot *slot, + bool *call_again, bool *all_dead) +{ + elog(ERROR, "cstore_index_fetch_tuple not implemented"); +} + + +static bool +cstore_fetch_row_version(Relation relation, + ItemPointer tid, + Snapshot snapshot, + TupleTableSlot *slot) +{ + elog(ERROR, "cstore_fetch_row_version not implemented"); +} + + +static void +cstore_get_latest_tid(TableScanDesc sscan, + ItemPointer tid) +{ + elog(ERROR, "cstore_get_latest_tid not implemented"); +} + + +static bool +cstore_tuple_tid_valid(TableScanDesc scan, ItemPointer tid) +{ + elog(ERROR, "cstore_tuple_tid_valid not implemented"); +} + + +static bool +cstore_tuple_satisfies_snapshot(Relation rel, TupleTableSlot *slot, + Snapshot snapshot) +{ + return true; +} + + +static TransactionId +cstore_compute_xid_horizon_for_tuples(Relation rel, + ItemPointerData *tids, + int nitems) +{ + elog(ERROR, "cstore_compute_xid_horizon_for_tuples not implemented"); +} + + +static void +cstore_tuple_insert(Relation relation, TupleTableSlot *slot, CommandId cid, + int options, BulkInsertState bistate) +{ + HeapTuple heapTuple; + MemoryContext oldContext = MemoryContextSwitchTo(GetCStoreMemoryContext()); + + cstore_init_write_state(relation); + + heapTuple = ExecCopySlotHeapTuple(slot); + if (HeapTupleHasExternal(heapTuple)) + { + /* detoast any toasted attributes */ + HeapTuple newTuple = toast_flatten_tuple(heapTuple, + slot->tts_tupleDescriptor); + + ExecForceStoreHeapTuple(newTuple, slot, true); + } + + slot_getallattrs(slot); + + CStoreWriteRow(CStoreWriteState, slot->tts_values, slot->tts_isnull); + MemoryContextSwitchTo(oldContext); +} + + +static void +cstore_tuple_insert_speculative(Relation relation, TupleTableSlot *slot, + CommandId cid, int options, + BulkInsertState bistate, uint32 specToken) +{ + elog(ERROR, "cstore_tuple_insert_speculative not implemented"); +} + + +static void +cstore_tuple_complete_speculative(Relation relation, TupleTableSlot *slot, + uint32 specToken, bool succeeded) +{ + elog(ERROR, "cstore_tuple_complete_speculative not implemented"); +} + + +static void +cstore_multi_insert(Relation relation, TupleTableSlot **slots, int ntuples, + CommandId cid, int options, BulkInsertState bistate) +{ + MemoryContext oldContext = MemoryContextSwitchTo(GetCStoreMemoryContext()); + + cstore_init_write_state(relation); + + for (int i = 0; i < ntuples; i++) + { + TupleTableSlot *tupleSlot = slots[i]; + HeapTuple heapTuple = ExecCopySlotHeapTuple(tupleSlot); + + if (HeapTupleHasExternal(heapTuple)) + { + /* detoast any toasted attributes */ + HeapTuple newTuple = toast_flatten_tuple(heapTuple, + tupleSlot->tts_tupleDescriptor); + + ExecForceStoreHeapTuple(newTuple, tupleSlot, true); + } + + slot_getallattrs(tupleSlot); + + CStoreWriteRow(CStoreWriteState, tupleSlot->tts_values, tupleSlot->tts_isnull); + } + MemoryContextSwitchTo(oldContext); +} + + +static TM_Result +cstore_tuple_delete(Relation relation, ItemPointer tid, CommandId cid, + Snapshot snapshot, Snapshot crosscheck, bool wait, + TM_FailureData *tmfd, bool changingPart) +{ + elog(ERROR, "cstore_tuple_delete not implemented"); +} + + +static TM_Result +cstore_tuple_update(Relation relation, ItemPointer otid, TupleTableSlot *slot, + CommandId cid, Snapshot snapshot, Snapshot crosscheck, + bool wait, TM_FailureData *tmfd, + LockTupleMode *lockmode, bool *update_indexes) +{ + elog(ERROR, "cstore_tuple_update not implemented"); +} + + +static TM_Result +cstore_tuple_lock(Relation relation, ItemPointer tid, Snapshot snapshot, + TupleTableSlot *slot, CommandId cid, LockTupleMode mode, + LockWaitPolicy wait_policy, uint8 flags, + TM_FailureData *tmfd) +{ + elog(ERROR, "cstore_tuple_lock not implemented"); +} + + +static void +cstore_finish_bulk_insert(Relation relation, int options) +{ + /*TODO: flush relation like for heap? */ + /* free write state or only in ExecutorEnd_hook? */ + + /* for COPY */ + cstore_free_write_state(); +} + + +static void +cstore_relation_set_new_filenode(Relation rel, + const RelFileNode *newrnode, + char persistence, + TransactionId *freezeXid, + MultiXactId *minmulti) +{ + SMgrRelation srel; + + Assert(persistence == RELPERSISTENCE_PERMANENT); + *freezeXid = RecentXmin; + *minmulti = GetOldestMultiXactId(); + srel = RelationCreateStorage(*newrnode, persistence); + InitializeCStoreTableFile(rel->rd_id, rel, CStoreTableAMGetOptions()); + smgrclose(srel); +} + + +static void +cstore_relation_nontransactional_truncate(Relation rel) +{ + elog(ERROR, "cstore_relation_nontransactional_truncate not implemented"); +} + + +static void +cstore_relation_copy_data(Relation rel, const RelFileNode *newrnode) +{ + elog(ERROR, "cstore_relation_copy_data not implemented"); +} + + +static void +cstore_relation_copy_for_cluster(Relation OldHeap, Relation NewHeap, + Relation OldIndex, bool use_sort, + TransactionId OldestXmin, + TransactionId *xid_cutoff, + MultiXactId *multi_cutoff, + double *num_tuples, + double *tups_vacuumed, + double *tups_recently_dead) +{ + elog(ERROR, "cstore_relation_copy_for_cluster not implemented"); +} + + +static bool +cstore_scan_analyze_next_block(TableScanDesc scan, BlockNumber blockno, + BufferAccessStrategy bstrategy) +{ + /* TODO */ + return false; +} + + +static bool +cstore_scan_analyze_next_tuple(TableScanDesc scan, TransactionId OldestXmin, + double *liverows, double *deadrows, + TupleTableSlot *slot) +{ + /* TODO */ + return false; +} + + +static double +cstore_index_build_range_scan(Relation heapRelation, + Relation indexRelation, + IndexInfo *indexInfo, + bool allow_sync, + bool anyvisible, + bool progress, + BlockNumber start_blockno, + BlockNumber numblocks, + IndexBuildCallback callback, + void *callback_state, + TableScanDesc scan) +{ + elog(ERROR, "cstore_index_build_range_scan not implemented"); +} + + +static void +cstore_index_validate_scan(Relation heapRelation, + Relation indexRelation, + IndexInfo *indexInfo, + Snapshot snapshot, + ValidateIndexState *state) +{ + elog(ERROR, "cstore_index_validate_scan not implemented"); +} + + +static uint64 +cstore_relation_size(Relation rel, ForkNumber forkNumber) +{ + uint64 nblocks = 0; + + /* Open it at the smgr level if not already done */ + RelationOpenSmgr(rel); + + /* InvalidForkNumber indicates returning the size for all forks */ + if (forkNumber == InvalidForkNumber) + { + for (int i = 0; i < MAX_FORKNUM; i++) + { + nblocks += smgrnblocks(rel->rd_smgr, i); + } + } + else + { + nblocks = smgrnblocks(rel->rd_smgr, forkNumber); + } + + return nblocks * BLCKSZ; +} + + +static bool +cstore_relation_needs_toast_table(Relation rel) +{ + return false; +} + + +static void +cstore_estimate_rel_size(Relation rel, int32 *attr_widths, + BlockNumber *pages, double *tuples, + double *allvisfrac) +{ + RelationOpenSmgr(rel); + *pages = smgrnblocks(rel->rd_smgr, MAIN_FORKNUM); + *tuples = CStoreTableRowCount(rel); + + /* + * Append-only, so everything is visible except in-progress or rolled-back + * transactions. + */ + *allvisfrac = 1.0; + + get_rel_data_width(rel, attr_widths); +} + + +static bool +cstore_scan_sample_next_block(TableScanDesc scan, SampleScanState *scanstate) +{ + elog(ERROR, "cstore_scan_sample_next_block not implemented"); +} + + +static bool +cstore_scan_sample_next_tuple(TableScanDesc scan, SampleScanState *scanstate, + TupleTableSlot *slot) +{ + elog(ERROR, "cstore_scan_sample_next_tuple not implemented"); +} + + +static void +CStoreExecutorEnd(QueryDesc *queryDesc) +{ + cstore_free_write_state(); + if (PreviousExecutorEndHook) + { + PreviousExecutorEndHook(queryDesc); + } + else + { + standard_ExecutorEnd(queryDesc); + } +} + + +void +cstore_tableam_init() +{ + PreviousExecutorEndHook = ExecutorEnd_hook; + ExecutorEnd_hook = CStoreExecutorEnd; +} + + +void +cstore_tableam_finish() +{ + ExecutorEnd_hook = PreviousExecutorEndHook; +} + + +static const TableAmRoutine cstore_am_methods = { + .type = T_TableAmRoutine, + + .slot_callbacks = cstore_slot_callbacks, + + .scan_begin = cstore_beginscan, + .scan_end = cstore_endscan, + .scan_rescan = cstore_rescan, + .scan_getnextslot = cstore_getnextslot, + + .parallelscan_estimate = cstore_parallelscan_estimate, + .parallelscan_initialize = cstore_parallelscan_initialize, + .parallelscan_reinitialize = cstore_parallelscan_reinitialize, + + .index_fetch_begin = cstore_index_fetch_begin, + .index_fetch_reset = cstore_index_fetch_reset, + .index_fetch_end = cstore_index_fetch_end, + .index_fetch_tuple = cstore_index_fetch_tuple, + + .tuple_fetch_row_version = cstore_fetch_row_version, + .tuple_get_latest_tid = cstore_get_latest_tid, + .tuple_tid_valid = cstore_tuple_tid_valid, + .tuple_satisfies_snapshot = cstore_tuple_satisfies_snapshot, + .compute_xid_horizon_for_tuples = cstore_compute_xid_horizon_for_tuples, + + .tuple_insert = cstore_tuple_insert, + .tuple_insert_speculative = cstore_tuple_insert_speculative, + .tuple_complete_speculative = cstore_tuple_complete_speculative, + .multi_insert = cstore_multi_insert, + .tuple_delete = cstore_tuple_delete, + .tuple_update = cstore_tuple_update, + .tuple_lock = cstore_tuple_lock, + .finish_bulk_insert = cstore_finish_bulk_insert, + + .relation_set_new_filenode = cstore_relation_set_new_filenode, + .relation_nontransactional_truncate = cstore_relation_nontransactional_truncate, + .relation_copy_data = cstore_relation_copy_data, + .relation_copy_for_cluster = cstore_relation_copy_for_cluster, + .relation_vacuum = heap_vacuum_rel, + .scan_analyze_next_block = cstore_scan_analyze_next_block, + .scan_analyze_next_tuple = cstore_scan_analyze_next_tuple, + .index_build_range_scan = cstore_index_build_range_scan, + .index_validate_scan = cstore_index_validate_scan, + + .relation_size = cstore_relation_size, + .relation_needs_toast_table = cstore_relation_needs_toast_table, + + .relation_estimate_size = cstore_estimate_rel_size, + + .scan_bitmap_next_block = NULL, + .scan_bitmap_next_tuple = NULL, + .scan_sample_next_block = cstore_scan_sample_next_block, + .scan_sample_next_tuple = cstore_scan_sample_next_tuple +}; + + +const TableAmRoutine * +GetCstoreTableAmRoutine(void) +{ + return &cstore_am_methods; +} + + +PG_FUNCTION_INFO_V1(cstore_tableam_handler); +Datum +cstore_tableam_handler(PG_FUNCTION_ARGS) +{ + PG_RETURN_POINTER(&cstore_am_methods); +} diff --git a/cstore_tableam.h b/cstore_tableam.h new file mode 100644 index 000000000..bdf7f96c0 --- /dev/null +++ b/cstore_tableam.h @@ -0,0 +1,7 @@ +#include "postgres.h" +#include "fmgr.h" +#include "access/tableam.h" + +const TableAmRoutine * GetCstoreTableAmRoutine(void); +extern void cstore_tableam_init(void); +extern void cstore_tableam_finish(void); diff --git a/expected/am_alter.out b/expected/am_alter.out new file mode 100644 index 000000000..bd0737b4b --- /dev/null +++ b/expected/am_alter.out @@ -0,0 +1,177 @@ +-- +-- Testing ALTER TABLE on cstore_fdw tables. +-- +CREATE TABLE test_alter_table (a int, b int, c int) USING cstore_tableam; +WITH sample_data AS (VALUES + (1, 2, 3), + (4, 5, 6), + (7, 8, 9) +) +INSERT INTO test_alter_table SELECT * FROM sample_data; +-- drop a column +ALTER TABLE test_alter_table DROP COLUMN a; +-- test analyze +ANALYZE test_alter_table; +-- verify select queries run as expected +SELECT * FROM test_alter_table; + b | c +---+--- + 2 | 3 + 5 | 6 + 8 | 9 +(3 rows) + +SELECT a FROM test_alter_table; +ERROR: column "a" does not exist +LINE 1: SELECT a FROM test_alter_table; + ^ +SELECT b FROM test_alter_table; + b +--- + 2 + 5 + 8 +(3 rows) + +-- verify insert runs as expected +INSERT INTO test_alter_table (SELECT 3, 5, 8); +ERROR: INSERT has more expressions than target columns +LINE 1: INSERT INTO test_alter_table (SELECT 3, 5, 8); + ^ +INSERT INTO test_alter_table (SELECT 5, 8); +-- add a column with no defaults +ALTER TABLE test_alter_table ADD COLUMN d int; +SELECT * FROM test_alter_table; + b | c | d +---+---+--- + 2 | 3 | + 5 | 6 | + 8 | 9 | + 5 | 8 | +(4 rows) + +INSERT INTO test_alter_table (SELECT 3, 5, 8); +SELECT * FROM test_alter_table; + b | c | d +---+---+--- + 2 | 3 | + 5 | 6 | + 8 | 9 | + 5 | 8 | + 3 | 5 | 8 +(5 rows) + +-- add a fixed-length column with default value +ALTER TABLE test_alter_table ADD COLUMN e int default 3; +SELECT * from test_alter_table; + b | c | d | e +---+---+---+--- + 2 | 3 | | 3 + 5 | 6 | | 3 + 8 | 9 | | 3 + 5 | 8 | | 3 + 3 | 5 | 8 | 3 +(5 rows) + +INSERT INTO test_alter_table (SELECT 1, 2, 4, 8); +SELECT * from test_alter_table; + b | c | d | e +---+---+---+--- + 2 | 3 | | 3 + 5 | 6 | | 3 + 8 | 9 | | 3 + 5 | 8 | | 3 + 3 | 5 | 8 | 3 + 1 | 2 | 4 | 8 +(6 rows) + +-- add a variable-length column with default value +ALTER TABLE test_alter_table ADD COLUMN f text DEFAULT 'TEXT ME'; +SELECT * from test_alter_table; + b | c | d | e | f +---+---+---+---+--------- + 2 | 3 | | 3 | TEXT ME + 5 | 6 | | 3 | TEXT ME + 8 | 9 | | 3 | TEXT ME + 5 | 8 | | 3 | TEXT ME + 3 | 5 | 8 | 3 | TEXT ME + 1 | 2 | 4 | 8 | TEXT ME +(6 rows) + +INSERT INTO test_alter_table (SELECT 1, 2, 4, 8, 'ABCDEF'); +SELECT * from test_alter_table; + b | c | d | e | f +---+---+---+---+--------- + 2 | 3 | | 3 | TEXT ME + 5 | 6 | | 3 | TEXT ME + 8 | 9 | | 3 | TEXT ME + 5 | 8 | | 3 | TEXT ME + 3 | 5 | 8 | 3 | TEXT ME + 1 | 2 | 4 | 8 | TEXT ME + 1 | 2 | 4 | 8 | ABCDEF +(7 rows) + +-- drop couple of columns +ALTER TABLE test_alter_table DROP COLUMN c; +ALTER TABLE test_alter_table DROP COLUMN e; +ANALYZE test_alter_table; +SELECT * from test_alter_table; + b | d | f +---+---+--------- + 2 | | TEXT ME + 5 | | TEXT ME + 8 | | TEXT ME + 5 | | TEXT ME + 3 | 8 | TEXT ME + 1 | 4 | TEXT ME + 1 | 4 | ABCDEF +(7 rows) + +SELECT count(*) from test_alter_table; + count +------- + 7 +(1 row) + +SELECT count(t.*) from test_alter_table t; + count +------- + 7 +(1 row) + +-- unsupported default values +ALTER TABLE test_alter_table ADD COLUMN g boolean DEFAULT isfinite(current_date); +ALTER TABLE test_alter_table ADD COLUMN h DATE DEFAULT current_date; +SELECT * FROM test_alter_table; +ERROR: unsupported default value for column "g" +HINT: Expression is either mutable or does not evaluate to constant value +ALTER TABLE test_alter_table ALTER COLUMN g DROP DEFAULT; +SELECT * FROM test_alter_table; +ERROR: unsupported default value for column "h" +HINT: Expression is either mutable or does not evaluate to constant value +ALTER TABLE test_alter_table ALTER COLUMN h DROP DEFAULT; +ANALYZE test_alter_table; +SELECT * FROM test_alter_table; + b | d | f | g | h +---+---+---------+---+--- + 2 | | TEXT ME | | + 5 | | TEXT ME | | + 8 | | TEXT ME | | + 5 | | TEXT ME | | + 3 | 8 | TEXT ME | | + 1 | 4 | TEXT ME | | + 1 | 4 | ABCDEF | | +(7 rows) + +-- unsupported type change +ALTER TABLE test_alter_table ADD COLUMN i int; +ALTER TABLE test_alter_table ADD COLUMN j float; +ALTER TABLE test_alter_table ADD COLUMN k text; +-- this is valid type change +ALTER TABLE test_alter_table ALTER COLUMN i TYPE float; +-- this is not valid +ALTER TABLE test_alter_table ALTER COLUMN j TYPE int; +-- text / varchar conversion is valid both ways +ALTER TABLE test_alter_table ALTER COLUMN k TYPE varchar(20); +ALTER TABLE test_alter_table ALTER COLUMN k TYPE text; +DROP TABLE test_alter_table; diff --git a/expected/am_analyze.out b/expected/am_analyze.out new file mode 100644 index 000000000..f8c4d974a --- /dev/null +++ b/expected/am_analyze.out @@ -0,0 +1,19 @@ +-- +-- Test the ANALYZE command for cstore_fdw tables. +-- +-- ANALYZE uncompressed table +ANALYZE contestant; +SELECT count(*) FROM pg_stats WHERE tablename='contestant'; + count +------- + 6 +(1 row) + +-- ANALYZE compressed table +ANALYZE contestant_compressed; +SELECT count(*) FROM pg_stats WHERE tablename='contestant_compressed'; + count +------- + 6 +(1 row) + diff --git a/expected/am_block_filtering.out b/expected/am_block_filtering.out new file mode 100644 index 000000000..005b42e64 --- /dev/null +++ b/expected/am_block_filtering.out @@ -0,0 +1,120 @@ +-- +-- Test block filtering in cstore_fdw using min/max values in stripe skip lists. +-- +-- +-- filtered_row_count returns number of rows filtered by the WHERE clause. +-- If blocks get filtered by cstore_fdw, less rows are passed to WHERE +-- clause, so this function should return a lower number. +-- +CREATE OR REPLACE FUNCTION filtered_row_count (query text) RETURNS bigint AS +$$ + DECLARE + result bigint; + rec text; + BEGIN + result := 0; + + FOR rec IN EXECUTE 'EXPLAIN ANALYZE ' || query LOOP + IF rec ~ '^\s+Rows Removed by Filter' then + result := regexp_replace(rec, '[^0-9]*', '', 'g'); + END IF; + END LOOP; + + RETURN result; + END; +$$ LANGUAGE PLPGSQL; +-- Create and load data +-- block_row_count '1000', stripe_row_count '2000' +set cstore.stripe_row_count = 2000; +set cstore.block_row_count = 1000; +CREATE TABLE test_block_filtering (a int) + USING cstore_tableam; +COPY test_block_filtering FROM '/Users/jefdavi/wd/cstore2/data/block_filtering.csv' WITH CSV; +-- Verify that filtered_row_count is less than 1000 for the following queries +SELECT filtered_row_count('SELECT count(*) FROM test_block_filtering'); + filtered_row_count +-------------------- + 0 +(1 row) + +SELECT filtered_row_count('SELECT count(*) FROM test_block_filtering WHERE a < 200'); + filtered_row_count +-------------------- + 801 +(1 row) + +SELECT filtered_row_count('SELECT count(*) FROM test_block_filtering WHERE a > 200'); + filtered_row_count +-------------------- + 200 +(1 row) + +SELECT filtered_row_count('SELECT count(*) FROM test_block_filtering WHERE a < 9900'); + filtered_row_count +-------------------- + 101 +(1 row) + +SELECT filtered_row_count('SELECT count(*) FROM test_block_filtering WHERE a > 9900'); + filtered_row_count +-------------------- + 900 +(1 row) + +SELECT filtered_row_count('SELECT count(*) FROM test_block_filtering WHERE a < 0'); + filtered_row_count +-------------------- + 0 +(1 row) + +-- Verify that filtered_row_count is less than 2000 for the following queries +SELECT filtered_row_count('SELECT count(*) FROM test_block_filtering WHERE a BETWEEN 1 AND 10'); + filtered_row_count +-------------------- + 990 +(1 row) + +SELECT filtered_row_count('SELECT count(*) FROM test_block_filtering WHERE a BETWEEN 990 AND 2010'); + filtered_row_count +-------------------- + 1979 +(1 row) + +SELECT filtered_row_count('SELECT count(*) FROM test_block_filtering WHERE a BETWEEN -10 AND 0'); + filtered_row_count +-------------------- + 0 +(1 row) + +-- Load data for second time and verify that filtered_row_count is exactly twice as before +COPY test_block_filtering FROM '/Users/jefdavi/wd/cstore2/data/block_filtering.csv' WITH CSV; +SELECT filtered_row_count('SELECT count(*) FROM test_block_filtering WHERE a < 200'); + filtered_row_count +-------------------- + 1602 +(1 row) + +SELECT filtered_row_count('SELECT count(*) FROM test_block_filtering WHERE a < 0'); + filtered_row_count +-------------------- + 0 +(1 row) + +SELECT filtered_row_count('SELECT count(*) FROM test_block_filtering WHERE a BETWEEN 990 AND 2010'); + filtered_row_count +-------------------- + 3958 +(1 row) + +set cstore.stripe_row_count to default; +set cstore.block_row_count to default; +-- Verify that we are fine with collations which use a different alphabet order +CREATE TABLE collation_block_filtering_test(A text collate "da_DK") + USING cstore_tableam; +COPY collation_block_filtering_test FROM STDIN; +SELECT * FROM collation_block_filtering_test WHERE A > 'B'; + a +--- + Å +(1 row) + diff --git a/expected/am_clean.out b/expected/am_clean.out new file mode 100644 index 000000000..2c1e82ee6 --- /dev/null +++ b/expected/am_clean.out @@ -0,0 +1,8 @@ +DROP TABLE test_null_values; +DROP TABLE test_other_types; +DROP TABLE test_range_types; +DROP TABLE test_enum_and_composite_types; +DROP TYPE composite_type; +DROP TYPE enum_type; +DROP TABLE test_datetime_types; +DROP TABLE test_array_types; diff --git a/expected/am_copyto.out b/expected/am_copyto.out new file mode 100644 index 000000000..c8a5f676b --- /dev/null +++ b/expected/am_copyto.out @@ -0,0 +1,23 @@ +-- +-- Test copying data from cstore_fdw tables. +-- +CREATE TABLE test_contestant(handle TEXT, birthdate DATE, rating INT, + percentile FLOAT, country CHAR(3), achievements TEXT[]) + USING cstore_tableam; +-- load table data from file +COPY test_contestant FROM '/Users/jefdavi/wd/cstore2/data/contestants.1.csv' WITH CSV; +-- export using COPY table TO ... +COPY test_contestant TO STDOUT; +a 01-10-1990 2090 97.1 XA {a} +b 11-01-1990 2203 98.1 XA {a,b} +c 11-01-1988 2907 99.4 XB {w,y} +d 05-05-1985 2314 98.3 XB {} +e 05-05-1995 2236 98.2 XC {a} +-- export using COPY (SELECT * FROM table) TO ... +COPY (select * from test_contestant) TO STDOUT; +a 01-10-1990 2090 97.1 XA {a} +b 11-01-1990 2203 98.1 XA {a,b} +c 11-01-1988 2907 99.4 XB {w,y} +d 05-05-1985 2314 98.3 XB {} +e 05-05-1995 2236 98.2 XC {a} +DROP TABLE test_contestant CASCADE; diff --git a/expected/am_create.out b/expected/am_create.out new file mode 100644 index 000000000..47c6a6c44 --- /dev/null +++ b/expected/am_create.out @@ -0,0 +1,20 @@ +-- +-- Test the CREATE statements related to cstore. +-- +-- Create uncompressed table +CREATE TABLE contestant (handle TEXT, birthdate DATE, rating INT, + percentile FLOAT, country CHAR(3), achievements TEXT[]) + USING cstore_tableam; +-- Create compressed table with automatically determined file path +-- COMPRESSED +CREATE TABLE contestant_compressed (handle TEXT, birthdate DATE, rating INT, + percentile FLOAT, country CHAR(3), achievements TEXT[]) + USING cstore_tableam; +-- Test that querying an empty table works +ANALYZE contestant; +SELECT count(*) FROM contestant; + count +------- + 0 +(1 row) + diff --git a/expected/am_data_types.out b/expected/am_data_types.out new file mode 100644 index 000000000..a597ff8de --- /dev/null +++ b/expected/am_data_types.out @@ -0,0 +1,78 @@ +-- +-- Test loading and reading different data types to/from cstore_fdw foreign tables. +-- +-- Settings to make the result deterministic +SET datestyle = "ISO, YMD"; +SET timezone to 'GMT'; +SET intervalstyle TO 'POSTGRES_VERBOSE'; +-- Test array types +CREATE TABLE test_array_types (int_array int[], bigint_array bigint[], + text_array text[]) USING cstore_tableam; +COPY test_array_types FROM '/Users/jefdavi/wd/cstore2/data/array_types.csv' WITH CSV; +SELECT * FROM test_array_types; + int_array | bigint_array | text_array +--------------------------+--------------------------------------------+------------ + {1,2,3} | {1,2,3} | {a,b,c} + {} | {} | {} + {-2147483648,2147483647} | {-9223372036854775808,9223372036854775807} | {""} +(3 rows) + +-- Test date/time types +CREATE TABLE test_datetime_types (timestamp timestamp, + timestamp_with_timezone timestamp with time zone, date date, time time, + interval interval) USING cstore_tableam; +COPY test_datetime_types FROM '/Users/jefdavi/wd/cstore2/data/datetime_types.csv' WITH CSV; +SELECT * FROM test_datetime_types; + timestamp | timestamp_with_timezone | date | time | interval +---------------------+-------------------------+------------+----------+----------- + 2000-01-02 04:05:06 | 1999-01-08 12:05:06+00 | 2000-01-02 | 04:05:06 | @ 4 hours + 1970-01-01 00:00:00 | infinity | -infinity | 00:00:00 | @ 0 +(2 rows) + +-- Test enum and composite types +CREATE TYPE enum_type AS ENUM ('a', 'b', 'c'); +CREATE TYPE composite_type AS (a int, b text); +CREATE TABLE test_enum_and_composite_types (enum enum_type, + composite composite_type) USING cstore_tableam; +COPY test_enum_and_composite_types FROM + '/Users/jefdavi/wd/cstore2/data/enum_and_composite_types.csv' WITH CSV; +SELECT * FROM test_enum_and_composite_types; + enum | composite +------+----------- + a | (2,b) + b | (3,c) +(2 rows) + +-- Test range types +CREATE TABLE test_range_types (int4range int4range, int8range int8range, + numrange numrange, tsrange tsrange) USING cstore_tableam; +COPY test_range_types FROM '/Users/jefdavi/wd/cstore2/data/range_types.csv' WITH CSV; +SELECT * FROM test_range_types; + int4range | int8range | numrange | tsrange +-----------+-----------+----------+----------------------------------------------- + [1,3) | [1,3) | [1,3) | ["2000-01-02 00:30:00","2010-02-03 12:30:00") + empty | [1,) | (,) | empty +(2 rows) + +-- Test other types +CREATE TABLE test_other_types (bool boolean, bytea bytea, money money, + inet inet, bitstring bit varying(5), uuid uuid, json json) USING cstore_tableam; +COPY test_other_types FROM '/Users/jefdavi/wd/cstore2/data/other_types.csv' WITH CSV; +SELECT * FROM test_other_types; + bool | bytea | money | inet | bitstring | uuid | json +------+------------+-------+-------------+-----------+--------------------------------------+------------------ + f | \xdeadbeef | $1.00 | 192.168.1.2 | 10101 | a0eebc99-9c0b-4ef8-bb6d-6bb9bd380a11 | {"key": "value"} + t | \xcdb0 | $1.50 | 127.0.0.1 | | a0eebc99-9c0b-4ef8-bb6d-6bb9bd380a11 | [] +(2 rows) + +-- Test null values +CREATE TABLE test_null_values (a int, b int[], c composite_type) + USING cstore_tableam; +COPY test_null_values FROM '/Users/jefdavi/wd/cstore2/data/null_values.csv' WITH CSV; +SELECT * FROM test_null_values; + a | b | c +---+--------+----- + | {NULL} | (,) + | | +(2 rows) + diff --git a/expected/am_drop.out b/expected/am_drop.out new file mode 100644 index 000000000..e1c634d7f --- /dev/null +++ b/expected/am_drop.out @@ -0,0 +1,36 @@ +-- +-- Tests the different DROP commands for cstore_fdw tables. +-- +-- DROP TABL +-- DROP SCHEMA +-- DROP EXTENSION +-- DROP DATABASE +-- +-- Note that travis does not create +-- cstore_fdw extension in default database (postgres). This has caused +-- different behavior between travis tests and local tests. Thus +-- 'postgres' directory is excluded from comparison to have the same result. +-- store postgres database oid +SELECT oid postgres_oid FROM pg_database WHERE datname = 'postgres' \gset +-- DROP cstore_fdw tables +DROP TABLE contestant; +DROP TABLE contestant_compressed; +-- Create a cstore_fdw table under a schema and drop it. +CREATE SCHEMA test_schema; +CREATE TABLE test_schema.test_table(data int) USING cstore_tableam; +DROP SCHEMA test_schema CASCADE; +NOTICE: drop cascades to table test_schema.test_table +SELECT current_database() datname \gset +CREATE DATABASE db_to_drop; +\c db_to_drop +CREATE EXTENSION cstore_fdw; +SELECT oid::text databaseoid FROM pg_database WHERE datname = current_database() \gset +CREATE TABLE test_table(data int) USING cstore_tableam; +DROP EXTENSION cstore_fdw CASCADE; +NOTICE: drop cascades to table test_table +-- test database drop +CREATE EXTENSION cstore_fdw; +SELECT oid::text databaseoid FROM pg_database WHERE datname = current_database() \gset +CREATE TABLE test_table(data int) USING cstore_tableam; +\c :datname +DROP DATABASE db_to_drop; diff --git a/expected/am_functions.out b/expected/am_functions.out new file mode 100644 index 000000000..6351ba0bf --- /dev/null +++ b/expected/am_functions.out @@ -0,0 +1,18 @@ +-- +-- Test utility functions for cstore_fdw tables. +-- +CREATE TABLE empty_table (a int) USING cstore_tableam; +CREATE TABLE table_with_data (a int) USING cstore_tableam; +CREATE TABLE non_cstore_table (a int); +COPY table_with_data FROM STDIN; +SELECT pg_relation_size('empty_table') < pg_relation_size('table_with_data'); + ?column? +---------- + t +(1 row) + +SELECT cstore_table_size('non_cstore_table'); +ERROR: relation is not a cstore table +DROP TABLE empty_table; +DROP TABLE table_with_data; +DROP TABLE non_cstore_table; diff --git a/expected/am_insert.out b/expected/am_insert.out new file mode 100644 index 000000000..8d06d4323 --- /dev/null +++ b/expected/am_insert.out @@ -0,0 +1,86 @@ +-- +-- Testing insert on cstore_fdw tables. +-- +CREATE TABLE test_insert_command (a int) USING cstore_tableam; +-- test single row inserts fail +select count(*) from test_insert_command; + count +------- + 0 +(1 row) + +insert into test_insert_command values(1); +select count(*) from test_insert_command; + count +------- + 1 +(1 row) + +insert into test_insert_command default values; +select count(*) from test_insert_command; + count +------- + 2 +(1 row) + +-- test inserting from another table succeed +CREATE TABLE test_insert_command_data (a int); +select count(*) from test_insert_command_data; + count +------- + 0 +(1 row) + +insert into test_insert_command_data values(1); +select count(*) from test_insert_command_data; + count +------- + 1 +(1 row) + +insert into test_insert_command select * from test_insert_command_data; +select count(*) from test_insert_command; + count +------- + 3 +(1 row) + +drop table test_insert_command_data; +drop table test_insert_command; +-- test long attribute value insertion +-- create sufficiently long text so that data is stored in toast +CREATE TABLE test_long_text AS +SELECT a as int_val, string_agg(random()::text, '') as text_val +FROM generate_series(1, 10) a, generate_series(1, 1000) b +GROUP BY a ORDER BY a; +-- store hash values of text for later comparison +CREATE TABLE test_long_text_hash AS +SELECT int_val, md5(text_val) AS hash +FROM test_long_text; +CREATE TABLE test_cstore_long_text(int_val int, text_val text) +USING cstore_tableam; +-- store long text in cstore table +INSERT INTO test_cstore_long_text SELECT * FROM test_long_text; +-- drop source table to remove original text from toast +DROP TABLE test_long_text; +-- check if text data is still available in cstore table +-- by comparing previously stored hash. +SELECT a.int_val +FROM test_long_text_hash a, test_cstore_long_text c +WHERE a.int_val = c.int_val AND a.hash = md5(c.text_val); + int_val +--------- + 1 + 2 + 3 + 4 + 5 + 6 + 7 + 8 + 9 + 10 +(10 rows) + +DROP TABLE test_long_text_hash; +DROP TABLE test_cstore_long_text; diff --git a/expected/am_load.out b/expected/am_load.out new file mode 100644 index 000000000..02cff343a --- /dev/null +++ b/expected/am_load.out @@ -0,0 +1,42 @@ +-- +-- Test loading data into cstore_fdw tables. +-- +-- COPY with incorrect delimiter +COPY contestant FROM '/Users/jefdavi/wd/cstore2/data/contestants.1.csv' + WITH DELIMITER '|'; -- ERROR +ERROR: missing data for column "birthdate" +CONTEXT: COPY contestant, line 1: "a,1990-01-10,2090,97.1,XA ,{a}" +-- COPY with invalid program +COPY contestant FROM PROGRAM 'invalid_program' WITH CSV; -- ERROR +ERROR: program "invalid_program" failed +DETAIL: command not found +-- COPY into uncompressed table from file +COPY contestant FROM '/Users/jefdavi/wd/cstore2/data/contestants.1.csv' WITH CSV; +-- COPY into uncompressed table from program +COPY contestant FROM PROGRAM 'cat /Users/jefdavi/wd/cstore2/data/contestants.2.csv' WITH CSV; +-- COPY into compressed table +set cstore.compression = 'pglz'; +COPY contestant_compressed FROM '/Users/jefdavi/wd/cstore2/data/contestants.1.csv' WITH CSV; +-- COPY into uncompressed table from program +COPY contestant_compressed FROM PROGRAM 'cat /Users/jefdavi/wd/cstore2/data/contestants.2.csv' + WITH CSV; +set cstore.compression to default; +-- Test column list +CREATE TABLE famous_constants (id int, name text, value real) + USING cstore_tableam; +COPY famous_constants (value, name, id) FROM STDIN WITH CSV; +COPY famous_constants (name, value) FROM STDIN WITH CSV; +SELECT * FROM famous_constants ORDER BY id, name; + id | name | value +----+----------------+----------- + 1 | pi | 3.141 + 2 | e | 2.718 + 3 | gamma | 0.577 + 4 | bohr radius | 5.291e-11 + | avagadro | 6.022e+23 + | electron mass | 9.109e-31 + | proton mass | 1.672e-27 + | speed of light | 2.997e+08 +(8 rows) + +DROP TABLE famous_constants; diff --git a/expected/am_query.out b/expected/am_query.out new file mode 100644 index 000000000..2f0ff6cc7 --- /dev/null +++ b/expected/am_query.out @@ -0,0 +1,105 @@ +-- +-- Test querying cstore_fdw tables. +-- +-- Settings to make the result deterministic +SET datestyle = "ISO, YMD"; +-- Query uncompressed data +SELECT count(*) FROM contestant; + count +------- + 8 +(1 row) + +SELECT avg(rating), stddev_samp(rating) FROM contestant; + avg | stddev_samp +-----------------------+------------------ + 2344.3750000000000000 | 433.746119785032 +(1 row) + +SELECT country, avg(rating) FROM contestant WHERE rating > 2200 + GROUP BY country ORDER BY country; + country | avg +---------+----------------------- + XA | 2203.0000000000000000 + XB | 2610.5000000000000000 + XC | 2236.0000000000000000 + XD | 3090.0000000000000000 +(4 rows) + +SELECT * FROM contestant ORDER BY handle; + handle | birthdate | rating | percentile | country | achievements +--------+------------+--------+------------+---------+-------------- + a | 1990-01-10 | 2090 | 97.1 | XA | {a} + b | 1990-11-01 | 2203 | 98.1 | XA | {a,b} + c | 1988-11-01 | 2907 | 99.4 | XB | {w,y} + d | 1985-05-05 | 2314 | 98.3 | XB | {} + e | 1995-05-05 | 2236 | 98.2 | XC | {a} + f | 1983-04-02 | 3090 | 99.6 | XD | {a,b,c,y} + g | 1991-12-13 | 1803 | 85.1 | XD | {a,c} + h | 1987-10-26 | 2112 | 95.4 | XD | {w,a} +(8 rows) + +-- Query compressed data +SELECT count(*) FROM contestant_compressed; + count +------- + 8 +(1 row) + +SELECT avg(rating), stddev_samp(rating) FROM contestant_compressed; + avg | stddev_samp +-----------------------+------------------ + 2344.3750000000000000 | 433.746119785032 +(1 row) + +SELECT country, avg(rating) FROM contestant_compressed WHERE rating > 2200 + GROUP BY country ORDER BY country; + country | avg +---------+----------------------- + XA | 2203.0000000000000000 + XB | 2610.5000000000000000 + XC | 2236.0000000000000000 + XD | 3090.0000000000000000 +(4 rows) + +SELECT * FROM contestant_compressed ORDER BY handle; + handle | birthdate | rating | percentile | country | achievements +--------+------------+--------+------------+---------+-------------- + a | 1990-01-10 | 2090 | 97.1 | XA | {a} + b | 1990-11-01 | 2203 | 98.1 | XA | {a,b} + c | 1988-11-01 | 2907 | 99.4 | XB | {w,y} + d | 1985-05-05 | 2314 | 98.3 | XB | {} + e | 1995-05-05 | 2236 | 98.2 | XC | {a} + f | 1983-04-02 | 3090 | 99.6 | XD | {a,b,c,y} + g | 1991-12-13 | 1803 | 85.1 | XD | {a,c} + h | 1987-10-26 | 2112 | 95.4 | XD | {w,a} +(8 rows) + +-- Verify that we handle whole-row references correctly +SELECT to_json(v) FROM contestant v ORDER BY rating LIMIT 1; + to_json +------------------------------------------------------------------------------------------------------------------ + {"handle":"g","birthdate":"1991-12-13","rating":1803,"percentile":85.1,"country":"XD ","achievements":["a","c"]} +(1 row) + +-- Test variables used in expressions +CREATE TABLE union_first (a int, b int) USING cstore_tableam; +CREATE TABLE union_second (a int, b int) USING cstore_tableam; +INSERT INTO union_first SELECT a, a FROM generate_series(1, 5) a; +INSERT INTO union_second SELECT a, a FROM generate_series(11, 15) a; +(SELECT a*1, b FROM union_first) union all (SELECT a*1, b FROM union_second); + ?column? | b +----------+---- + 1 | 1 + 2 | 2 + 3 | 3 + 4 | 4 + 5 | 5 + 11 | 11 + 12 | 12 + 13 | 13 + 14 | 14 + 15 | 15 +(10 rows) + +DROP TABLE union_first, union_second; diff --git a/expected/am_truncate.out b/expected/am_truncate.out new file mode 100644 index 000000000..99db7fe72 --- /dev/null +++ b/expected/am_truncate.out @@ -0,0 +1,239 @@ +-- +-- Test the TRUNCATE TABLE command for cstore_fdw tables. +-- +-- print whether we're using version > 10 to make version-specific tests clear +SHOW server_version \gset +SELECT substring(:'server_version', '\d+')::int > 10 AS version_above_ten; + version_above_ten +------------------- + t +(1 row) + +-- CREATE a cstore_fdw table, fill with some data -- +CREATE TABLE cstore_truncate_test (a int, b int) USING cstore_tableam; +CREATE TABLE cstore_truncate_test_second (a int, b int) USING cstore_tableam; +-- COMPRESSED +CREATE TABLE cstore_truncate_test_compressed (a int, b int) USING cstore_tableam; +CREATE TABLE cstore_truncate_test_regular (a int, b int); +INSERT INTO cstore_truncate_test select a, a from generate_series(1, 10) a; +set cstore.compression = 'pglz'; +INSERT INTO cstore_truncate_test_compressed select a, a from generate_series(1, 10) a; +INSERT INTO cstore_truncate_test_compressed select a, a from generate_series(1, 10) a; +set cstore.compression to default; +-- query rows +SELECT * FROM cstore_truncate_test; + a | b +----+---- + 1 | 1 + 2 | 2 + 3 | 3 + 4 | 4 + 5 | 5 + 6 | 6 + 7 | 7 + 8 | 8 + 9 | 9 + 10 | 10 +(10 rows) + +TRUNCATE TABLE cstore_truncate_test; +SELECT * FROM cstore_truncate_test; + a | b +---+--- +(0 rows) + +SELECT COUNT(*) from cstore_truncate_test; + count +------- + 0 +(1 row) + +SELECT count(*) FROM cstore_truncate_test_compressed; + count +------- + 20 +(1 row) + +TRUNCATE TABLE cstore_truncate_test_compressed; +SELECT count(*) FROM cstore_truncate_test_compressed; + count +------- + 0 +(1 row) + +SELECT pg_relation_size('cstore_truncate_test_compressed'); + pg_relation_size +------------------ + 0 +(1 row) + +INSERT INTO cstore_truncate_test select a, a from generate_series(1, 10) a; +INSERT INTO cstore_truncate_test_regular select a, a from generate_series(10, 20) a; +INSERT INTO cstore_truncate_test_second select a, a from generate_series(20, 30) a; +SELECT * from cstore_truncate_test; + a | b +----+---- + 1 | 1 + 2 | 2 + 3 | 3 + 4 | 4 + 5 | 5 + 6 | 6 + 7 | 7 + 8 | 8 + 9 | 9 + 10 | 10 +(10 rows) + +SELECT * from cstore_truncate_test_second; + a | b +----+---- + 20 | 20 + 21 | 21 + 22 | 22 + 23 | 23 + 24 | 24 + 25 | 25 + 26 | 26 + 27 | 27 + 28 | 28 + 29 | 29 + 30 | 30 +(11 rows) + +SELECT * from cstore_truncate_test_regular; + a | b +----+---- + 10 | 10 + 11 | 11 + 12 | 12 + 13 | 13 + 14 | 14 + 15 | 15 + 16 | 16 + 17 | 17 + 18 | 18 + 19 | 19 + 20 | 20 +(11 rows) + +-- make sure multi truncate works +-- notice that the same table might be repeated +TRUNCATE TABLE cstore_truncate_test, + cstore_truncate_test_regular, + cstore_truncate_test_second, + cstore_truncate_test; +SELECT * from cstore_truncate_test; + a | b +---+--- +(0 rows) + +SELECT * from cstore_truncate_test_second; + a | b +---+--- +(0 rows) + +SELECT * from cstore_truncate_test_regular; + a | b +---+--- +(0 rows) + +-- test if truncate on empty table works +TRUNCATE TABLE cstore_truncate_test; +SELECT * from cstore_truncate_test; + a | b +---+--- +(0 rows) + +-- test if a cached truncate from a pl/pgsql function works +CREATE FUNCTION cstore_truncate_test_regular_func() RETURNS void AS $$ +BEGIN + INSERT INTO cstore_truncate_test_regular select a, a from generate_series(1, 10) a; + TRUNCATE TABLE cstore_truncate_test_regular; +END;$$ +LANGUAGE plpgsql; +SELECT cstore_truncate_test_regular_func(); + cstore_truncate_test_regular_func +----------------------------------- + +(1 row) + +-- the cached plans are used stating from the second call +SELECT cstore_truncate_test_regular_func(); + cstore_truncate_test_regular_func +----------------------------------- + +(1 row) + +DROP FUNCTION cstore_truncate_test_regular_func(); +DROP TABLE cstore_truncate_test, cstore_truncate_test_second; +DROP TABLE cstore_truncate_test_regular; +DROP TABLE cstore_truncate_test_compressed; +-- test truncate with schema +CREATE SCHEMA truncate_schema; +-- COMPRESSED +CREATE TABLE truncate_schema.truncate_tbl (id int) USING cstore_tableam; +set cstore.compression = 'pglz'; +INSERT INTO truncate_schema.truncate_tbl SELECT generate_series(1, 100); +set cstore.compression to default; +SELECT COUNT(*) FROM truncate_schema.truncate_tbl; + count +------- + 100 +(1 row) + +TRUNCATE TABLE truncate_schema.truncate_tbl; +SELECT COUNT(*) FROM truncate_schema.truncate_tbl; + count +------- + 0 +(1 row) + +set cstore.compression = 'pglz'; +INSERT INTO truncate_schema.truncate_tbl SELECT generate_series(1, 100); +set cstore.compression to default; +-- create a user that can not truncate +CREATE USER truncate_user; +GRANT USAGE ON SCHEMA truncate_schema TO truncate_user; +GRANT SELECT ON TABLE truncate_schema.truncate_tbl TO truncate_user; +REVOKE TRUNCATE ON TABLE truncate_schema.truncate_tbl FROM truncate_user; +SELECT current_user \gset +\c - truncate_user +-- verify truncate command fails and check number of rows +SELECT count(*) FROM truncate_schema.truncate_tbl; + count +------- + 100 +(1 row) + +TRUNCATE TABLE truncate_schema.truncate_tbl; +ERROR: permission denied for table truncate_tbl +SELECT count(*) FROM truncate_schema.truncate_tbl; + count +------- + 100 +(1 row) + +-- switch to super user, grant truncate to truncate_user +\c - :current_user +GRANT TRUNCATE ON TABLE truncate_schema.truncate_tbl TO truncate_user; +-- verify truncate_user can truncate now +\c - truncate_user +SELECT count(*) FROM truncate_schema.truncate_tbl; + count +------- + 100 +(1 row) + +TRUNCATE TABLE truncate_schema.truncate_tbl; +SELECT count(*) FROM truncate_schema.truncate_tbl; + count +------- + 0 +(1 row) + +\c - :current_user +-- cleanup +DROP SCHEMA truncate_schema CASCADE; +NOTICE: drop cascades to table truncate_schema.truncate_tbl +DROP USER truncate_user; diff --git a/expected/am_truncate_0.out b/expected/am_truncate_0.out new file mode 100644 index 000000000..c8cc4ad98 --- /dev/null +++ b/expected/am_truncate_0.out @@ -0,0 +1,262 @@ +-- +-- Test the TRUNCATE TABLE command for cstore_fdw tables. +-- +-- print whether we're using version > 10 to make version-specific tests clear +SHOW server_version \gset +SELECT substring(:'server_version', '\d+')::int > 10 AS version_above_ten; + version_above_ten +------------------- + f +(1 row) + +-- Check that files for the automatically managed table exist in the +-- cstore_fdw/{databaseoid} directory. +SELECT count(*) FROM ( + SELECT pg_ls_dir('cstore_fdw/' || databaseoid ) FROM ( + SELECT oid::text databaseoid FROM pg_database WHERE datname = current_database() + ) AS q1) AS q2; + count +------- + 0 +(1 row) + +-- CREATE a cstore_fdw table, fill with some data -- +CREATE FOREIGN TABLE cstore_truncate_test (a int, b int) SERVER cstore_server; +CREATE FOREIGN TABLE cstore_truncate_test_second (a int, b int) SERVER cstore_server; +CREATE FOREIGN TABLE cstore_truncate_test_compressed (a int, b int) SERVER cstore_server OPTIONS (compression 'pglz'); +CREATE TABLE cstore_truncate_test_regular (a int, b int); +INSERT INTO cstore_truncate_test select a, a from generate_series(1, 10) a; +INSERT INTO cstore_truncate_test_compressed select a, a from generate_series(1, 10) a; +INSERT INTO cstore_truncate_test_compressed select a, a from generate_series(1, 10) a; +-- query rows +SELECT * FROM cstore_truncate_test; + a | b +----+---- + 1 | 1 + 2 | 2 + 3 | 3 + 4 | 4 + 5 | 5 + 6 | 6 + 7 | 7 + 8 | 8 + 9 | 9 + 10 | 10 +(10 rows) + +TRUNCATE TABLE cstore_truncate_test; +SELECT * FROM cstore_truncate_test; + a | b +---+--- +(0 rows) + +SELECT COUNT(*) from cstore_truncate_test; + count +------- + 0 +(1 row) + +SELECT count(*) FROM cstore_truncate_test_compressed; + count +------- + 20 +(1 row) + +TRUNCATE TABLE cstore_truncate_test_compressed; +SELECT count(*) FROM cstore_truncate_test_compressed; + count +------- + 0 +(1 row) + +SELECT cstore_table_size('cstore_truncate_test_compressed'); + cstore_table_size +------------------- + 26 +(1 row) + +-- make sure data files still present +SELECT count(*) FROM ( + SELECT pg_ls_dir('cstore_fdw/' || databaseoid ) FROM ( + SELECT oid::text databaseoid FROM pg_database WHERE datname = current_database() + ) AS q1) AS q2; + count +------- + 6 +(1 row) + +INSERT INTO cstore_truncate_test select a, a from generate_series(1, 10) a; +INSERT INTO cstore_truncate_test_regular select a, a from generate_series(10, 20) a; +INSERT INTO cstore_truncate_test_second select a, a from generate_series(20, 30) a; +SELECT * from cstore_truncate_test; + a | b +----+---- + 1 | 1 + 2 | 2 + 3 | 3 + 4 | 4 + 5 | 5 + 6 | 6 + 7 | 7 + 8 | 8 + 9 | 9 + 10 | 10 +(10 rows) + +SELECT * from cstore_truncate_test_second; + a | b +----+---- + 20 | 20 + 21 | 21 + 22 | 22 + 23 | 23 + 24 | 24 + 25 | 25 + 26 | 26 + 27 | 27 + 28 | 28 + 29 | 29 + 30 | 30 +(11 rows) + +SELECT * from cstore_truncate_test_regular; + a | b +----+---- + 10 | 10 + 11 | 11 + 12 | 12 + 13 | 13 + 14 | 14 + 15 | 15 + 16 | 16 + 17 | 17 + 18 | 18 + 19 | 19 + 20 | 20 +(11 rows) + +-- make sure multi truncate works +-- notice that the same table might be repeated +TRUNCATE TABLE cstore_truncate_test, + cstore_truncate_test_regular, + cstore_truncate_test_second, + cstore_truncate_test; +SELECT * from cstore_truncate_test; + a | b +---+--- +(0 rows) + +SELECT * from cstore_truncate_test_second; + a | b +---+--- +(0 rows) + +SELECT * from cstore_truncate_test_regular; + a | b +---+--- +(0 rows) + +-- test if truncate on empty table works +TRUNCATE TABLE cstore_truncate_test; +SELECT * from cstore_truncate_test; + a | b +---+--- +(0 rows) + +-- test if a cached truncate from a pl/pgsql function works +CREATE FUNCTION cstore_truncate_test_regular_func() RETURNS void AS $$ +BEGIN + INSERT INTO cstore_truncate_test_regular select a, a from generate_series(1, 10) a; + TRUNCATE TABLE cstore_truncate_test_regular; +END;$$ +LANGUAGE plpgsql; +SELECT cstore_truncate_test_regular_func(); + cstore_truncate_test_regular_func +----------------------------------- + +(1 row) + +-- the cached plans are used stating from the second call +SELECT cstore_truncate_test_regular_func(); + cstore_truncate_test_regular_func +----------------------------------- + +(1 row) + +DROP FUNCTION cstore_truncate_test_regular_func(); +DROP FOREIGN TABLE cstore_truncate_test, cstore_truncate_test_second; +DROP TABLE cstore_truncate_test_regular; +DROP FOREIGN TABLE cstore_truncate_test_compressed; +-- test truncate with schema +CREATE SCHEMA truncate_schema; +CREATE FOREIGN TABLE truncate_schema.truncate_tbl (id int) SERVER cstore_server OPTIONS(compression 'pglz'); +INSERT INTO truncate_schema.truncate_tbl SELECT generate_series(1, 100); +SELECT COUNT(*) FROM truncate_schema.truncate_tbl; + count +------- + 100 +(1 row) + +TRUNCATE TABLE truncate_schema.truncate_tbl; +SELECT COUNT(*) FROM truncate_schema.truncate_tbl; + count +------- + 0 +(1 row) + +INSERT INTO truncate_schema.truncate_tbl SELECT generate_series(1, 100); +-- create a user that can not truncate +CREATE USER truncate_user; +GRANT USAGE ON SCHEMA truncate_schema TO truncate_user; +GRANT SELECT ON TABLE truncate_schema.truncate_tbl TO truncate_user; +REVOKE TRUNCATE ON TABLE truncate_schema.truncate_tbl FROM truncate_user; +SELECT current_user \gset +\c - truncate_user +-- verify truncate command fails and check number of rows +SELECT count(*) FROM truncate_schema.truncate_tbl; + count +------- + 100 +(1 row) + +TRUNCATE TABLE truncate_schema.truncate_tbl; +ERROR: permission denied for relation truncate_tbl +SELECT count(*) FROM truncate_schema.truncate_tbl; + count +------- + 100 +(1 row) + +-- switch to super user, grant truncate to truncate_user +\c - :current_user +GRANT TRUNCATE ON TABLE truncate_schema.truncate_tbl TO truncate_user; +-- verify truncate_user can truncate now +\c - truncate_user +SELECT count(*) FROM truncate_schema.truncate_tbl; + count +------- + 100 +(1 row) + +TRUNCATE TABLE truncate_schema.truncate_tbl; +SELECT count(*) FROM truncate_schema.truncate_tbl; + count +------- + 0 +(1 row) + +\c - :current_user +-- cleanup +DROP SCHEMA truncate_schema CASCADE; +NOTICE: drop cascades to foreign table truncate_schema.truncate_tbl +DROP USER truncate_user; +-- verify files are removed +SELECT count(*) FROM ( + SELECT pg_ls_dir('cstore_fdw/' || databaseoid ) FROM ( + SELECT oid::text databaseoid FROM pg_database WHERE datname = current_database() + ) AS q1) AS q2; + count +------- + 0 +(1 row) + diff --git a/expected/extension_create.out b/expected/extension_create.out new file mode 100644 index 000000000..c4d94e1e5 --- /dev/null +++ b/expected/extension_create.out @@ -0,0 +1,2 @@ +-- Install cstore_fdw +CREATE EXTENSION cstore_fdw; diff --git a/expected/fdw_clean.out b/expected/fdw_clean.out new file mode 100644 index 000000000..ecd4d67a1 --- /dev/null +++ b/expected/fdw_clean.out @@ -0,0 +1,10 @@ +DROP FOREIGN TABLE collation_block_filtering_test; +DROP FOREIGN TABLE test_block_filtering; +DROP FOREIGN TABLE test_null_values; +DROP FOREIGN TABLE test_other_types; +DROP FOREIGN TABLE test_range_types; +DROP FOREIGN TABLE test_enum_and_composite_types; +DROP TYPE composite_type; +DROP TYPE enum_type; +DROP FOREIGN TABLE test_datetime_types; +DROP FOREIGN TABLE test_array_types; diff --git a/input/am_block_filtering.source b/input/am_block_filtering.source new file mode 100644 index 000000000..f93eb1988 --- /dev/null +++ b/input/am_block_filtering.source @@ -0,0 +1,73 @@ +-- +-- Test block filtering in cstore_fdw using min/max values in stripe skip lists. +-- + + +-- +-- filtered_row_count returns number of rows filtered by the WHERE clause. +-- If blocks get filtered by cstore_fdw, less rows are passed to WHERE +-- clause, so this function should return a lower number. +-- +CREATE OR REPLACE FUNCTION filtered_row_count (query text) RETURNS bigint AS +$$ + DECLARE + result bigint; + rec text; + BEGIN + result := 0; + + FOR rec IN EXECUTE 'EXPLAIN ANALYZE ' || query LOOP + IF rec ~ '^\s+Rows Removed by Filter' then + result := regexp_replace(rec, '[^0-9]*', '', 'g'); + END IF; + END LOOP; + + RETURN result; + END; +$$ LANGUAGE PLPGSQL; + + +-- Create and load data +-- block_row_count '1000', stripe_row_count '2000' +set cstore.stripe_row_count = 2000; +set cstore.block_row_count = 1000; +CREATE TABLE test_block_filtering (a int) + USING cstore_tableam; + +COPY test_block_filtering FROM '@abs_srcdir@/data/block_filtering.csv' WITH CSV; + + +-- Verify that filtered_row_count is less than 1000 for the following queries +SELECT filtered_row_count('SELECT count(*) FROM test_block_filtering'); +SELECT filtered_row_count('SELECT count(*) FROM test_block_filtering WHERE a < 200'); +SELECT filtered_row_count('SELECT count(*) FROM test_block_filtering WHERE a > 200'); +SELECT filtered_row_count('SELECT count(*) FROM test_block_filtering WHERE a < 9900'); +SELECT filtered_row_count('SELECT count(*) FROM test_block_filtering WHERE a > 9900'); +SELECT filtered_row_count('SELECT count(*) FROM test_block_filtering WHERE a < 0'); + + +-- Verify that filtered_row_count is less than 2000 for the following queries +SELECT filtered_row_count('SELECT count(*) FROM test_block_filtering WHERE a BETWEEN 1 AND 10'); +SELECT filtered_row_count('SELECT count(*) FROM test_block_filtering WHERE a BETWEEN 990 AND 2010'); +SELECT filtered_row_count('SELECT count(*) FROM test_block_filtering WHERE a BETWEEN -10 AND 0'); + + +-- Load data for second time and verify that filtered_row_count is exactly twice as before +COPY test_block_filtering FROM '@abs_srcdir@/data/block_filtering.csv' WITH CSV; +SELECT filtered_row_count('SELECT count(*) FROM test_block_filtering WHERE a < 200'); +SELECT filtered_row_count('SELECT count(*) FROM test_block_filtering WHERE a < 0'); +SELECT filtered_row_count('SELECT count(*) FROM test_block_filtering WHERE a BETWEEN 990 AND 2010'); + +set cstore.stripe_row_count to default; +set cstore.block_row_count to default; + +-- Verify that we are fine with collations which use a different alphabet order +CREATE TABLE collation_block_filtering_test(A text collate "da_DK") + USING cstore_tableam; +COPY collation_block_filtering_test FROM STDIN; +A +Å +B +\. + +SELECT * FROM collation_block_filtering_test WHERE A > 'B'; diff --git a/input/am_copyto.source b/input/am_copyto.source new file mode 100644 index 000000000..bb333bacf --- /dev/null +++ b/input/am_copyto.source @@ -0,0 +1,17 @@ +-- +-- Test copying data from cstore_fdw tables. +-- +CREATE TABLE test_contestant(handle TEXT, birthdate DATE, rating INT, + percentile FLOAT, country CHAR(3), achievements TEXT[]) + USING cstore_tableam; + +-- load table data from file +COPY test_contestant FROM '@abs_srcdir@/data/contestants.1.csv' WITH CSV; + +-- export using COPY table TO ... +COPY test_contestant TO STDOUT; + +-- export using COPY (SELECT * FROM table) TO ... +COPY (select * from test_contestant) TO STDOUT; + +DROP TABLE test_contestant CASCADE; diff --git a/input/am_create.source b/input/am_create.source new file mode 100644 index 000000000..6d4d5a388 --- /dev/null +++ b/input/am_create.source @@ -0,0 +1,20 @@ +-- +-- Test the CREATE statements related to cstore. +-- + + +-- Create uncompressed table +CREATE TABLE contestant (handle TEXT, birthdate DATE, rating INT, + percentile FLOAT, country CHAR(3), achievements TEXT[]) + USING cstore_tableam; + + +-- Create compressed table with automatically determined file path +-- COMPRESSED +CREATE TABLE contestant_compressed (handle TEXT, birthdate DATE, rating INT, + percentile FLOAT, country CHAR(3), achievements TEXT[]) + USING cstore_tableam; + +-- Test that querying an empty table works +ANALYZE contestant; +SELECT count(*) FROM contestant; diff --git a/input/am_data_types.source b/input/am_data_types.source new file mode 100644 index 000000000..24c661090 --- /dev/null +++ b/input/am_data_types.source @@ -0,0 +1,68 @@ +-- +-- Test loading and reading different data types to/from cstore_fdw foreign tables. +-- + + +-- Settings to make the result deterministic +SET datestyle = "ISO, YMD"; +SET timezone to 'GMT'; +SET intervalstyle TO 'POSTGRES_VERBOSE'; + + +-- Test array types +CREATE TABLE test_array_types (int_array int[], bigint_array bigint[], + text_array text[]) USING cstore_tableam; + +COPY test_array_types FROM '@abs_srcdir@/data/array_types.csv' WITH CSV; + +SELECT * FROM test_array_types; + + +-- Test date/time types +CREATE TABLE test_datetime_types (timestamp timestamp, + timestamp_with_timezone timestamp with time zone, date date, time time, + interval interval) USING cstore_tableam; + +COPY test_datetime_types FROM '@abs_srcdir@/data/datetime_types.csv' WITH CSV; + +SELECT * FROM test_datetime_types; + + +-- Test enum and composite types +CREATE TYPE enum_type AS ENUM ('a', 'b', 'c'); +CREATE TYPE composite_type AS (a int, b text); + +CREATE TABLE test_enum_and_composite_types (enum enum_type, + composite composite_type) USING cstore_tableam; + +COPY test_enum_and_composite_types FROM + '@abs_srcdir@/data/enum_and_composite_types.csv' WITH CSV; + +SELECT * FROM test_enum_and_composite_types; + + +-- Test range types +CREATE TABLE test_range_types (int4range int4range, int8range int8range, + numrange numrange, tsrange tsrange) USING cstore_tableam; + +COPY test_range_types FROM '@abs_srcdir@/data/range_types.csv' WITH CSV; + +SELECT * FROM test_range_types; + + +-- Test other types +CREATE TABLE test_other_types (bool boolean, bytea bytea, money money, + inet inet, bitstring bit varying(5), uuid uuid, json json) USING cstore_tableam; + +COPY test_other_types FROM '@abs_srcdir@/data/other_types.csv' WITH CSV; + +SELECT * FROM test_other_types; + + +-- Test null values +CREATE TABLE test_null_values (a int, b int[], c composite_type) + USING cstore_tableam; + +COPY test_null_values FROM '@abs_srcdir@/data/null_values.csv' WITH CSV; + +SELECT * FROM test_null_values; diff --git a/input/am_load.source b/input/am_load.source new file mode 100644 index 000000000..d0ef9bfac --- /dev/null +++ b/input/am_load.source @@ -0,0 +1,46 @@ +-- +-- Test loading data into cstore_fdw tables. +-- + +-- COPY with incorrect delimiter +COPY contestant FROM '@abs_srcdir@/data/contestants.1.csv' + WITH DELIMITER '|'; -- ERROR + +-- COPY with invalid program +COPY contestant FROM PROGRAM 'invalid_program' WITH CSV; -- ERROR + +-- COPY into uncompressed table from file +COPY contestant FROM '@abs_srcdir@/data/contestants.1.csv' WITH CSV; + +-- COPY into uncompressed table from program +COPY contestant FROM PROGRAM 'cat @abs_srcdir@/data/contestants.2.csv' WITH CSV; + +-- COPY into compressed table +set cstore.compression = 'pglz'; +COPY contestant_compressed FROM '@abs_srcdir@/data/contestants.1.csv' WITH CSV; + +-- COPY into uncompressed table from program +COPY contestant_compressed FROM PROGRAM 'cat @abs_srcdir@/data/contestants.2.csv' + WITH CSV; +set cstore.compression to default; + +-- Test column list +CREATE TABLE famous_constants (id int, name text, value real) + USING cstore_tableam; +COPY famous_constants (value, name, id) FROM STDIN WITH CSV; +3.141,pi,1 +2.718,e,2 +0.577,gamma,3 +5.291e-11,bohr radius,4 +\. + +COPY famous_constants (name, value) FROM STDIN WITH CSV; +avagadro,6.022e23 +electron mass,9.109e-31 +proton mass,1.672e-27 +speed of light,2.997e8 +\. + +SELECT * FROM famous_constants ORDER BY id, name; + +DROP TABLE famous_constants; diff --git a/input/fdw_create.source b/input/fdw_create.source index ba52137c1..bb3a38e28 100644 --- a/input/fdw_create.source +++ b/input/fdw_create.source @@ -2,10 +2,6 @@ -- Test the CREATE statements related to cstore_fdw. -- - --- Install cstore_fdw -CREATE EXTENSION cstore_fdw; - CREATE SERVER cstore_server FOREIGN DATA WRAPPER cstore_fdw; diff --git a/mod.c b/mod.c index d962e9820..e81f7a6e5 100644 --- a/mod.c +++ b/mod.c @@ -15,20 +15,42 @@ #include "fmgr.h" +#include "cstore.h" #include "mod.h" + +#ifdef USE_TABLEAM +#include "cstore_tableam.h" +#endif + +#ifdef USE_FDW #include "cstore_fdw.h" +#endif PG_MODULE_MAGIC; void _PG_init(void) { + cstore_init(); + +#ifdef USE_TABLEAM + cstore_tableam_init(); +#endif + +#ifdef USE_FDW cstore_fdw_init(); +#endif } void _PG_fini(void) { +#if USE_TABLEAM + cstore_tableam_finish(); +#endif + +#ifdef USE_FDW cstore_fdw_finish(); +#endif } diff --git a/output/am_block_filtering.source b/output/am_block_filtering.source new file mode 100644 index 000000000..45cb702b6 --- /dev/null +++ b/output/am_block_filtering.source @@ -0,0 +1,120 @@ +-- +-- Test block filtering in cstore_fdw using min/max values in stripe skip lists. +-- +-- +-- filtered_row_count returns number of rows filtered by the WHERE clause. +-- If blocks get filtered by cstore_fdw, less rows are passed to WHERE +-- clause, so this function should return a lower number. +-- +CREATE OR REPLACE FUNCTION filtered_row_count (query text) RETURNS bigint AS +$$ + DECLARE + result bigint; + rec text; + BEGIN + result := 0; + + FOR rec IN EXECUTE 'EXPLAIN ANALYZE ' || query LOOP + IF rec ~ '^\s+Rows Removed by Filter' then + result := regexp_replace(rec, '[^0-9]*', '', 'g'); + END IF; + END LOOP; + + RETURN result; + END; +$$ LANGUAGE PLPGSQL; +-- Create and load data +-- block_row_count '1000', stripe_row_count '2000' +set cstore.stripe_row_count = 2000; +set cstore.block_row_count = 1000; +CREATE TABLE test_block_filtering (a int) + USING cstore_tableam; +COPY test_block_filtering FROM '@abs_srcdir@/data/block_filtering.csv' WITH CSV; +-- Verify that filtered_row_count is less than 1000 for the following queries +SELECT filtered_row_count('SELECT count(*) FROM test_block_filtering'); + filtered_row_count +-------------------- + 0 +(1 row) + +SELECT filtered_row_count('SELECT count(*) FROM test_block_filtering WHERE a < 200'); + filtered_row_count +-------------------- + 801 +(1 row) + +SELECT filtered_row_count('SELECT count(*) FROM test_block_filtering WHERE a > 200'); + filtered_row_count +-------------------- + 200 +(1 row) + +SELECT filtered_row_count('SELECT count(*) FROM test_block_filtering WHERE a < 9900'); + filtered_row_count +-------------------- + 101 +(1 row) + +SELECT filtered_row_count('SELECT count(*) FROM test_block_filtering WHERE a > 9900'); + filtered_row_count +-------------------- + 900 +(1 row) + +SELECT filtered_row_count('SELECT count(*) FROM test_block_filtering WHERE a < 0'); + filtered_row_count +-------------------- + 0 +(1 row) + +-- Verify that filtered_row_count is less than 2000 for the following queries +SELECT filtered_row_count('SELECT count(*) FROM test_block_filtering WHERE a BETWEEN 1 AND 10'); + filtered_row_count +-------------------- + 990 +(1 row) + +SELECT filtered_row_count('SELECT count(*) FROM test_block_filtering WHERE a BETWEEN 990 AND 2010'); + filtered_row_count +-------------------- + 1979 +(1 row) + +SELECT filtered_row_count('SELECT count(*) FROM test_block_filtering WHERE a BETWEEN -10 AND 0'); + filtered_row_count +-------------------- + 0 +(1 row) + +-- Load data for second time and verify that filtered_row_count is exactly twice as before +COPY test_block_filtering FROM '@abs_srcdir@/data/block_filtering.csv' WITH CSV; +SELECT filtered_row_count('SELECT count(*) FROM test_block_filtering WHERE a < 200'); + filtered_row_count +-------------------- + 1602 +(1 row) + +SELECT filtered_row_count('SELECT count(*) FROM test_block_filtering WHERE a < 0'); + filtered_row_count +-------------------- + 0 +(1 row) + +SELECT filtered_row_count('SELECT count(*) FROM test_block_filtering WHERE a BETWEEN 990 AND 2010'); + filtered_row_count +-------------------- + 3958 +(1 row) + +set cstore.stripe_row_count to default; +set cstore.block_row_count to default; +-- Verify that we are fine with collations which use a different alphabet order +CREATE TABLE collation_block_filtering_test(A text collate "da_DK") + USING cstore_tableam; +COPY collation_block_filtering_test FROM STDIN; +SELECT * FROM collation_block_filtering_test WHERE A > 'B'; + a +--- + Å +(1 row) + diff --git a/output/am_copyto.source b/output/am_copyto.source new file mode 100644 index 000000000..127bdc65d --- /dev/null +++ b/output/am_copyto.source @@ -0,0 +1,23 @@ +-- +-- Test copying data from cstore_fdw tables. +-- +CREATE TABLE test_contestant(handle TEXT, birthdate DATE, rating INT, + percentile FLOAT, country CHAR(3), achievements TEXT[]) + USING cstore_tableam; +-- load table data from file +COPY test_contestant FROM '@abs_srcdir@/data/contestants.1.csv' WITH CSV; +-- export using COPY table TO ... +COPY test_contestant TO STDOUT; +a 01-10-1990 2090 97.1 XA {a} +b 11-01-1990 2203 98.1 XA {a,b} +c 11-01-1988 2907 99.4 XB {w,y} +d 05-05-1985 2314 98.3 XB {} +e 05-05-1995 2236 98.2 XC {a} +-- export using COPY (SELECT * FROM table) TO ... +COPY (select * from test_contestant) TO STDOUT; +a 01-10-1990 2090 97.1 XA {a} +b 11-01-1990 2203 98.1 XA {a,b} +c 11-01-1988 2907 99.4 XB {w,y} +d 05-05-1985 2314 98.3 XB {} +e 05-05-1995 2236 98.2 XC {a} +DROP TABLE test_contestant CASCADE; diff --git a/output/am_create.source b/output/am_create.source new file mode 100644 index 000000000..47c6a6c44 --- /dev/null +++ b/output/am_create.source @@ -0,0 +1,20 @@ +-- +-- Test the CREATE statements related to cstore. +-- +-- Create uncompressed table +CREATE TABLE contestant (handle TEXT, birthdate DATE, rating INT, + percentile FLOAT, country CHAR(3), achievements TEXT[]) + USING cstore_tableam; +-- Create compressed table with automatically determined file path +-- COMPRESSED +CREATE TABLE contestant_compressed (handle TEXT, birthdate DATE, rating INT, + percentile FLOAT, country CHAR(3), achievements TEXT[]) + USING cstore_tableam; +-- Test that querying an empty table works +ANALYZE contestant; +SELECT count(*) FROM contestant; + count +------- + 0 +(1 row) + diff --git a/output/am_data_types.source b/output/am_data_types.source new file mode 100644 index 000000000..8431e6ca2 --- /dev/null +++ b/output/am_data_types.source @@ -0,0 +1,78 @@ +-- +-- Test loading and reading different data types to/from cstore_fdw foreign tables. +-- +-- Settings to make the result deterministic +SET datestyle = "ISO, YMD"; +SET timezone to 'GMT'; +SET intervalstyle TO 'POSTGRES_VERBOSE'; +-- Test array types +CREATE TABLE test_array_types (int_array int[], bigint_array bigint[], + text_array text[]) USING cstore_tableam; +COPY test_array_types FROM '@abs_srcdir@/data/array_types.csv' WITH CSV; +SELECT * FROM test_array_types; + int_array | bigint_array | text_array +--------------------------+--------------------------------------------+------------ + {1,2,3} | {1,2,3} | {a,b,c} + {} | {} | {} + {-2147483648,2147483647} | {-9223372036854775808,9223372036854775807} | {""} +(3 rows) + +-- Test date/time types +CREATE TABLE test_datetime_types (timestamp timestamp, + timestamp_with_timezone timestamp with time zone, date date, time time, + interval interval) USING cstore_tableam; +COPY test_datetime_types FROM '@abs_srcdir@/data/datetime_types.csv' WITH CSV; +SELECT * FROM test_datetime_types; + timestamp | timestamp_with_timezone | date | time | interval +---------------------+-------------------------+------------+----------+----------- + 2000-01-02 04:05:06 | 1999-01-08 12:05:06+00 | 2000-01-02 | 04:05:06 | @ 4 hours + 1970-01-01 00:00:00 | infinity | -infinity | 00:00:00 | @ 0 +(2 rows) + +-- Test enum and composite types +CREATE TYPE enum_type AS ENUM ('a', 'b', 'c'); +CREATE TYPE composite_type AS (a int, b text); +CREATE TABLE test_enum_and_composite_types (enum enum_type, + composite composite_type) USING cstore_tableam; +COPY test_enum_and_composite_types FROM + '@abs_srcdir@/data/enum_and_composite_types.csv' WITH CSV; +SELECT * FROM test_enum_and_composite_types; + enum | composite +------+----------- + a | (2,b) + b | (3,c) +(2 rows) + +-- Test range types +CREATE TABLE test_range_types (int4range int4range, int8range int8range, + numrange numrange, tsrange tsrange) USING cstore_tableam; +COPY test_range_types FROM '@abs_srcdir@/data/range_types.csv' WITH CSV; +SELECT * FROM test_range_types; + int4range | int8range | numrange | tsrange +-----------+-----------+----------+----------------------------------------------- + [1,3) | [1,3) | [1,3) | ["2000-01-02 00:30:00","2010-02-03 12:30:00") + empty | [1,) | (,) | empty +(2 rows) + +-- Test other types +CREATE TABLE test_other_types (bool boolean, bytea bytea, money money, + inet inet, bitstring bit varying(5), uuid uuid, json json) USING cstore_tableam; +COPY test_other_types FROM '@abs_srcdir@/data/other_types.csv' WITH CSV; +SELECT * FROM test_other_types; + bool | bytea | money | inet | bitstring | uuid | json +------+------------+-------+-------------+-----------+--------------------------------------+------------------ + f | \xdeadbeef | $1.00 | 192.168.1.2 | 10101 | a0eebc99-9c0b-4ef8-bb6d-6bb9bd380a11 | {"key": "value"} + t | \xcdb0 | $1.50 | 127.0.0.1 | | a0eebc99-9c0b-4ef8-bb6d-6bb9bd380a11 | [] +(2 rows) + +-- Test null values +CREATE TABLE test_null_values (a int, b int[], c composite_type) + USING cstore_tableam; +COPY test_null_values FROM '@abs_srcdir@/data/null_values.csv' WITH CSV; +SELECT * FROM test_null_values; + a | b | c +---+--------+----- + | {NULL} | (,) + | | +(2 rows) + diff --git a/output/am_load.source b/output/am_load.source new file mode 100644 index 000000000..5eb81a250 --- /dev/null +++ b/output/am_load.source @@ -0,0 +1,42 @@ +-- +-- Test loading data into cstore_fdw tables. +-- +-- COPY with incorrect delimiter +COPY contestant FROM '@abs_srcdir@/data/contestants.1.csv' + WITH DELIMITER '|'; -- ERROR +ERROR: missing data for column "birthdate" +CONTEXT: COPY contestant, line 1: "a,1990-01-10,2090,97.1,XA ,{a}" +-- COPY with invalid program +COPY contestant FROM PROGRAM 'invalid_program' WITH CSV; -- ERROR +ERROR: program "invalid_program" failed +DETAIL: command not found +-- COPY into uncompressed table from file +COPY contestant FROM '@abs_srcdir@/data/contestants.1.csv' WITH CSV; +-- COPY into uncompressed table from program +COPY contestant FROM PROGRAM 'cat @abs_srcdir@/data/contestants.2.csv' WITH CSV; +-- COPY into compressed table +set cstore.compression = 'pglz'; +COPY contestant_compressed FROM '@abs_srcdir@/data/contestants.1.csv' WITH CSV; +-- COPY into uncompressed table from program +COPY contestant_compressed FROM PROGRAM 'cat @abs_srcdir@/data/contestants.2.csv' + WITH CSV; +set cstore.compression to default; +-- Test column list +CREATE TABLE famous_constants (id int, name text, value real) + USING cstore_tableam; +COPY famous_constants (value, name, id) FROM STDIN WITH CSV; +COPY famous_constants (name, value) FROM STDIN WITH CSV; +SELECT * FROM famous_constants ORDER BY id, name; + id | name | value +----+----------------+----------- + 1 | pi | 3.141 + 2 | e | 2.718 + 3 | gamma | 0.577 + 4 | bohr radius | 5.291e-11 + | avagadro | 6.022e+23 + | electron mass | 9.109e-31 + | proton mass | 1.672e-27 + | speed of light | 2.997e+08 +(8 rows) + +DROP TABLE famous_constants; diff --git a/output/fdw_create.source b/output/fdw_create.source index 961c0494d..41f17fdd8 100644 --- a/output/fdw_create.source +++ b/output/fdw_create.source @@ -1,8 +1,6 @@ -- -- Test the CREATE statements related to cstore_fdw. -- --- Install cstore_fdw -CREATE EXTENSION cstore_fdw; CREATE SERVER cstore_server FOREIGN DATA WRAPPER cstore_fdw; -- Validator tests CREATE FOREIGN TABLE test_validator_invalid_option () diff --git a/sql/am_alter.sql b/sql/am_alter.sql new file mode 100644 index 000000000..3b608f9cd --- /dev/null +++ b/sql/am_alter.sql @@ -0,0 +1,85 @@ +-- +-- Testing ALTER TABLE on cstore_fdw tables. +-- + +CREATE TABLE test_alter_table (a int, b int, c int) USING cstore_tableam; + +WITH sample_data AS (VALUES + (1, 2, 3), + (4, 5, 6), + (7, 8, 9) +) +INSERT INTO test_alter_table SELECT * FROM sample_data; + +-- drop a column +ALTER TABLE test_alter_table DROP COLUMN a; + +-- test analyze +ANALYZE test_alter_table; + +-- verify select queries run as expected +SELECT * FROM test_alter_table; +SELECT a FROM test_alter_table; +SELECT b FROM test_alter_table; + +-- verify insert runs as expected +INSERT INTO test_alter_table (SELECT 3, 5, 8); +INSERT INTO test_alter_table (SELECT 5, 8); + + +-- add a column with no defaults +ALTER TABLE test_alter_table ADD COLUMN d int; +SELECT * FROM test_alter_table; +INSERT INTO test_alter_table (SELECT 3, 5, 8); +SELECT * FROM test_alter_table; + + +-- add a fixed-length column with default value +ALTER TABLE test_alter_table ADD COLUMN e int default 3; +SELECT * from test_alter_table; +INSERT INTO test_alter_table (SELECT 1, 2, 4, 8); +SELECT * from test_alter_table; + + +-- add a variable-length column with default value +ALTER TABLE test_alter_table ADD COLUMN f text DEFAULT 'TEXT ME'; +SELECT * from test_alter_table; +INSERT INTO test_alter_table (SELECT 1, 2, 4, 8, 'ABCDEF'); +SELECT * from test_alter_table; + + +-- drop couple of columns +ALTER TABLE test_alter_table DROP COLUMN c; +ALTER TABLE test_alter_table DROP COLUMN e; +ANALYZE test_alter_table; +SELECT * from test_alter_table; +SELECT count(*) from test_alter_table; +SELECT count(t.*) from test_alter_table t; + + +-- unsupported default values +ALTER TABLE test_alter_table ADD COLUMN g boolean DEFAULT isfinite(current_date); +ALTER TABLE test_alter_table ADD COLUMN h DATE DEFAULT current_date; +SELECT * FROM test_alter_table; +ALTER TABLE test_alter_table ALTER COLUMN g DROP DEFAULT; +SELECT * FROM test_alter_table; +ALTER TABLE test_alter_table ALTER COLUMN h DROP DEFAULT; +ANALYZE test_alter_table; +SELECT * FROM test_alter_table; + +-- unsupported type change +ALTER TABLE test_alter_table ADD COLUMN i int; +ALTER TABLE test_alter_table ADD COLUMN j float; +ALTER TABLE test_alter_table ADD COLUMN k text; + +-- this is valid type change +ALTER TABLE test_alter_table ALTER COLUMN i TYPE float; + +-- this is not valid +ALTER TABLE test_alter_table ALTER COLUMN j TYPE int; + +-- text / varchar conversion is valid both ways +ALTER TABLE test_alter_table ALTER COLUMN k TYPE varchar(20); +ALTER TABLE test_alter_table ALTER COLUMN k TYPE text; + +DROP TABLE test_alter_table; diff --git a/sql/am_analyze.sql b/sql/am_analyze.sql new file mode 100644 index 000000000..4476454a6 --- /dev/null +++ b/sql/am_analyze.sql @@ -0,0 +1,11 @@ +-- +-- Test the ANALYZE command for cstore_fdw tables. +-- + +-- ANALYZE uncompressed table +ANALYZE contestant; +SELECT count(*) FROM pg_stats WHERE tablename='contestant'; + +-- ANALYZE compressed table +ANALYZE contestant_compressed; +SELECT count(*) FROM pg_stats WHERE tablename='contestant_compressed'; diff --git a/sql/am_block_filtering.sql b/sql/am_block_filtering.sql new file mode 100644 index 000000000..2a45716ed --- /dev/null +++ b/sql/am_block_filtering.sql @@ -0,0 +1,73 @@ +-- +-- Test block filtering in cstore_fdw using min/max values in stripe skip lists. +-- + + +-- +-- filtered_row_count returns number of rows filtered by the WHERE clause. +-- If blocks get filtered by cstore_fdw, less rows are passed to WHERE +-- clause, so this function should return a lower number. +-- +CREATE OR REPLACE FUNCTION filtered_row_count (query text) RETURNS bigint AS +$$ + DECLARE + result bigint; + rec text; + BEGIN + result := 0; + + FOR rec IN EXECUTE 'EXPLAIN ANALYZE ' || query LOOP + IF rec ~ '^\s+Rows Removed by Filter' then + result := regexp_replace(rec, '[^0-9]*', '', 'g'); + END IF; + END LOOP; + + RETURN result; + END; +$$ LANGUAGE PLPGSQL; + + +-- Create and load data +-- block_row_count '1000', stripe_row_count '2000' +set cstore.stripe_row_count = 2000; +set cstore.block_row_count = 1000; +CREATE TABLE test_block_filtering (a int) + USING cstore_tableam; + +COPY test_block_filtering FROM '/Users/jefdavi/wd/cstore2/data/block_filtering.csv' WITH CSV; + + +-- Verify that filtered_row_count is less than 1000 for the following queries +SELECT filtered_row_count('SELECT count(*) FROM test_block_filtering'); +SELECT filtered_row_count('SELECT count(*) FROM test_block_filtering WHERE a < 200'); +SELECT filtered_row_count('SELECT count(*) FROM test_block_filtering WHERE a > 200'); +SELECT filtered_row_count('SELECT count(*) FROM test_block_filtering WHERE a < 9900'); +SELECT filtered_row_count('SELECT count(*) FROM test_block_filtering WHERE a > 9900'); +SELECT filtered_row_count('SELECT count(*) FROM test_block_filtering WHERE a < 0'); + + +-- Verify that filtered_row_count is less than 2000 for the following queries +SELECT filtered_row_count('SELECT count(*) FROM test_block_filtering WHERE a BETWEEN 1 AND 10'); +SELECT filtered_row_count('SELECT count(*) FROM test_block_filtering WHERE a BETWEEN 990 AND 2010'); +SELECT filtered_row_count('SELECT count(*) FROM test_block_filtering WHERE a BETWEEN -10 AND 0'); + + +-- Load data for second time and verify that filtered_row_count is exactly twice as before +COPY test_block_filtering FROM '/Users/jefdavi/wd/cstore2/data/block_filtering.csv' WITH CSV; +SELECT filtered_row_count('SELECT count(*) FROM test_block_filtering WHERE a < 200'); +SELECT filtered_row_count('SELECT count(*) FROM test_block_filtering WHERE a < 0'); +SELECT filtered_row_count('SELECT count(*) FROM test_block_filtering WHERE a BETWEEN 990 AND 2010'); + +set cstore.stripe_row_count to default; +set cstore.block_row_count to default; + +-- Verify that we are fine with collations which use a different alphabet order +CREATE TABLE collation_block_filtering_test(A text collate "da_DK") + USING cstore_tableam; +COPY collation_block_filtering_test FROM STDIN; +A +Å +B +\. + +SELECT * FROM collation_block_filtering_test WHERE A > 'B'; diff --git a/sql/am_clean.sql b/sql/am_clean.sql new file mode 100644 index 000000000..f7dc889fc --- /dev/null +++ b/sql/am_clean.sql @@ -0,0 +1,9 @@ + +DROP TABLE test_null_values; +DROP TABLE test_other_types; +DROP TABLE test_range_types; +DROP TABLE test_enum_and_composite_types; +DROP TYPE composite_type; +DROP TYPE enum_type; +DROP TABLE test_datetime_types; +DROP TABLE test_array_types; diff --git a/sql/am_copyto.sql b/sql/am_copyto.sql new file mode 100644 index 000000000..7288ff66f --- /dev/null +++ b/sql/am_copyto.sql @@ -0,0 +1,17 @@ +-- +-- Test copying data from cstore_fdw tables. +-- +CREATE TABLE test_contestant(handle TEXT, birthdate DATE, rating INT, + percentile FLOAT, country CHAR(3), achievements TEXT[]) + USING cstore_tableam; + +-- load table data from file +COPY test_contestant FROM '/Users/jefdavi/wd/cstore2/data/contestants.1.csv' WITH CSV; + +-- export using COPY table TO ... +COPY test_contestant TO STDOUT; + +-- export using COPY (SELECT * FROM table) TO ... +COPY (select * from test_contestant) TO STDOUT; + +DROP TABLE test_contestant CASCADE; diff --git a/sql/am_create.sql b/sql/am_create.sql new file mode 100644 index 000000000..6d4d5a388 --- /dev/null +++ b/sql/am_create.sql @@ -0,0 +1,20 @@ +-- +-- Test the CREATE statements related to cstore. +-- + + +-- Create uncompressed table +CREATE TABLE contestant (handle TEXT, birthdate DATE, rating INT, + percentile FLOAT, country CHAR(3), achievements TEXT[]) + USING cstore_tableam; + + +-- Create compressed table with automatically determined file path +-- COMPRESSED +CREATE TABLE contestant_compressed (handle TEXT, birthdate DATE, rating INT, + percentile FLOAT, country CHAR(3), achievements TEXT[]) + USING cstore_tableam; + +-- Test that querying an empty table works +ANALYZE contestant; +SELECT count(*) FROM contestant; diff --git a/sql/am_data_types.sql b/sql/am_data_types.sql new file mode 100644 index 000000000..b2668e71f --- /dev/null +++ b/sql/am_data_types.sql @@ -0,0 +1,68 @@ +-- +-- Test loading and reading different data types to/from cstore_fdw foreign tables. +-- + + +-- Settings to make the result deterministic +SET datestyle = "ISO, YMD"; +SET timezone to 'GMT'; +SET intervalstyle TO 'POSTGRES_VERBOSE'; + + +-- Test array types +CREATE TABLE test_array_types (int_array int[], bigint_array bigint[], + text_array text[]) USING cstore_tableam; + +COPY test_array_types FROM '/Users/jefdavi/wd/cstore2/data/array_types.csv' WITH CSV; + +SELECT * FROM test_array_types; + + +-- Test date/time types +CREATE TABLE test_datetime_types (timestamp timestamp, + timestamp_with_timezone timestamp with time zone, date date, time time, + interval interval) USING cstore_tableam; + +COPY test_datetime_types FROM '/Users/jefdavi/wd/cstore2/data/datetime_types.csv' WITH CSV; + +SELECT * FROM test_datetime_types; + + +-- Test enum and composite types +CREATE TYPE enum_type AS ENUM ('a', 'b', 'c'); +CREATE TYPE composite_type AS (a int, b text); + +CREATE TABLE test_enum_and_composite_types (enum enum_type, + composite composite_type) USING cstore_tableam; + +COPY test_enum_and_composite_types FROM + '/Users/jefdavi/wd/cstore2/data/enum_and_composite_types.csv' WITH CSV; + +SELECT * FROM test_enum_and_composite_types; + + +-- Test range types +CREATE TABLE test_range_types (int4range int4range, int8range int8range, + numrange numrange, tsrange tsrange) USING cstore_tableam; + +COPY test_range_types FROM '/Users/jefdavi/wd/cstore2/data/range_types.csv' WITH CSV; + +SELECT * FROM test_range_types; + + +-- Test other types +CREATE TABLE test_other_types (bool boolean, bytea bytea, money money, + inet inet, bitstring bit varying(5), uuid uuid, json json) USING cstore_tableam; + +COPY test_other_types FROM '/Users/jefdavi/wd/cstore2/data/other_types.csv' WITH CSV; + +SELECT * FROM test_other_types; + + +-- Test null values +CREATE TABLE test_null_values (a int, b int[], c composite_type) + USING cstore_tableam; + +COPY test_null_values FROM '/Users/jefdavi/wd/cstore2/data/null_values.csv' WITH CSV; + +SELECT * FROM test_null_values; diff --git a/sql/am_drop.sql b/sql/am_drop.sql new file mode 100644 index 000000000..f92f90b9d --- /dev/null +++ b/sql/am_drop.sql @@ -0,0 +1,46 @@ +-- +-- Tests the different DROP commands for cstore_fdw tables. +-- +-- DROP TABL +-- DROP SCHEMA +-- DROP EXTENSION +-- DROP DATABASE +-- + +-- Note that travis does not create +-- cstore_fdw extension in default database (postgres). This has caused +-- different behavior between travis tests and local tests. Thus +-- 'postgres' directory is excluded from comparison to have the same result. + +-- store postgres database oid +SELECT oid postgres_oid FROM pg_database WHERE datname = 'postgres' \gset + +-- DROP cstore_fdw tables +DROP TABLE contestant; +DROP TABLE contestant_compressed; + +-- Create a cstore_fdw table under a schema and drop it. +CREATE SCHEMA test_schema; +CREATE TABLE test_schema.test_table(data int) USING cstore_tableam; +DROP SCHEMA test_schema CASCADE; + +SELECT current_database() datname \gset + +CREATE DATABASE db_to_drop; +\c db_to_drop +CREATE EXTENSION cstore_fdw; +SELECT oid::text databaseoid FROM pg_database WHERE datname = current_database() \gset + +CREATE TABLE test_table(data int) USING cstore_tableam; + +DROP EXTENSION cstore_fdw CASCADE; + +-- test database drop +CREATE EXTENSION cstore_fdw; +SELECT oid::text databaseoid FROM pg_database WHERE datname = current_database() \gset + +CREATE TABLE test_table(data int) USING cstore_tableam; + +\c :datname + +DROP DATABASE db_to_drop; diff --git a/sql/am_functions.sql b/sql/am_functions.sql new file mode 100644 index 000000000..1945eeb46 --- /dev/null +++ b/sql/am_functions.sql @@ -0,0 +1,20 @@ +-- +-- Test utility functions for cstore_fdw tables. +-- + +CREATE TABLE empty_table (a int) USING cstore_tableam; +CREATE TABLE table_with_data (a int) USING cstore_tableam; +CREATE TABLE non_cstore_table (a int); + +COPY table_with_data FROM STDIN; +1 +2 +3 +\. + +SELECT pg_relation_size('empty_table') < pg_relation_size('table_with_data'); +SELECT cstore_table_size('non_cstore_table'); + +DROP TABLE empty_table; +DROP TABLE table_with_data; +DROP TABLE non_cstore_table; diff --git a/sql/am_insert.sql b/sql/am_insert.sql new file mode 100644 index 000000000..5a6d7d385 --- /dev/null +++ b/sql/am_insert.sql @@ -0,0 +1,56 @@ +-- +-- Testing insert on cstore_fdw tables. +-- + +CREATE TABLE test_insert_command (a int) USING cstore_tableam; + +-- test single row inserts fail +select count(*) from test_insert_command; +insert into test_insert_command values(1); +select count(*) from test_insert_command; + +insert into test_insert_command default values; +select count(*) from test_insert_command; + +-- test inserting from another table succeed +CREATE TABLE test_insert_command_data (a int); + +select count(*) from test_insert_command_data; +insert into test_insert_command_data values(1); +select count(*) from test_insert_command_data; + +insert into test_insert_command select * from test_insert_command_data; +select count(*) from test_insert_command; + +drop table test_insert_command_data; +drop table test_insert_command; + +-- test long attribute value insertion +-- create sufficiently long text so that data is stored in toast +CREATE TABLE test_long_text AS +SELECT a as int_val, string_agg(random()::text, '') as text_val +FROM generate_series(1, 10) a, generate_series(1, 1000) b +GROUP BY a ORDER BY a; + +-- store hash values of text for later comparison +CREATE TABLE test_long_text_hash AS +SELECT int_val, md5(text_val) AS hash +FROM test_long_text; + +CREATE TABLE test_cstore_long_text(int_val int, text_val text) +USING cstore_tableam; + +-- store long text in cstore table +INSERT INTO test_cstore_long_text SELECT * FROM test_long_text; + +-- drop source table to remove original text from toast +DROP TABLE test_long_text; + +-- check if text data is still available in cstore table +-- by comparing previously stored hash. +SELECT a.int_val +FROM test_long_text_hash a, test_cstore_long_text c +WHERE a.int_val = c.int_val AND a.hash = md5(c.text_val); + +DROP TABLE test_long_text_hash; +DROP TABLE test_cstore_long_text; diff --git a/sql/am_load.sql b/sql/am_load.sql new file mode 100644 index 000000000..edc727b3c --- /dev/null +++ b/sql/am_load.sql @@ -0,0 +1,46 @@ +-- +-- Test loading data into cstore_fdw tables. +-- + +-- COPY with incorrect delimiter +COPY contestant FROM '/Users/jefdavi/wd/cstore2/data/contestants.1.csv' + WITH DELIMITER '|'; -- ERROR + +-- COPY with invalid program +COPY contestant FROM PROGRAM 'invalid_program' WITH CSV; -- ERROR + +-- COPY into uncompressed table from file +COPY contestant FROM '/Users/jefdavi/wd/cstore2/data/contestants.1.csv' WITH CSV; + +-- COPY into uncompressed table from program +COPY contestant FROM PROGRAM 'cat /Users/jefdavi/wd/cstore2/data/contestants.2.csv' WITH CSV; + +-- COPY into compressed table +set cstore.compression = 'pglz'; +COPY contestant_compressed FROM '/Users/jefdavi/wd/cstore2/data/contestants.1.csv' WITH CSV; + +-- COPY into uncompressed table from program +COPY contestant_compressed FROM PROGRAM 'cat /Users/jefdavi/wd/cstore2/data/contestants.2.csv' + WITH CSV; +set cstore.compression to default; + +-- Test column list +CREATE TABLE famous_constants (id int, name text, value real) + USING cstore_tableam; +COPY famous_constants (value, name, id) FROM STDIN WITH CSV; +3.141,pi,1 +2.718,e,2 +0.577,gamma,3 +5.291e-11,bohr radius,4 +\. + +COPY famous_constants (name, value) FROM STDIN WITH CSV; +avagadro,6.022e23 +electron mass,9.109e-31 +proton mass,1.672e-27 +speed of light,2.997e8 +\. + +SELECT * FROM famous_constants ORDER BY id, name; + +DROP TABLE famous_constants; diff --git a/sql/am_query.sql b/sql/am_query.sql new file mode 100644 index 000000000..7ac8c2ea4 --- /dev/null +++ b/sql/am_query.sql @@ -0,0 +1,34 @@ +-- +-- Test querying cstore_fdw tables. +-- + +-- Settings to make the result deterministic +SET datestyle = "ISO, YMD"; + +-- Query uncompressed data +SELECT count(*) FROM contestant; +SELECT avg(rating), stddev_samp(rating) FROM contestant; +SELECT country, avg(rating) FROM contestant WHERE rating > 2200 + GROUP BY country ORDER BY country; +SELECT * FROM contestant ORDER BY handle; + +-- Query compressed data +SELECT count(*) FROM contestant_compressed; +SELECT avg(rating), stddev_samp(rating) FROM contestant_compressed; +SELECT country, avg(rating) FROM contestant_compressed WHERE rating > 2200 + GROUP BY country ORDER BY country; +SELECT * FROM contestant_compressed ORDER BY handle; + +-- Verify that we handle whole-row references correctly +SELECT to_json(v) FROM contestant v ORDER BY rating LIMIT 1; + +-- Test variables used in expressions +CREATE TABLE union_first (a int, b int) USING cstore_tableam; +CREATE TABLE union_second (a int, b int) USING cstore_tableam; + +INSERT INTO union_first SELECT a, a FROM generate_series(1, 5) a; +INSERT INTO union_second SELECT a, a FROM generate_series(11, 15) a; + +(SELECT a*1, b FROM union_first) union all (SELECT a*1, b FROM union_second); + +DROP TABLE union_first, union_second; diff --git a/sql/am_truncate.sql b/sql/am_truncate.sql new file mode 100644 index 000000000..3fdce1d82 --- /dev/null +++ b/sql/am_truncate.sql @@ -0,0 +1,122 @@ +-- +-- Test the TRUNCATE TABLE command for cstore_fdw tables. +-- + +-- print whether we're using version > 10 to make version-specific tests clear +SHOW server_version \gset +SELECT substring(:'server_version', '\d+')::int > 10 AS version_above_ten; + +-- CREATE a cstore_fdw table, fill with some data -- +CREATE TABLE cstore_truncate_test (a int, b int) USING cstore_tableam; +CREATE TABLE cstore_truncate_test_second (a int, b int) USING cstore_tableam; +-- COMPRESSED +CREATE TABLE cstore_truncate_test_compressed (a int, b int) USING cstore_tableam; +CREATE TABLE cstore_truncate_test_regular (a int, b int); + +INSERT INTO cstore_truncate_test select a, a from generate_series(1, 10) a; + +set cstore.compression = 'pglz'; +INSERT INTO cstore_truncate_test_compressed select a, a from generate_series(1, 10) a; +INSERT INTO cstore_truncate_test_compressed select a, a from generate_series(1, 10) a; +set cstore.compression to default; + +-- query rows +SELECT * FROM cstore_truncate_test; + +TRUNCATE TABLE cstore_truncate_test; + +SELECT * FROM cstore_truncate_test; + +SELECT COUNT(*) from cstore_truncate_test; + +SELECT count(*) FROM cstore_truncate_test_compressed; +TRUNCATE TABLE cstore_truncate_test_compressed; +SELECT count(*) FROM cstore_truncate_test_compressed; + +SELECT pg_relation_size('cstore_truncate_test_compressed'); + +INSERT INTO cstore_truncate_test select a, a from generate_series(1, 10) a; +INSERT INTO cstore_truncate_test_regular select a, a from generate_series(10, 20) a; +INSERT INTO cstore_truncate_test_second select a, a from generate_series(20, 30) a; + +SELECT * from cstore_truncate_test; + +SELECT * from cstore_truncate_test_second; + +SELECT * from cstore_truncate_test_regular; + +-- make sure multi truncate works +-- notice that the same table might be repeated +TRUNCATE TABLE cstore_truncate_test, + cstore_truncate_test_regular, + cstore_truncate_test_second, + cstore_truncate_test; + +SELECT * from cstore_truncate_test; +SELECT * from cstore_truncate_test_second; +SELECT * from cstore_truncate_test_regular; + +-- test if truncate on empty table works +TRUNCATE TABLE cstore_truncate_test; +SELECT * from cstore_truncate_test; + +-- test if a cached truncate from a pl/pgsql function works +CREATE FUNCTION cstore_truncate_test_regular_func() RETURNS void AS $$ +BEGIN + INSERT INTO cstore_truncate_test_regular select a, a from generate_series(1, 10) a; + TRUNCATE TABLE cstore_truncate_test_regular; +END;$$ +LANGUAGE plpgsql; + +SELECT cstore_truncate_test_regular_func(); +-- the cached plans are used stating from the second call +SELECT cstore_truncate_test_regular_func(); +DROP FUNCTION cstore_truncate_test_regular_func(); + +DROP TABLE cstore_truncate_test, cstore_truncate_test_second; +DROP TABLE cstore_truncate_test_regular; +DROP TABLE cstore_truncate_test_compressed; + +-- test truncate with schema +CREATE SCHEMA truncate_schema; +-- COMPRESSED +CREATE TABLE truncate_schema.truncate_tbl (id int) USING cstore_tableam; +set cstore.compression = 'pglz'; +INSERT INTO truncate_schema.truncate_tbl SELECT generate_series(1, 100); +set cstore.compression to default; +SELECT COUNT(*) FROM truncate_schema.truncate_tbl; + +TRUNCATE TABLE truncate_schema.truncate_tbl; +SELECT COUNT(*) FROM truncate_schema.truncate_tbl; + +set cstore.compression = 'pglz'; +INSERT INTO truncate_schema.truncate_tbl SELECT generate_series(1, 100); +set cstore.compression to default; +-- create a user that can not truncate +CREATE USER truncate_user; +GRANT USAGE ON SCHEMA truncate_schema TO truncate_user; +GRANT SELECT ON TABLE truncate_schema.truncate_tbl TO truncate_user; +REVOKE TRUNCATE ON TABLE truncate_schema.truncate_tbl FROM truncate_user; + +SELECT current_user \gset + +\c - truncate_user +-- verify truncate command fails and check number of rows +SELECT count(*) FROM truncate_schema.truncate_tbl; +TRUNCATE TABLE truncate_schema.truncate_tbl; +SELECT count(*) FROM truncate_schema.truncate_tbl; + +-- switch to super user, grant truncate to truncate_user +\c - :current_user +GRANT TRUNCATE ON TABLE truncate_schema.truncate_tbl TO truncate_user; + +-- verify truncate_user can truncate now +\c - truncate_user +SELECT count(*) FROM truncate_schema.truncate_tbl; +TRUNCATE TABLE truncate_schema.truncate_tbl; +SELECT count(*) FROM truncate_schema.truncate_tbl; +\c - :current_user + +-- cleanup +DROP SCHEMA truncate_schema CASCADE; +DROP USER truncate_user; diff --git a/sql/extension_create.sql b/sql/extension_create.sql new file mode 100644 index 000000000..2e73f5be7 --- /dev/null +++ b/sql/extension_create.sql @@ -0,0 +1,4 @@ + +-- Install cstore_fdw +CREATE EXTENSION cstore_fdw; + diff --git a/sql/fdw_clean.sql b/sql/fdw_clean.sql new file mode 100644 index 000000000..ecd4d67a1 --- /dev/null +++ b/sql/fdw_clean.sql @@ -0,0 +1,10 @@ +DROP FOREIGN TABLE collation_block_filtering_test; +DROP FOREIGN TABLE test_block_filtering; +DROP FOREIGN TABLE test_null_values; +DROP FOREIGN TABLE test_other_types; +DROP FOREIGN TABLE test_range_types; +DROP FOREIGN TABLE test_enum_and_composite_types; +DROP TYPE composite_type; +DROP TYPE enum_type; +DROP FOREIGN TABLE test_datetime_types; +DROP FOREIGN TABLE test_array_types;