Skip to content
This repository has been archived by the owner on Feb 8, 2018. It is now read-only.

Commit

Permalink
Merge pull request #1369 from gittip/elsewhere
Browse files Browse the repository at this point in the history
refactor accounts elsewhere
  • Loading branch information
chadwhitacre committed Feb 26, 2014
2 parents 36170fc + 5508641 commit 7290e0d
Show file tree
Hide file tree
Showing 82 changed files with 2,260 additions and 3,634 deletions.
2 changes: 2 additions & 0 deletions .travis.yml
Original file line number Diff line number Diff line change
@@ -1,4 +1,6 @@
language: python
addons:
postgresql: 9.3
before_install:
- node --version
install: make env node_modules
Expand Down
142 changes: 142 additions & 0 deletions branch.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,142 @@
-------------------------------------------------------------------------------
-- https://github.com/gittip/www.gittip.com/pull/1369

BEGIN;


-- Add new columns

-- Note: using "user_name" instead of "username" avoids having the same
-- column name in the participants and elsewhere tables.
ALTER TABLE elsewhere ADD COLUMN user_name text;
ALTER TABLE elsewhere ADD COLUMN display_name text;
ALTER TABLE elsewhere ADD COLUMN email text;
ALTER TABLE elsewhere ADD COLUMN avatar_url text;
ALTER TABLE participants ADD COLUMN avatar_url text;
ALTER TABLE elsewhere ADD COLUMN is_team boolean NOT NULL DEFAULT FALSE;



-- Extract info

-- Extract user_name from user_info
UPDATE elsewhere SET user_name = user_id WHERE platform = 'bitbucket';
UPDATE elsewhere SET user_name = user_info->'display_name' WHERE platform = 'bountysource';
UPDATE elsewhere SET user_name = user_info->'login' WHERE platform = 'github';
UPDATE elsewhere SET user_name = user_info->'username' WHERE platform = 'openstreetmap';
UPDATE elsewhere SET user_name = user_info->'screen_name' WHERE platform = 'twitter';
UPDATE elsewhere SET user_name = user_info->'username' WHERE platform = 'venmo';

-- Extract display_name from user_info
UPDATE elsewhere SET display_name = user_info->'display_name' WHERE platform = 'bitbucket';
UPDATE elsewhere SET display_name = user_info->'name' WHERE platform = 'github';
UPDATE elsewhere SET display_name = user_info->'username' WHERE platform = 'openstreetmap';
UPDATE elsewhere SET display_name = user_info->'name' WHERE platform = 'twitter';
UPDATE elsewhere SET display_name = user_info->'display_name' WHERE platform = 'venmo';
UPDATE elsewhere SET display_name = NULL WHERE display_name = 'None';

-- Extract available email addresses
UPDATE elsewhere SET email = user_info->'email' WHERE user_info->'email' LIKE '%@%';

-- Extract available avatar URLs
UPDATE elsewhere SET avatar_url = concat('https://www.gravatar.com/avatar/',
user_info->'gravatar_id')
WHERE platform = 'github'
AND user_info->'gravatar_id' != ''
AND user_info->'gravatar_id' != 'None';
UPDATE elsewhere SET avatar_url = concat('https://www.gravatar.com/avatar/',
md5(lower(trim(email))))
WHERE email IS NOT NULL AND avatar_url IS NULL;
UPDATE elsewhere SET avatar_url = user_info->'avatar' WHERE platform = 'bitbucket';
UPDATE elsewhere SET avatar_url = user_info->'avatar_url'
WHERE platform = 'bitbucket' AND avatar_url IS NULL;
UPDATE elsewhere SET avatar_url = substring(user_info->'links', $$u'avatar': {u'href': u'([^']+)$$)
WHERE platform = 'bitbucket' AND avatar_url IS NULL;
UPDATE elsewhere SET avatar_url = user_info->'image_url' WHERE platform = 'bountysource';
UPDATE elsewhere SET avatar_url = user_info->'avatar_url' WHERE platform = 'github' AND avatar_url IS NULL;
UPDATE elsewhere SET avatar_url = user_info->'img_src' WHERE platform = 'openstreetmap';
UPDATE elsewhere SET avatar_url = replace(user_info->'profile_image_url_https', '_normal.', '.')
WHERE platform = 'twitter';
UPDATE elsewhere SET avatar_url = user_info->'profile_picture_url' WHERE platform = 'venmo';
UPDATE elsewhere SET avatar_url = NULL WHERE avatar_url = 'None';
-- Propagate avatar_url to participants
UPDATE participants p
SET avatar_url = (
SELECT avatar_url
FROM elsewhere
WHERE participant = p.username
ORDER BY platform = 'github' DESC,
avatar_url LIKE '%gravatar.com%' DESC
LIMIT 1
);

-- Extract is_team from user_info
UPDATE elsewhere SET is_team = true WHERE platform = 'bitbucket' AND user_info->'is_team' = 'True';
UPDATE elsewhere SET is_team = true WHERE platform = 'github' AND lower(user_info->'type') = 'organization';



-- Drop old columns and add new ones

-- Update user_name constraints
ALTER TABLE elsewhere ALTER COLUMN user_name SET NOT NULL,
ALTER COLUMN user_name DROP DEFAULT;

-- Replace user_info by a new column of type json (instead of hstore)
ALTER TABLE elsewhere DROP COLUMN user_info,
ADD COLUMN extra_info json;
DROP EXTENSION hstore;

-- Simplify homepage_top_* tables
ALTER TABLE homepage_top_givers DROP COLUMN gravatar_id,
DROP COLUMN twitter_pic,
ADD COLUMN avatar_url text;
ALTER TABLE homepage_top_receivers DROP COLUMN claimed_time,
DROP COLUMN gravatar_id,
DROP COLUMN twitter_pic,
ADD COLUMN avatar_url text;

-- The following lets us cast queries to elsewhere_with_participant to get the
-- participant data dereferenced and returned in a composite type along with
-- the elsewhere data. Then we can register orm.Models in the application for
-- both participant and elsewhere_with_participant, and when we cast queries
-- elsewhere.*::elsewhere_with_participant, we'll get a hydrated Participant
-- object at .participant. Woo-hoo!

CREATE TYPE elsewhere_with_participant AS
( id integer
, platform text
, user_id text
, user_name text
, display_name text
, email text
, avatar_url text
, extra_info json
, is_locked boolean
, is_team boolean
, participant participants
); -- If Postgres had type inheritance this would be even awesomer.

CREATE OR REPLACE FUNCTION load_participant_for_elsewhere (elsewhere)
RETURNS elsewhere_with_participant
AS $$
SELECT $1.id
, $1.platform
, $1.user_id
, $1.user_name
, $1.display_name
, $1.email
, $1.avatar_url
, $1.extra_info
, $1.is_locked
, $1.is_team
, participants.*::participants
FROM participants
WHERE participants.username = $1.participant
;
$$ LANGUAGE SQL;

CREATE CAST (elsewhere AS elsewhere_with_participant)
WITH FUNCTION load_participant_for_elsewhere(elsewhere);

END;
9 changes: 0 additions & 9 deletions configure-aspen.py
Original file line number Diff line number Diff line change
@@ -1,6 +1,5 @@
from __future__ import division

from importlib import import_module
import os
import sys
import threading
Expand All @@ -12,7 +11,6 @@
from gittip import canonize, configure_payments
from gittip.security import authentication, csrf, x_frame_options
from gittip.utils import cache_static, timer
from gittip.elsewhere import platform_classes


from aspen import log_dammit
Expand Down Expand Up @@ -46,12 +44,6 @@
gittip.wireup.envvars(website)
tell_sentry = gittip.wireup.make_sentry_teller(website)

# this serves two purposes:
# 1) ensure all platform classes are created (and thus added to platform_classes)
# 2) keep the platform modules around to be added to the context below
platform_modules = {platform: import_module("gittip.elsewhere.%s" % platform)
for platform in platform_classes}

# The homepage wants expensive queries. Let's periodically select into an
# intermediate table.

Expand Down Expand Up @@ -124,7 +116,6 @@ def log_busy_threads():

def add_stuff_to_context(request):
request.context['username'] = None
request.context.update(platform_modules)

def scab_body_onto_response(response):

Expand Down
13 changes: 8 additions & 5 deletions defaults.env
Original file line number Diff line number Diff line change
Expand Up @@ -16,6 +16,10 @@ STRIPE_PUBLISHABLE_API_KEY=1

BALANCED_API_SECRET=90bb3648ca0a11e1a977026ba7e239a9

DEBUG=1 # Used by oauthlib to bypass security checks. We need it because when
# running locally the OAuth callbacks are http:, not https:. Of course
# DEBUG shouldn't be set in production.

GITHUB_CLIENT_ID=3785a9ac30df99feeef5
GITHUB_CLIENT_SECRET=e69825fafa163a0b0b6d2424c107a49333d46985
GITHUB_CALLBACK=http://127.0.0.1:8537/on/github/associate
Expand All @@ -26,23 +30,22 @@ BITBUCKET_CALLBACK=http://127.0.0.1:8537/on/bitbucket/associate

TWITTER_CONSUMER_KEY=QBB9vEhxO4DFiieRF68zTA
TWITTER_CONSUMER_SECRET=mUymh1hVMiQdMQbduQFYRi79EYYVeOZGrhj27H59H78
TWITTER_ACCESS_TOKEN=34175404-G6W8Hh19GWuUhIMEXK0LyZsy7N9aCMcy1bYJ9rI
TWITTER_ACCESS_TOKEN_SECRET=K6wxV1OCsihZAkEPkWtoLYDiRJnWajBBWn4UgliTRQ
TWITTER_CALLBACK=http://127.0.0.1:8537/on/twitter/associate

BOUNTYSOURCE_API_SECRET=e2BbqjNY60kC7V-Uq1dv2oHgGavbWm9pUJmiRHCApFZHDiY9aZyAspInhZaZ94x9
BOUNTYSOURCE_API_HOST=https://staging-qa.bountysource.com
BOUNTYSOURCE_WWW_HOST=https://staging.bountysource.com
BOUNTYSOURCE_CALLBACK=http://127.0.0.1:8537/on/bountysource/associate
BOUNTYSOURCE_API_HOST=https://staging-api.bountysource.com
BOUNTYSOURCE_WWW_HOST=https://staging.bountysource.com

VENMO_CLIENT_ID=1534
VENMO_CLIENT_SECRET=55ckgsguYC3cj7xWW5c95PHvUzrwgZMA
VENMO_CALLBACK=http://127.0.0.1:8537/on/venmo/associate

OPENSTREETMAP_API=http://master.apis.dev.openstreetmap.org
OPENSTREETMAP_CONSUMER_KEY=J2SS5GM0A7tM1CIBjAHXUTMeCEkRBMYsTJzGONxe
OPENSTREETMAP_CONSUMER_SECRET=hgvZkbtWVOEoaJV5AzQPcBI9m8f7BylkpT0cP7wS
OPENSTREETMAP_CALLBACK=http://127.0.0.1:8537/on/openstreetmap/associate
OPENSTREETMAP_API_URL=http://master.apis.dev.openstreetmap.org/api/0.6
OPENSTREETMAP_AUTH_URL=http://master.apis.dev.openstreetmap.org

NANSWERS_THRESHOLD=2

Expand Down
1 change: 0 additions & 1 deletion gittip/billing/__init__.py
Original file line number Diff line number Diff line change
Expand Up @@ -19,7 +19,6 @@
from __future__ import unicode_literals
from urllib import quote

import gittip
import balanced
import stripe
from aspen.utils import typecheck
Expand Down
4 changes: 2 additions & 2 deletions gittip/billing/steady_state.py
Original file line number Diff line number Diff line change
Expand Up @@ -42,12 +42,12 @@ def converge(payouts, epsilon = 1e-10, max_rounds = 100):
Converges to the steady state.
"""
if not issparse(payouts):
raise ArgumentError("Please provide a sparse matrix")
raise ValueError("Please provide a sparse matrix")

(n_rows, n_cols) = payouts.shape

if n_rows != n_cols:
raise ArgumentError("The payout matrix must be square")
raise ValueError("The payout matrix must be square")

payouts_d = lil_matrix((n_rows, n_cols))
payouts_d.setdiag(payouts.diagonal())
Expand Down
Loading

0 comments on commit 7290e0d

Please sign in to comment.