This repository has been archived on 2024-07-18. You can view files and clone it, but cannot push or open issues or pull requests.
lwb6/legacyworlds-server/legacyworlds-server-data/db-structure/parts/functions/035-users-view.sql

85 lines
No EOL
2.7 KiB
SQL

-- LegacyWorlds Beta 6
-- PostgreSQL database scripts
--
-- General account view
--
-- Copyright(C) 2004-2010, DeepClone Development
-- --------------------------------------------------------
--
-- General account view
--
-- Allows most account-related data to be loooked up, and computes account statuses.
--
CREATE VIEW users.accounts_view
AS SELECT addr.id AS id , addr.address AS address , lang.language AS language ,
cred.pass_md5 AS pass_md5 , cred.pass_sha1 AS pass_sha1 , cred.credits AS game_credits ,
( CASE ( ban.account_id IS NULL )
WHEN TRUE THEN
( CASE ( iacc.credentials_id IS NULL )
WHEN TRUE THEN
( CASE ( aacc.credentials_id IS NULL )
WHEN TRUE THEN
'UNCONFIRMED'
ELSE
( CASE ( vac.status IS NULL )
WHEN TRUE THEN
'ACTIVE'
ELSE
( CASE vac.status
WHEN 'PROCESSED' THEN
'VACATION'
ELSE
'START_VACATION'
END )
END )
END )
ELSE
( CASE ( aacc.credentials_id IS NULL )
WHEN TRUE THEN
( CASE ( vkey.credentials_id IS NULL )
WHEN TRUE THEN
'DISABLED'
ELSE
'REACTIVATING'
END )
ELSE
'QUITTING'
END )
END )
ELSE
'BANNED'
END ) AS status ,
vkey.token AS validation_token , prr.token AS pwd_recovery_token ,
acr.token AS address_change_token , naddr.address AS new_address ,
aacc.vacation_credits AS vacation_credits ,
floor( aacc.vacation_credits / sys.get_constant( 'vacation.cost' ) ) AS vacation_time,
vac.since AS vacation_start ,
iacc.since AS inactivity_begin , ires.reason AS inactivity_reason ,
ban.ban_id AS ban_request_id
FROM users.addresses addr
INNER JOIN users.credentials cred
ON cred.address_id = addr.id
INNER JOIN defs.languages lang
ON lang.id = cred.language_id
LEFT OUTER JOIN users.validation_keys vkey
ON vkey.credentials_id = cred.address_id
LEFT OUTER JOIN users.pwd_recovery_requests prr
ON prr.credentials_id = cred.address_id AND NOT prr.used
LEFT OUTER JOIN users.address_change_requests acr
ON acr.credentials_id = cred.address_id AND NOT acr.used
LEFT OUTER JOIN users.addresses naddr
ON naddr.id = acr.address_id
LEFT OUTER JOIN users.active_accounts aacc
ON aacc.credentials_id = cred.address_id
LEFT OUTER JOIN users.vacations AS vac
ON vac.account_id = aacc.credentials_id
LEFT OUTER JOIN users.inactive_accounts AS iacc
ON iacc.credentials_id = cred.address_id
LEFT OUTER JOIN users.reasons AS ires
ON ires.account_id = iacc.credentials_id
LEFT OUTER JOIN users.bans AS ban
ON ban.account_id = iacc.credentials_id;
GRANT SELECT ON users.accounts_view TO :dbuser;