Skip to content

Commit

Permalink
resolve conflicts
Browse files Browse the repository at this point in the history
  • Loading branch information
NikolayS committed May 14, 2017
2 parents a3cd5fb + 08b4275 commit bd191ad
Show file tree
Hide file tree
Showing 15 changed files with 656 additions and 392 deletions.
30 changes: 16 additions & 14 deletions install_api.sql
Original file line number Diff line number Diff line change
@@ -1,15 +1,17 @@
create schema if not exists v2;
do
$$
begin
if not exists (
select *
from pg_catalog.pg_user
where usename = 'apiuser'
) then
create role apiuser password 'pass-for-apiuser' login;
end if;
end
$$;
CREATE OR REPLACE FUNCTION v2.translate_array(source CHAR(2), target CHAR(2), q JSON)
RETURNS TEXT[] AS $BODY$
DECLARE
rez TEXT[];
BEGIN
SELECT
CASE current_setting('translation_proxy.api.current_engine')
WHEN 'google' THEN
translation_proxy.google_translate_array( source, target, q )
WHEN 'promt' THEN
translation_proxy.promt_translate_array( source, target, array_agg( json_array_elements_text(q) ) )
END INTO rez;
RETURN rez;
END;
$BODY$ LANGUAGE PLPGSQL SECURITY DEFINER;

grant usage on schema v2 to apiuser;
GRANT EXECUTE ON FUNCTION v2.translate_array(CHAR(2), CHAR(2), JSON) TO apiuser;
17 changes: 17 additions & 0 deletions install_api_vars.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,17 @@
ALTER DATABASE DBNAME SET translation_proxy.api.current_engine = 'CURRENT_API_ENGINE';

CREATE SCHEMA IF NOT EXISTS v2;
DO
$$
BEGIN
IF NOT EXISTS (
SELECT *
FROM pg_catalog.pg_user
WHERE usename = 'apiuser'
) THEN
CREATE ROLE apiuser PASSWORD 'APIUSER-PASSWORD' LOGIN;
END IF;
END
$$;

GRANT USAGE ON SCHEMA v2 TO apiuser;
63 changes: 42 additions & 21 deletions install_bing_core.sql
Original file line number Diff line number Diff line change
@@ -1,27 +1,48 @@
-- Microsoft Bing
-- main function is the bing_translate( source char(2), target char(2), qs text[] )

-- api_key, source lang, target lang, text
create or replace function translation_proxy._bing_translate_curl(text, char(2), char(2), text) returns text as $$
-- api_key
CREATE OR REPLACE FUNCTION translation_proxy._bing_get_token_curl(text) RETURNS INTEGER AS $$
#!/bin/sh
curl --connect-timeout 2 -H "Accept: application/json" "https://www.googleapis.com/language/translate/v2?key=$1&source=$2&target=$3&q=$4" 2>/dev/null | sed 's/\r//g'
$$ language plsh;
KEY=$1
ACCESS_TOKEN = `curl -X POST -H "content-type: application/x-www-form-urlencoded" \
-d "grant_type=client_credentials&client_id=$CLIENTID&client_secret=$CLIENTSECRET&scope=http://api.microsofttranslator.com" \
https://datamarket.accesscontrol.windows.net/v2/OAuth2-13 | grep -Po '"access_token":.*?[^\\]",'`

create or replace function translation_proxy.bing_translate(api_key text, source char(2), target char(2), qs text[]) returns text[] as $$
begin
end;
$$ language plpgsql;
curl -X POST --header 'Ocp-Apim-Subscription-Key: ${KEY}' --data "" 'https://api.cognitive.microsoft.com/sts/v1.0/issueToken' 2>/dev/null
$$ LANGUAGE plsh;

create or replace function translation_proxy.bing_translate(source char(2), target char(2), qs text[]) returns text[] as $$
begin
end;
$$ language plpgsql;
CREATE OR REPLACE FUNCTION translation_proxy._bing_login() RETURNS BOOLEAN AS $$
DECLARE
token TEXT;
BEGIN
token := translation_proxy._bing_get_token_curl(current_setting('translation_proxy.bing.api_key'));
IF token IS NOT NULL AND token <> '' THEN
UPDATE translation_proxy.authcache SET ( creds, updated ) = ( token, now() ) WHERE api_engine = 'bing';
RETURN 't';
ELSE
RETURN 'f';
END IF;
END;
$$ LANGUAGE plpgsql;

create or replace function translation_proxy.bing_translate(source char(2), target char(2), q text) returns text as $$
begin
end;
$$ language plpgsql;
-- token, source lang, target lang, text, category
CREATE OR REPLACE FUNCTION translation_proxy._bing_translate_curl(TEXT, CHAR(2), CHAR(2), TEXT) RETURNS TEXT AS $$
#!/bin/sh
TOKEN=$1
SRC=$2
DST=$3
QUERY=$4
$CTG=$5
curl -X GET -H "Authorization: Bearer $TOKEN" \
--data-urlencode "text=$QUERY" \
--data-urlencode "from=$SRC" \
--data-urlencode "to=$DST" \
--data-urlencode "category=$CTG" \
'https://api.cognitive.microsoft.com/sts/v1.0/Translate' 2>/dev/null
$$ LANGUAGE plsh;

create or replace function translation_proxy.bing_translate_array(source char(2), target char(2), q json) returns text[] as $$
begin
end;
$$ language plpgsql;
CREATE OR REPLACE FUNCTION translation_proxy.bing_translate(source CHAR(2), target CHAR(2), qs TEXT[], profile TEXT DEFAULT '')
RETURNS text[] as $$
BEGIN
END;
$$ LANGUAGE plpgsql;
3 changes: 3 additions & 0 deletions install_bing_vars.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,3 @@
-- Microsoft Bing
ALTER DATABASE DBNAME SET translation_proxy.bing.api_key = 'YOUR_BING_API_KEY';
ALTER DATABASE DBNAME SET translation_proxy.bing.key_expiration = 'BING_TOKEN_EXPIRATION';
112 changes: 98 additions & 14 deletions install_global_core.sql
Original file line number Diff line number Diff line change
@@ -1,16 +1,100 @@
create schema if not exists translation_proxy;
create extension if not exists plsh;

create table translation_proxy.cache(
id bigserial primary key,
source char(2) not null,
target char(2) not null,
q text not null,
result text not null,
created timestamp not null default now(),
api_engine text not null
CREATE SCHEMA IF NOT EXISTS translation_proxy;
CREATE EXTENSION IF NOT EXISTS plsh;
CREATE EXTENSION IF NOT EXISTS plpython2u;

CREATE TYPE translation_proxy.api_engine_type AS ENUM ('google', 'promt', 'bing');

CREATE TABLE translation_proxy.cache(
id BIGSERIAL PRIMARY KEY,
source char(2), -- if this is NULL, it need to be detected
target char(2) NOT NULL,
q TEXT NOT NULL,
result TEXT, -- if this is NULL, it need to be translated
profile TEXT NOT NULL DEFAULT '',
created TIMESTAMP NOT NULL DEFAULT now(),
api_engine translation_proxy.api_engine_type NOT NULL,
encoded TEXT -- urlencoded string for GET request. Is null after an successfull translation.
);

CREATE UNIQUE INDEX u_cache_q_source_target ON translation_proxy.cache
USING btree(md5(q), source, target, api_engine, profile);
CREATE INDEX cache_created ON translation_proxy.cache ( created );
COMMENT ON TABLE translation_proxy.cache IS 'The cache for API calls of the Translation proxy';

-- trigger, that URLencodes query in cache, when no translation is given
CREATE OR REPLACE FUNCTION translation_proxy._urlencode_fields()
RETURNS TRIGGER AS $BODY$
from urllib import quote_plus
TD['new']['encoded'] = quote_plus( TD['new']['q'] )
return 'MODIFY'
$BODY$ LANGUAGE plpython2u;

CREATE TRIGGER _prepare_for_fetch BEFORE INSERT ON translation_proxy.cache
FOR EACH ROW
WHEN (NEW.result IS NULL)
EXECUTE PROCEDURE translation_proxy._urlencode_fields();

-- cookies, oauth keys and so on
CREATE TABLE translation_proxy.authcache(
api_engine translation_proxy.api_engine_type NOT NULL,
creds TEXT,
updated TIMESTAMP NOT NULL DEFAULT now()
);
create unique index u_cache_q_source_target on translation_proxy.cache
using btree(md5(q), source, target, api_engine);

comment on table translation_proxy.cache is 'Cache for Translation proxy API calls';
CREATE UNIQUE INDEX u_authcache_engine ON translation_proxy.authcache ( api_engine );

COMMENT ON TABLE translation_proxy.authcache IS 'Translation API cache for remote authorization keys';

INSERT INTO translation_proxy.authcache (api_engine) VALUES ('google'), ('promt'), ('bing')
ON CONFLICT DO NOTHING;

CREATE OR REPLACE FUNCTION translation_proxy._save_cookie(engine translation_proxy.api_engine_type, cookie TEXT)
RETURNS VOID AS $$
BEGIN
UPDATE translation_proxy.authcache
SET ( creds, updated ) = ( cookie, now() )
WHERE api_engine = engine;
END;
$$ LANGUAGE plpgsql;

CREATE OR REPLACE FUNCTION translation_proxy._load_cookie(engine translation_proxy.api_engine_type)
RETURNS TEXT AS $$
DECLARE
cookie TEXT;
BEGIN
SELECT creds INTO cookie FROM translation_proxy.authcache
WHERE api_engine = engine AND
updated > ( now() - current_setting('translation_proxy.promt.login_timeout')::INTERVAL )
AND creds IS NOT NULL AND creds <> ''
LIMIT 1;
RETURN cookie;
END;
$$ LANGUAGE plpgsql;

CREATE OR REPLACE FUNCTION translation_proxy._find_detected_language(qs TEXT, engine translation_proxy.api_engine_type)
RETURNS TEXT AS $$
DECLARE
lng CHAR(2);
BEGIN
SELECT lang INTO lng FROM translation_proxy.cache
WHERE api_engine = engine AND q = qs AND lang IS NOT NULL
LIMIT 1;
RETURN lng;
END;
$$ LANGUAGE plpgsql;

-- adding new parameter to url until it exceeds the limit of 2000 bytes
CREATE OR REPLACE FUNCTION translation_proxy._urladd( url TEXT, a TEXT ) RETURNS TEXT AS $$
from urllib import quote_plus
r = url + quote_plus( a )
if len(r) > 1999 :
plpy.error('URL length is over, time to fetch.', sqlstate = 'EOURL')
return r
$$ LANGUAGE plpython2u;

-- urlencoding utility
CREATE OR REPLACE FUNCTION translation_proxy._urlencode(q TEXT)
RETURNS TEXT AS $BODY$
from urllib import quote_plus
return quote_plus( q )
$BODY$ LANGUAGE plpython2u;
Empty file added install_global_vars.sql
Empty file.
10 changes: 0 additions & 10 deletions install_google_api.sql

This file was deleted.

Loading

0 comments on commit bd191ad

Please sign in to comment.