structure.sql 7.3 KB

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