The entire connection string is
jdbc:postgresql://mypostgresserver01:5432/vegdb01
Minimalistic Oracle contains a collection of practical examples from my encounters with Oracle technologies. When relevant, I also write about other technologies, like Linux or PostgreSQL. Many of the posts starts with "how to" since they derive directly from my own personal experience. My goal is to provide simple examples, so that they can be easily adapted to other situations.
CREATE TABLE regional_orders( id NUMBER, country_code VARCHAR2(5), region_code VARCHAR2(20), customer_id NUMBER, order_date DATE, order_total NUMBER(8,2), CONSTRAINT regional_orders_pk PRIMARY KEY (id) ) PARTITION BY LIST (country_code,region_code) ( PARTITION NORWAY_SOUTH_WEST VALUES ( ( 'NOR','AUST-AGDER'), ( 'NOR','VEST-AGDER'), ( 'NOR','ROGALAND') ), PARTITION NORWAY_WEST VALUES ( ( 'NOR','HORDALAND'), ( 'NOR','SOGN OG FJORDANDE'), ( 'NOR','MØRE OG ROMSDAL') ), PARTITION NORWAY_CENTRAL VALUES ( ( 'NOR','TRØNDELAG') ), PARTITION NORWAY_EAST VALUES ( ( 'NOR','BUSKERUD'), ( 'NOR','HEDMARK'), ( 'NOR','TELEMARK') ) );Incoming data that has any of the combinations below, will enter the partition NORWAY_SOUTH_WEST
'NOR','AUST-AGDER' 'NOR','VEST-AGDER' 'NOR','ROGALAND'
select partition_name,partition_position,tablespace_name from user_tab_partitions where table_name='REGIONAL_ORDERS';
PARTITION_NAME | PARTITION_POSITION | TABLESPACE_NAME |
---|---|---|
NORWAY_SOUTH_WEST | 1 | USERS |
NORWAY_WEST | 2 | USERS |
NORWAY_CENTRAL | 3 | USERS |
NORWAY_EAST | 4 | USERS |
SELECT PARTITIONING_TYPE,PARTITION_COUNT,PARTITIONING_KEY_COUNT FROM USER_PART_TABLES where table_name='REGIONAL_ORDERS';
PARTITIONING_TYPE | PARTITION_COUNT | PARTITIONING_KEY_COUNT |
---|---|---|
LIST | 4 | 2 |
SELECT column_name,column_position FROM USER_PART_KEY_COLUMNS where name='REGIONAL_ORDERS';
COLUMN_NAME | COLUMN_POSITION |
---|---|
COUNTRY_CODE | 1 |
REGION_CODE | 2 |
insert into regional_orders values (1,'NOR','ROGALAND',3344,'04.01.2019', 1000); commit;
exec DBMS_STATS.GATHER_TABLE_STATS (OwnName => 'SCOTT',TabName => 'REGIONAL_ORDERS');
select partition_name, num_rows from user_tab_partitions where table_name='REGIONAL_ORDERS';
PARTITION_NAME | NUM_ROWS |
---|---|
NORWAY_CENTRAL | 0 |
NORWAY_EAST | 0 |
NORWAY_SOUTH_WEST | 1 |
NORWAY_WEST | 0 |
insert into regional_orders values (2,'NOR','BUSKERUD',3345,'04.01.2019', 1200); COMMIT;Analyze again:
exec DBMS_STATS.GATHER_TABLE_STATS (OwnName => 'SCOTT',TabName => 'REGIONAL_ORDERS');
select partition_name, num_rows from user_tab_partitions where table_name='REGIONAL_ORDERS';
PARTITION_NAME | NUM_ROWS |
---|---|
NORWAY_CENTRAL | 0 |
NORWAY_EAST | 1 |
NORWAY_SOUTH_WEST | 1 |
NORWAY_WEST | 0 |
insert into regional_orders values (3,'NOR','NORDLAND',3346,'04.01.2019', 1100); ORA-14400: inserted partition key does not map to any partition
CREATE TABLE regional_orders( id NUMBER, country_code VARCHAR2(5), region_code VARCHAR2(20), customer_id NUMBER, order_date DATE, order_total NUMBER(8,2), CONSTRAINT regional_orders_pk PRIMARY KEY (id) ) PARTITION BY LIST (country_code,region_code) ( PARTITION NORWAY_SOUTH_WEST VALUES ( ( 'NOR','AUST-AGDER'), ( 'NOR','VEST-AGDER'), ( 'NOR','ROGALAND') ), PARTITION NORWAY_WEST VALUES ( ( 'NOR','HORDALAND'), ( 'NOR','SOGN OG FJORDANDE'), ( 'NOR','MØRE OG ROMSDAL') ), PARTITION NORWAY_CENTRAL VALUES ( ( 'NOR','TRØNDELAG') ), PARTITION NORWAY_EAST VALUES ( ( 'NOR','BUSKERUD'), ( 'NOR','HEDMARK'), ( 'NOR','TELEMARK') ), PARTITION NORWAY_REST VALUES (DEFAULT) ) ;
CREATE TABLE regional_orders( id NUMBER, country_code VARCHAR2(5), region_code VARCHAR2(20), customer_id NUMBER, order_date DATE, order_total NUMBER(8,2), CONSTRAINT regional_orders_pk PRIMARY KEY (id) ) PARTITION BY LIST (country_code,region_code) AUTOMATIC ( PARTITION NORWAY_SOUTH_WEST VALUES ( ( 'NOR','AUST-AGDER'), ( 'NOR','VEST-AGDER'), ( 'NOR','ROGALAND') ), PARTITION NORWAY_WEST VALUES ( ( 'NOR','HORDALAND'), ( 'NOR','SOGN OG FJORDANDE'), ( 'NOR','MØRE OG ROMSDAL') ), PARTITION NORWAY_CENTRAL VALUES ( ( 'NOR','TRØNDELAG') ), PARTITION NORWAY_EAST VALUES ( ( 'NOR','BUSKERUD'), ( 'NOR','HEDMARK'), ( 'NOR','TELEMARK') ) ) ;
'NOR','NORDLAND'may logically belong to the same partition as the values
'NOR','TROMS' and 'NOR','FINNMARK'If I knew such a value may be sent at the time of table creation, I would of course create another partition, like this:
PARTITION NORWAY_NORTH VALUES ( ( 'NOR','NORDLAND'), ( 'NOR','TROMS'), ( 'NOR','FINNMARK') )
select partition_name,high_value from dba_tab_partitions where table_name='MYTABLE' and high_value='201805';
ORA-00997: illegal use of LONG datatype
CREATE GLOBAL TEMPORARY TABLE PARTITION_HIGH_VAL ON COMMIT PRESERVE ROWS AS select PARTITION_NAME, to_lob(high_value) as text_clob from dba_tab_partitions where TABLE_OWNER='SH' and table_name='SALES';
select PARTITION_NAME,TO_CHAR(TEXT_CLOB) "high value" from partition_high_Val;
PARTITION_NAME | high value |
---|---|
SYS_P79451 | 201806 |
SYS_P71617 | 201805 |
SYS_P70243 | 201803 |
SYS_P70231 | 201804 |
SYS_P70112 | 201802 |
SQLNET.CRYPTO_CHECKSUM_SERVER = requested SQLNET.CRYPTO_CHECKSUM_TYPES_SERVER= (SHA256, SHA384, SHA512, SHA1, MD5)All of the hash algorithms in the list create a checksum that changes if the data is altered in any way.
CREATE MATERIALIZED VIEW LOG ON DATE_TO_SEQNO TABLESPACE DATA1 CACHE ENABLE ROW MOVEMENT WITH ROWID (SEQNO, RDATE) INCLUDING NEW VALUES;
CREATE MATERIALIZED VIEW SEQ_AGGR_INFO SEGMENT CREATION IMMEDIATE TABLESPACE DATA1 CACHE ENABLE ROW MOVEMENT ROW STORE COMPRESS ADVANCED BUILD IMMEDIATE REFRESH FAST ON COMMIT ENABLE QUERY REWRITE AS select RDATE, count(SEQNO) as antall, max(SEQNO) as makssekvens from DATE_TO_SEQNO group by dato order by 1, 2;
SELECT mview_name,rewrite_enabled,refresh_mode,refresh_method, last_refresh_type, last_refresh_date,last_refresh_end_time,staleness,compile_state FROM USER_MVIEWS;
MVIEW_NAME | REWRITE_ENABLED | REFRESH_MODE | REFRESH_METHOD | LAST_REFRESH_TYPE | LAST_REFRESH_DATE | LAST_REFRESH_END_TIME | STALENESS | COMPILE_STATE |
---|---|---|---|---|---|---|---|---|
SEQ_AGGR_INFO | Y | COMMIT | FAST | COMPLETE | 18.01.2019 13:58:24 | 18.01.2019 13:58:24 | FRESH | VALID |
SELECT master,log_table,rowids, primary_key,filter_columns, include_new_values FROM USER_MVIEW_LOGS;
MASTER | LOG_TABLE | ROWIDS | PRIMARY_KEY | FILTER_COLUMNS | INCLUDE_NEW_VALUES |
---|---|---|---|---|---|
DATE_TO_SEQNO | MLOG$_DATE_TO_SEQNO | YES | NO | YES | YES |
var B1 VARCHAR2(10); EXEC :B1 := to_date('01.01.2018','dd.mm.yyyy'); set lines 200 set autot on set timing on select max(seqno) from DATE_TO_SEQNO where rdate = :B1;
MAX(SEKVENSNUMMER) ------------------ 18580449 Elapsed: 00:00:00.05 Execution Plan ---------------------------------------------------------- Plan hash value: 1856567295 -------------------------------------------------------------------------------------------------------- | Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time | -------------------------------------------------------------------------------------------------------- | 0 | SELECT STATEMENT | | 1 | 14 | 243 (0)| 00:00:01 | | 1 | SORT AGGREGATE | | 1 | 14 | | | |* 2 | MAT_VIEW REWRITE ACCESS FULL| SEQ_AGGR_INFO | 1 | 14 | 243 (0)| 00:00:01 | -------------------------------------------------------------------------------------------------------- Predicate Information (identified by operation id): --------------------------------------------------- 2 - filter("SEQ_AGGR_INFO"."RDATE"=:B1)
drop materialized view log on DATE_TO_SEQNO; drop materialized view SEQ_AGGR_INFO;
$ su - postgres Last login: Tue Dec 18 23:03:07 CET 2018 $ pg_config --version PostgreSQL 11.1
[postgres@til0drift-dbteam-sandbox-pgsql01 ~]$ psql psql (11.2) Type "help" for help. postgres=# select version(); version --------------------------------------------------------------------------------------------------------- PostgreSQL 11.2 on x86_64-pc-linux-gnu, compiled by gcc (GCC) 4.8.5 20150623 (Red Hat 4.8.5-36), 64-bit (1 row)