Skip to content

removing inline sql. #3529

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

Merged
merged 11 commits into from
Feb 18, 2017
Merged
Show file tree
Hide file tree
Changes from all 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
92 changes: 7 additions & 85 deletions src/Adapters/Storage/Postgres/PostgresStorageAdapter.js
Original file line number Diff line number Diff line change
@@ -1,6 +1,7 @@
import { createClient } from './PostgresClient';
import Parse from 'parse/node';
import _ from 'lodash';
import sql from './sql';

const PostgresRelationDoesNotExistError = '42P01';
const PostgresDuplicateRelationError = '42P07';
Expand Down Expand Up @@ -1171,22 +1172,22 @@ export class PostgresStorageAdapter {
});
/* eslint-disable no-console */
promises = promises.concat([
this._client.any(json_object_set_key).catch((err) => {
this._client.none(sql.misc.jsonObjectSetKeys).catch((err) => {
console.error(err);
}),
this._client.any(array_add).catch((err) => {
this._client.none(sql.array.add).catch((err) => {
console.error(err);
}),
this._client.any(array_add_unique).catch((err) => {
this._client.none(sql.array.addUnique).catch((err) => {
console.error(err);
}),
this._client.any(array_remove).catch((err) => {
this._client.none(sql.array.remove).catch((err) => {
console.error(err);
}),
this._client.any(array_contains_all).catch((err) => {
this._client.none(sql.array.containsAll).catch((err) => {
console.error(err);
}),
this._client.any(array_contains).catch((err) => {
this._client.none(sql.array.contains).catch((err) => {
console.error(err);
})
]);
Expand Down Expand Up @@ -1270,84 +1271,5 @@ function literalizeRegexPart(s) {
);
}

// Function to set a key on a nested JSON document
const json_object_set_key = 'CREATE OR REPLACE FUNCTION "json_object_set_key"(\
"json" jsonb,\
"key_to_set" TEXT,\
"value_to_set" anyelement\
)\
RETURNS jsonb \
LANGUAGE sql \
IMMUTABLE \
STRICT \
AS $function$\
SELECT concat(\'{\', string_agg(to_json("key") || \':\' || "value", \',\'), \'}\')::jsonb\
FROM (SELECT *\
FROM jsonb_each("json")\
WHERE "key" <> "key_to_set"\
UNION ALL\
SELECT "key_to_set", to_json("value_to_set")::jsonb) AS "fields"\
$function$;'

const array_add = `CREATE OR REPLACE FUNCTION "array_add"(
"array" jsonb,
"values" jsonb
)
RETURNS jsonb
LANGUAGE sql
IMMUTABLE
STRICT
AS $function$
SELECT array_to_json(ARRAY(SELECT unnest(ARRAY(SELECT DISTINCT jsonb_array_elements("array")) || ARRAY(SELECT jsonb_array_elements("values")))))::jsonb;
$function$;`;

const array_add_unique = `CREATE OR REPLACE FUNCTION "array_add_unique"(
"array" jsonb,
"values" jsonb
)
RETURNS jsonb
LANGUAGE sql
IMMUTABLE
STRICT
AS $function$
SELECT array_to_json(ARRAY(SELECT DISTINCT unnest(ARRAY(SELECT DISTINCT jsonb_array_elements("array")) || ARRAY(SELECT DISTINCT jsonb_array_elements("values")))))::jsonb;
$function$;`;

const array_remove = `CREATE OR REPLACE FUNCTION "array_remove"(
"array" jsonb,
"values" jsonb
)
RETURNS jsonb
LANGUAGE sql
IMMUTABLE
STRICT
AS $function$
SELECT array_to_json(ARRAY(SELECT * FROM jsonb_array_elements("array") as elt WHERE elt NOT IN (SELECT * FROM (SELECT jsonb_array_elements("values")) AS sub)))::jsonb;
$function$;`;

const array_contains_all = `CREATE OR REPLACE FUNCTION "array_contains_all"(
"array" jsonb,
"values" jsonb
)
RETURNS boolean
LANGUAGE sql
IMMUTABLE
STRICT
AS $function$
SELECT RES.CNT = jsonb_array_length("values") FROM (SELECT COUNT(*) as CNT FROM jsonb_array_elements("array") as elt WHERE elt IN (SELECT jsonb_array_elements("values"))) as RES ;
$function$;`;

const array_contains = `CREATE OR REPLACE FUNCTION "array_contains"(
"array" jsonb,
"values" jsonb
)
RETURNS boolean
LANGUAGE sql
IMMUTABLE
STRICT
AS $function$
SELECT RES.CNT >= 1 FROM (SELECT COUNT(*) as CNT FROM jsonb_array_elements("array") as elt WHERE elt IN (SELECT jsonb_array_elements("values"))) as RES ;
$function$;`;

export default PostgresStorageAdapter;
module.exports = PostgresStorageAdapter; // Required for tests
11 changes: 11 additions & 0 deletions src/Adapters/Storage/Postgres/sql/array/add-unique.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,11 @@
CREATE OR REPLACE FUNCTION array_add_unique(
"array" jsonb,
"values" jsonb
)
RETURNS jsonb
LANGUAGE sql
IMMUTABLE
STRICT
AS $function$
SELECT array_to_json(ARRAY(SELECT DISTINCT unnest(ARRAY(SELECT DISTINCT jsonb_array_elements("array")) || ARRAY(SELECT DISTINCT jsonb_array_elements("values")))))::jsonb;
$function$;
11 changes: 11 additions & 0 deletions src/Adapters/Storage/Postgres/sql/array/add.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,11 @@
CREATE OR REPLACE FUNCTION array_add(
"array" jsonb,
"values" jsonb
)
RETURNS jsonb
LANGUAGE sql
IMMUTABLE
STRICT
AS $function$
SELECT array_to_json(ARRAY(SELECT unnest(ARRAY(SELECT DISTINCT jsonb_array_elements("array")) || ARRAY(SELECT jsonb_array_elements("values")))))::jsonb;
$function$;
11 changes: 11 additions & 0 deletions src/Adapters/Storage/Postgres/sql/array/contains-all.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,11 @@
CREATE OR REPLACE FUNCTION array_contains_all(
"array" jsonb,
"values" jsonb
)
RETURNS boolean
LANGUAGE sql
IMMUTABLE
STRICT
AS $function$
SELECT RES.CNT = jsonb_array_length("values") FROM (SELECT COUNT(*) as CNT FROM jsonb_array_elements("array") as elt WHERE elt IN (SELECT jsonb_array_elements("values"))) as RES;
$function$;
11 changes: 11 additions & 0 deletions src/Adapters/Storage/Postgres/sql/array/contains.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,11 @@
CREATE OR REPLACE FUNCTION array_contains(
"array" jsonb,
"values" jsonb
)
RETURNS boolean
LANGUAGE sql
IMMUTABLE
STRICT
AS $function$
SELECT RES.CNT >= 1 FROM (SELECT COUNT(*) as CNT FROM jsonb_array_elements("array") as elt WHERE elt IN (SELECT jsonb_array_elements("values"))) as RES;
$function$;
11 changes: 11 additions & 0 deletions src/Adapters/Storage/Postgres/sql/array/remove.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,11 @@
CREATE OR REPLACE FUNCTION array_remove(
"array" jsonb,
"values" jsonb
)
RETURNS jsonb
LANGUAGE sql
IMMUTABLE
STRICT
AS $function$
SELECT array_to_json(ARRAY(SELECT * FROM jsonb_array_elements("array") as elt WHERE elt NOT IN (SELECT * FROM (SELECT jsonb_array_elements("values")) AS sub)))::jsonb;
$function$;
32 changes: 32 additions & 0 deletions src/Adapters/Storage/Postgres/sql/index.js
Original file line number Diff line number Diff line change
@@ -0,0 +1,32 @@
'use strict';

var QueryFile = require('pg-promise').QueryFile;
var path = require('path');

module.exports = {
array: {
add: sql('array/add.sql'),
addUnique: sql('array/add-unique.sql'),
contains: sql('array/contains.sql'),
containsAll: sql('array/contains-all.sql'),
remove: sql('array/remove.sql')
},
misc: {
jsonObjectSetKeys: sql('misc/json-object-set-keys.sql')
}
};

///////////////////////////////////////////////
// Helper for linking to external query files;
function sql(file) {

var fullPath = path.join(__dirname, file); // generating full path;

var qf = new QueryFile(fullPath, {minify: true});

if (qf.error) {
throw qf.error;
}

return qf;
}
19 changes: 19 additions & 0 deletions src/Adapters/Storage/Postgres/sql/misc/json-object-set-keys.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,19 @@
-- Function to set a key on a nested JSON document

CREATE OR REPLACE FUNCTION json_object_set_key(
"json" jsonb,
key_to_set TEXT,
value_to_set anyelement
)
RETURNS jsonb
LANGUAGE sql
IMMUTABLE
STRICT
AS $function$
SELECT concat('{', string_agg(to_json("key") || ':' || "value", ','), '}')::jsonb
FROM (SELECT *
FROM jsonb_each("json")
WHERE key <> key_to_set
UNION ALL
SELECT key_to_set, to_json("value_to_set")::jsonb) AS fields
$function$;