structure.sql 3.3 KB

12345678910111213141516171819202122232425262728293031323334353637383940414243444546474849505152535455565758596061626364656667686970717273
  1. -- Database Structure For ohUrlShortener
  2. CREATE DATABASE oh_url_shortener ENCODING 'UTF8';
  3. -- Connect to database repostats
  4. \c oh_url_shortener
  5. CREATE TABLE public.short_urls (
  6. id serial4 NOT NULL,
  7. short_url varchar(200) NOT NULL,
  8. dest_url text NOT NULL,
  9. created_at timestamp with time zone NOT NULL DEFAULT now(),
  10. is_valid bool NOT NULL DEFAULT true,
  11. memo text,
  12. CONSTRAINT short_urls_pk PRIMARY KEY (id),
  13. CONSTRAINT short_urls_un UNIQUE (short_url)
  14. );
  15. CREATE TABLE public.access_logs (
  16. id serial4 NOT NULL,
  17. short_url varchar(200) NOT NULL,
  18. access_time timestamp with time zone NOT NULL DEFAULT NOW(),
  19. ip varchar(64) NULL,
  20. user_agent varchar(1000) NULL,
  21. CONSTRAINT access_logs_pk PRIMARY KEY (id)
  22. );
  23. CREATE INDEX access_logs_short_url_idx ON public.access_logs (short_url);
  24. CREATE INDEX access_logs_access_time_idx ON public.access_logs (access_time);
  25. CREATE INDEX access_logs_ip_idx ON public.access_logs (ip);
  26. CREATE INDEX access_logs_ua_idx ON public.access_logs (user_agent);
  27. CREATE TABLE public.users (
  28. id serial4 NOT NULL,
  29. account varchar(200) NOT NULL,
  30. password text NOT NULL,
  31. CONSTRAINT users_pk PRIMARY KEY (id),
  32. CONSTRAINT users_account_un UNIQUE (account)
  33. );
  34. -- account: ohUrlShortener password: -2aDzm=0(ln_9^1
  35. INSERT INTO public.users (account, "password") VALUES('ohUrlShortener', 'EZ2zQjC3fqbkvtggy9p2YaJiLwx1kKPTJxvqVzowtx6t');
  36. CREATE VIEW public.url_ip_count_stats AS
  37. SELECT
  38. u.short_url AS short_url,
  39. (SELECT count(ip) FROM public.access_logs WHERE date(ACCESS_TIME) = date(NOW()) AND short_url = u.short_url) AS today_count,
  40. (SELECT count(ip) FROM public.access_logs WHERE date(ACCESS_TIME) = (NOW() - INTERVAL '1 day')::date AND short_url = u.short_url) AS yesterday_count,
  41. (SELECT count(ip) FROM public.access_logs WHERE date(ACCESS_TIME) = (NOW() - INTERVAL '7 day')::date AND short_url = u.short_url) AS last_7_days_count,
  42. (SELECT count(ip) FROM public.access_logs WHERE DATE_PART('month',access_time) = DATE_PART('month',NOW()) AND short_url = u.short_url) AS monthly_count,
  43. (SELECT count(ip) FROM public.access_logs WHERE short_url = u.short_url) AS total_count,
  44. (SELECT count(DISTINCT(ip)) FROM public.access_logs WHERE date(ACCESS_TIME) = date(NOW()) AND short_url = u.short_url) AS d_today_count,
  45. (SELECT count(DISTINCT(ip)) FROM public.access_logs WHERE date(ACCESS_TIME) = (NOW() - INTERVAL '1 day')::date AND short_url = u.short_url) AS d_yesterday_count,
  46. (SELECT count(DISTINCT(ip)) FROM public.access_logs WHERE date(ACCESS_TIME) = (NOW() - INTERVAL '7 day')::date AND short_url = u.short_url) AS d_last_7_days_count,
  47. (SELECT count(DISTINCT(ip)) FROM public.access_logs WHERE DATE_PART('month',access_time) = DATE_PART('month',NOW()) AND short_url = u.short_url) AS d_monthly_count,
  48. (SELECT count(DISTINCT(ip)) FROM public.access_logs WHERE short_url = u.short_url) AS d_total_count
  49. FROM public.short_urls u
  50. LEFT JOIN public.access_logs l ON u.short_url = l.short_url
  51. GROUP BY u.short_url;
  52. CREATE VIEW public.sum_url_ip_count_stats AS
  53. SELECT
  54. COUNT(l.ip) AS today_count,
  55. COUNT(DISTINCT(l.ip)) AS d_today_count
  56. FROM public.access_logs l
  57. WHERE date(l.access_time) = date(NOW());
  58. CREATE VIEW public.total_count_top25 AS
  59. SELECT s.*, u.id,u.dest_url,u.created_at,u.is_valid,u.memo
  60. FROM public.url_ip_count_stats s, public.short_urls u
  61. WHERE u.short_url = s.short_url
  62. ORDER BY s.today_count DESC
  63. LIMIT 25;