├── .gitignore ├── README ├── README.md ├── __init__.py ├── forcefdw.py ├── license └── setup.py /.gitignore: -------------------------------------------------------------------------------- 1 | build 2 | dist 3 | forcefdw.py~ 4 | MANIFEST 5 | setup.cfg 6 | ForceFDW.egg-info -------------------------------------------------------------------------------- /README: -------------------------------------------------------------------------------- 1 | See README.md 2 | -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | Database.com FDW for PostgreSQL 2 | =============================== 3 | 4 | This Python module implements the `multicorn.ForeignDataWrapper` interface to allow you to create foreign tables in PostgreSQL 9.1+ that map to sobjects in database.com/Force.com. Column names and qualifiers (e.g. `Name LIKE 'P%'`) are passed to database.com to minimize the amount of data on the wire. 5 | 6 | * Version 0.0.7 fix a bug that prevented querying using null values 7 | * Version 0.0.6 allow to set api_version in the options 8 | * Version 0.0.5 fix utf8 encoding error, when querying with non ascii characters 9 | * Version 0.0.4 updates yajl-py refs to prevent YajlContentHandler is not defined issue with latest yajl and yajl-py 10 | * Version 0.0.3 removes the requirement for column names to be a case-sensitive match for the database.com field names. 11 | * Version 0.0.2 switched to using the yajl-py streaming JSON parser to avoid reading the entire response from database.com into memory at once. 12 | 13 | Pre-requisites 14 | -------------- 15 | 16 | * [PostgreSQL 9.1+](http://www.postgresql.org/) 17 | * [Python](http://python.org/) 18 | * [Multicorn](http://multicorn.org) 19 | * [yajl-py](http://pykler.github.com/yajl-py/) 20 | * [YAJL](http://lloyd.github.com/yajl/) 21 | 22 | Installation 23 | ------------ 24 | 25 | 1. [Create a Remote Access Application](http://wiki.developerforce.com/page/Getting_Started_with_the_Force.com_REST_API#Setup), since you will need a client ID and client secret so that that the FDW can login via OAuth and use the REST API. 26 | 2. [Install Multicorn](http://multicorn.org/#installation) 27 | 3. [Build and install YAJL](http://lloyd.github.com/yajl/) 28 | 4. [Build and install yajl-py](http://pykler.github.com/yajl-py/) 29 | 5. Build the FDW module: 30 | 31 | $ cd Database.com-FDW-for-PostgreSQL 32 | $ python setup.py sdist 33 | $ sudo python setup.py install 34 | 35 | or, with easy_install: 36 | 37 | $ cd Database.com-FDW-for-PostgreSQL 38 | $ sudo easy_install . 39 | 40 | 6. In the PostgreSQL client, create an extension and foreign server: 41 | 42 | 43 | CREATE EXTENSION multicorn; 44 | CREATE SERVER multicorn_force FOREIGN DATA WRAPPER multicorn 45 | OPTIONS ( 46 | wrapper 'forcefdw.DatabaseDotComForeignDataWrapper', 47 | api_version 'v35.0', 48 | login_server 'https://login.salesforce.com' 49 | ); 50 | 51 | Default version is v23.0 and default login server is `https://login.salesforce.com` 52 | 53 | 7. Create a foreign table. You can use any subset of fields from the sobject, and column/field name matching is not case-sensitive: 54 | 55 | CREATE FOREIGN TABLE contacts ( 56 | firstname character varying, 57 | lastname character varying, 58 | email character varying 59 | ) SERVER multicorn_force OPTIONS ( 60 | obj_type 'Contact', 61 | client_id 'CONSUMER_KEY_FROM_REMOTE_ACCESS_APP, 62 | client_secret 'CONSUMER_SECRET_FROM_REMOTE_ACCESS_APP', 63 | username 'user@domain.com', 64 | password '********' 65 | ); 66 | 67 | 8. Query the foreign table as if it were any other table. You will see some diagnostics as the FDW interacts with database.com/Force.com. Here are some examples: 68 | 69 | `SELECT *` 70 | 71 | SELECT * FROM contacts; 72 | NOTICE: Logged in to https://login.salesforce.com as pat@superpat.com 73 | NOTICE: SOQL query is SELECT lastname,email,firstname FROM Contact 74 | firstname | lastname | email 75 | -----------+-------------------------------------+--------------------------- 76 | Rose | Gonzalez | rose@edge.com 77 | Sean | Forbes | sean@edge.com 78 | Jack | Rogers | jrogers@burlington.com 79 | Pat | Stumuller | pat@pyramid.net 80 | Andy | Young | a_young@dickenson.com 81 | Tim | Barr | barr_tim@grandhotels.com 82 | ...etc... 83 | 84 | `SELECT` a column with a condition 85 | 86 | postgres=# SELECT email FROM contacts WHERE lastname LIKE 'G%'; 87 | NOTICE: SOQL query is SELECT lastname,email FROM Contact WHERE lastname LIKE 'G%' 88 | email 89 | ------------------- 90 | rose@edge.com 91 | jane_gray@uoa.edu 92 | agreen@uog.com 93 | (3 rows) 94 | 95 | Aggregator 96 | 97 | postgres=# SELECT COUNT(*) FROM contacts WHERE lastname LIKE 'G%'; 98 | NOTICE: SOQL query is SELECT lastname,email,firstname FROM Contact WHERE lastname LIKE 'G%' 99 | count 100 | ------- 101 | 3 102 | (1 row)s 103 | 104 | `JOIN` 105 | 106 | postgres=# CREATE TABLE example ( 107 | postgres(# email varchar PRIMARY KEY, 108 | postgres(# favorite_color varchar NOT NULL 109 | postgres(# ); 110 | NOTICE: CREATE TABLE / PRIMARY KEY will create implicit index "example_pkey" for table "example" 111 | CREATE TABLE 112 | postgres=# INSERT INTO example VALUES('rose@edge.com', 'Red'); 113 | INSERT 0 1 114 | postgres=# INSERT INTO example VALUES('jane_gray@uoa.edu', 'Green'); 115 | INSERT 0 1 116 | postgres=# INSERT INTO example VALUES('agreen@uog.com', 'Blue'); 117 | INSERT 0 1 118 | postgres=# SELECT favorite_color FROM example JOIN contacts ON example.email=contacts.email; 119 | NOTICE: SOQL query is SELECT lastname,email,firstname FROM Contact 120 | favorite_color 121 | ---------------- 122 | Red 123 | Green 124 | Blue 125 | (3 rows) 126 | postgres=# SELECT favorite_color FROM example JOIN contacts ON example.email=contacts.email WHERE contacts.firstname = 'Rose'; 127 | NOTICE: SOQL query is SELECT lastname,email,firstname FROM Contact WHERE firstname = 'Rose' 128 | favorite_color 129 | ---------------- 130 | Red 131 | (1 row) 132 | 133 | Token refresh 134 | 135 | postgres=# SELECT DISTINCT email FROM contacts LIMIT 1; 136 | NOTICE: SOQL query is SELECT email FROM Contact 137 | NOTICE: Invalid token 00D50000000IZ3Z!AQ0AQBwEiMxpN5VhLER2PKlifISWxln8ztl2V0cw3BPUAf3IxiD6ZG8Ei5PBcJoCKHDZRmp8lGnFDPQl7kaYgKL73vHHkqbG - trying refresh 138 | NOTICE: Logged in to https://login.salesforce.com as pat@superpat.com 139 | NOTICE: SOQL query is SELECT email FROM Contact 140 | email 141 | ------------------------ 142 | jrogers@burlington.com 143 | (1 row) 144 | 145 | `EXPLAIN` 146 | 147 | postgres=# EXPLAIN ANALYZE SELECT * FROM contacts ORDER BY lastname ASC LIMIT 3; 148 | NOTICE: SOQL query is SELECT lastname,email,firstname FROM Contact 149 | QUERY PLAN 150 | -------------------------------------------------------------------------------------------------------------------------------- 151 | Limit (cost=129263.11..129263.12 rows=3 width=96) (actual time=431.883..431.887 rows=3 loops=1) 152 | -> Sort (cost=129263.11..154263.11 rows=9999999 width=96) (actual time=431.880..431.880 rows=3 loops=1) 153 | Sort Key: lastname 154 | Sort Method: top-N heapsort Memory: 17kB 155 | -> Foreign Scan on contacts (cost=10.00..15.00 rows=9999999 width=96) (actual time=429.914..431.726 rows=69 loops=1) 156 | Foreign multicorn: multicorn 157 | Foreign multicorn cost: 10 158 | Total runtime: 431.941 ms 159 | (8 rows) 160 | 161 | License 162 | ------- 163 | 164 | 3-clause BSD. See license file. 165 | -------------------------------------------------------------------------------- /__init__.py: -------------------------------------------------------------------------------- 1 | # ForceFDW - A PostgreSQL Foreign Data Wrapper for Database.com/Force.com 2 | 3 | __version__ = '0.0.7' 4 | -------------------------------------------------------------------------------- /forcefdw.py: -------------------------------------------------------------------------------- 1 | from multicorn import ForeignDataWrapper 2 | from multicorn.utils import log_to_postgres, ERROR, DEBUG 3 | from yajl import YajlContentHandler, YajlParser 4 | 5 | from Queue import Queue 6 | from threading import Thread 7 | 8 | import urllib 9 | import urllib2 10 | import json 11 | import pprint 12 | 13 | import collections 14 | 15 | class CaseInsensitiveDict(collections.Mapping): 16 | def __init__(self, d): 17 | self._d = d 18 | self._s = dict((k.lower(), k) for k in d) 19 | def __contains__(self, k): 20 | return k.lower() in self._s 21 | def __len__(self): 22 | return len(self._s) 23 | def __iter__(self): 24 | return iter(self._s) 25 | def __getitem__(self, k): 26 | return self._d[self._s[k.lower()]] 27 | def actual_key_case(self, k): 28 | return self._s.get(k.lower()) 29 | 30 | # ContentHandler implements a simple state machine to parse the records from 31 | # the incoming JSON stream, adding them to the queue as maps of column name 32 | # to column value. We skip over any record properties that are not simple 33 | # values (e.g. attributes, which is an object containing the record's type 34 | # and URL)/ 35 | class ContentHandler(YajlContentHandler): 36 | _column = '' 37 | 38 | # States 39 | INIT = 0 40 | IN_OBJECT = 1 41 | SEEN_RECORDS = 2 42 | IN_ARRAY = 3 43 | IN_RECORD = 4 44 | SEEN_KEY = 5 45 | 46 | _state = INIT 47 | 48 | _depth = 0 49 | 50 | def __init__(self, queue, column_map): 51 | self._queue = queue 52 | self._column_map = column_map 53 | 54 | def handle_value(self, ctx, val): 55 | if self._state == ContentHandler.SEEN_KEY and self._depth == 0: 56 | self._state = ContentHandler.IN_RECORD 57 | self._record[self._column_map[self._column]] = val 58 | 59 | def yajl_null(self, ctx): 60 | self.handle_value(ctx, None) 61 | 62 | def yajl_boolean(self, ctx, boolVal): 63 | self.handle_value(ctx, boolVal) 64 | 65 | def yajl_integer(self, ctx, integerVal): 66 | self.handle_value(ctx, integerVal) 67 | 68 | def yajl_double(self, ctx, doubleVal): 69 | self.handle_value(ctx, doubleVal) 70 | 71 | def yajl_string(self, ctx, stringVal): 72 | self.handle_value(ctx, stringVal) 73 | 74 | def yajl_start_map(self, ctx): 75 | if self._state == ContentHandler.SEEN_KEY: 76 | self._depth += 1 77 | elif self._state == ContentHandler.IN_ARRAY: 78 | self._state = ContentHandler.IN_RECORD 79 | self._record = {} 80 | elif self._state == ContentHandler.INIT: 81 | self._state = ContentHandler.IN_OBJECT 82 | 83 | def yajl_map_key(self, ctx, stringVal): 84 | if self._state == ContentHandler.IN_RECORD: 85 | self._state = ContentHandler.SEEN_KEY 86 | self._column = stringVal 87 | elif self._state == ContentHandler.IN_OBJECT and stringVal == 'records': 88 | self._state = ContentHandler.SEEN_RECORDS 89 | 90 | def yajl_end_map(self, ctx): 91 | if self._state == ContentHandler.SEEN_KEY: 92 | self._depth -= 1 93 | if self._depth == 0: 94 | self._state = ContentHandler.IN_RECORD 95 | elif self._state == ContentHandler.IN_RECORD: 96 | self._state = ContentHandler.IN_ARRAY 97 | self._queue.put(self._record) 98 | elif self._state == ContentHandler.IN_OBJECT: 99 | self._state = ContentHandler.INIT 100 | 101 | def yajl_start_array(self, ctx): 102 | if self._state == ContentHandler.SEEN_RECORDS: 103 | self._state = ContentHandler.IN_ARRAY 104 | 105 | def yajl_end_array(self, ctx): 106 | if self._state == ContentHandler.IN_ARRAY: 107 | self._state = ContentHandler.IN_OBJECT 108 | 109 | # Parse the given stream to a queue 110 | def parseToQueue(stream, queue, column_map): 111 | parser = YajlParser(ContentHandler(queue, column_map)) 112 | parser.parse(stream) 113 | queue.put(None) 114 | 115 | class DatabaseDotComForeignDataWrapper(ForeignDataWrapper): 116 | 117 | def __init__(self, options, columns): 118 | super(DatabaseDotComForeignDataWrapper, self).__init__(options, columns) 119 | self.column_map = CaseInsensitiveDict(dict([(x, x) for x in columns])) 120 | 121 | self.obj_type = options.get('obj_type', None) 122 | if self.obj_type is None: 123 | log_to_postgres('You MUST set the obj_type', 124 | ERROR) 125 | self.client_id = options.get('client_id', None) 126 | if self.client_id is None: 127 | log_to_postgres('You MUST set the client_id', 128 | ERROR) 129 | self.client_secret = options.get('client_secret', None) 130 | if self.client_secret is None: 131 | log_to_postgres('You MUST set the client_secret', 132 | ERROR) 133 | self.username = options.get('username', None) 134 | if self.username is None: 135 | log_to_postgres('You MUST set the username', 136 | ERROR) 137 | self.password = options.get('password', None) 138 | 139 | if self.password is None: 140 | log_to_postgres('You MUST set the password', 141 | ERROR) 142 | 143 | self.api_version = options.get('api_version', 'v23.0') 144 | self.login_server = options.get('login_server', 'https://login.salesforce.com') 145 | 146 | self.oauth = self.get_token() 147 | 148 | def get_token(self): 149 | # Do OAuth username/password 150 | token_url = '%s/services/oauth2/token' % self.login_server 151 | 152 | params = urllib.urlencode({ 153 | 'grant_type': 'password', 154 | 'client_id': self.client_id, 155 | 'client_secret': self.client_secret, 156 | 'username': self.username, 157 | 'password': self.password 158 | }) 159 | 160 | log_to_postgres('Getting token from %s' % token_url, DEBUG) 161 | 162 | try: 163 | data = urllib2.urlopen(token_url, params).read() 164 | except urllib2.URLError, e: 165 | if hasattr(e, 'code'): 166 | if e.code == 400: 167 | log_to_postgres( 168 | 'Bad Request', ERROR, 169 | 'Check the client_id, client_secret, username and password') 170 | else: 171 | log_to_postgres('HTTP status %d' % e.code, ERROR) 172 | elif hasattr(e, 'reason'): 173 | log_to_postgres('Error posting to URL %s: %d %s' % 174 | (token_url, e.reason[0], e.reason[1]), ERROR, 175 | 'Check the login_server') 176 | else: 177 | log_to_postgres('Unknown error %s' % e, ERROR) 178 | log_to_postgres('Got token %s' % data, DEBUG) 179 | oauth = json.loads(data) 180 | log_to_postgres('Logged in to %s as %s' % (self.login_server, self.username)) 181 | 182 | return oauth 183 | 184 | def execute(self, quals, columns, retry = True): 185 | 186 | cols = ''; 187 | for column_name in list(columns): 188 | cols += ',%s' % column_name 189 | cols = cols[1:] 190 | 191 | where = '' 192 | parameters = [] 193 | for qual in quals: 194 | operator = 'LIKE' if qual.operator == '~~' else qual.operator 195 | if qual.value is None: 196 | where += ' AND %s %s NULL' % ( 197 | qual.field_name, operator 198 | ) 199 | else: 200 | where += ' AND %s %s \'%s\'' % ( 201 | qual.field_name, operator, qual.value 202 | ) 203 | where = where[5:] 204 | 205 | query = 'SELECT '+cols+' FROM '+self.obj_type 206 | if len(where) > 0: 207 | query += ' WHERE %s ' % where 208 | 209 | log_to_postgres('SOQL query is %s' % query) 210 | 211 | params = urllib.urlencode({ 212 | 'q': query.encode('utf8') 213 | }) 214 | 215 | query_url = (self.oauth['instance_url'] + '/services/data/' + self.api_version 216 | + '/query?%s' % params) 217 | 218 | headers = { 219 | 'Authorization': 'OAuth %s' % self.oauth['access_token'] 220 | } 221 | 222 | req = urllib2.Request(query_url, None, headers) 223 | 224 | queue = Queue() 225 | 226 | try: 227 | stream = urllib2.urlopen(req); 228 | except urllib2.URLError, e: 229 | if hasattr(e, 'code'): 230 | if e.code == 401 and retry: 231 | log_to_postgres('Invalid token %s - trying refresh' % 232 | self.oauth['access_token']) 233 | self.oauth = self.get_token() 234 | for line in self.execute(quals, columns, False): 235 | yield line 236 | return 237 | else: 238 | log_to_postgres('HTTP status %d' % e.code, ERROR) 239 | elif hasattr(e, 'reason'): 240 | log_to_postgres('Error posting to URL %s: %d %s' % 241 | (token_url, e.reason[0], e.reason[1]), ERROR) 242 | else: 243 | log_to_postgres('Unknown error %s' % e, ERROR) 244 | t = Thread(target=parseToQueue, args=(stream, queue, self.column_map)) 245 | t.daemon = True 246 | t.start() 247 | item = queue.get() 248 | while item is not None: 249 | yield item 250 | queue.task_done() 251 | item = queue.get() 252 | -------------------------------------------------------------------------------- /license: -------------------------------------------------------------------------------- 1 | Copyright (c) 2012, Salesforce.com 2 | All rights reserved. 3 | 4 | Redistribution and use in source and binary forms, with or without 5 | modification, are permitted provided that the following conditions are met: 6 | 7 | * Redistributions of source code must retain the above copyright notice, this 8 | list of conditions and the following disclaimer. 9 | * Redistributions in binary form must reproduce the above copyright notice, 10 | this list of conditions and the following disclaimer in the documentation 11 | and/or other materials provided with the distribution. 12 | * Neither the name of Salesforce.com nor the names of its contributors may be 13 | used to endorse or promote products derived from this software without 14 | specific prior written permission. 15 | 16 | THIS SOFTWARE IS PROVIDED BY THE COPYRIGHT HOLDERS AND CONTRIBUTORS "AS IS" AND 17 | ANY EXPRESS OR IMPLIED WARRANTIES, INCLUDING, BUT NOT LIMITED TO, THE IMPLIED 18 | WARRANTIES OF MERCHANTABILITY AND FITNESS FOR A PARTICULAR PURPOSE ARE 19 | DISCLAIMED. IN NO EVENT SHALL THE COPYRIGHT HOLDER OR CONTRIBUTORS BE LIABLE 20 | FOR ANY DIRECT, INDIRECT, INCIDENTAL, SPECIAL, EXEMPLARY, OR CONSEQUENTIAL 21 | DAMAGES (INCLUDING, BUT NOT LIMITED TO, PROCUREMENT OF SUBSTITUTE GOODS OR 22 | SERVICES; LOSS OF USE, DATA, OR PROFITS; OR BUSINESS INTERRUPTION) HOWEVER 23 | CAUSED AND ON ANY THEORY OF LIABILITY, WHETHER IN CONTRACT, STRICT LIABILITY, 24 | OR TORT (INCLUDING NEGLIGENCE OR OTHERWISE) ARISING IN ANY WAY OUT OF THE USE 25 | OF THIS SOFTWARE, EVEN IF ADVISED OF THE POSSIBILITY OF SUCH DAMAGE. 26 | -------------------------------------------------------------------------------- /setup.py: -------------------------------------------------------------------------------- 1 | from distutils.core import setup 2 | setup(name='ForceFDW', 3 | version='0.0.7', 4 | description='Database.com FDW for PostgreSQL', 5 | author='Pat Patterson', 6 | author_email='ppatterson@salesforce.com', 7 | url='https://github.com/metadaddy-sfdc/Database.com-FDW-for-PostgreSQL', 8 | py_modules=['forcefdw']) 9 | --------------------------------------------------------------------------------