Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

WIP: PostgreSQL JSON and jsonb types #561

Merged
merged 7 commits into from
Jan 30, 2017
Merged
Show file tree
Hide file tree
Changes from 4 commits
Commits
File filter

Filter by extension

Filter by extension


Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
1 change: 1 addition & 0 deletions diesel/Cargo.toml
Original file line number Diff line number Diff line change
Expand Up @@ -17,6 +17,7 @@ byteorder = "0.3.*"
quickcheck = { version = "0.3.1", optional = true }
chrono = { version = "^0.2.17", optional = true }
uuid = { version = ">=0.2.0, <0.4.0", optional = true, features = ["use_std"] }
serde_json = { version = "0.8", optional = true }

[dev-dependencies]
quickcheck = "0.3.1"
Expand Down
121 changes: 121 additions & 0 deletions diesel/src/pg/types/json.rs
Original file line number Diff line number Diff line change
@@ -0,0 +1,121 @@
//! Support for JSON and `jsonb` values under PostgreSQL.

extern crate serde_json;

use std::io::prelude::*;
use std::error::Error;

use pg::Pg;
use types::{self, ToSql, IsNull, FromSql};

// The OIDs used to identify `json` and `jsonb` are not documented anywhere
// obvious, but they are discussed on various PostgreSQL mailing lists,
// including:
//
// https://www.postgresql.org/message-id/CA+mi_8Yv2SVOdhAtx-4CbpzoDtaJGkf8QvnushdF8bMgySAbYg@mail.gmail.com
// https://www.postgresql.org/message-id/CA+mi_8bd_g-MDPMwa88w0HXfjysaLFcrCza90+KL9zpRGbxKWg@mail.gmail.com
primitive_impls!(Json -> (serde_json::Value, pg: (114, 199)));
primitive_impls!(Jsonb -> (serde_json::Value, pg: (3802, 3807)));
Copy link
Member

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

I'd like to add a comment on those magic oid/array_oid numbers here, with links to the postgres spec. But I can't find them, except for in other implementations and the source code…

Copy link
Contributor Author

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Unfortunately, my only source for the magic numbers was Googling around and looking at what other libraries did, then confirming that it worked. :-/ I'll keep looking.

Copy link

@jashank jashank Jan 2, 2017

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

The C interface defines, in server/catalog/pg_type.h, the macros JSONOID and JSONBOID as 114 and 3802, respectively. Not sure why there's no better documentation than that.

Copy link
Member

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Yeah, that sounds like a solid reference :) Maybe we can link to a current release: https://github.com/postgres/postgres/blob/REL9_6_1/src/include/catalog/pg_type.h#L623-L627

(We should probably go through the code and add more references for type OIDs… I hate magic numbers)

Copy link

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Seconded. This seems like something that should be added in the pq-sys bindings, too.

Copy link
Member

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

I usually get these by querying the pg_type table FWIW. Eventually I'd like to just load these dynamically, as they technically aren't supposed to be assumed stable (in practice they are though other than user defined types so it's very low priority and possibly not even possible with the rest of the project's goals)


impl FromSql<types::Json, Pg> for serde_json::Value {
fn from_sql(bytes: Option<&[u8]>) -> Result<Self, Box<Error+Send+Sync>> {
let bytes = not_none!(bytes);
serde_json::from_slice(bytes)
.map_err(|e| Box::new(e) as Box<Error+Send+Sync>)
Copy link
Member

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Huh, is that as Box<Error+Send+Sync not inferred?

Copy link
Contributor Author

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Unfortunately, that does not seem to be the case. I tried removing it and got expected trait std::error::Error, found enum pg::types::json::serde_json::Error.

}
}

impl ToSql<types::Json, Pg> for serde_json::Value {
fn to_sql<W: Write>(&self, out: &mut W) -> Result<IsNull, Box<Error+Send+Sync>> {
serde_json::to_writer(out, self)
.map(|_| IsNull::No)
.map_err(|e| Box::new(e) as Box<Error+Send+Sync>)
}
}

impl FromSql<types::Jsonb, Pg> for serde_json::Value {
fn from_sql(bytes: Option<&[u8]>) -> Result<Self, Box<Error+Send+Sync>> {
let bytes = not_none!(bytes);
if bytes[0] != 1 {
return Err("Unsupported JSONB encoding version".into());
}
serde_json::from_slice(&bytes[1..])
.map_err(|e| Box::new(e) as Box<Error+Send+Sync>)
}
}

impl ToSql<types::Jsonb, Pg> for serde_json::Value {
fn to_sql<W: Write>(&self, out: &mut W) -> Result<IsNull, Box<Error+Send+Sync>> {
try!(out.write_all(&[1]));
serde_json::to_writer(out, self)
.map(|_| IsNull::No)
.map_err(|e| Box::new(e) as Box<Error+Send+Sync>)
}
}

#[test]
fn json_to_sql() {
let mut bytes = vec![];
let test_json = serde_json::Value::Bool(true);
ToSql::<types::Json, Pg>::to_sql(&test_json, &mut bytes).unwrap();
assert_eq!(bytes, b"true");
}

#[test]
fn some_json_from_sql() {
let input_json = b"true";
let output_json: serde_json::Value =
FromSql::<types::Json, Pg>::from_sql(Some(input_json)).unwrap();
assert_eq!(output_json, serde_json::Value::Bool(true));
}

#[test]
fn bad_json_from_sql() {
let uuid: Result<serde_json::Value, Box<Error+Send+Sync>> =
FromSql::<types::Json, Pg>::from_sql(Some(b"boom"));
assert_eq!(uuid.unwrap_err().description(), "syntax error");
}

#[test]
fn no_json_from_sql() {
let uuid: Result<serde_json::Value, Box<Error+Send+Sync>> =
FromSql::<types::Json, Pg>::from_sql(None);
assert_eq!(uuid.unwrap_err().description(), "Unexpected null for non-null column");
}

#[test]
fn jsonb_to_sql() {
let mut bytes = vec![];
let test_json = serde_json::Value::Bool(true);
ToSql::<types::Jsonb, Pg>::to_sql(&test_json, &mut bytes).unwrap();
assert_eq!(bytes, b"\x01true");
}

#[test]
fn some_jsonb_from_sql() {
let input_json = b"\x01true";
let output_json: serde_json::Value =
FromSql::<types::Jsonb, Pg>::from_sql(Some(input_json)).unwrap();
assert_eq!(output_json, serde_json::Value::Bool(true));
}

#[test]
fn bad_jsonb_from_sql() {
let uuid: Result<serde_json::Value, Box<Error+Send+Sync>> =
FromSql::<types::Jsonb, Pg>::from_sql(Some(b"\x01boom"));
assert_eq!(uuid.unwrap_err().description(), "syntax error");
}

#[test]
fn bad_jsonb_version_from_sql() {
let uuid: Result<serde_json::Value, Box<Error+Send+Sync>> =
FromSql::<types::Jsonb, Pg>::from_sql(Some(b"\x02true"));
assert_eq!(uuid.unwrap_err().description(), "Unsupported JSONB encoding version");
}

#[test]
fn no_jsonb_from_sql() {
let uuid: Result<serde_json::Value, Box<Error+Send+Sync>> =
FromSql::<types::Jsonb, Pg>::from_sql(None);
assert_eq!(uuid.unwrap_err().description(), "Unexpected null for non-null column");
}
53 changes: 53 additions & 0 deletions diesel/src/pg/types/mod.rs
Original file line number Diff line number Diff line change
Expand Up @@ -5,6 +5,8 @@ mod integers;
mod primitives;
#[cfg(feature = "uuid")]
mod uuid;
#[cfg(feature = "serde_json")]
mod json;

/// PostgreSQL specific SQL types
///
Expand Down Expand Up @@ -88,4 +90,55 @@ pub mod sql_types {

#[doc(hidden)]
pub type Bpchar = ::types::VarChar;

#[cfg(feature = "serde_json")]
/// The JSON SQL type. This type can only be used with `feature =
/// "serde_json"`
///
/// Normally you should prefer `Jsonb` instead, for the reasons
/// discussed there.
///
/// ### [`ToSql`](/diesel/types/trait.ToSql.html) impls
///
/// - [`serde_json::Value`][Value]
///
/// ### [`FromSql`](/diesel/types/trait.FromSql.html) impls
///
/// - [`serde_json`][Value]
///
/// [Value]: https://docs.serde.rs/serde_json/value/enum.Value.html
#[derive(Debug, Clone, Copy, Default)] pub struct Json;

#[cfg(feature = "serde_json")]
/// The `jsonb` SQL type. This type can only be used with `feature =
/// "serde_json"`
///
/// `jsonb` offers [several advantages][adv] over regular JSON:
///
/// > There are two JSON data types: `json` and `jsonb`. They accept almost
/// > identical sets of values as input. The major practical difference
/// > is one of efficiency. The `json` data type stores an exact copy of
/// > the input text, which processing functions must reparse on each
/// > execution; while `jsonb` data is stored in a decomposed binary format
/// > that makes it slightly slower to input due to added conversion
/// > overhead, but significantly faster to process, since no reparsing
/// > is needed. `jsonb` also supports indexing, which can be a significant
/// > advantage.
/// >
/// > ...In general, most applications should prefer to store JSON data as
/// > `jsonb`, unless there are quite specialized needs, such as legacy
/// > assumptions about ordering of object keys.
///
/// [adv]: https://www.postgresql.org/docs/9.6/static/datatype-json.html
///
/// ### [`ToSql`](/diesel/types/trait.ToSql.html) impls
///
/// - [`serde_json::Value`][Value]
///
/// ### [`FromSql`](/diesel/types/trait.FromSql.html) impls
///
/// - [`serde_json`][Value]
///
/// [Value]: https://docs.serde.rs/serde_json/value/enum.Value.html
#[derive(Debug, Clone, Copy, Default)] pub struct Jsonb;
Copy link
Member

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Do you think we should call this type JsonB and have #[doc(hidden)] pub type Jsonb = JsonB to make schema inference happy like we do for VarChar?

}
3 changes: 2 additions & 1 deletion diesel_tests/Cargo.toml
Original file line number Diff line number Diff line change
Expand Up @@ -13,11 +13,12 @@ dotenv = "0.8.0"
[dependencies]
assert_matches = "1.0.1"
chrono = { version = "^0.2.17" }
diesel = { path = "../diesel", default-features = false, features = ["quickcheck", "chrono", "uuid"] }
diesel = { path = "../diesel", default-features = false, features = ["quickcheck", "chrono", "uuid", "serde_json"] }
Copy link
Member

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

I wonder if we should add an everything feature so we use that here (which would also reduce churn in the travis scripts)

diesel_codegen = { path = "../diesel_codegen", optional = true }
dotenv = "0.8.0"
quickcheck = { version = "0.3.1", features = ["unstable"] }
uuid = { version = ">=0.2.0, <0.4.0" }
serde_json = "0.8"

[features]
default = ["with-syntex"]
Expand Down
35 changes: 35 additions & 0 deletions diesel_tests/tests/types.rs
Original file line number Diff line number Diff line change
Expand Up @@ -385,6 +385,41 @@ fn pg_uuid_to_sql_uuid() {
assert!(!query_to_sql_equality::<Uuid, uuid::Uuid>(expected_non_equal_value, value));
}

#[test]
#[cfg(feature = "postgres")]
fn pg_json_from_sql() {
Copy link
Member

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

I think you mean serde_json_value_from_sql here.

extern crate serde_json;

let query = "'true'::json";
let expected_value = serde_json::Value::Bool(true);
assert_eq!(expected_value, query_single_value::<Json, serde_json::Value>(query));
}

// See http://stackoverflow.com/q/32843213/12089 for why we don't have a
// pg_json_to_sql_json test. There's no `'true':json = 'true':json`
// because JSON string representations are ambiguous. We _do_ have this
// test for `jsonb` values.

#[test]
#[cfg(feature = "postgres")]
fn pg_jsonb_from_sql() {
extern crate serde_json;

let query = "'true'::jsonb";
let expected_value = serde_json::Value::Bool(true);
assert_eq!(expected_value, query_single_value::<Jsonb, serde_json::Value>(query));
}

#[test]
#[cfg(feature = "postgres")]
fn pg_jsonb_to_sql_jsonb() {
extern crate serde_json;

let expected_value = "'false'::jsonb";
let value = serde_json::Value::Bool(false);
assert!(query_to_sql_equality::<Jsonb, serde_json::Value>(expected_value, value));
}

#[test]
#[cfg(feature = "postgres")]
fn text_array_can_be_assigned_to_varchar_array_column() {
Expand Down