structure.sql 7.0 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137138139140141142143144145146147148149150151152153154155156157158159160161162163164165166167168169170171172173174175176177178
  1. -- Database Structure For ohUrlShortener
  2. CREATE DATABASE oh_url_shortener ENCODING 'UTF8';
  3. -- Connect to database oh_url_shortener
  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. -- Insert new data
  16. INSERT INTO public.short_urls(short_url, dest_url, created_at, is_valid, memo) VALUES
  17. ('AC7VgPE9', 'https://www.gitlink.org.cn/baladiwei/ohurlshortener', NOW(), true, '短链接系统 gitlink 页面'),
  18. ('AvTkHZP7', 'https://gitee.com/barat/ohurlshortener', NOW(), true, '短链接系统 gitee 页面'),
  19. ('gkT39tb5', 'https://github.com/barats/ohUrlShortener', NOW(), true, '短链接系统 github 页面');
  20. CREATE TABLE public.access_logs (
  21. id serial4 NOT NULL,
  22. short_url varchar(200) NOT NULL,
  23. access_time timestamp with time zone NOT NULL DEFAULT NOW(),
  24. ip varchar(64) NULL,
  25. user_agent varchar(1000) NULL,
  26. CONSTRAINT access_logs_pk PRIMARY KEY (id)
  27. );
  28. CREATE INDEX access_logs_short_url_idx ON public.access_logs (short_url);
  29. CREATE INDEX access_logs_access_time_idx ON public.access_logs (access_time);
  30. CREATE INDEX access_logs_ip_idx ON public.access_logs (ip);
  31. CREATE INDEX access_logs_ua_idx ON public.access_logs (user_agent);
  32. CREATE TABLE public.users (
  33. id serial4 NOT NULL,
  34. account varchar(200) NOT NULL,
  35. password text NOT NULL,
  36. CONSTRAINT users_pk PRIMARY KEY (id),
  37. CONSTRAINT users_account_un UNIQUE (account)
  38. );
  39. -- account: ohUrlShortener password: -2aDzm=0(ln_9^1
  40. INSERT INTO public.users (account, "password") VALUES('ohUrlShortener', 'EZ2zQjC3fqbkvtggy9p2YaJiLwx1kKPTJxvqVzowtx6t');
  41. -- Create table for top25 urls
  42. CREATE TABLE public.stats_top25 (
  43. id serial4 NOT NULL,
  44. short_url varchar(200) NOT NULL,
  45. today_count int8 NOT NULL DEFAULT 0,
  46. d_today_count int8 NOT NULL DEFAULT 0,
  47. stats_time timestamp with time zone NOT NULL DEFAULT NOW(),
  48. CONSTRAINT stats_tv_pk PRIMARY KEY (id)
  49. );
  50. -- Stored procedure for top25 urls
  51. CREATE FUNCTION p_stats_top25() RETURNS void AS $$
  52. BEGIN
  53. RAISE NOTICE 'Procedure p_stats_top25() called';
  54. -- delete all records
  55. DELETE FROM public.stats_top25 WHERE 1=1;
  56. -- insert fresh-new records
  57. INSERT INTO public.stats_top25(short_url,today_count,d_today_count,stats_time)
  58. SELECT l.short_url AS short_url, COUNT(l.ip) AS today_count ,COUNT(DISTINCT(l.ip)) AS d_today_count, NOW() AS stats_time
  59. FROM public.access_logs l WHERE date(l.access_time) = date(NOW()) GROUP BY l.short_url ORDER BY today_count DESC LIMIT 25;
  60. END;
  61. $$ LANGUAGE plpgsql;
  62. -- Create table for sum view
  63. CREATE TABLE public.stats_sum (
  64. stats_key varchar(200) NOT NULL,
  65. stats_value int8 NOT NULL DEFAULT 0,
  66. CONSTRAINT stats_sum_key PRIMARY KEY (stats_key)
  67. );
  68. -- Insert pre-defined stats
  69. INSERT INTO public.stats_sum (stats_key,stats_value) VALUES
  70. ('today_count',0), ('d_today_count',0),
  71. ('yesterday_count',0), ('d_yesterday_count',0),
  72. ('last_7_days_count',0), ('d_last_7_days_count',0),
  73. ('monthly_count',0), ('d_monthly_count',0);
  74. -- Stored procedure for stats sum view
  75. CREATE FUNCTION p_stats_sum() RETURNS void AS $$
  76. DECLARE
  77. today_count int8;
  78. d_today_count int8;
  79. yesterday_count int8;
  80. d_yesterday_count int8;
  81. last_7_days_count int8;
  82. d_last_7_days_count int8;
  83. monthly_count int8;
  84. d_monthly_count int8;
  85. BEGIN
  86. RAISE NOTICE 'Procedure p_stats_sum() called';
  87. SELECT COUNT(l.ip),COUNT(DISTINCT(l.ip)) INTO today_count,d_today_count
  88. FROM public.access_logs l WHERE date(l.access_time) = date(NOW());
  89. SELECT COUNT(l.ip),COUNT(DISTINCT(l.ip)) INTO yesterday_count,d_yesterday_count
  90. FROM public.access_logs l WHERE date(l.access_time) = (NOW() - INTERVAL '1 day')::date;
  91. SELECT COUNT(l.ip),COUNT(DISTINCT(l.ip)) INTO last_7_days_count,d_last_7_days_count
  92. FROM public.access_logs l WHERE date(l.access_time) >= (NOW() - INTERVAL '7 day')::date;
  93. SELECT COUNT(l.ip),COUNT(DISTINCT(l.ip)) INTO monthly_count,d_monthly_count
  94. FROM public.access_logs l WHERE DATE_PART('month', l.access_time) = DATE_PART('month',NOW());
  95. UPDATE public.stats_sum SET stats_value =
  96. CASE
  97. WHEN stats_key = 'today_count' THEN today_count
  98. WHEN stats_key = 'd_today_count' THEN d_today_count
  99. WHEN stats_key = 'yesterday_count' THEN yesterday_count
  100. WHEN stats_key = 'd_yesterday_count' THEN d_yesterday_count
  101. WHEN stats_key = 'last_7_days_count' THEN last_7_days_count
  102. WHEN stats_key = 'd_last_7_days_count' THEN d_last_7_days_count
  103. WHEN stats_key = 'monthly_count' THEN monthly_count
  104. WHEN stats_key = 'd_monthly_count' THEN d_monthly_count
  105. ELSE 0
  106. END;
  107. END;
  108. $$ LANGUAGE plpgsql;
  109. -- Create table for ip url sum
  110. CREATE TABLE public.stats_ip_sum (
  111. short_url varchar(200) NOT NULL,
  112. today_count int8 NOT NULL DEFAULT 0,
  113. d_today_count int8 NOT NULL DEFAULT 0,
  114. yesterday_count int8 NOT NULL DEFAULT 0,
  115. d_yesterday_count int8 NOT NULL DEFAULT 0,
  116. last_7_days_count int8 NOT NULL DEFAULT 0,
  117. d_last_7_days_count int8 NOT NULL DEFAULT 0,
  118. monthly_count int8 NOT NULL DEFAULT 0,
  119. d_monthly_count int8 NOT NULL DEFAULT 0,
  120. total_count int8 NOT NULL DEFAULT 0,
  121. d_total_count int8 NOT NULL DEFAULT 0,
  122. CONSTRAINT stats_ip_sum_pk PRIMARY KEY (short_url)
  123. );
  124. -- Stored procedure for ip url sum
  125. CREATE FUNCTION p_stats_ip_sum() RETURNS void AS $$
  126. BEGIN
  127. RAISE NOTICE 'Procedure p_stats_ip_sum() called';
  128. -- Delete all records
  129. DELETE FROM public.stats_ip_sum WHERE 1=1;
  130. -- Calculate new stats data
  131. INSERT INTO public.stats_ip_sum(short_url,today_count,d_today_count,yesterday_count,d_yesterday_count,last_7_days_count,d_last_7_days_count,
  132. monthly_count,d_monthly_count,total_count,d_total_count)
  133. SELECT
  134. u.short_url,
  135. (SELECT count(ip) FROM public.access_logs WHERE date(access_time) = date(NOW()) AND short_url = u.short_url),
  136. (SELECT count(DISTINCT(ip)) FROM public.access_logs WHERE date(access_time) = date(NOW()) AND short_url = u.short_url),
  137. (SELECT count(ip) FROM public.access_logs WHERE date(access_time) = (NOW() - INTERVAL '1 day')::date AND short_url = u.short_url),
  138. (SELECT count(DISTINCT(ip)) FROM public.access_logs WHERE date(access_time) = (NOW() - INTERVAL '1 day')::date AND short_url = u.short_url),
  139. (SELECT count(ip) FROM public.access_logs WHERE date(access_time) >= (NOW() - INTERVAL '7 day')::date AND short_url = u.short_url),
  140. (SELECT count(DISTINCT(ip)) FROM public.access_logs WHERE date(access_time) >= (NOW() - INTERVAL '7 day')::date AND short_url = u.short_url),
  141. (SELECT count(ip) FROM public.access_logs WHERE DATE_PART('month',access_time) = DATE_PART('month',NOW()) AND short_url = u.short_url),
  142. (SELECT count(DISTINCT(ip)) FROM public.access_logs WHERE DATE_PART('month',access_time) = DATE_PART('month',NOW()) AND short_url = u.short_url),
  143. (SELECT count(ip) FROM public.access_logs WHERE short_url = u.short_url),
  144. (SELECT count(DISTINCT(ip)) FROM public.access_logs WHERE short_url = u.short_url)
  145. FROM public.short_urls u
  146. LEFT JOIN public.access_logs l ON u.short_url = l.short_url
  147. GROUP BY u.short_url;
  148. END;
  149. $$ LANGUAGE plpgsql;