From 95ef1fce28232aa6a213a09bd0854071e04f9473 Mon Sep 17 00:00:00 2001 From: "Bradley M. Kuhn" Date: Wed, 30 Dec 2015 03:10:07 -0800 Subject: [PATCH] Change table to donor; add is_supporter field. Up until now, this software has been focused on just Supporters, but really there is no reason this should not be a general donor database. Therefore, don't use the name supporter in the database, and add a field. public_ack is now allowed to be NULL, because the idea being we don't have an answer from all who donate whether or not they want public acknowledgment. the is_supporter boolean is added to record whether or not they came through the supporter program. --- Supporters/lib/Supporters.pm | 53 ++++++++++++++++++------------------ Supporters/t/Supporters.t | 10 +++---- sql/supporters-schema.sql | 34 +++++++++++------------ 3 files changed, 49 insertions(+), 48 deletions(-) diff --git a/Supporters/lib/Supporters.pm b/Supporters/lib/Supporters.pm index 9db9f47..2c5a866 100644 --- a/Supporters/lib/Supporters.pm +++ b/Supporters/lib/Supporters.pm @@ -113,8 +113,9 @@ sub addSupporter ($$) { } $self->_beginWork; my $sth = $self->dbh->prepare( - "INSERT INTO supporter(ledger_entity_id, display_name, public_ack)" . - " values(?, ?, ?)"); + "INSERT INTO donor(ledger_entity_id, display_name, public_ack, is_supporter)" . + " values(?, ?, ?, " . + $self->dbh->quote(1, 'SQL_BOOLEAN') . ')'); $sth->execute($sp->{ledger_entity_id}, $sp->{display_name}, $sp->{public_ack}); my $id = $self->dbh->last_insert_id("","","",""); @@ -218,9 +219,9 @@ sub addEmailAddress($$$$) { my $addressId = $self->dbh->last_insert_id("","","",""); $sth->finish(); - $sth = $self->dbh->prepare("INSERT INTO supporter_email_address_mapping" . - "(supporter_id, email_address_id) " . - "VALUES( ?, ?)"); + $sth = $self->dbh->prepare("INSERT INTO donor_email_address_mapping" . + "(donor_id, email_address_id) " . + "VALUES( ?, ?)"); $sth->execute($id, $addressId); $sth->finish(); @@ -263,9 +264,9 @@ sub setPreferredEmailAddress($$$) { unless Mail::RFC822::Address::valid($emailAddress); my $ems = $self->dbh()->selectall_hashref("SELECT ea.email_address, ea.id, sem.preferred " . - "FROM email_address ea, supporter_email_address_mapping sem " . + "FROM email_address ea, donor_email_address_mapping sem " . "WHERE ea.id = sem.email_address_id AND ". - "sem.supporter_id = " . $self->dbh->quote($supporterId, 'SQL_INTEGER'), + "sem.donor_id = " . $self->dbh->quote($supporterId, 'SQL_INTEGER'), 'email_address'); # Shortcut: it was already set return $ems->{$emailAddress}{id} if (defined $ems->{$emailAddress} and $ems->{$emailAddress}{preferred}); @@ -281,11 +282,11 @@ sub setPreferredEmailAddress($$$) { $self->_beginWork(); if ($anotherPreferred) { - $self->dbh->do("UPDATE supporter_email_address_mapping " . + $self->dbh->do("UPDATE donor_email_address_mapping " . "SET preferred = " . $self->dbh->quote(0, 'SQL_BOOLEAN') . " " . - "WHERE supporter_id = " . $self->dbh->quote($supporterId, 'SQL_INTEGER')); + "WHERE donor_id = " . $self->dbh->quote($supporterId, 'SQL_INTEGER')); } - $self->dbh->do("UPDATE supporter_email_address_mapping " . + $self->dbh->do("UPDATE donor_email_address_mapping " . "SET preferred = " . $self->dbh->quote(1, 'SQL_BOOLEAN') . " " . "WHERE email_address_id = " . $self->dbh->quote($emailAddressId, 'SQL_INTEGER')); $self->_commit; @@ -322,9 +323,9 @@ sub getPreferredEmailAddress($$) { die "setPreferredEmailAddress: invalid supporter id, $supporterId" unless $self->_verifyId($supporterId); - my $ems = $self->dbh()->selectall_hashref("SELECT email_address FROM email_address em, supporter_email_address_mapping sem " . + my $ems = $self->dbh()->selectall_hashref("SELECT email_address FROM email_address em, donor_email_address_mapping sem " . "WHERE preferred AND sem.email_address_id = em.id AND " . - "sem.supporter_id = " . $self->dbh->quote($supporterId, 'SQL_INTEGER'), + "sem.donor_id = " . $self->dbh->quote($supporterId, 'SQL_INTEGER'), 'email_address'); my $rowCount = scalar keys %{$ems}; die "setPreferredEmailAddress: DATABASE INTEGRITY ERROR: more than one email address is preferred for supporter, \"$supporterId\"" @@ -391,9 +392,9 @@ sub addPostalAddress($$$$) { my $addressId = $self->dbh->last_insert_id("","","",""); $sth->finish(); - $sth = $self->dbh->prepare("INSERT INTO supporter_postal_address_mapping" . - "(supporter_id, postal_address_id) " . - "VALUES( ?, ?)"); + $sth = $self->dbh->prepare("INSERT INTO donor_postal_address_mapping" . + "(donor_id, postal_address_id) " . + "VALUES( ?, ?)"); $sth->execute($id, $addressId); $sth->finish(); @@ -567,7 +568,7 @@ Arguments: =item $supporterId - Valid supporter_id number currently in the database. die() will occur if + Valid donor_id number currently in the database. die() will occur if the id number is not in the database already as a supporter id. =item $requestType @@ -654,7 +655,7 @@ sub getRequest($$;$) { my $req = $self->dbh()->selectall_hashref("SELECT r.id, r.request_type_id, r.request_configuration_id, r.date_requested, r.notes, rt.type " . "FROM request r, request_type rt WHERE r.request_type_id = rt.id AND " . - "r.supporter_id = " . $self->dbh->quote($supporterId, 'SQL_INTEGER') . + "r.donor_id = " . $self->dbh->quote($supporterId, 'SQL_INTEGER') . " AND rt.type = " . $self->dbh->quote($requestType), 'type'); return undef unless (defined $req and defined $req->{$requestType} and defined $req->{$requestType}{'id'}); @@ -701,7 +702,7 @@ A hash reference, the following keys are considered: =item supporterId - Valid supporter_id number currently in the database. die() will occur if + Valid donor_id number currently in the database. die() will occur if the id number is not in the database already as a supporter id. =item requestTypeId @@ -761,7 +762,7 @@ sub addRequest($$) { # $params->{requestConfigurationId} can be undef, which is permitted in the # database schema. - my $sth = $self->dbh->prepare("INSERT INTO request(supporter_id, request_type_id, request_configuration_id, notes, date_requested) " . + my $sth = $self->dbh->prepare("INSERT INTO request(donor_id, request_type_id, request_configuration_id, notes, date_requested) " . "VALUES(?, ?, ?, ?, date('now'))"); $sth->execute($supporterId, $params->{requestTypeId}, $params->{requestConfigurationId}, $params->{notes}); my $id = $self->dbh->last_insert_id("","","",""); @@ -784,7 +785,7 @@ A hash reference, the following keys are considered: =item supporterId - Valid supporter_id number currently in the database. die() will occur if + Valid donor_id number currently in the database. die() will occur if the id number is not in the database already as a supporter id. =item requestType @@ -903,7 +904,7 @@ sub _verifyId($$) { die "_verifyId() called with a non-numeric id" unless defined $id and looks_like_number($id); - my $val = $self->dbh()->selectall_hashref("SELECT id FROM supporter WHERE id = " . + my $val = $self->dbh()->selectall_hashref("SELECT id FROM donor WHERE id = " . $self->dbh->quote($id, 'SQL_INTEGER'), 'id'); return (defined $val and defined $val->{$id}); @@ -1152,8 +1153,8 @@ License: AGPLv3-or-later sub Supporter_FullLookupUsingId($$) { my($dbh, $id) = @_; - my $sth = $dbh->prepare('SELECT m.supporter_id ' . - 'FROM email_address e, supporter_email_address_mapping m ' . + my $sth = $dbh->prepare('SELECT m.donor_id ' . + 'FROM email_address e, donor_email_address_mapping m ' . 'WHERE e.email_address = ? and e.id = m.email_address_id'); $sth->execute($email); } @@ -1161,14 +1162,14 @@ License: AGPLv3-or-later sub Supporter_LookupByEmail($$) { my($dbh, $email) = @_; - my $sth = $dbh->prepare('SELECT m.supporter_id ' . - 'FROM email_address e, supporter_email_address_mapping m ' . + my $sth = $dbh->prepare('SELECT m.donor_id ' . + 'FROM email_address e, donor_email_address_mapping m ' . 'WHERE e.email_address = ? and e.id = m.email_address_id'); $sth->execute($email); my $supporter = $sth->fetchrow_hashref(); if (defined $supporter) { - return Supporter_FullLookupUsingId($dbh, $supporter->{'m.supporter_id'}); + return Supporter_FullLookupUsingId($dbh, $supporter->{'m.donor_id'}); } else { return undef; } diff --git a/Supporters/t/Supporters.t b/Supporters/t/Supporters.t index 2967996..f7fb751 100644 --- a/Supporters/t/Supporters.t +++ b/Supporters/t/Supporters.t @@ -92,10 +92,10 @@ lives_ok { $olsonId = $sp->addSupporter({ display_name => "Peggy Olson", ok( (looks_like_number($olsonId) and $olsonId > $drapperId), "addSupporter: add succeeded with email address added."); -my $val = $sp->dbh()->selectall_hashref("SELECT supporter_id, email_address_id " . - "FROM supporter_email_address_mapping " . - "WHERE supporter_id = " . $sp->dbh->quote($olsonId, 'SQL_INTEGER'), - 'supporter_id'); +my $val = $sp->dbh()->selectall_hashref("SELECT donor_id, email_address_id " . + "FROM donor_email_address_mapping " . + "WHERE donor_id = " . $sp->dbh->quote($olsonId, 'SQL_INTEGER'), + 'donor_id'); ok((defined $val and defined $val->{$olsonId}{email_address_id} and $val->{$olsonId}{email_address_id} > 0), "addSuporter: email address mapping is created on addSupporter() w/ email address included"); @@ -629,7 +629,7 @@ dies_ok { $tempSP->addSupporter({ display_name => "Roger Sterling", $tempDBH->disconnect; $tempDBH = reopen_test_dbh(); -$val = $tempDBH->selectall_hashref("SELECT id FROM supporter;", 'id'); +$val = $tempDBH->selectall_hashref("SELECT id FROM donor;", 'id'); ok( (defined $val and reftype $val eq "HASH" and keys(%{$val}) == 0), "addSupporter: fails if email_address given but email cannot be inserted"); diff --git a/sql/supporters-schema.sql b/sql/supporters-schema.sql index 27960a4..2b320a6 100644 --- a/sql/supporters-schema.sql +++ b/sql/supporters-schema.sql @@ -1,19 +1,20 @@ -- Conservancy Supporter Database, Version 0.2 -DROP TABLE IF EXISTS "supporter"; +DROP TABLE IF EXISTS "donor"; -CREATE TABLE "supporter" ( +CREATE TABLE "donor" ( "id" integer NOT NULL PRIMARY KEY, "ledger_entity_id" varchar(300) NOT NULL UNIQUE, "display_name" varchar(300), - "public_ack" bool NOT NULL + "public_ack" bool, + "is_supporter" bool NOT NULL ); DROP TABLE IF EXISTS "request"; CREATE TABLE "request" ( "id" integer NOT NULL PRIMARY KEY, - "supporter_id" integer NOT NULL, + "donor_id" integer NOT NULL, "request_type_id" integer NOT NULL, "request_configuration_id" integer, "date_requested" date NOT NULL, @@ -21,8 +22,8 @@ CREATE TABLE "request" ( "notes" TEXT ); -CREATE UNIQUE INDEX request__one_request_for_each_type_per_supporter - ON request(supporter_id, request_type_id); +CREATE UNIQUE INDEX request__one_request_for_each_type_per_donor + ON request(donor_id, request_type_id); DROP TABLE IF EXISTS "request_configuration"; @@ -63,13 +64,13 @@ CREATE TABLE "email_address" ( "date_encountered" date NOT NULL ); -DROP TABLE IF EXISTS "supporter_email_address_mapping"; +DROP TABLE IF EXISTS "donor_email_address_mapping"; -CREATE TABLE "supporter_email_address_mapping" ( - "supporter_id" integer NOT NULL, +CREATE TABLE "donor_email_address_mapping" ( + "donor_id" integer NOT NULL, "email_address_id" integer NOT NULL, "preferred" bool, - PRIMARY KEY(supporter_id, email_address_id) + PRIMARY KEY(donor_id, email_address_id) ); DROP TABLE IF EXISTS "address_type"; @@ -88,15 +89,14 @@ CREATE TABLE "postal_address" ( "date_encountered" date NOT NULL ); -DROP TABLE IF EXISTS "supporter_postal_address_mapping"; +DROP TABLE IF EXISTS "donor_postal_address_mapping"; -CREATE TABLE "supporter_postal_address_mapping" ( - "supporter_id" integer NOT NULL, +CREATE TABLE "donor_postal_address_mapping" ( + "donor_id" integer NOT NULL, "postal_address_id" integer NOT NULL, "preferred" bool, - PRIMARY KEY(supporter_id, postal_address_id) + PRIMARY KEY(donor_id, postal_address_id) ); -CREATE UNIQUE INDEX supporter_postal_address_mapping_single_prefferred_per_supporter - ON supporter_postal_address_mapping(supporter_id, preferred); - +CREATE UNIQUE INDEX donor_postal_address_mapping_single_prefferred_per_donor + ON donor_postal_address_mapping(donor_id, preferred);