Skip to content

Commit 423e12b

Browse files
committed
Initial inet data type implementation, merge with master
1 parent ea52a24 commit 423e12b

File tree

29 files changed

+17261
-2065
lines changed

29 files changed

+17261
-2065
lines changed

Makefile

+1-1
Original file line numberDiff line numberDiff line change
@@ -27,7 +27,7 @@ $(info There is NO PostGIS support for SQLite FDW)
2727
endif
2828

2929
# Tests for PostgreSQL data types support
30-
DATA_TYPE_TESTS = types/bitstring types/bool types/float4 types/float8 types/int4 types/int8 types/json types/numeric types/macaddr types/macaddr8 types/out_of_range types/timestamp types/uuid
30+
DATA_TYPE_TESTS = types/bitstring types/bool types/float4 types/float8 types/inet types/int4 types/int8 types/json types/numeric types/macaddr types/macaddr8 types/out_of_range types/timestamp types/uuid
3131
# Tests with different versions with GIS support and without GIS support
3232
GIS_DEP_TESTS = $(GIS_DEP_TESTS_DIR)/type $(GIS_DEP_TESTS_DIR)/auto_import $(GIS_DEP_TESTS_DIR)/$(GIS_TEST)
3333

README.md

+109-3
Original file line numberDiff line numberDiff line change
@@ -49,18 +49,20 @@ Features
4949
- `double precision`, `float` and `numeric`: `real` values and special values with `text` affinity (`+Infinity`, `-Infinity`, `NaN`),
5050
- `macaddr`: `text`(12..17) or `blob`(6) or `integer`,
5151
- `macaddr8`: `text`(16..23) or `blob`(8) or `integer`,
52-
- `json`: `text`(default) or `blob` as SQLite `jsonb` object.
52+
- `json`: `text`(default) or `blob` as SQLite `jsonb` object,
53+
- `inet`: `text`(8..49) or `blob`(4..5 IP v4, 16..17 IP v6) or `integer` (IP v4).
5354
- Support mixed SQLite [data affinity](https://www.sqlite.org/datatype3.html) output (`INSERT`/`UPDATE`) for such data types as
5455
- `timestamp`: `text`(default) or `int`,
5556
- `uuid`: `text`(36) or `blob`(16)(default),
5657
- `macaddr`: `text`(17) or `blob`(6) or `integer`(default),
57-
- `macaddr8`: `text`(23) or `blob`(8) or `integer`(default).
58+
- `macaddr8`: `text`(23) or `blob`(8) or `integer`(default),
59+
- `inet`: `integer` (default for IP v4) or `blob`(4..5 IP v4, 16..17 default for IP v6) or `text`(8..49).
5860
- Full support for `+Infinity` (means ∞) and `-Infinity` (means -∞) special values for IEEE 754-2008 numbers in `double precision`, `float` and `numeric` columns including such conditions as ` n < '+Infinity'` or ` m > '-Infinity'`.
5961
- Bidirectional data transformation for `geometry` and `geography` data types for SpatiaLite ↔ PostGIS. [EWKB](https://libgeos.org/specifications/wkb/#extended-wkb) data transport is used. See [GIS support description](GIS.md).
6062

6163
### Pushing down
6264
- `WHERE` clauses are pushdowned
63-
- Aggregate function are pushdowned
65+
- Aggregate functions are pushdowned
6466
- `ORDER BY` is pushdowned
6567
- Joins (left/right/inner/cross/semi) are pushdowned
6668
- `CASE` expressions are pushdowned.
@@ -267,6 +269,7 @@ SQLite `NULL` affinity always can be transparent converted for a nullable column
267269
| float8 | V+ ||| i | `NULL` | REAL |
268270
|[geometry](GIS.md)||| V+ ||| BLOB |
269271
|[geography](GIS.md)||| V+ ||| BLOB |
272+
| inet | ✔- ||V<br>(Len=4..5, 16..17)| V+ | `NULL` | INT v4, BLOB v6 |
270273
| int2 | ✔- | ? ||| `NULL` | INT |
271274
| int4 | ✔- | ? ||| `NULL` | INT |
272275
| int8 || ? ||| `NULL` | INT |
@@ -641,6 +644,17 @@ Array support is experimental. Please be careful.
641644
- `sqlite_fdw` UUID values support exists only for `uuid` columns in foreign table. SQLite documentation recommends to store UUID as value with both `blob` and `text` [affinity](https://www.sqlite.org/datatype3.html). `sqlite_fdw` can pushdown both reading and filtering both `text` and `blob` values.
642645
- Expected affinity of UUID value in SQLite table determined by `column_type` option of the column
643646
for `INSERT` and `UPDATE` commands. PostgreSQL supports both `blob` and `text` [affinity](https://www.sqlite.org/datatype3.html).
647+
- Usual form of UUID from a value with `blob` affinity can be generated with such SQLite query as
648+
```sql
649+
select case when typeof(u) = 'blob' then
650+
substr(lower(hex(u)),1,8) || '-' ||
651+
substr(lower(hex(u)),9,4) || '-' ||
652+
substr(lower(hex(u)),13,4) || '-' ||
653+
substr(lower(hex(u)),17,4) || '-' ||
654+
substr(lower(hex(u)),21,12)
655+
else null end uuid_canon
656+
from "type_UUID";
657+
```
644658

645659
### bit and varbit support
646660
- `sqlite_fdw` PostgreSQL `bit`/`varbit` values support based on `int` SQLite data affinity, because there is no per bit operations for SQLite `blob` affinity data. Maximum SQLite `int` affinity value is 8 bytes length, hence maximum `bit`/`varbit` values length is 64 bits.
@@ -649,6 +663,98 @@ for `INSERT` and `UPDATE` commands. PostgreSQL supports both `blob` and `text` [
649663
### MAC address support
650664
- `sqlite_fdw` PostgreSQL `macaddr`/`macaddr8` values support based on `int` SQLite data affinity, because there is no per bit operations for SQLite `blob` affinity data. For `macaddr` out of range error is possible because this type is 6 bytes length, but SQLite `int` can store value up to 8 bytes.
651665
- `sqlite_fdw` doesn't pushdown any operations with MAC adresses because there is 3 possible affinities for it in SQLite: `integer`, `blob` and `text`.
666+
### IP address support
667+
- `sqlite_fdw` PostgreSQL `inet` values support based on `int` SQLite data affinity for IP v4 and `blob` SQLite data affinity for IP v6.
668+
- Usual form of IP v4 address with cidr from a value with `integer` affinity can be generated with such SQLite query as
669+
```sql
670+
select case when typeof(ip) = 'integer'
671+
then ((ip >> 24) & 255) || '.' || ((ip >> 16) & 255) || '.' || ((ip >> 8) & 255) || '.' || (ip & 255) ||
672+
case when (ip >> 32) > 0 then '/' || (ip >> 32) else '' end
673+
else null
674+
end ipv4_text,
675+
ip
676+
from "type_INET";
677+
```
678+
- Usual form of IP v6 or IP v4 address from a value with `blob` affinity can be generated with such SQLite query as
679+
```sql
680+
select
681+
case
682+
when typeof(ip) = 'blob' and (length(ip) = 16 or length(ip) = 17) then
683+
lower(
684+
substr(hex(ip),1,4) || ':' ||
685+
substr(hex(ip),5,4) || ':' ||
686+
substr(hex(ip),9,4) || ':' ||
687+
substr(hex(ip),13,4) || ':' ||
688+
substr(hex(ip),17,4) || ':' ||
689+
substr(hex(ip),21,4) || ':' ||
690+
substr(hex(ip),25,4) || ':' ||
691+
substr(hex(ip),29,4)
692+
) ||
693+
case
694+
when length(ip) = 17 then
695+
'/' || ((instr('123456789ABCDEF', substr(hex(ip),33,1)) << 4) + instr('123456789ABCDEF', substr(hex(ip),34,1)))
696+
else ''
697+
end
698+
when typeof(ip) = 'blob' and (length(ip) = 4 or length(ip) = 5) then
699+
((instr('123456789ABCDEF', substr(hex(ip),1,1)) << 4) + instr('123456789ABCDEF', substr(hex(ip),2,1))) || '.' ||
700+
((instr('123456789ABCDEF', substr(hex(ip),3,1)) << 4) + instr('123456789ABCDEF', substr(hex(ip),4,1))) || '.' ||
701+
((instr('123456789ABCDEF', substr(hex(ip),5,1)) << 4) + instr('123456789ABCDEF', substr(hex(ip),6,1))) || '.' ||
702+
((instr('123456789ABCDEF', substr(hex(ip),7,1)) << 4) + instr('123456789ABCDEF', substr(hex(ip),8,1)))
703+
||
704+
case
705+
when length(ip) = 5 then
706+
'/' || ((instr('123456789ABCDEF', substr(hex(ip),9,1)) << 4) + instr('123456789ABCDEF', substr(hex(ip),10,1)))
707+
else ''
708+
end
709+
else null
710+
end as ip_text
711+
from "type_INET";
712+
```
713+
- IP address with possible cidr addition enconing as SQLite BLOB value based on such conventions
714+
```
715+
m - mask as number of bits
716+
a - bytes of IP address
717+
718+
IP v4 + cidr
719+
┏━━━┳━━━┳━━━┳━━━┳━━━┓
720+
┃ a ┃ a ┃ a ┃ a ┃ m ┃
721+
┗━━━┻━━━┻━━━┻━━━┻━━━┛
722+
0 1 2 3 4 - byte index
723+
IP v6 + cidr
724+
┏━━━┳━━━┳━━━┳━━━┳━━━┳━━━┳━━━┳━━━┳━━━┳━━━┳━━━┳━━━┳━━━┳━━━┳━━━┳━━━┳━━━┳━━━┓
725+
┃ a ┃ a ┃ a ┃ a ┃ a ┃ a ┃ a ┃ a ┃ a ┃ a ┃ a ┃ a ┃ a ┃ a ┃ a ┃ a ┃ a ┃ m ┃
726+
┗━━━┻━━━┻━━━┻━━━┻━━━┻━━━┻━━━┻━━━┻━━━┻━━━┻━━━┻━━━┻━━━┻━━━┻━━━┻━━━┻━━━┻━━━┛
727+
0 1 2 3 4 5 5 7 8 9 10 11 12 13 14 15 16 17 - byte index
728+
729+
IP v4
730+
┏━━━┳━━━┳━━━┳━━━┓
731+
┃ a ┃ a ┃ a ┃ a ┃
732+
┗━━━┻━━━┻━━━┻━━━┛
733+
0 1 2 3 - byte index
734+
IP v6
735+
┏━━━┳━━━┳━━━┳━━━┳━━━┳━━━┳━━━┳━━━┳━━━┳━━━┳━━━┳━━━┳━━━┳━━━┳━━━┳━━━┳━━━┓
736+
┃ a ┃ a ┃ a ┃ a ┃ a ┃ a ┃ a ┃ a ┃ a ┃ a ┃ a ┃ a ┃ a ┃ a ┃ a ┃ a ┃ a ┃
737+
┗━━━┻━━━┻━━━┻━━━┻━━━┻━━━┻━━━┻━━━┻━━━┻━━━┻━━━┻━━━┻━━━┻━━━┻━━━┻━━━┻━━━┛
738+
0 1 2 3 4 5 5 7 8 9 10 11 12 13 14 15 16 - byte index
739+
```
740+
- IP address v4 with possible cidr addition enconing as SQLite integer based on such conventions
741+
```
742+
m - mask as number of bits
743+
a - IP address bytes
744+
745+
IP v4 + cidr
746+
┏━━━┳━━━┳━━━┳━━━┳━━━┓
747+
┃ m ┃ a ┃ a ┃ a ┃ a ┃
748+
┗━━━┻━━━┻━━━┻━━━┻━━━┛
749+
0 1 2 3 4 - byte index
750+
751+
IP v4
752+
┏━━━┳━━━┳━━━┳━━━┓
753+
┃ a ┃ a ┃ a ┃ a ┃
754+
┗━━━┻━━━┻━━━┻━━━┛
755+
0 1 2 3 - byte index
756+
```
757+
- `sqlite_fdw` doesn't pushdown any operations with IP adresses because there is 3 possible affinities for it in SQLite: `integer`, `blob` and `text`.
652758

653759
### JSON support and operators
654760
- Operators `->` and `->>` for `json` and `jsonb` are pushed down. This means if you deal with a foreign table only, you can use SQLite syntax of `->` and `->>` operators which is more rich than PostgreSQL syntax. In PostgreSQL this operators means only 1-leveled extraction after one call, but possible multilevel extraction in one call of the operator in SQLite. You can extract `'{"a": 2, "c": [4, 5, {"f": 7}]}' ->'c' -> 2` with result `{"f":7}` both for PostgreSQL and SQLite tables, but `'{"a": 2, "c": [4, 5, {"f": 7}]}' ->'$.c[2]'` possible only in SQLite and for a foreign table.

deparse.c

+58
Original file line numberDiff line numberDiff line change
@@ -33,9 +33,11 @@
3333
#include "parser/parsetree.h"
3434
#include "parser/parse_type.h"
3535
#include "utils/builtins.h"
36+
#include "utils/inet.h"
3637
#include "utils/lsyscache.h"
3738
#include "utils/syscache.h"
3839
#include "utils/typcache.h"
40+
#include <sys/socket.h>
3941

4042
/*
4143
* Global context for sqlite_foreign_expr_walker's search of an expression tree.
@@ -364,6 +366,7 @@ sqlite_deparsable_data_type(Param *p)
364366
case MACADDR8OID:
365367
case JSONOID:
366368
case JSONBOID:
369+
case INETOID:
367370
return true;
368371
}
369372
#ifdef SQLITE_FDW_GIS_ENABLE
@@ -2455,6 +2458,16 @@ sqlite_deparse_column_ref(StringInfo buf, int varno, int varattno, PlannerInfo *
24552458
appendStringInfoString(buf, ")");
24562459
break;
24572460
}
2461+
case INETOID:
2462+
{
2463+
elog(DEBUG2, "IP addr unification for \"%s\"", colname);
2464+
appendStringInfoString(buf, "sqlite_fdw_ipaddr_blob(");
2465+
if (qualify_col)
2466+
ADD_REL_QUALIFIER(buf, varno);
2467+
appendStringInfoString(buf, sqlite_quote_identifier(colname, '`'));
2468+
appendStringInfoString(buf, ")");
2469+
break;
2470+
}
24582471
default:
24592472
{
24602473
no_unification = true;
@@ -2818,6 +2831,24 @@ sqlite_deparse_direct_update_sql(StringInfo buf, PlannerInfo *root,
28182831
appendStringInfo(buf, "sqlite_fdw_macaddr_blob(");
28192832
special_affinity = true;
28202833
}
2834+
else if (pg_attyp == INETOID)
2835+
{
2836+
if (preferred_affinity == SQLITE_TEXT)
2837+
{
2838+
appendStringInfo(buf, "sqlite_fdw_ipaddr_str(");
2839+
special_affinity = true;
2840+
}
2841+
else if (preferred_affinity == SQLITE_INTEGER)
2842+
{
2843+
appendStringInfo(buf, "sqlite_fdw_ipaddr_int(");
2844+
special_affinity = true;
2845+
}
2846+
else if (preferred_affinity == SQLITE_NULL)
2847+
{
2848+
appendStringInfo(buf, "sqlite_fdw_ipaddr_native(");
2849+
special_affinity = true;
2850+
}
2851+
}
28212852

28222853
sqlite_deparse_expr((Expr *) tle->expr, &context);
28232854

@@ -3255,6 +3286,33 @@ sqlite_deparse_const(Const *node, deparse_expr_cxt *context, int showtype)
32553286
appendStringInfo(buf, ")");
32563287
}
32573288
break;
3289+
case INETOID:
3290+
{
3291+
inet *pg_inet = DatumGetInetP(node->constvalue);
3292+
unsigned char bits = ip_bits(pg_inet);
3293+
unsigned char *ipaddr = pg_inet->inet_data.ipaddr;
3294+
3295+
appendStringInfo(buf, "X\'");
3296+
for (int i = 0; i < ip_addrsize(pg_inet); i++)
3297+
{
3298+
int d1 = (ipaddr[i] >> 4) & 0x0F;
3299+
int d2 = ipaddr[i] & 0x0F;
3300+
3301+
appendStringInfoChar(buf, hex_dig[d1]);
3302+
appendStringInfoChar(buf, hex_dig[d2]);
3303+
}
3304+
/* Is here an address mask? */
3305+
if (bits < ip_maxbits(pg_inet))
3306+
{
3307+
int d1 = (bits >> 4) & 0x0F;
3308+
int d2 = bits & 0x0F;
3309+
3310+
appendStringInfoChar(buf, hex_dig[d1]);
3311+
appendStringInfoChar(buf, hex_dig[d2]);
3312+
}
3313+
appendStringInfo(buf, "\'");
3314+
}
3315+
break;
32583316
default:
32593317
{
32603318
if (listed_datatype_oid(node->consttype, -1, postGisSQLiteCompatibleTypes))

0 commit comments

Comments
 (0)